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.

Extracting First and Last Words

Written by Allen Wyatt (last updated September 21, 2019)
This tip applies to Excel 97, 2000, 2002, and 2003


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)

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

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.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Swapping Two Strings

Strings are used quite frequently in macros. You may want to swap the contents of two string variables, and you can do so ...

Discover More

Working with Elapsed Time

Work with times in a worksheet and you will eventually want to start working with elapsed times. Here's an explanation of ...

Discover More

Disappearing Ribbon Buttons

Excel allows you to configure your system, even to the point of adding macros to your ribbon area. What are you to do, ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (menu)

Finding the Smallest Even Value

When processing data in a worksheet, you may have a need to know what the smallest (lowest) even value in a range is. You ...

Discover More

Dealing with Circular References

Circular references occur when a formula includes a reference to the cell in which the formula appears. Here's how you ...

Discover More

Combining Cell Contents

Excel allows you to easily combine text together. The key is to understand and use the ampersand operator.

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 8 + 7?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


This Site

Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.