Excel.Tips.Net ExcelTips (Menu Interface)

Adding Dashes between Letters

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.

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) + "-"
        Cell.Value = Left(sTemp, Len(sTemp) - 1)
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

    sTemp = ""
    For C = 1 To Len(Src)
        sTemp = sTemp + Mid(Src, C, 1) + "-"
    AddDashes2 = Left(sTemp, Len(sTemp) - 1)
End Function

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


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

    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
    AddDashes3 = sTemp
End Function

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.

Related Tips:

Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!


Leave your own comment:

  Notify me about new comments ONLY FOR THIS TIP
Notify me about new comments ANYWHERE ON THIS SITE
Hide my email address
*What is 5+3 (To prevent automated submissions and spam.)
           Commenting Terms

Comments for this tip:

Rick Rothstein    07 Nov 2015, 05:38
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.

Our Company

Sharon Parq Associates, Inc.

About Tips.Net

Contact Us


Advertise with Us

Our Privacy Policy

Our Sites


Beauty and Style




DriveTips (Google Drive)

ExcelTips (Excel 97–2003)

ExcelTips (Excel 2007–2016)



Home Improvement

Money and Finances


Pests and Bugs

Pets and Animals

WindowsTips (Microsoft Windows)

WordTips (Word 97–2003)

WordTips (Word 2007–2016)

Our Products

Helpful E-books

Newsletter Archives


Excel Products

Word Products

Our Authors

Author Index

Write for Tips.Net

Copyright © 2016 Sharon Parq Associates, Inc.