Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 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: Breaking Up Variable-Length Part Numbers.
Written by Allen Wyatt (last updated September 14, 2019)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Marty has a worksheet with a long series of part numbers in column A. These consist of letters and numbers, such as A123BC, AB123C, etc. Marty wants to break the data into three columns, so that text before the numbers will be in one column, numbers in the second column, and text after the numbers in the third.
The factor that complicates dividing the part number into segments is that there is no set length for each component of the combined part number. If the components were of standard lengths, then you could use the Text to Columns function in Excel. Since they aren't, and there is no delimiter between the components, then that potential avenue for a solution is closed.
If you want to use formulas to pull apart the part numbers, then you will need three of them, one for each component you want to extract. Assuming that the part numbers follow the pattern indicated (text, digits, text) and that the first part number is in cell A1, you could use the following in cell B1:
=LEFT(A1,MATCH(FALSE,ISERROR(1*MID(A1,ROW(INDIRECT("1:100")),1)),0)-1)
This needs to be entered as an array formula, meaning that you need to enter it using Ctrl+Shift+Enter. The formula finds the first numeric digit in the part number, and then returns everything before that digit. It will work on any part number that isn't over 100 characters in length.
To extract the second component of the part number, you can put the following formula in cell C1:
=MID(A1,MATCH(FALSE,ISERROR(1*MID(A1,ROW(INDIRECT("1:100")), 1)),0),COUNT(1*MID(A1,ROW(INDIRECT("1:100")),1)))
Again, this is a single formula, and it needs to be entered as an array formula (Ctrl+Shift+Enter) so that it can work on each character in the original part number. It examines the part number and determines the beginning point of the digits, and then extracts all those digits. It returns a text string, even though that string is composed of digits. If you want it to actually be treated as a number (which would get rid of any leading zeros, of course), then you need to enclose the entire formula in a Value function, as shown here:
=VALUE(MID(A1,MATCH(FALSE,ISERROR(1*MID(A1,ROW(INDIRECT("1:100")), 1)),0),COUNT(1*MID(A1,ROW(INDIRECT("1:100")),1))))
To get the last component of the part number, you need to use the following formula, again entered as an array formula:
=MID(A1,MATCH(FALSE,ISERROR(1*MID(A1,ROW(INDIRECT("1:100")), 1)),0)+COUNT(1*MID(A1,ROW(INDIRECT("1:100")),1)),100)
While this approach works very well, array formulas are notoriously calculation intensive, especially when you have a lot of the formulas in your worksheet. If you need to pull apart a thousand part numbers, that means that you end up with 3,000 array formulas, which can be very, very slow in recalculating.
If you find yourself in this situation, you may want to use a macro to actually pull apart the part numbers. The following macro should work on part numbers that follow the pattern of text, digits, text, as already described.
Sub Split1() Dim C As Range Dim sNew As New Dim i As Integer For Each C In Selection sNew = "" i = 1 ' Get first part, which is text Do While IsNumeric(Mid(C, i, 1)) = False sNew = sNew & Mid(C, i, 1) i = i + 1 If i > Len(C) Then Exit Do Loop C.Offset(0, 1).Value = sNew ' Pull next part, which should be digits sNew = "" Do While IsNumeric(Mid(C, i, 1)) = True sNew = sNew & Mid(C, i, 1) i = i + 1 If i > Len(C) Then Exit Do Loop C.Offset(0, 2).Value = sNew ' Use rest of original cell sNew = Mid(C, i, Len(C)) C.Offset(0, 3).Value = sNew Next C End Sub
To use the macro, just make a selection of part numbers and run it. The macro uses the concept of looking for changes between numeric/nonnumeric values in a string of characters in the cell. When one of these boundaries is reached, the part of the original string before the boundary is stuffed into a new cell. This concept can be shortened a bit, as is done in the following example.
Sub Split2() Dim C As Range Dim j As Integer Dim k As Integer For Each C In Selection j = 1 Do While Not (IsNumeric(Mid(C.Value, j, 1))) And j <= Len(C) j = j + 1 Loop k = j Do While IsNumeric(Mid(C.Value, k, 1)) And k <= Len(C) k = k + 1 Loop C.Offset(0, 1) = Left(C, j - 1) C.Offset(0, 2) = Mid(C, j, k - j) C.Offset(0, 3) = Mid(C, k, Len(C) - (k - 1)) Next C End Sub
The difference between this version of the macro and the previous one, of course, is that this version steps through the original cell and determines the boundaries all at once. When they are known, then the components of the original part number are stuffed into the cells.
An interesting approach to pulling apart the part numbers is to use a couple of short user-defined functions that determine where the boundaries are between the components. Consider the following two functions:
Function pNumber(X) i = 1 Do Until Mid(X, i, 1) Like "#": i = i + 1: Loop pNumber = i End Function
Function pAlpha(X) X = UCase(X) i = pNumber(X) Do Until Mid(X, i, 1) Like "[A-Z]": i = i + 1: Loop pAlpha = i End Function
These are much shorter than the previous macros, and all they do is return the boundary where the numbers start (in the case of pNumber) and the boundary where the second group of text starts (in the case of pAlpha). To use the functions, you use the following three formulas to return, respectively, the first, second, and third components of the original part number:
=MID(A1,1,pNumber(A1)-1) =MID(A1,pNumber(A1),pAlpha(A1)-pNumber(A1)) =MID(A1,pAlpha(A1),LEN(A1)-pAlpha(A1)+1)
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10369) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Breaking Up Variable-Length Part Numbers.
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!
If you have a list of names in a column, and you want to know how many times those names appear in a larger list of data, ...
Discover MoreWhen processing data in a worksheet, you may have a need to know what the smallest (lowest) even value in a range is. You ...
Discover MoreOperators are used in formulas to instruct Excel what to do to arrive at a result. Not all operators are evaluated in the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-09-14 11:28:46
Willy Vanhaelen
Here is an alternitive for the second macro in this tip that is even a little bit shorter and in my opinion more consise:
Sub Split3()
Dim C As Range, X As Integer, Y As Integer
For Each C In Selection
For X = 1 To Len(C)
If IsNumeric(Mid(C, X, 1)) Then Exit For
Next X
For Y = X To Len(C)
If Not IsNumeric(Mid(C, Y, 1)) Then Exit For
Next Y
C.Offset(0, 1) = Left(C, X - 1) 'first text part
C.Offset(0, 2) = Mid(C, X, Y - X) 'digit(s) part
C.Offset(0, 3) = Mid(C, Y) 'last text part
Next C
End Sub
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 © 2024 Sharon Parq Associates, Inc.
Comments