Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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

by Allen Wyatt
(last updated May 31, 2014)

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 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

    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

    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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9091) applies to Microsoft Excel 2007, 2010, and 2013. 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

Periodically Delete TMP Files

After using Word for a while, you may notice some "litter" of unused files on your hard drive. This tip explains how those ...

Discover More

Hyperlinks Not Found

When creating hyperlinks in a document, it is important to remember the difference between absolute and relative referencing. ...

Discover More

Counting Commas in a Selection

If you have a range of cells in which you want to count all the commas, there are several ways you can derive the figure you ...

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)

Referencing the Last Six Items in a Formula

If you have a list of data in a column, you may want to determine an average of whatever the last few items are in the ...

Discover More

Finding the Directory Name

Need to know the directory (folder) in which a workbook was saved? You can create a formula that will return this information ...

Discover More

Determining Combinations to Make a Total

If you have a range of cells that contain values, you may wonder which combinations of those cells should be used to meet a ...

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 0 + 7?

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


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.