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 2016", then he needs a formula to extract "Reggie" and one to extract "2016".
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)
To extract the last word, you'll need a slightly different formula:
=TRIM(RIGHT(SUBSTITUTE(TRIM(A1)," ",REPT(" ",255)),255))
This formula changes the spaces into strings of 255 blanks. Then it finds the last 255 characters and trims the characters to the left, leaving the last word.
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)
If you prefer, you could bypass using the Split function and, instead, use some other string-related functions:
Function GetFirst(c As String) GetFirst = Left(c, InStr(c, " ") - 1) End Function
Function GetLast(c As String) GetFirst = Mid(c, InstrRev(c, " ") + 1) End Function
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (11985) applies to Microsoft Excel 2007, 2010, 2013, and 2016. You can find a version of this tip for the older menu interface of Excel here: Extracting First and Last Words.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
When analyzing data, you may need to distill groupings from that data. This tip examines how you can use formulas and ...
Discover MoreIf a series of cells contain the amount of money won by individuals, you may want to count the number of individuals who ...
Discover MoreWhen you store textual information in a worksheet, it can be helpful to figure out if that information follows a pattern ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-09-24 11:27:55
Peter Atherton
To all interested
Here is my macro to split names. It assumes that the names will be split accross three columns and the middle name or names are placed into the second column
Sub SplitNames()
Dim c As Range, MidNames As String
Dim x As Variant, i As Integer, n As Integer
For Each c In Selection
If Len(c) > 0 Then
x = Split(c, " ")
n = UBound(x) + 1
c.Offset(0, 1) = x(LBound(x))
c.Offset(0, 3) = x(UBound(x))
If n = 3 Then
MidNames = x(LBound(x) + 1)
c.Offset(0, 2) = MidNames
ElseIf n > 3 Then
For i = 1 To UBound(x) - 1
MidNames = MidNames & x(i) & " "
Next i
c.Offset(0, 2) = Trim(MidNames)
End If
MidNames = ""
End If
Next c
End Sub
Names such as du Pre have been entered du& Hard Space & Pre where hard space is entered as ALT + 0160
[{fig]}
2019-09-21 15:19:23
Frederick Rothstein
@Luis Pazeto,
I know this is a few years late, but there is a more compact formula available to find the last word in a piece of text...
=TRIM(RIGHT(SUBSTITUTE(A1," ",REPT(" ",99)),99))
The above assumes the text will have less than 99 characters in it... if the text could be longer, just replace the two 99's with a number guaranteed to be larger than length of the text plus maybe an additional 10% as a cushion.
2016-06-29 16:13:18
Balkee
Brilliant!
2016-06-27 08:21:50
Luis Pazeto
I used to apply this formula to get the last word in a string:
=RIGHT(REPLACE(A10," ","#",LEN(A10)-LEN(REPLACE(A10," ",""))),LEN(REPLACE(A10," ","#",LEN(A10)-LEN(REPLACE(A10," ",""))))-FIND("#",REPLACE(A10," ","#",LEN(A10)-LEN(REPLACE(A10," ","")))))
But the formula shared by Allan is much more simple!
2016-06-27 08:07:20
Luis Pazeto
@williamwclee
The number used can be any higher than the length of last word. But as this length can vary for word to word, 255 was used because a word hardly exceed this limit.
Sorry for my poor english.
2016-06-26 22:44:16
williamwclee
why 255 characters?
is it a max of characters that a cell can hold?
2016-06-26 08:06:38
Willy Vanhaelen
When I read this tip I first thought why not combine the FirstWord and LastWord macros by adding a second argument to indicate what you want. Then it came up to me that the second argument could be used to indicate not only the first or last but any word in the cell. Here it is:
Function GetWord(c As String, Optional x As Integer = 1)
Dim arr
arr = Split(Trim(c))
x = x - 1
If x = -1 Or x > UBound(arr) Then x = UBound(arr)
GetWord = arr(x)
End Function
You use GetWord like this (suposing A1 contains "first second last", without the quotes:
=GetWord(A1) --> first (if you omit the 2nd argument the default is 1)
=GetWord(A1,0) --> last
=GetWord(A1,1) --> first
=GetWord(A1,2) --> second
=GetWord(A1,3) --> last
=GetWord(A1,9) --> last
If the number of the 2nd argument is > than the number of words in the cell the last word is returned.
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2022 Sharon Parq Associates, Inc.
Comments