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

Adding Dashes between Letters

Written by Allen Wyatt (last updated July 23, 2020)
This tip applies to Excel 97, 2000, 2002, and 2003


5

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 (9633) 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: 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

Changing the Default Chart Type

If you don't have Excel installed on your system, Microsoft Graph is a handy way to create simple charts for your ...

Discover More

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

Discover More

Editing the Windows Registry

The Registry is the central depository of configuration information used by Windows and by programs running on your ...

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

Shortcut for Viewing Formulas

If you need to switch between viewing formulas and viewing the results of those formulas, you'll love the keyboard ...

Discover More

Summing Every Fourth Cell in a Row

Need to sum a series of cells that fits some regular pattern? Here are several ways that you can get the summation that ...

Discover More

Returning the Smallest Non-Zero Value

In a series of values you may need to know the smallest value that isn't a zero. There is no built-in function to do ...

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?

2021-04-12 04:28:48

Rick Rothstein

@Willy...

There is no need to use Split and then Join, Chr(0) is an actual character so you can use the Replace function instead (reduces the number of function calls VBA has to execute by one)....

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


2021-04-11 05:56:33

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


2021-04-10 11:10:41

Roy

Yikes, seems like it would be much simpler to do:

=TEXTJOIN("-",TRUE,MID(A1,SEQUENCE(LEN(A1)),1))

Older versions can use the "ROW(1:xxx)" approach to get the varying value for the length of the word to convert that I use SEQUENCE() for. Longtime technique in the dark old days.

(Replacing TEXTJOIN() would be harder, and the best way heavily dependent upon one's exact set up, version, data, and layout-wise.)

In the case of not using TEXTJOIN, one can concatenate each result " &"-" " to get "h-o-u-s-e-", then take the LEFT(input,len(input)-1) string. Many of the infinite possibilities would yield to that.


2017-01-06 16:29:37

Amanda

So I like simple...This is what I would do... Select the cell or column that you want to change (make sure there are enough blank columns to the right for each letter in the longest word), under Data tab select TEXT TO COLUMNS, FIXED WIDTH, NEXT, and then add a break between each letter until there are enough for all letters in the longest word. Click NEXT. I did the word Coach. Now in the column next to the last letter (the H) I type this formula: =A3&"-"&B3&"-"&C3&"-"&D3&"-"&E3
And my result is C-o-a-c-h. Then you can drag down to copy formula to the entire column.


2015-11-07 05:38:54

Rick Rothstein

Your AddDashes3 and AddDashes4 UDF's can be written as one-liners (I omitted the Application.Volatile that you used because I am not sure it is needed, if I am wrong, then adding it to my UDF's will make them two-liners)...

Function AddDashes3(Strg As String, Spacer As String) As String
AddDashes3 = Join(Evaluate("TRANSPOSE(MID(""" & Strg & """,ROW(1:" & Len(Strg) & "),1))"), Spacer)
End Function

Function AddDashes4(ByVal Strg As String, Spacer As String) As String
AddDashes4 = Replace(Join(Evaluate("TRANSPOSE(MID(""" & Strg & """,ROW(1:" & Len(Strg) & "),1))"), Spacer), "- -", " ")
End Function

Note: AddDashes4 is the same function I posted to your previous posting of this tip (mentioned in your "Please Note" comment at the beginning of this tip... the second function is different (simpler) than the one I posted there originally.


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.