Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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.
Written by Allen Wyatt (last updated June 10, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
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.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10610) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. 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.
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!
Replacing one character in a text value with another character is easy. All you need to do is use the SUBSTITUTE ...
Discover MoreWhen you discover that there is an invalid reference in a workbook, you can have a bear of a time tracking down the ...
Discover MoreDo you need to know how many precedents or dependents there are on a worksheet? You could count them manually, or you ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2021-09-21 15:21:10
Chris
Here's one, how do you find the first number from the end of a string?
Example:
5.552A.P
7.1156A
8.345.P
2020-11-21 12:12:49
Willy Vanhaelen
Here is my version of the function and a lot smaller and very efficient too:
Function FirstNonDigit(str As String)
If str Like String(Len(str), "#") Then Exit Function
For FirstNonDigit = 1 To Len(str)
If Not Mid(str, FirstNonDigit, 1) Like "#" Then Exit For
Next
End Function
I use rather unusual techniques as
If str Like String(Len(str), "#") Then Exit Function
which tests if the cell is empty or numeric and if so quits.
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments