Loading
Excel.Tips.Net ExcelTips (Menu Interface)

Extracting First and Last Words

Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Extracting First and Last Words.

Reggie has a cell that contains three or more words. (The number of words could vary.) He needs a formula that allows him to extract either the first word of the cell or the last word of the cell. For instance, if the cell contains the phrase "Reggie was here in 2012", then he needs a formula to extract "Reggie" and one to extract "2012".

You can extract both words using formulas. Extracting the first word is relatively straightforward. All you need to do is find the location of the first space in the phrase, then extract whatever is to the left of it. If one presumes that the phrase is in A1, one can use the formula:

=LEFT(A1,FIND(" ",A1)-1)

In principle, to get the last word can be accomplished the same, it is just more complicated to find the last space in the string. A way to do this is to:

  1. Count the number of spaces
  2. Change the last space to a different character (which is not elsewhere in the phrase)
  3. Then find that "different character"
  4. Take the portion of the phrase to the right of that "different character"

The "different character" one can use is the first ASCII character (i.e., char(1)), which is non-printing and very unlikely to be in the phrase. The number of spaces can be found by taking the difference between the length of the phrase with the length of the phrase with no spaces (by using SUBSTITUTE to replace all spaces with the null string):

LEN(A1)-LEN(SUBSTITUTE(A1," ",""))

Then you can substitute char(1) for the last occurrence of the space:

SUBSTITUTE(A1," ",CHAR(1),LEN(A1)-LEN(SUBSTITUTE(A1," ","")))

You can then FIND the location of char(1) in that string:

FIND(CHAR(1),SUBSTITUTE(A1," ",CHAR(1),LEN(A1)-
LEN(SUBSTITUTE(A1," ",""))))

The first character of the last word is 1 character past this:

1+ FIND(CHAR(1),SUBSTITUTE(A1," ",CHAR(1),LEN(A1)-
LEN(SUBSTITUTE(A1," ",""))))

You can then use the MID function to extract the part of the string starting at this location until the end of the string. (You don't have to calculate the exact length. If you pick a number larger than the length of the last word, only the last word will be chosen. Thus, you can start at the location above and extract the number of characters in the string to ensure you have enough.):

=MID(A1,1+FIND(CHAR(1),SUBSTITUTE(A1," ",CHAR(1),
LEN(A1)-LEN(SUBSTITUTE(A1," ","")))),LEN(A1))

You can also, if you prefer, create user-defined functions to grab the words you want. Grabbing the first word is easy:

Function FirstWord(c As String)
    Dim arr

    arr = Split(Trim(c), " ")
    FirstWord = arr(LBound(arr))
End Function

The function uses the Split function to pull apart whatever is in the specified cell, using the second parameter (" ") as the delimiter. Each element in the array (arr) then contains a portion of the original string. In this case what is being returned is the first element (specified by LBound) of the array—the first word.

Since the words from the phrase are being placed in an array, you can use just a slight variation on the function to return the last word:

Function LastWord(c As String)
    Dim arr

    arr = Split(Trim(c), " ")
    LastWord = arr(UBound(arr))
End Function

Note that, essentially, the only real change in the function is the use of UBound instead of LBound. The UBound function specifies the last element of the array. You can use both of these functions in a worksheet in this manner:

=FirstWord(A1)
=LastWord(A1)

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11984) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Extracting First and Last Words.

Related Tips:

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

 

Leave your own comment:

*Name:
Email:
  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*Text:
*What is 5+3 (To prevent automated submissions and spam.)
 
 
           Commenting Terms

Comments for this tip:

Michael (Micky) Avidan    19 Sep 2015, 05:26
@Dean,
"^his son" are TWO(!) words - not one.
Please rephrase your request and give 1-2 more examples.
----------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL
Dean    18 Sep 2015, 22:49
I would like to know if there's an MS Excel formula, that will allow me to extract one word to the right of a delimiter character "^".

Example:
John Doe and ^his son to see the movies, but it was to late.

Results
^his son

Please note, I would like to keep the delimited value with the identified word.

Thanks
Willy Vanhaelen    09 Sep 2014, 11:45
Of course the formulas has to start with =
Willy Vanhaelen    09 Sep 2014, 11:36
Micky's solution is very clever indeed but I prefer a user defined function because it is much easier to enter especially when you use it often.

Here is a tiny UDF that does it all:

Function nthWord(S As String, X As Integer) As String
    nthWord = Split(S, " ")(X - 1)
End Function

You use it in this manner:

nthWord(A1,1) to get the first word
nthWord(A1,2) to get the second word
etc...
Barry    07 Sep 2014, 07:22
Well done Micky for a clever and elegant solution.

It shows that that there are many ways the skin a problem, and a what a bit of lateral thinking can do.

The limitation of course is that the last word must be less than 255 characters in length. But as very few if any "real" words are this long I don't think it is a real problem.
Michael (Micky) Avidan    06 Sep 2014, 06:36
@Neil,
To my opinion it has nothing to do with "programmer's perspective".
I can show you 1,000(!) times more complicated Array formulas that has also nothing to do with the term "Programmer".
Programming relates to writing VBA Codes.
I'm fully aware of what my suggested formula do and every Excel "novice" should "break", the formula, apart and examine its parts - nothing more.
...and yes - it should and can be considered as simple
Neil Parker    05 Sep 2014, 14:01
Michael, your solution works but is not 'simple' or intuitive from a non-programmer's perspective.

The formula replaces every space in the trimmed original string with 255 spaces, then trims the rightmost 255 characters of the result.
Michael Avidan    04 Aug 2012, 05:58
To get the last(!) word is not so complicated as it was presented in the above tip.

It can be accomplished very easily with a very short & simple formula:

=TRIM(RIGHT(SUBSTITUTE(TRIM(A1)," ",REPT(" ",255)),255))

Michael Avidan
“Microsoft®” MVP – Excel
 
 

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us

 

Advertise with Us

Our Privacy Policy

Our Sites

Tips.Net

Beauty and Style

Cars

Cleaning

Cooking

DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)

Gardening

Health

Home Improvement

Money and Finances

Organizing

Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives

 

Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.