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

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:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

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

Adding Drop Shadows to Cells

Want to draw attention to what is in a cell? What better way than to add a drop shadow to that cell! Here's how you can ...

Discover More

Finding Documents Containing Multiple Occurrences of a Word

Searching for documents that contain a particular word is rather straightforward. The task becomes a bit trickier when ...

Discover More

Weird Actions for Arrow Keys and Enter

If your arrow keys and the Enter key aren't working as you expect them to, the problem could have any number of causes. ...

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)

Character Replacement in Simple Formulas

Do you see some small rectangular boxes appearing in your formula results? It could be because Excel is substituting that ...

Discover More

Non-adjusting References in Formulas

Sometimes making sure that a reference in a formula doesn't get changed is not as simple as putting dollar signs in front ...

Discover More

Using a Formula to Replace Spaces with Dashes

If you need a formula to change spaces to some other character, the SUBSTITUTE function fits the bill. Here's how to use it.

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}] (all 7 characters, in the sequence shown) 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 4 + 1?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.