Manik has a worksheet that, in column A, has text values in the format "mikeDAVIS", where the person's first name is in lowercase and the last name is in uppercase. He would like to split the names to two separate columns, according to the case of the text.
This can be accomplished using either a formula or a macro. Regardless of which approach you use, the key is to figure out where the text switches from lower- to uppercase. This can only be done by examining each character in the string. So, if you want to use a formulaic approach, then you'll need to use an array formula. The following array formula returns the last name of whatever is in cell A1:
=MID(A1,MATCH(1,(CODE(MID(A1,ROW($1:$255),1))>=65) *(CODE(MID(A1,ROW($2:$255),1))<90),)+1,255)
Remember, since this is an array formula, you should enter it by pressing Ctrl+Shift+Enter. It returns everything in the cell starting with the first uppercase letter it finds. Thus, in "mikeDAVIS" it would return "DAVIS" and in "mikeDavis" it would return "Davis". Assuming that you use the array formula in cell B1, you could then determine the first name by using the following:
=SUBSTITUTE(A1,B1,"")
This is a regular formula, not an array formula.
There are many similar array formulas that can accomplish much the same task. For example, this array formula will return the first name (all the characters up to the first uppercase character) of whatever is in cell A1:
=LEFT(A1,MAX((CODE(MID(A$1,ROW(INDIRECT("1:"& LEN(A1))),1))>96)*ROW(INDIRECT("1:"&LEN(A1)))))
You can then use the same regular formula (the one that uses the SUBSTITUTE function) to derive the last name.
If you want to use a macro approach to finding the names, all you need to do is come up with a formula that will return the location of the first capital letter in the text. The following code returns this "change point" in the text:
Function GetFirstUpper(MyCell As Range) As Integer Dim sCellValue As String Dim i As Integer sCellValue = Trim(MyCell.Value) i = 1 Do While (Asc(Mid(sCellValue, i, 1)) > 90 _ Or Asc(Mid(sCellValue, i, 1)) < 65) _ And i < Len(sCellValue) + 1 i = i + 1 Loop If i > Len(sCellValue) Then GetFirstUpper = 99 Else GetFirstUpper = i End If End Function
To use the function, let's assume that the name is in cell A1. You could find the first and last names using these formulas in your worksheet:
=LEFT(A1,GetFirstUpper(A1)-1) =MID(A1,GetFirstUpper(A1),LEN(TRIM(A1))-GetFirstUpper(A1)+1)
If you prefer your macro to return the actual names, you could use the following one to return everything before the first capital letter:
Function GetFirstName(MyCell As Range) As String Dim sCellValue As String Dim i As Integer sCellValue = Trim(MyCell.Value) i = 1 Do While (Asc(Mid(sCellValue, i, 1)) > 90 _ Or Asc(Mid(sCellValue, i, 1)) < 65) _ And i < Len(sCellValue) + 1 i = i + 1 Loop If i > Len(sCellValue) Then GetFirstName = sCellValue Else GetFirstName = Left(sCellValue, i - 1) End If End Function
To use the macro, all you need to do is use the following in a worksheet cell. (This assumes that the text string to be evaluated is in cell A1.)
=GetFirstName(A1)
A minor variation on the macro will allow you to similarly fetch the last name, which is assumed to be everything starting with the first capital letter encountered.
Function GetLastName(MyCell As Range) As String Dim sCellValue As String Dim i As Integer sCellValue = Trim(MyCell.Value) i = 1 Do While (Asc(Mid(sCellValue, i, 1)) > 90 _ Or Asc(Mid(sCellValue, i, 1)) < 65) _ And i < Len(sCellValue) + 1 i = i + 1 Loop If i > Len(sCellValue) Then GetLastName = sCellValue Else GetLastName = Mid(sCellValue, i) End If End Function
If you prefer, you could combine the macros into a single function that would, based upon what you specify, return either the first or last name:
Function GetName(MyCell As Range, sWanted As String) As String Dim sCellValue As String Dim i As Integer sCellValue = Trim(MyCell.Value) i = 1 Do While (Asc(Mid(sCellValue, i, 1)) > 90 _ Or Asc(Mid(sCellValue, i, 1)) < 65) _ And i < Len(sCellValue) + 1 i = i + 1 Loop If i > Len(sCellValue) Then GetName = sCellValue Else If LCase(sWanted) = "first" Then GetName = Left(sCellValue, i - 1) Else GetName = Mid(sCellValue, i) End If End If End Function
To use this combined function, you simply need to specify which name you want:
=GetName(A1, "First")
The word "First" passed as a parameter in this manner returns the first name (everything before the first capital letter). Any other string passed as the second parameter (such as "Last" or "xxx" or "Rest" or even "") results in the last name being returned.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9091) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365. You can find a version of this tip for the older menu interface of Excel here: Splitting Cells by Case.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!
At the heart of working with Excel is the process of creating formulas that calculate results based on information within ...
Discover MoreWhen working with text phrases stored in cells, it might be helpful to be able to extract words from the phrase. In this ...
Discover MoreNeed to know the directory (folder) in which a workbook was saved? You can create a formula that will return this ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2017-12-06 23:16:38
Ken Kast
I'm on an iPad so don't have Excel in front of me, but I think there is a very simple macro solution using regular expressions. I believe regular expressions can find the first and last name from a string xxxxXxxxxxx. I think the pattern ^[a-z]+ finds the first name and [A-Z][A-Za-z]* finds the last name. If there can be more variability in the structure of the names, then slightly more complex patterns may be needed.
2017-12-06 12:48:28
Kyle
Thanks Allen,
Within Excel (using the array formula) I successfully used the code to extract the last name, but the code to only return the first name is not working for me.
And I'm not sure where or what the issue is. Note that it does still return the full name as originally inputted.
Example in cell A1 is: MikeDavis --And it returns the exact same thing: MikeDavis.
I can't get it to only extract or display the first name.
Keep the tips coming.
Enjoy these.
Kyle
2017-03-14 11:51:48
Willy Vanhaelen
@Ra
It is not the "If X = LCase(X) Then Exit For" that generates an error but the line before that: X = Mid(cell, Len(cell) - i, 1).
At the first loop the start argument "Len(cell) - i" returns zero and this must be a positive number.
So the correct syntax is "X = Mid(cell, i, 1)".
But even with this correction your macro, although it will not crash anymore, will not work correctly because the loop will stop at the colon:
":" = LCase(":") returns True and Exit For is executed.
But this can be avoided by reversing the comparison:
instead of "If X = LCase(X) Then Exit For" you can use "If X <> UCase(X) Then Exit For".
The result is the same for letters but the loop doesn't stop at the colon.
So this version of the macro should do the job for you:
Sub tickers()
Dim cell As Range, i As Integer, X As String
'Range(Selection.Offset(0, 1)).Insert Shift:=xlToRight
For Each cell In Selection
For i = Len(cell) To 1 Step -1
X = Mid(cell, i, 1)
If X <> UCase(X) Then Exit For
Next i
cell.Offset(0, 1) = Mid(cell, i + 1)
Next cell
End Sub
2017-03-13 08:28:08
Ra
Hi,
First, congratulations on a very useful site for VBA beginners. "Tuning" your code for personal use, I cannot get rid of an error.
LtdCWN:ASX
LtdJIN:ASX
LtdSGR:ASX
LtdRXP:ASX
Want to find the first lowercase letter starting from the right, and then take all the text to the right of that character.As you can see, the position is not always the same.
Sub tickers()
Dim cell As Range, i As Integer, X As String
'Range(Selection.Offset(0, 1)).Insert Shift:=xlToRight
For Each cell In Selection
For i = Len(cell) To 1 Step -1
X = Mid(cell, Len(cell) - i, 1)
If X = LCase(X) Then Exit For
Next i
cell.Offset(0, 1) = Right(cell, i - 1)
Next cell
End Sub
This is the code, but "If X = LCase(X) Then Exit For" gives me an error. Any hint on this?
Thanks
2016-06-13 06:27:25
Christian
@Nabil
Just FIND() the comma in the cell and keep the left part of the text string.
2015-08-17 10:37:34
Nabil Taha
Hello,
if I have the following data (the last name and the first name are in one cell and in one column):
Column A
____________
JAMES, Peter
DAVID, Sarah
AHMED, Ali
BAKER, Lisa
Is there any formula can determine THE LAST NAME ONLY, which they are all in Uppercase, and place it in a new column like below:
Column B
________
JAMES
DAVID
AHMED
BAKER
Thank you very much in advance for your kind help.
2014-06-02 08:47:35
Bryan
I'm glad you decided to take my suggestion of removing volatility of the functions (comment since removed).
I liked the solution suggested by Willy Vanhaelen as well (I'm not sure I would shift cells over, but to each their own):
Willy Vanhaelen 21 Dec 2013, 10:43
Here is another approach: a small macro that does it all in one operation.
Simply highlight the range containing the names to split and run the macro: the two columns to the right of the current selection will contain the first names(lower case) and the last names (upper case) respectively. In case these columns might already contain data, they are shifted to the right first.
Sub doitall()
Dim cell As Range, i As Integer, X As String
Range(Selection.Offset(0, 1), Selection.Offset(0, 2)).Insert Shift:=xlToRight
For Each cell In Selection
For i = 1 To Len(cell)
X = Mid(cell, i, 1)
If X = UCase(X) Then Exit For
Next i
cell.Offset(0, 1) = Left(cell, i - 1)
cell.Offset(0, 2) = Mid(cell, i)
Next cell
End Sub
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 © 2021 Sharon Parq Associates, Inc.
Comments