Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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

by Allen Wyatt
(last updated January 28, 2019)

14

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, and 2013. 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

Introducing the Organizer

The Organizer is a great tool for, well, organizing the information stored in your templates. This tip introduces the ...

Discover More

Creating Default Formatting for Workbooks and Worksheets

Not satisfied with the way that default workbooks and worksheets look in Excel? You can easily create your own defaults ...

Discover More

Creating a Dynamic Hyperlink

Want to create a hyperlink that will always display a different worksheet in your workbook? There are several ways to do ...

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

Pulling a Phone Number with a Known First and Last Name

When using an Excel worksheet to store data (such as names and phone numbers), you may need a way to easily look up a ...

Discover More

Tracing Errors

Sometimes it can be confusing to figure out the source of an error that is displayed in your worksheet. Excel provides a ...

Discover More

Shortening ZIP Codes

US ZIP Codes can be of two varieties: five-digits or nine-digits. Here's how to convert longer ZIP Codes to the shorter ...

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}] 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 five more than 3?

2019-01-29 12:22:59

Willy Vanhaelen

@ryn
Although VBA allows to use the "+" sign to concatenate strings, it is strongly advised NOT to and use the ampersand "&" instead. In some circumstances the "+" can lead to erroneous results.
So instead of
sTemp = sTemp + "-"
better use
sTemp = sTemp & "-"

They should have done it in the first place in this tip.


2019-01-28 08:17:08

ryn

But...why?+


2015-09-21 16:15:59

Rick Rothstein

We can address Perth's comment about the "dashes around spaces" issue as a "one liner" as well. The only issue is how much to increase the size of the space to make it look "balanced" with the rest of the expanded text. I chose to double the length of the spacer character(s) plus 1 and use that value for the number of spaces between words.

Function IBC(Strg As String, Spacer As String) As String
IBC = Replace(Join(Evaluate("TRANSPOSE(MID(""" & Strg & """,ROW(1:" & Len(Strg) & "),1))"), Spacer), Spacer & " " & Spacer, Space(1 + 2 * Len(Spacer)))
End Function


2015-09-21 15:59:54

Rick Rothstein

While longer, character-wise, than Micky's "simplest & shortest" UDF, I think the following is interesting because it is a "one-liner"...

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


2014-12-23 06:57:11

Michael (Micky) Avidan

@Peter,
Good solution.
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL


2014-12-22 17:26:09

Peter Atherton

@Micky
I took the liberty of altering your code slightly to accommodate various spacers, including spacers before and after the spacer character e.g. " - ".

Function IBC(Str, Spacer As String)
Dim stemp As String
stemp = Replace(Replace(StrConv(Str, 64), ChrW(0), Spacer), Spacer & " " & Spacer, " ")
IBC = Left(stemp, Len(stemp) - Len(Spacer))
End Function

I've also used a period and CHAR(7) as spacer; someone might try to use sume such.
Regards
Peter


2014-12-21 07:37:12

Peter Atherton

@Micky
Excellent, I knew you'd have a solution. I prefer the second replacement to have an extra space between words but that just me.


2014-12-07 08:28:49

Michael (Micky) Avidan

@Peter Atherton,
1) Just from looking at your revised code it seems as if you run your suggested UDF on: Micky Avidan
You'll get: M-i-c-k-y A-v-i-d-a-n
(Lot of spaces between the names).
2) If you'll alter my UDF into:
------------------------------------
Function IBC(Str, Spacer As String)
stemp = Replace(Replace(StrConv(Str, 64), ChrW(0), Spacer), "- -", " ")
IBC = Left(stemp, Len(stemp) - 1)
End Function
------------
You'll end up with a littler more appropriate result.
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL


2014-12-06 16:04:36

Peter Atherton

I tell a lie. I'd altered Dash spaces and included a new variable for the word spacer and not posted the code. My mistake. The revised code is:

Function AddDashes3(Src As String, Optional Spacer As String = " - ") As String
Dim stemp As String
Dim C As Integer, i As Integer
Dim Separator As String

Separator = chr(32) 'Space
For i = 1 To Len(Spacer)
Separator = Separator & chr(32)
Next

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 + Spacer
Else
stemp = stemp & Separator
End If
Next
AddDashes3 = stemp
End Function


2014-12-06 12:04:17

Peter Atherton

The only trouble with IBC it returns extra dashes. Txt:= Bream Julian
Formula:==AddDashes3(A11, "-") returns
B-r-e-a-m J-u-l-i-a-n

Formula:=ibc(A11,"-") returns
B-r-e-a-m- -J-u-l-i-a-n


2014-12-06 11:53:04

Peter Atherton

Micky

Yes, really good


2014-12-06 10:59:27

Willy Vanhaelen

@Mickey

That is a very clever solution.


2014-12-05 11:52:06

Michael (Micky) Avidan

If I'm not mistaken - the following UDF is the simplest & shortest:
-----------------------------
Function IBC(Str, Spacer As String) ' In-Between Character
sTemp = Replace(StrConv(Str, 64), ChrW(0), Spacer)
IBC = Left(sTemp, Len(sTemp) - 1)
End Function
--------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL


2014-12-04 19:58:46

Peter Atherton

I think that there is a clause missing in the code; separated words need @ least two spaces. This version gives the opportunity to change the spacer.

Function AddDashes3(Src As String, Optional Spacer 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 + Spacer
Else
sTemp = sTemp & " "
End If
Next
AddDashes3 = sTemp
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.