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) + "-"
        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