Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 2021, 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 September 28, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365


11

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

As is often the case, the macro could be shortened quite a bit. For example, the following could be used to do the conversion:

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

    For Each Cell In Selection
        sTemp = StrConv(Cell, vbUnicode)
        sTemp = Replace(sTemp, Chr(0), "-")
        Cell.Value = Left(sTemp, Len(sTemp) - 1)
    Next Cell
End Sub

This could be made shorter still, but I purposely broke out the lines within the For...Next loop so that they are more understandable. The key to this approach is the StrConv function which, in this case, converts the cell contents so that each character uses two bytes (in Unicode), and the second byte will be null, or an ASCII value of 0. Then, each of the null characters is replaced with a dash. Finally, everything except the trailing dash is stuffed back into the cell.

There is one thing to note about this approach: While it is shorter (and can be shorter still), it won't work on the Mac. So, if you are sharing your workbook that contains a macro such as this with someone using a Mac, you won't want to use the StrConv function at all. (It is the Unicode conversion process used in StrConv that won't work on the Mac. Other uses of StrConv, which aren't necessary in this tip, will work just fine.)

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

Each of these user-defined functions (AddDashes2 and AddDashes3) could be shortened by utilizing the StrConv approach described earlier, with the same caveat noted earlier.

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, 2021, 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

Using Mandatory Form Fields

When using form fields to gather information from users of your documents, you may want to make sure that some of the ...

Discover More

Permanently Turning Off the Tracking of Formatting Changes

The Track Changes tool can be a great asset when you are working on a document with others. It can also be a hassle if ...

Discover More

Generating a Keyword Occurrence List

Need to pull a list of words from a range of cells? This tip shows how easy you can perform the task using a macro.

Discover More

Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!

More ExcelTips (ribbon)

Compiling a List of Students in a Course

Need to pull just a limited amount of information from a large list? Here are a few approaches you might be able to use ...

Discover More

First Value Less Than or Equal to 100

If you need to evaluate a row of values to meet specific criteria, then you'll appreciate the discussion in this tip. It ...

Discover More

Counting Unique Values

Need to know a count of unique values in a range of cells? There are a couple of ways you can tackle the problem.

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 seven less than 8?

2024-10-04 15:44:16

J. Woolley

My Excel Toolbox includes the following regular expression function:
    =RegExReplace(Text, Pattern, Replacement,
        [Instance], [IgnoreCase], [Multiline])
This function uses the VBScript 5.5 regular expression syntax described here: https://learn.microsoft.com/en-us/previous-versions/1400241x(v=vs.85)
and https://drive.google.com/file/d/1qWS2qLib0sL_u6Sh95FuEeZxRzzr4SUE/view
It is similar to the new Excel function REGEXREPLACE described here: https://insider.microsoft365.com/en-us/blog/new-regular-expression-regex-functions-in-excel
The following formula satisfies the Tip's requirement:
    =RegExReplace(A1, "\w\B", "$&-")
"\w\B" matches any word character (A-Z, a-z, 0-9, and underscore) that is not followed by a word boundary (space).
"$&-" replaces the match with itself followed by dash (hyphen).
The default is global (all matches).
This is not an array formula and does not require Excel 2019 or later.
A1 can optionally be replaced by TRIM(A1); in that case the result is the same as the formula in my most recent comment below.
See https://sites.google.com/view/MyExcelToolbox/


2024-10-03 15:26:58

J. Woolley

My earliest comment below describes the following formula that uses the ForNext function in My Excel Toolbox:
    =SUBSTITUTE(
        TEXTJOIN("-", , MID(TRIM(A1), ForNext(1, LEN(TRIM(A1))), 1)),
        "- -", " ")
TEXTJOIN requires Excel 2019 or later, but My Excel Toolbox includes the JoinAsText function which duplicates TEXTJOIN except its 2nd argument IgnoreEmpty is required (not optional). Therefore, the following formula returns the same result:
    =SUBSTITUTE(
        JoinAsText("-", TRUE, MID(TRIM(A1), ForNext(1, LEN(TRIM(A1))), 1)),
        "- -", " ")
This array formula does not require Excel 2019, but in older versions it must be entered using Ctrl+Shift+Enter.
See https://sites.google.com/view/MyExcelToolbox/


2024-10-02 04:22:50

sandeep kothari

Got it Woolley. Thanks.


2024-10-01 09:56:41

J. Woolley

@sandeep kothari
Please review all the previous comments below.


2024-10-01 09:42:26

sandeep kothari

Dear Woolley, TEXTJOIN("-",,MID(A2,SEQUENCE(LEN(A2)),1)) also yields the same result as your bigger formula does. The SUBSTITUTE function is redundant here.


2024-09-30 11:30:51

J. Woolley

Andy's formula is fine:
    =SUBSTITUTE(TEXTJOIN("-",,MID(A1,SEQUENCE(LEN(A1)),1)),"- -"," ")
TEXTJOIN is in Excel 2019 but SEQUENCE requires Excel 2021 or later.
The following dynamic array function in My Excel Toolbox returns an array of numeric values beginning with Start incrementing by Step until Finish (not beyond):
    =ForNext(Start, Finish, [Step], [AsColumn])
Start, Finish, and Step can be any numeric value. Default Step is 1.
If AsColumn is FALSE (default), the result is a row array; TRUE returns a column array.
Here is a version of Andy's formula that uses ForNext instead of SEQUENCE in case you use Excel 2019:
    =SUBSTITUTE(
        TEXTJOIN("-", , MID(TRIM(A1), ForNext(1, LEN(TRIM(A1))), 1)),
        "- -", " ")
(The formula was divided into 3 lines for appearance.) Notice TRIM(A1) removes all spaces from text except single spaces between words; this would be useful in Andy's formula, also.
See https://sites.google.com/view/MyExcelToolbox/


2024-09-29 12:34:31

Jeff C

A LET could help:

=LET(
chars, MID(A1, SEQUENCE(LEN(A1)), 1),
hyphenated, TEXTJOIN("-", , chars),
cleaned, SUBSTITUTE(hyphenated, "- -", " "),
cleaned + N("Converts each character in A1 to an array, joins with hyphens, replaces double hyphens with a space."))

Or you could make a LAMBDA out of it and give it a name like 'Hypenator' so you can just enter =Hypenator (A1) etc.

=LAMBDA(input,
LET(
chars, MID(input, SEQUENCE(LEN(input)), 1),
hyphenated, TEXTJOIN("-", , chars),
cleaned, SUBSTITUTE(hyphenated, "- -", " "),
finalResult, cleaned + N("Converts each character in input to array, joins with hyphens, replaces double hyphens with space."),
finalResult
)
)


2024-09-29 09:32:07

Andy

Please ignore my previous suggestion, this is a shorter version which deals with multiple words:
=SUBSTITUTE(TEXTJOIN("-",,MID(A1,SEQUENCE(LEN(A1)),1)),"- -"," ")


2024-09-29 09:28:48

Andy

Hi Allen, for Excel 2021/365 this formula will deal with multiple words:
=SUBSTITUTE(TEXTJOIN("-",,MID(SUBSTITUTE(A1," ","@"),SEQUENCE(LEN(SUBSTITUTE(A1," ","@"))),1)),"-@-"," ")
I am sure there is an easier approach but that is the one that came to mind for me. It could be shortened slightly by using LET and defining SUBSTITUTE(A1," ","@") as a variable, as it's used twice in the formula. There may be a limit to the length of the string it can process, in that case the macro would be the better pick.


2024-09-28 10:15:47

Allen

Nice usage of the newer worksheet functions, Andy. There is one place where it isn't out of date, however, and that would be where your original cell contents contain spaces and you don't want the spaces to have dashes around them. In this case, I believe you still need the AddDashes3 macro.

-Allen


2024-09-28 07:40:58

Andy

If you have access to Excel 2021 or Office 365, then the tip is out of date. It can be done with this formula:

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


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.