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: Inserting Dashes between Letters and Numbers.

Inserting Dashes between Letters and Numbers

Written by Allen Wyatt (last updated January 11, 2025)
This tip applies to Excel 97, 2000, 2002, and 2003


Let's say you have a worksheet with lots of product codes in column A. These codes are in the format A4, B12, AD4, etc. Due to a change in the way your company operates, you are directed to change all the product codes so they contain a dash between the letters and the numbers.

There are several ways you can perform this task. If the structure of your product codes is consistent, then inserting the dashes is a snap. For instance, if there will always be a single letter followed by numbers, then you could use a formula such as this:

=LEFT(A1,1) & "-" & RIGHT(A1,LEN(A1)-1)

Chances are good that your data won't be structured, meaning you could have one or two letters followed by up to three digits. Thus, both A4 and QD284 would both be valid product codes. In this case, a solution formula takes a bit more creativity.

One way to handle it is with an array formula. Consider the following formula:

=REPLACE(A1,MATCH(FALSE,ISERROR(1*MID(A1,ROW(INDIRECT("1:100")),1)),0),0,"-")

If values are in A1-A10, you can put this formula into B1, and then copy it down the column. Since it is an array formula, it must be entered by pressing Ctrl+Shift+Enter. The formula finds the location of the first number in the cell and inserts a dash before it.

Assume, for the sake of example, that cell A1 contains BR27. The innermost part of the formula, INDIRECT("1:100"), converts the text 1:100 to a range. This is used so that inserting or deleting rows does not affect the formula. The next part of the formula, ROW(INDIRECT("1:100")), essentially creates an array of the values 1-100: 1,2,3,...,99,100. This is used to act on each character in the cell.

The next part, MID(A1,ROW(INDIRECT("1:100")),1), refers to each individual character in the string. This results in the array: "B", "R", "2", and "7". Multiplying the array by 1 (the next part of the formula) results in each of the individual characters being converted to a number. If the character is not a number, this conversion yields an error. In the case of the string being converted (BR27), this results in: #VALUE, #VALUE, 2, and 7.

The next step is to apply the ISERROR function to the results of the multiplication. This converts the errors to TRUE and the non-errors to FALSE, yielding TRUE, TRUE, FALSE, and FALSE. The MATCH function looks in the array of TRUE and FALSE values for an exact match of FALSE. In this example, the MATCH function returns the number 3, since the first FALSE value is in the third position of the array. At this point, we essentially know the location of the first number in the cell.

The final function is REPLACE, which is used to actually insert the dash into the source string, beginning at the third character.

As you can tell, the formula to perform the transformation can be a bit daunting to decipher. For those so inclined, it may be easier to just create a user-defined function. The following macro is an example of one that will return a string with the dash in the proper place:

Function DashIn(myText As String)
    Dim i As Integer
    Dim myCharCode As Integer
    Dim myLength As Integer

    Application.Volatile
    myLength = Len(myText)
    For i = 1 To myLength
        myCharCode = Asc(Mid(myText, i, 1))
        If myCharCode >= 48 And myCharCode <= 57 Then
            Exit For
        End If
    Next i
    If i = 1 Or i > myLength Then
        DashIn = myText
    Else
        DashIn = Left(myText, i - 1) & "-" _
          & Mid(myText, i, myLength - 1)
    End If
End Function

The macro examines each character in the original string, and when it finds the first numeric character, it inserts a dash at that point. You would use the function in this way:

=DashIn(A1)

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 (2613) 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: Inserting Dashes between Letters and Numbers.

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

Selecting Combo Boxes in Locked Worksheets

Once you protect a worksheet, you may run into problems with any combo boxes that the worksheet contains. This is a ...

Discover More

Adjusting Row Height for Your Text

Want Excel to automatically adjust the height of a worksheet row when it wraps text within the cell? It's easy to do, ...

Discover More

Changing Focus when Starting to Print

Sometimes small changes between versions of Word can affect how we do our work. (And, thereby, bug the heck out of us.) ...

Discover More

Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!

More ExcelTips (menu)

Reference Shortcut

Need to modify how a cell reference, in a formula, is constructed? The shortcut described in this tip will help you step ...

Discover More

Adjusting Formulas when Pasting

The Paste Special feature in Excel can be used to uniformly adjust values and formulas. This tip shows how powerful this ...

Discover More

Inserting Rows

Need to insert rows in your worksheet? Excel provides a few techniques you can use to do this. Here are some ideas you ...

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 two minus 0?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.