Written by Allen Wyatt (last updated February 24, 2024)
This tip applies to Excel 97, 2000, 2002, and 2003
Tony has a bunch of data in a worksheet that consists of digits and other characters. For instance, he might have a cell that contains "1234567Blue." Tony wants to be able to figure out the character position at which the first non-digit character occurs. In the example of the text "1234567Blue" Tony wants some way to figure out that the first non-digit character is at position 8.
There are two primary ways to get the value you want. The first is to use an array formula to calculate the position. The following array formula (entered by using Ctrl+Shift+Enter) will work in the majority of cases:
=MATCH(TRUE,ISERROR(VALUE(MID(A1,ROW(INDIRECT("1:"&LEN(A1))),1))),0)
The only instances where this array formula won't work is if cell A1 is either empty or contains a strictly numeric value. If your list may contain this type of data (or no data at all), then you should consider using a slightly longer array formula:
=IF(LEN(A1)=0,0,MIN(IF(1*ISNUMBER(1*MID(A1,ROW(INDIRECT("A1:A"& LEN(A1))),1))=0,ROW(INDIRECT("A1:A"&LEN(A1))),LEN(A1)+1)))* (ISNUMBER(A1)=FALSE)
Remember that that is a single array formula, entered by using Ctrl+Shift+Enter. It will properly handle instances where A1 contains no non-digit characters (as in a blank cell or a value such as "123").
Of course, the other way you can handle finding out the position of the first non-digit character is to create a user-defined function. There are many different ways that such a macro can be implemented. One of the easiest ways to implement the macro is to simply step through each character in whatever is passed to the macro. When a character is found that is outside the ASCII code range for digits (48 to 57), then you know you've found the first position. The following macro shows a way to do this type of technique:
Function FirstNonDigit(str As String) Dim iChar As Integer Dim iPos As Integer Dim J As Integer Application.Volatile iPos = 0 For J = 1 To Len(str) iChar = Asc(Mid(str, J, 1)) If iChar <= 47 Or iChar >= 58 Then iPos = J Exit For End If Next J FirstNonDigit = iPos End Function
To use the function, simply use a formula such as this in your worksheet:
=FirstNonDigit(A1)
If the cell you reference is empty or if it only contains digits, then the function returns a 0 value.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3364) 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: Finding the First Non-Digit in a Text Value.
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!
When processing some text data, you may need to perform some esoteric function, such as adding dashes between letters. ...
Discover MoreDo you need to determine the top three values in a range of columns? The techniques discussed in this tip will come in ...
Discover MoreWhen analyzing data, you may need to distill groupings from that data. This tip examines how you can use formulas and ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
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