Written by Allen Wyatt (last updated June 29, 2021)
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.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
It is easy to use Excel functions to sum values based on criteria you establish, unless those criteria involve the ...
Discover MorePostal codes in Canada consist of six characters, separated into two groups. This tip explains the format and then shows ...
Discover MoreWhen working with large amounts of data, it is a good idea to make sure that the data all consistently follows a pattern. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2016-12-05 10:20:34
Rick Rothstein
{follow up to last post}
Darn, one asterisk too many. Here is my corrected function...
Function FirstNonDigit(S As String)
Application.Volatile
FirstNonDigit = -Len(CStr(Val(S))) * (S Like "*[!0-9.]*") - (S Like "#*")
End Function
2016-12-05 10:17:22
Rick Rothstein
@Willy Vanhaelen
Actually, my function does not return the correct value for either integers or floating point numbers. I am not sure why, but I constructed my function to return the position of the last digit for the leading number, not the position of the first non-digit. Here is my corrected function to do that (still a one-liner... if we ignore the Application.Volatile that is)...
Function FirstNonDigit(S As String)
Application.Volatile
FirstNonDigit = -Len(CStr(Val(S))) * (S Like "*[!0-9.]*") - (S Like "*#*")
End Function
2016-12-04 13:39:04
Willy Vanhaelen
@Rick Rothstein
Your UDF is a nice one liner again but only yields a correct answer when the entry starts with a floating point number. For example 123P99 returns 3 instead of 4.
But counting a period as a digit may not necessarily be wanted. Such entrees are by definition always strings and I suppose will mostly refer to part codes and when they include a period, it can as well be the goal to detect that as the first non digit.
2016-11-27 00:27:28
Rick Rothstein
There is a much simpler UDF (user defined function) that will produce the same results as your posted UDF...
Function FirstNonDigit(S As String) As Long
Application.Volatile
FirstNonDigit = -Len(CStr(Val(S))) * (S Like "*[!0-9.]*")
End Function
I would also note that my function appears to work properly with floating point numbers as well as whole numbers... your function reports the location of the decimal point for floating point values.
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 © 2023 Sharon Parq Associates, Inc.
Comments