Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later 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 November 26, 2016)

4

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.

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.

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

Deleting Styles

As documents evolve, so do your needs for various styles. You may create new ones and, invariably, old ones need to be ...

Discover More

Formatting Text Files with VBA

Got a bunch of text that you've imported from a text file? Need to make it look better? You can take a stab at it with this ...

Discover More

Hyphenating a Selection

Word provides a hyphenation tool that can help you hyphenate words within a document. If you want to apply hyphenation to ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (menu)

Finding the Sum of a Sequential Integer Range

In mathematics, the sum of a range of sequential integers, starting with 1, is known as a triangular number or Gaussian ...

Discover More

Counting Groupings Below a Threshold

When analyzing data, you may need to distill groupings from that data. This tip examines how you can use formulas and macros ...

Discover More

Calculating the Distance between Points

Want to figure out how far it is between two points on the globe? If you know the points by latitude and longitude, you can ...

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 6Mpixels. 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 seven less than 7?

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.


This Site

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.

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.