Written by Allen Wyatt (last updated February 3, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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 choosing 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
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12810) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.
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!
Need a quick way to jump to a particular part of your worksheet? You can do it by using the Go To dialog box.
Discover MoreWhen you type information into a cell, Excel tries to figure out what type of information you are entering. If Excel can ...
Discover MoreWhen you filter rows in your data, you may want to later number those rows. This tip provides a variety of ways you can ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-04-15 18:25:57
Yvan Loranger
The formula =LEFT(A1,B1-1)&" " & RIGHT(A1,(LEN(A1)-B1)+1)
could be replaced with =SUBSTITUTE(A1,MID(A1,B1,1)," " &MID(A1,B1,1),1)
or even shorter with =REPLACE(A1,B1,0," ").
2019-04-09 11:15:13
Willy Vanhaelen
@David
I tried your function but it doesn't work. Neither with ABCCorp nor with H&M. But you are right the approach used in this tip's last macro to solve this is wrong because it leaves ABCCorp untouched. Instead of checking if the previous character is a capital letter you have to see if the following letter is lower case.
This macro deals with it and gives the right results and is (again) much shorter than this tip's one.
Sub AddSpaces()
Dim i As Integer, j As Integer
Dim tmp As String, txt As String
Dim chr1 As String, chr2 As String
For i = 1 To Cells(1, 2).End(xlDown).Row
txt = Cells(i, 2)
tmp = Left(txt, 1)
For j = 2 To Len(txt)
chr1 = Mid(txt, j, 1)
chr2 = Mid(txt, j + 1, 1)
tmp = tmp & IIf(chr1 < "a" And chr2 > "Z", " ", "") & chr1
Next j
Cells(i, 3) = tmp
Next i
End Sub
In this macro the name with added space is made-up in vba and the final result is copied to the sheet which is much faster.
2019-04-08 09:04:42
David Robinson
Typo in my code: should be CharCode1 <= 122
2019-04-08 05:51:21
David Robinson
I would seek a lower case letter followed by an upper case letter. I took your macro and modified it slightly:
Function Add_Spaces(ByVal sText As String) As String
Dim CharNum As Long
Dim FixedText As String
Dim CharCode1 As Long, CharCode2 As Long
FixedText = Left(sText, 1)
For CharNum = 2 To Len(sText)
CharCode1 = Asc(Mid(sText, CharNum - 1, 1))
CharCode2 = Asc(Mid(sText, CharNum, 1))
If CharCode1 >= 97 And CharCode2 <= 122 And CharCode2 >= 65 And CharCode2 <= 90 Then
FixedText = FixedText & " "
End If
FixedText = FixedText & Mid(sText, CharNum, 1)
Next CharNum
Add_Spaces = FixedText
End Function
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.
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