Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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: Finding the First Non-Digit in a Text Value.

Finding the First Non-Digit in a Text Value

by Allen Wyatt
(last updated August 29, 2015)

10

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").

Another possible array formula that should return the desired position is the following. This one should handle empty cells and strictly numeric values just fine, but it is shorter than the previously presented array formula:

=IFERROR(MATCH(1,ISERR(MID(A1,ROW(INDIRECT("1:"&LEN(A1))),1)*1)*1,),)

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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10610) applies to Microsoft Excel 2007, 2010, and 2013. You can find a version of this tip for the older menu interface of Excel here: Finding the First Non-Digit in a Text Value.

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

Defining Styles

Styles are a powerful component of Word. You use them to determine the way that your text should appear. This tip explains ...

Discover More

Correctly Saving Delimited Files

Delimited files are often created through Excel so that your data can be exported to other programs. If the delimited data ...

Discover More

Counting All Graphics

Need to know how many graphics a document contains? Getting at the true number may take a little more work than it first ...

Discover More

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!

More ExcelTips (ribbon)

Locating a Single-Occurrence Value in a Column

Given a range of cells containing values, you may have a need to find the first value in the range that is unique. This tip ...

Discover More

Getting a Conditional Count of Cells Containing Values

Excel provides several worksheet functions that can be used to count cells containing values—particularly numeric ...

Discover More

Counting Unique Values with Functions

Using Excel to maintain lists of information is not unusual. When working with the list you may need to determine how many ...

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}] in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 8Mpixels. 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 6 - 3?

2017-04-17 14:56:26

Dennis Costello

As Willy Vanhaelen pointed out early in this really old thread, the INDIRECT function has some baggage. But the key here is splitting the string to be matched into separate characters and testing each for membership in the acceptable set. Splitting the string is accomplished by the MID function; for a string such as the proposed example "1234567Blue." the call must be
MID(A1, {1;2;3;4;5;6;7;8;9;10;11;12}, 1)
Because this is a single-cell array function, Excel will execute the call to MID for each of the 12 values in its second parameter, returning "1" the first time, "2" the second time, ..., and "B" the eighth time. The VALUE call will be 1, 2, etc. - but will trip over the letter and return a #VALUE there. The ISERROR call will return FALSE until it gets to the #VALUE error, and the MATCH will return the position of the first instance of TRUE in the array of values. I go into this detail here because no-one addressed Martin's question at the beginning of the thread.

But how to get the array of constants {1;2;...;n} - where n is the length of the string in the cell - and thus start this happy sequence of events? The original formula had ROW(INDIRECT("1:"&LEN(A1))) - where A1 has a 12-character string, this evaluates as
ROW(INDIRECT("1:12"))
ROW($1:$12)
{1;2;3;4;5;6;7;8;9;10;11;12}
But you could also use OFFSET. The formula would be:
{=MATCH(TRUE, ISERROR(VALUE(MID(A1, ROW(OFFSET(A$1, 0, 0, LEN($A$1), 1)), 1))), 0)}

Its successive evaluation is:
{=MATCH(TRUE, ISERROR(VALUE(MID(<cell>, ROW(OFFSET(A$1, 0, 0, LEN($A$1), 1)), 1))), 0)}
MATCH(TRUE, ISERROR(VALUE(MID("1234567Blue.", ROW(OFFSET(A$1, 0, 0, LEN($A$1), 1)), 1))), 0)
MATCH(TRUE, ISERROR(VALUE(MID("1234567Blue.", ROW(OFFSET(A$1, 0, 0, 12, 1)), 1))), 0)
MATCH(TRUE, ISERROR(VALUE(MID("1234567Blue.", ROW($A$1:$A$12), 1))), 0)
MATCH(TRUE, ISERROR(VALUE(MID("1234567Blue.", {1;2;3;4;5;6;7;8;9;10;11;12}, 1))), 0)
MATCH(TRUE, ISERROR(VALUE({"1"; "2"; "3"; "4"; "5"; "6"; "7"; "B"; "l"; "u"; "e"; "."})), 0)
MATCH(TRUE, ISERROR({1; 2; 3; 4; 5; 6; 7; #VALUE!; #VALUE!; #VALUE!; #VALUE!; #VALUE!}), 0)
MATCH(TRUE, {FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; FALSE; TRUE; TRUE; TRUE; TRUE; TRUE}, 0)
8

Note that it doesn't matter what cell you're testing (that's why I showed it as "<cell>"), but in both the INDIRECT and OFFSET formulae, it's essential that the Reference parameter of OFFSET be somewhere on row 1.

Note also that you could also accomplish the same thing using COLUMN instead of ROW, by jiggering the parameters of the OFFSET function; if you do, the Reference parameter of OFFSET needs to be in column A for the same sort of reason, but it wouldn't matter what row it was on.

This addresses Wyatt's original problem statement - finding the first non-digit. It thus would return 3 for the string "12.345" whereas one of the proposed UDFs would recognize the decimal point as part of a legitimate number.

If you want to go completely off the deep end, none of the UDFs proposed in the thread would interpret scientific notation, e.g., "+1.234E-05", as a number - or for that matter even a signed integer, without adding a good deal more sophistication (it's not enough to simply allow E + - and . as valid characters, as they're only allowed in certain places). You could go nuts trying to get the parsing right, but it would probably be simpler to let VBA try to interpret it as a number and then go into the RE matching only if it isn't.


2016-12-05 10:21:54

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:15:56

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:40:45

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:22:22

Rick Rothstein

I forgot to declare my function "As Long"... anyone choosing to use it should add that function declaration.

Also, I forgot to 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.


2016-11-27 00:17:27

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)
Application.Volatile
FirstNonDigit = -Len(CStr(Val(S))) * (S Like "*[!0-9.]*")
End Function


2016-08-29 06:59:50

Ben Bol

This is very helpful. Searched a while on the net, found it here.
Thank you.


2015-08-29 09:37:14

Locke Garmin

Here is an alternative UDF using Regex.

Function SearchNonDigit(Source As String) As Long

With CreateObject("VBScript.Regexp")
.Pattern = "D"
On Error Resume Next
SearchNonDigit = .Execute(Source)(0).FirstIndex + 1
End With

End Function

If you remove the 'On Error Resume Next' it will produce a '#VALUE' result instead of '0', whichever you would prefer. :)


2015-08-29 08:02:17

Willy Vanhaelen

I always prefer a user defined function (UDF) instead of those lengthy complicated formulas.

Here is a much shorter UDF that does the job equally well:

Function FirstNonDigit(str As String)
Dim J As Integer
For J = 1 To Len(str)
If Not IsNumeric(Mid(str, J, 1)) Then
FirstNonDigit = J
Exit For
End If
Next J
End Function

I left out Application.Volatile because it not necessary here and has the disadvantage that the function gets recalculated each time you enter something in the sheet even in a cell that is not referenced by the function. This applies also to INDIRECT used in the formulas in this tip.


2015-08-29 07:15:34

Martin Nicol

I am left to guess why this formula works. Is it because 1:number, is not an error but 1:letter is an error?


This Site

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.

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.