Adding Spaces in Front of Capital Letters

by Allen Wyatt
(last updated November 30, 2013)

8

Muhammad has a long list of company names in a worksheet. Each company's name has somehow had all spaces removed, so that (for example) they appear as "AstroPhysics" instead of "Astro Physics." Muhammad needs a way to process all the company names to insert a single space between any occurrence of a capital letter, except for the first letter in the cell. He wonders if there is an easy way to do this.

There are a few ways that you can go about adding the spaces. Before getting to the inevitable macro-based solutions, you might want to examine the company names. It could be that there is simply a non-printing character between each word in the name, instead of a space. You can determine this by editing the cell, positioning the insertion point a few characters before a capital letter, and then pressing the right arrow several times. You should see the insertion point move a single space to the right after each press; if it seems to "hesitate" where the space should be, then there is a non-printing character there.

In this case, the best solution is to do a Find and Replace operation to replace the non-printing character with an actual space. (You can select the non-printing character—hold down the Shift key as you press the right arrow over where you believe it to be—and copy it. Then paste it into the Find What box to do your search.)

Assuming the data doesn't have any non-printing characters in it, you might also try using a non-macro approach. Perhaps the simplest approach is to add a helper column or two. In the first you can enter a formula to figure out the position of the second uppercase letter within the company name. Assuming the company name is in cell A1, the formula, which follows, should be entered as an array formula:

=SMALL(FIND(0,SUBSTITUTE(A1,CHAR(ROW(INDIRECT("65:90"))),0)&0),2)

If this formula was entered into cell B1, then you could use the following to insert the space into the original company name:

=LEFT(A1,B1-1)&" " & RIGHT(A1,(LEN(A1)-B1)+1)

There is a huge drawback to this approach, however: It assumes that your original data follows a very strict format. It works marvelously with company names that start with a capital letter and that require the insertion of only a single space. If the name doesn't fit these parameters, then it won't work as expected.

Of course, you can overcome these issues if you use a macro to insert the spaces. The following is a simple approach that looks at each character in the cell. If the character is an uppercase letter, then a space is inserted before the character. When the macro is done, the string is stuffed back into the cell.

Function Add_Spaces(ByVal sText As String) As String
   Dim CharNum As Long
   Dim FixedText As String
   Dim CharCode As Long

   FixedText = Left(sText, 1)

   For CharNum = 2 To Len(sText)
      CharCode = Asc(Mid(sText, CharNum, 1))
      If CharCode >= 65 And CharCode <= 90 Then
         FixedText = FixedText & " " & Mid(sText, CharNum, 1)
      Else
         FixedText = FixedText & Mid(sText, CharNum, 1)
      End If
   Next CharNum

   Add_Spaces = FixedText
End Function

Using the macro is simple; if the company name is in cell A1, then the following is used:

=Add_Spaces(A1)

A more compact approach is to rely on regular expressions to locate the capital letters and insert a space, as shown in the following:

Function SplitCaps(str As String) As String
    Dim objRegex As Object
    Set objRegex = CreateObject("vbscript.regexp")

    With objRegex
        .Global = True
        .Pattern = "([a-z])([A-Z])"
        SplitCaps = .Replace(str, "$1 $2")
    End With
End Function

This particular macro technique requires that you enable regular expressions. You do this in the VB Editor by choose Tools | References and then scrolling through the available references to locate the Microsoft VBScript Regular Expressions 5.5 option. Make sure the check box to the left of the reference is selected, then click OK. You can then utilize the SplitCaps function from within Excel in the same way you could use the Add_Spaces function.

Of course, the appropriateness of any approach will depend, in large part, on the characteristics of the data you are working with. If your original company names include multiple sequential capital letters (such as "ABCCorp.") then you will end up with too many spaces in your output, such that "ABCCorp." becomes "A B C Corp." instead of "ABC Corp.". Also, non-letter characters may throw a wrench in the works such that "H&M" becomes "H& M" or remains as "H&M" (depending on the macro approach you use).

In an effort to overcome some of these odd-ball company names, you might try a different macro approach that checks to see if there are multiple sequential capital letters and adjusts the output accordingly.

Sub AddSpaces()
    Dim i As Integer
    Dim j As Integer
    Dim PriorCap As Boolean
    Dim temp As String

    j = 1

    Do While Cells(j, 2) <> ""
        Cells(j, 3) = ""
        PriorCap = True
        For i = 1 To Len(Cells(j, 2))
            Select Case Mid(Cells(j, 2), i, 1)
                Case "A" To "Z", "-"
                    If PriorCap = False Then
                        Cells(j, 3) = Cells(j, 3) & " " & _
                          Mid(Cells(j, 2), i, 1)
                    Else
                        Cells(j, 3) = Cells(j, 3) & _
                          Mid(Cells(j, 2), i, 1)
                    End If
                    PriorCap = True
                Case Else
                    Cells(j, 3) = Cells(j, 3) & _
                      Mid(Cells(j, 2), i, 1)
                    PriorCap = False
            End Select
        Next i
        j = j + 1
    Loop
End Sub

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12810) applies to Microsoft Excel 2007, 2010, and 2013.

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

Working with Fonts

Windows allows you to install different fonts that control how information is displayed and printed. This tip gives a ...

Discover More

Special Differences when Searching

Word includes two different search engines. Which search engine you choose to use will dictate what Word shows as available ...

Discover More

Incrementing Numeric Portions of Serial Numbers

If you use serial numbers that include both letters and numbers, you might wonder how you can increment the numeric portion ...

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)

Limiting Input to a Format

When setting up a worksheet for others to use, you might want to make some limitations on what can be entered in certain ...

Discover More

Displaying Row and Column Labels

When you create a worksheet, it is common to place headings at the top of each column and the left of each row so you can ...

Discover More

Automatically Adding 20% to an Entry

When you are developing a worksheet for others to use, you may want to have entries in a particular cell (or cells) 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}] 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 four less than 9?

2013-12-02 23:58:18

LL

Thank, Bryan. I forgot the CTRL+Shift+Enter part and hit Enter just as you imagined. This post made me realize how little I know so I will be reading up on arrays. Thanks!


2013-12-02 09:51:05

Bryan

There's a lot of clever things going on in this article. I only have a couple comments to add:
* In the formula versions, you don't need the INDIRECT function. ROW(INDIRECT("65:90")) can be reduced to ROW(65:90). It's a little less to type (and fewer parentheses to keep track of!), and it makes the formula non-volatile.
* In the first macro version (Add_Spaces) I probably would have used StrComp() instead of Asc(), but I don't think either is really better than the other. I personally can never remember the ASCII codes so I'd have to do some exploring first to use that method.
* In the second macro (SplitCaps), I believe since the regexp object is late bound, you don't need to set the reference. If you do set the reference, then you might as well take advantage of early binding. To do so, change the first to lines to:

Dim objRegex As RegExp
Set objRegex = New RegExp

@LL: are you remembering that the formulas are array formulas? After you paste the formula, you have to press CTRL+Shift+Enter, not just Enter. Actually on rereading your question, it looks like you are only having trouble with the formula in cell C1... in that case I'm not sure what the issue is. Try stepping through the formula (Formulas > Formula Auditing > Evaluate Formula) to see which part is causing the error.


2013-12-01 06:14:00

Michael (Micky) Avidan

@LL:
The suggested formulas work OK although they are "not my cup of tea".
Maybe you typed something wrong.
You are welcome to send me the file (with the 2 formulas) to:
micky-a<at>tapuz.co.il

@Willy:
The original question AND solution state very clear that they refere towards cases where there are NO SPACES within the name(s).

Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2014)
ISRAEL


2013-11-30 22:22:44

LL

I tried the array formula with no luck as both the array formula and left formula came back with the horrific NUM! error. Can anyone help me shine some light onto what I did wrong? I entered "AstroPhysics" in cell A1 and copied/ pasted the array formula in cell B1 and the "=Left.." formula in cell C1. Thanks!


2013-11-30 20:28:43

Peter Atherton

No I've had another look and Willy's sub does not cover BAESystemsPlc. My original submission didn't either but here is an update that does and also covers a stray space.

Sub SplitByCaps()
Dim ch As String, ch2 As String, prior As String
Dim i As Integer, L As Integer, col As Integer
Dim j As Integer, Positions() As Variant, p As Integer
Dim c, str As String, tmp As String

For Each c In Selection
p = 0
str = ""
L = Len(c)
On Error Resume Next
For i = 1 To L - 1
ch = Mid(c, i, 1)
ch2 = Mid(c, i + 1, 1)
prior = Mid(c, i - 1, 1)
If ch = " " Then
'do nothing
ElseIf ch = UCase(ch) And ch2 = UCase(ch2) Then
str = str & ch
ElseIf ch <> UCase(ch) And ch <> " " And prior = UCase(prior) Then
p = p + 1
ReDim Preserve Positions(p)
Positions(p) = i - 1
End If
Next i
str = str & " "
' finish the string
For j = 1 To UBound(Positions)
' Handle the last position first
If j = p Then
tmp = Mid(c, Positions(j), L - (Positions(j) - 1))
Else
tmp = Mid(c, Positions(j), Positions(j + 1) - Positions(j)) & " "
End If
str = str & tmp
Next j
c.Value = Trim(str)
Next c
End Sub


2013-11-30 17:00:01

Peter Atherton

Another lovely solution Willy. If the user uses it he could wrap it up in a little macro and cut the overheads involved with formulas e.g.

Sub SplitText()
Dim c, str As String
For Each c In Selection
str = c.Value
c.Value = AddSpaces(str)
Next c
End Sub


2013-11-30 12:30:46

Willy Vanhaelen

None of these solutions handle accented capitals. Also if the name already contains a space before a capital letter a second one is added. Here is a macro that deals with both:

Function AddSpaces(sText As String) As String
Dim str As String, X As Integer, Y As String
str = Left(sText, 1)
For X = 2 To Len(sText)
Y = Mid(sText, X, 1)
If Y = UCase(Y) Then
If Y <> " " And Mid(sText, X - 1, 1) <> " " Then
Y = " " & Y
End If
End If
str = str & Y
Next X
AddSpaces = str
End Function

It also deals with names like Dan&Ben (-> Dan & Ben instead of Dan& Ben).


2013-11-30 09:57:22

Michael (Micky) Avidan

The suggested formula handles only a Company name "made of" two words.

In such a case there is no need for a helper column because a relatievly simple Array formula can resolve the space.

=REPLACE(A1,SMALL(FIND(0,SUBSTITUTE(A1,CHAR(ROW(INDIRECT("65:90"))),0)&0),2),0," ")

Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2014)
ISRAEL



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.