Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Splitting Cells by Case.

Splitting Cells by Case

Written by Allen Wyatt (last updated March 13, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


5

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:

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 (9091) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Splitting Cells by Case.

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

Using Fractional Number Formats

If you want information to display on the screen using fractions instead of decimals, you're in luck. Excel provides ...

Discover More

Controlling Endnote Placement

Endnotes are often used in technical and scholarly documents. You can control exactly where the endnotes appear in your ...

Discover More

Setting the Calculation Default

Excel can recalculate your worksheets either automatically or manually. The default is to calculate them automatically, ...

Discover More

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!

More ExcelTips (ribbon)

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

Identifying Digit-Only Part Numbers Excluding Special Characters

When working with data in Excel, you often need to determine if that data meets criteria that you specify. This tip ...

Discover More

Looking Backward through a Data Table

Sometimes you need to look backward, through the information above your formula, to find the data you need. This can be ...

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?

2021-03-15 09:44:39

Willy Vanhaelen

@Rick,
Your solution of inserting a character 1 at the position before the first upper case letter and then splitting the string into an array is high-tech vba: “chapeau”. This solved the “mary ann” case.

But at the request of Dean Parker in the pre 2007 version of this tip I made my GetName function so it could handle “MIKEdavis” as well as “mike DAVIS”. Your function doesn’t deal with that.

So, I changed your function a bit and I think we now get the best of both worlds:
mary annSMITH as well as MARY ANNsmith:

Function GetName(S As String, Optional First As Boolean = True) As String
Dim X As Long
For X = 1 To Len(S)
If Mid(S, X, 1) Like IIf(Asc(S) > 90, "[A-Z]", "[a-z]") Then Exit For
Next
GetName = Split(Application.Replace(S, X, 0, Chr(1)), Chr(1))(1 + First)
End Function

As for your second point, this is the result of the fact that my original function handles both mikeDAVIS and MIKEdavis. With argument 1 the first part of the text can be either lower or upper case depending on the case of the text’s first letter. So, with only upper-case text the function with no argument will return an empty string because there is no lower-case text to display.


2021-03-14 07:25:56

Peter Atherton

@Rick
Mary Ann LIGHTLY could be entered with a hard (non breaking) space. e.g.Mary Alt & 0160 & Ann " " LIGHTLY
Hear are my solutions, the secondwith a little bit of checking.


Function FName(s As String, Optional delimiter = " ")
Dim x
x = Split(s, delimiter)
FName = x(0)
End Function
Function LName(s As String, Optional delimiter = " ")
Dim x
x = Split(s, delimiter)
LName = x(1)
End Function

Function FName2(s As String, Optional delimiter = " ")
Dim x, i As Long, str As String, c As String
x = Split(s, delimiter)
For i = LBound(x) To LBound(x)
c = Mid(x(i), 2, 1)
If c = LCase(c) Then
FName2 = x(0)
End If
Next
End Function
Function LName2(s As String, Optional delimiter = " ")
Dim x, i As Long, str As String, c As String
x = Split(s, delimiter)
LName2 = x(UBound(x))
End Function


2021-03-13 16:22:13

Rick Rothstein

@Willy.,

Two things about your GetName function...

1) I have a friend whose first name contains a space in it (Mary Ann where Ann is not a middle name). If we assume the space will be retained as part of the lower case text, your function mishandles it.

2) If the text in the cell is all upper case letters or all lower case letters (think the name Cher), then your GetName function returns the text for either condition if the second argument is 1 and returns the empty text string ("") if the second argument is anything other than 1.


2021-03-13 15:58:51

Rick Rothstein

I agree with Willy that the aritcle's VBA functions are too long. Here is my take on how to shorten them. Note that I changed the arguments to String data type rather than Range to make them be able to work in both worksheet formulas (call it the same way as already explained) as well as in other VBA code procedures. Also, for the generalized GetName function, I made the second argument a Boolean and optional... if omitted or a True value is passed to it, the function returns the first name and if False is passed to it, then it returns the last name. Here are my functions...

Function GetFirstName(S As String) As String
Dim X As Long
For X = 1 To Len(S)
If Mid(S, X, 1) Like "[A-Z]" Then Exit For
Next
GetFirstName = Left(S, X - 1)
End Function

Function GetLastName(S As String) As String
Dim X As Long
For X = 1 To Len(S)
If Mid(S, X, 1) Like "[A-Z]" Then Exit For
Next
GetLastName = Mid(S, X)
End Function

Function GetName(S As String, Optional First As Boolean = True) As String
Dim X As Long
For X = 1 To Len(S)
If Mid(S, X, 1) Like "[A-Z]" Then Exit For
Next
GetName = Split(Application.Replace(S, X, 0, Chr(1)), Chr(1))(1 + First)
End Function


2021-03-13 10:02:53

Willy Vanhaelen

This tip's macros are way to long and complicated and generate an error when the cell they refer to is empty or contains a number or only lower case letters.

Here are my tiny versions who do the job more efficiently of course and without errors:

Function GetFirstUpper(myCell As Range) As Integer
Dim S As String, X As Integer
For X = 1 To Len(myCell)
S = Mid(myCell, X, 1)
If S = UCase(S) Then Exit For
Next X
GetFirstUpper = X
End Function
'---
Function GetFirstName(myCell As Range) As String
GetFirstName = Left(myCell, GetFirstUpper(myCell) - 1)
End Function
'---
Function GetLastName(myCell As Range) As String
GetLastName = Mid(myCell, GetFirstUpper(myCell))
End Function

My version of the combined macro does the split when the case changes. So it works as well with firstLAST as with FIRSTlast:

Function GetName(MyCell As Range, Optional sWanted As Integer) As String
Dim S As String, X As Integer
For X = 1 To Len(MyCell)
S = Mid(MyCell, X, 1)
If S = IIf(Asc(MyCell) > 90, UCase(S), LCase(S)) Then Exit For
Next X
GetName = IIf(sWanted = 1, Left(MyCell, X - 1), Mid(MyCell, X))
End Function

To use this function to get the first part you have to enter: =GetName(A1,1) instead of =GetName(A1, "First").
Any other number for the second argument or if you omit it will yield the last part.


This Site

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.

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.