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: Adding Dashes between Letters.

Adding Dashes between Letters

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


12

Scott wonders how he can make Excel automatically add a dash between every letter in a given cell. As an example, if cell A1 contains "house", Scott would like to convert it to "h-o-u-s-e".

This can be done with a formula, but it quickly becomes unwieldy. For instance, the following formula can be used to put dashes between the letters of whatever you type into cell A1:

=CHOOSE(LEN(A1),A1,LEFT(A1,1) & "-" & RIGHT(A1,1),
LEFT(A1,1) & "-" & MID(A1,2,1) & "-" & RIGHT(A1,1),
LEFT(A1,1) & "-" & MID(A1,2,1) & "-" & MID(A1,3,1) & "-"
& RIGHT(A1,1),LEFT(A1,1) & "-" & MID(A1,2,1) & "-"
& MID(A1,3,1) & "-" & MID(A1,4,1) & "-" & RIGHT(A1,1),
LEFT(A1,1) & "-" & MID(A1,2,1) & "-" & MID(A1,3,1)
& "-" & MID(A1,4,1) & "-" & MID(A1,5,1) & "-" & RIGHT(A1,1))

This particular example of a formula will only work on text up to six characters in length. Thus, it would work properly for "house", but not for "household". The formula could be lengthened but, again, it would quickly become very long.

A better approach is to use a macro to do the conversion. If you want to insert the dashes right into the cell, you could use a macro such as this:

Sub AddDashes1()
    Dim Cell As Range
    Dim sTemp As String
    Dim C As Integer

    For Each Cell In Selection
        sTemp = ""
        For C = 1 To Len(Cell)
            sTemp = sTemp & Mid(Cell, C, 1) & "-"
        Next
        Cell.Value = Left(sTemp, Len(sTemp) - 1)
    Next
End Sub

This macro is designed to be used on a selected range of cells. Just select the cells you want to convert, and then run the macro. The dashes are added between each letter in the cells.

If you prefer to not modify the original cell values, you could create a user-defined function that would do the job:

Function AddDashes2(Src As String) As String
    Dim sTemp As String
    Dim C As Integer

    Application.Volatile
    sTemp = ""
    For C = 1 To Len(Src)
        sTemp = sTemp & Mid(Src, C, 1) & "-"
    Next
    AddDashes2 = Left(sTemp, Len(sTemp) - 1)
End Function

To use this function, you would use the following in your worksheet:

=AddDashes2(A1)

If you want to make sure that the function is a bit more robust, you could modify it so that it handles multiple words. In such an instance you would not want it to treat a space as a "dashable letter." For example, you would want the routine to add dashes to "one two" so it came out as "o-n-e t-w-o" instead of "o-n-e- -t-w-o". The following variation on the function will do the trick:

Function AddDashes3(Src As String) As String
    Dim sTemp As String
    Dim C As Integer

    Application.Volatile
    sTemp = ""
    For C = 1 To Len(Src)
        sTemp = sTemp & Mid(Src, C, 1)
        If Mid(Src, C, 1) <> " " And
          Mid(Src, C + 1, 1) <> " " And
          C < Len(Src) Then
            sTemp = sTemp & "-"
        End If
    Next
    AddDashes3 = sTemp
End Function

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 (9634) 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: Adding Dashes between Letters.

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

Understanding the Normalize Text Command

Word includes tons of internal commands that you can access as you customize your system. One of these is the Normalize ...

Discover More

Grouping Records in a Mail Merge

Need to group records in some manner when they are used in a mail merge? It can be frustrating when your records are not ...

Discover More

Automatically Creating Charts for Individual Rows in a Data Table

If you have a lot of records in a data table, you may want to create individual charts based on the information in those ...

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 (ribbon)

Starting Out Formulas

When you enter a formula from the keyboard, Excel only knows it is a formula if you start it with an equal sign. You can ...

Discover More

Formatting Canadian Postal Codes

Postal codes in Canada consist of six characters, separated into two groups. This tip explains the format and then shows ...

Discover More

Calculating Statistical Values on Different-Sized Subsets of Data

Discovering different ways to analyze your data can be a challenge. Here's how to work with arbitrary subsets of a large ...

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

2020-03-08 13:22:07

Willy Vanhaelen

@Frederick
The macro AddDashes1 I presented in my comment of 17 Nov 2019 is shorter than your version because I use of the Count argument of Replace instead of the Left function.

Sub AddDashes1()
Dim cell As Range
For Each cell In Selection
cell = Replace(StrConv(cell, vbUnicode), Chr$(0), "-", 1, Len(cell) - 1)
Next cell
End Sub

Although your version of the function AddDashes2 is shorter than the one I presented in my comment of 16 Nov 2019, I managed now to make it even shorter than yours:

Function AddDashes2(S As String) As String
AddDashes2 = Replace(StrConv(S, vbUnicode), Chr(0), "-", 1, Len(S) - 1)
End Function

AddDashes3 can also be shorter:

Function AddDashes3(S As String) As String
AddDashes3 = Replace(Replace(StrConv(S, vbUnicode), Chr(0), "-", 1, Len(S) - 1), "- -", " ")
End Function


2020-03-07 18:04:15

Frederick Rothstein

Here are what I consider simpler procedures to replace those you included in your article (I kept the same names you used for them)...


Sub AddDashes1()
Dim Cell As Range
For Each Cell In Selection
Cell.Value = Left(Replace(StrConv(Cell.Value, vbUnicode), Chr(0), "-"), 2 * Len(Cell.Value) - 1)
Next
End Sub


Function AddDashes2(S As String) As String
AddDashes2 = Left(Replace(StrConv(S, vbUnicode), Chr(0), "-"), 2 * Len(S) - 1)
End Function


Function AddDashes3(S As String) As String
AddDashes3 = Replace(Left(Replace(StrConv(S, vbUnicode), Chr(0), "-"), 2 * Len(S) - 1), "- -", " ")
End Function


2020-03-07 14:19:16

Frederick Rothstein

Here are what I consider simpler procedures to replace those you included in your article (I kept the same names you used for them)...


Sub AddDashes1()
Dim Cell As Range
For Each Cell In Selection
Cell.Value = Left(Replace(StrConv(Cell.Value, vbUnicode), Chr(0), "-"), 2 * Len(Cell.Value) - 1)
Next
End Sub


Function AddDashes2(S As String) As String
AddDashes2 = Left(Replace(StrConv(S, vbUnicode), Chr(0), "-"), 2 * Len(S) - 1)
End Function


Function AddDashes3(S As String) As String
AddDashes3 = Replace(Left(Replace(StrConv(S, vbUnicode), Chr(0), "-"), 2 * Len(S) - 1), "- -", " ")
End Function


2019-11-25 13:47:20

JMJ

@Willy
Aren't you an APL programmer :-) ?
The APL programmer's theorem states that "for each working program written in APL, there is a shorter one with exactly the same functionalities"
Of course, it's a joke (albeit...), but I agree with you, and quoting A. Pope : "There is a certain majesty in simplicity which is far above all the quaintness of wit" !


2019-11-20 13:52:55

Willy Vanhaelen

Correection
Result: m y   t i t l e


2019-11-20 13:51:34

Willy Vanhaelen

Usage: =SeparateText("my title"," ")
Result: m y t i t l e


2019-11-20 12:49:19

Willy Vanhaelen

Peter,

Excellent idea. If you use a space as separator you can even use this macro as a title widener with the advantage that between words you get 3 spaces wich is more clear.


2019-11-19 18:25:41

Peter Atherton

Willy
I do like your short function. I woulf add a variable for the separator and this would address JC's concerns about maintaining it.

Function SeparateText(ByVal ref, Separator As String) As String
SeparateText = Replace(StrConv(ref, vbUnicode), Chr$(0), Separator, 1, Len(ref) - 1)
End Function

=SeparateText(A1,"-")
=SeparateText(A1," ")


2019-11-19 14:11:52

Willy Vanhaelen

@JC
For me it feels like simpler because it's shorter and more concise. But you are right, Allen's code is the traditional way to do it and easier to understand. In a way it is the "teacher's" approach.

But it is always interesting to show that a problem can mostly be solved in several ways. And generally, with Leonardo da Vinci's saying "Simplicity is the ultimate sophistication" in mind, I prefer the shorter and more concise ones :-)


2019-11-18 09:15:59

JC

I find the "shorter" code interesting, but wouldn't call it "simpler". Wyatt's code is IMO easier to maintain.


2019-11-17 10:42:16

Willy Vanhaelen

Here is an even shorter and simpler one-line UDF:

Function AddDashes2(Src As String) As String
AddDashes2 = Replace(StrConv(Src, vbUnicode), Chr$(0), "-", 1, Len(Src) - 1)
End Function

Here is how it works, the variable Src (cell referred to) is TEST as an example:

StrConv(Src, vbUnicode) -> StrConv("TEST", vbUnicode)
Converts TEST to unicode so each letter takes 2 bytes instead of one.
The first byte is the ascii code of the letter, the second byte is Null or Chr$(0).
The result in the example is T_E_S_T_ (the underscores represent null or Chr$(0)
This last character is used as find argument for the Replace function:

Replace(StrConv(Src, vbUnicode), Chr$(0), "-", 1, Len(Src) - 1)
-> Replace("T_E_S_T_", Chr$(0), "-", 1, Len(Src) - 1)
The count argument in Replace is Len(Src) - 1 to eliminate the unwanted last dash.

Finaly T-E-S-T is returned as result.

This tip's first macro can also be simplified a lot:

Sub AddDashes1()
Dim cell As Range
For Each cell In Selection
cell = Replace(StrConv(cell, vbUnicode), Chr$(0), "-", 1, Len(cell) - 1)
Next cell
End Sub


2019-11-16 13:09:40

Willy Vanhaelen

Here is a one-liner for the AddDashes2 UDF:

Function AddDashes2(S As String) As String
AddDashes2=Left(Join(Split(StrConv(S,vbUnicode),Chr$(0)),"-"),Len(S)*2-1)
End Function


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.