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:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10182) applies to Microsoft Excel 2007 and 2010. You can find a version of this tip for the older menu interface of Excel here: Inserting Dashes between Letters and Numbers.
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!
When working with arrays in a formula, it can be a bit confusing to understand how they work. In this tip I examine a ...
Discover MoreWhen you are working with sequenced values in a list, you’ll often want to take some action based on the top X or ...
Discover MoreWhen editing a formula, the F4 shortcut key can be helpful. It may not, however, be helpful in all instances. This tip ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2025-10-07 07:15:51
jamies
VBA scripts assume the data of "myText" is to be accessed as the attribute ".VALUE"
and that may do conversion of entries that look like dates to be held as the numeric version - dayNUMBER and fractional part of the day for a timestamp so it's no longer text
Also it may take a number that appears to be in a currency format cell to be USD, and - round it to 2 decimal places ( maybe bankers rounding !) and add a preceding "$" so it's a text value !
Maybe force Formula result to be text by preceding the generated, or intermediate results with ""& stops the formula/function generating 0 for ,"", and ,,
and in VBA specify .VALUE2 to avoid the unwanted Excel processing !
But do check that functions in the excel sheet do not fail when processing empty cells that are "void text strings" rather than 0
It may also be appropriate to check that
your added "-" is not being added where there was already the needed "-", so generating "--"
and that adding the "-" does not get Excel to consider that value as a negative number,
and that the Excel considering the value as a number has not removed leading "0"'s, or imbedded "," or ".", or "E" meaning scientific number entry ,
and that - for your location, language, date the "-", or "/" are treated as meaning it is a dd mm, or mm dd structured date.
Maybe use TRIM on the data - or maybe keep extra whitespace - within as well as at the start and end of a string,
and there is the growing propensity to use unicode to put graphics in data fields as text characters - changing the just typed set of characters e.g. 1F697 with a unicode character by pressing ALT, and then X to get đźš—
and that works for filenames even getting leading spaces with " đźš—"
and ... ... that sort of thing works with excel sheet tabs too !
Finally - in this response -
A first character of "'" denotes a text value is being entered into a cell, and sometimes that confuses VBA where the data seems to get a an extra "'" added so the value being processed contains a leading pair of of apostrophe's on the text string , and "^" may be taken as meaning Text, and to be centred in the cell !
From experience, Data Cleaning and standardisation is not always simple !
and that's with just the expected language and codepage settings !
2025-10-07 04:41:06
Rene
As mentioned in a previous post, the flash solution works. A formula can also be used:
=LEFT(A1,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A1&"0123456789"))-1)
& "-" &
MID(A1,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A1&"0123456789")),99)
Power query also works:
let
InsertDash = (code as text) =>
let
pos = List.PositionOfAny(Text.ToList(code), {"0".."9"}),
result = if pos > 0
then Text.Start(code, pos) & "-" & Text.Range(code, pos)
else code
in
result
in
InsertDash
Then add a custom column using InsertDash([ProductCode]).
Avoids having to use macros.
2020-06-11 04:21:06
Mike
ASAPUTILITIES has a couple of functions that would work here:-
ASAPSTRIPNUMBERS() will remove the digits and ASAPEXTRACTNUMBERS() will remove the alphacharacters, so
=ASAPSTRIPNUMBERS(A1)&"-"&ASAPEXTRACTNUMBERS(A1)
would do what is required
2014-12-23 15:51:13
I Think I'm inching close: How can I do this in Word?
2013-12-18 11:57:02
Willy Vanhaelen
Instead of those complicated formulas, I prefer a user defined function. Here is a much shorter one:
Function DashIn(myText As String)
Dim i As Integer
For i = 2 To Len(myText)
If IsNumeric(Mid(myText, i, 1)) Then
myText = Left(myText, i - 1) & "-" & Mid(myText, i)
Exit For
End If
Next i
DashIn = myText
End Function
2013-12-16 13:33:04
gerdami
Much more easy to do with regular expressions.
Go to http://www.codedawn.com/excel-add-ins.php and install RegEx Find/Replace.
With the product codes in column A,
type =RegExReplace(A1,"([a-zA-Z]+)([0-9]+)","$1-$2") in cell B1, and copy down the formula.
The search field:
([a-zA-Z]+) is first "token", i.e. one or many letters.
([0-9]+) is the second toke, i.e. one or many digits.
The replace field indicates that token $1 is concatenated to "-", then to the token $2.
2013-12-16 12:24:04
TSpeake
In Excel 2013, the new Flash Fill feature does what is requested virtually automatically. It even handles the case where there are different numbers of letters, i.e., A4, BR16, P33, etc.
Make sure you have uniquely formatted column headers. Select the cell next to the first data entry, and type "A-4". Now, on the Data tab, in the Data Tools group, click on the Flash Fill icon. The second column will contain "BR-16", "P-33", etc.
As Arthur C. Clarke said, "Any sufficiently advanced technology is indistinguishable from magic."
See the tutorials that come with Help on Flash Fill.
2013-12-16 08:29:10
Michael (Micky) Avidan
The first suggested formula can be much shorter - something like:
=REPLACE(A1,2,,"-")
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2014)
ISRAEL
2013-04-20 10:40:55
WRosocha
I am thankful for the macro code. I will leave the array formula for Excel Ph.D.'s working on a post Doc.
In the macro, using the Boolean function IsNumeric(sChar) will simplify the test for a numeric character. It returns TRUE if sChar is a character that can be converted to a numeric.
If IsNumeric (Mid(myText, i, 1)) Then...
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments