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.

Splitting Cells by Case

by Allen Wyatt
(last updated November 23, 2013)

2

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.

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.

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 the WEEKNUM Function

Need to know which week of the year a particular date falls within? Excel provides the WEEKNUM function so you can easily ...

Discover More

Spell Checking Forms

Word may be used to create protected forms that limit where the user may input data. Normally spell checking is disabled in ...

Discover More

Adjusting Column Widths on Joined Tables

Each table in a document can have different numbers of columns and different widths for columns. If you want to join two ...

Discover More

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!

More ExcelTips (menu)

Returning Zero when a Referenced Cell is Blank

Reference a cell in a macro, and if that cell is blank Excel normally equates that to a zero value. What if you don't want ...

Discover More

Counting Consecutive Negative Numbers

If you have a range of values that can be either positive or negative, you might wonder how to determine the largest ...

Discover More

Determining "Highest Since" or "Lowest Since"

When compiling statistics on a collection of data points, you may want to know whether a particular value is the "highest ...

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}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 8Mpixels. 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 5 + 0?

2015-02-07 10:58:38

Willy Vanhaelen

I have never seen such clumsy macros as the ones in this tip. They are too 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 efficitly 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

@ Dean Parker

Finaly here is my version of the combined macro who 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

The only difference is that 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 name


2015-02-05 06:48:51

dean.parker04@gmail.com

This is an exceptional MS Excel formula to splitting name using case sensitive arguments.

I would like to know if there's a way to perform the same scenario, but reversing the name splitting using letter casing from "mikeDAVIS" to split names such as: "MIKEDavis" and/or "MIKEdavis".

Overall tremendously pleased, any assistance or recommendations is greatly appreciated. Two Thumbs Up.


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.