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: Splitting Cells by Case.
Written by Allen Wyatt (last updated July 31, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003
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 for 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 Application.Volatile 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 for 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 Application.Volatile 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 Application.Volatile 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 Application.Volatile 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 (9089) 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: Splitting Cells by Case.
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!
For some operations and functions, Excel allows you to use wild card characters. One such character is an asterisk. What ...
Discover MoreDo you ever have a need to return just a few digits out of a number? This tip shows different formulas you can use to ...
Discover MoreA common task faced by Excel users is to determine whether items in one list are also found in a different list. There ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments