Skip to main content

How to find position of first/last number in a text string in Excel?

For example, you have a list of text string which is a mixture of letters and numbers. If you want to find the position of the first or last number in each string, what would you do? Actually, using formula will help you quickly find the position of first/last number in a specified text string. In this tutorial, we will show you the details of dealing with this problem.

Find position of first number in text string in Excel
Find position of last number in text string in Excel


Find position of first number in text string in Excel

As the below screenshot shown, for finding positions of first numbers in the text strings, please do as follows.

1. Select the cell B2, copy and paste one of the below formula into the Formula Bar:

1). Formula 1: =MIN(SEARCH({0,1,2,3,4,5,6,7,8,9},A2&"0123456789"));

2). Formula 2: =MATCH(TRUE,ABS(CODE(MID(A2,ROW($A$1:INDEX(A:A,LEN(A2))),1))-52.5)<5,0) + Ctrl + Shift + Enter;

3). Formula 3: =MIN(IF(ISERROR(FIND({1;2;3;4;5;6;7;8;9;0},A2)),"",FIND({1;2;3;4;5;6;7;8;9;0},A2))).

2. Then the first number position of the first string is displaying in the cell B2. Now drag the Fill Handle down to cell B7 to fill the below range.

Then all first number positions of the whole strings are listed out.


Find position of last number in text string in Excel

After finding the position of first number, we now start finding the position of last number in strings.

In this section, there are two formulas for you.

Formula 1: =MAX(IF(ISNUMBER(VALUE(MID(A2,ROW(INDIRECT("1:" & LEN(A2))),1))),ROW(INDIRECT("1:" & LEN(A2))))) + Ctrl + Shift + Enter;

Formula 2: =MAX(IFERROR(FIND({1,2,3,4,5,6,7,8,9,0},A2,ROW(INDIRECT("1:"&LEN(A2)))),0)) + Ctrl + Shift + Enter

1. Select cell B2, copy and paste one of the above formulas into the Formula Bar, then press Ctrl + Shift + Enter keys simultaneously. Then you can see the result displays in B2.

2. Select the B2, drag the Fill Handle down to cell B7 to auto fill the range.

Then you will get positions of all last numbers of the whole text string immediately.


Easily separate text and number from one cell into two columns in Excel:

With Kutools for Excel’s Split Cells utility, you can split a range of cells into rows or columns by specific separator, split text and numbers or split text by certian length. Download and try it now! (30-day free trail)


Related articles:

Best Office Productivity Tools

🤖 Kutools AI Aide: Revolutionize data analysis based on: Intelligent Execution   |  Generate Code  |  Create Custom Formulas  |  Analyze Data and Generate Charts  |  Invoke Kutools Functions
Popular Features: Find, Highlight or Identify Duplicates   |  Delete Blank Rows   |  Combine Columns or Cells without Losing Data   |   Round without Formula ...
Super Lookup: Multiple Criteria VLookup    Multiple Value VLookup  |   VLookup Across Multiple Sheets   |   Fuzzy Lookup ....
Advanced Drop-down List: Quickly Create Drop Down List   |  Dependent Drop Down List   |  Multi-select Drop Down List ....
Column Manager: Add a Specific Number of Columns  |  Move Columns  |  Toggle Visibility Status of Hidden Columns  |  Compare Ranges & Columns ...
Featured Features: Grid Focus   |  Design View   |   Big Formula Bar    Workbook & Sheet Manager   |  Resource Library (Auto Text)   |  Date Picker   |  Combine Worksheets   |  Encrypt/Decrypt Cells    Send Emails by List   |  Super Filter   |   Special Filter (filter bold/italic/strikethrough...) ...
Top 15 Toolsets12 Text Tools (Add Text, Remove Characters, ...)   |   50+ Chart Types (Gantt Chart, ...)   |   40+ Practical Formulas (Calculate age based on birthday, ...)   |   19 Insertion Tools (Insert QR Code, Insert Picture from Path, ...)   |   12 Conversion Tools (Numbers to Words, Currency Conversion, ...)   |   7 Merge & Split Tools (Advanced Combine Rows, Split Cells, ...)   |   ... and more

Supercharge Your Excel Skills with Kutools for Excel, and Experience Efficiency Like Never Before. Kutools for Excel Offers Over 300 Advanced Features to Boost Productivity and Save Time.  Click Here to Get The Feature You Need The Most...

Description


Office Tab Brings Tabbed interface to Office, and Make Your Work Much Easier

  • Enable tabbed editing and reading in Word, Excel, PowerPoint, Publisher, Access, Visio and Project.
  • Open and create multiple documents in new tabs of the same window, rather than in new windows.
  • Increases your productivity by 50%, and reduces hundreds of mouse clicks for you every day!
Comments (15)
No ratings yet. Be the first to rate!
This comment was minimized by the moderator on the site
Ich habe gerade diese Lösung ausprobiert und es klappt bei mir nicht. Hat sich inzwischen etwas, was die Matrixformel betrifft, geändert?
This comment was minimized by the moderator on the site
Hi Wolfgang,

The formulas provided in this post work well in my case. What result did you get?
This comment was minimized by the moderator on the site
Thought I would let everyone know that I needed to find the last position of the house numbers in an address field in access. The only way I could do this was to export a short query to excel and run this formula. I know there is a way to get the excel functions in access but this was much easier. I had addresses that had varying house number lengths and then you throw in the 1st, 2nd, 3rd...St., Ave into the mix within the street name and you got a major problem parsing a very bad formatted address string.

address examples 1234 nw (or NW) 4th St.
12 West St North (or N)
123,456, and 789 Heritage Circle (or Crc)
123 & 456 N 1st. St

I figured out a way to parse off the first and second example real quick with some research (I would give credit, but right now I can't remember where I got the answer). It involved creating a VBA function to accomplish it. That worked great but I came to a problem when we come to the first "," or "and" or "&".

Using this formula in excel found the last number I needed without choosing the street number. Since most house numbers ended with a space " " between them and the direction segment or the street name segment, I added --- &" " after the find formula. Like this: in an array formula
=MAX(IFERROR(FIND({1,2,3,4,5,6,7,8,9,0}&" ",E2,ROW(INDIRECT("1:"&LEN(E2)))),0))
A quick export back to an access table and wala! you have the number.
202 & 206 N Blanche Ave = 9

Now I know I could probably parse the rest of the address in excel but it actually worked real well in Access, so I just decided to do the rest there.

If there is a way to do it all in Access, I couldn't find it or figure it out.
This comment was minimized by the moderator on the site
goood, thanks
This comment was minimized by the moderator on the site
That's what I needed =MIN(SEARCH({0,1,2,3,4,5,6,7,8,9},A2&"0123456789"));

thank you very much!
This comment was minimized by the moderator on the site
You are welcome O(∩_∩)O
This comment was minimized by the moderator on the site
how to get this to work in powerpivot
This comment was minimized by the moderator on the site
Hi,
Sorry can't help with this.
This comment was minimized by the moderator on the site
.... and here I thought that I knew Excel well. Bravo!!!!!
This comment was minimized by the moderator on the site
And here is a formula for finding the position of the last numeric character in a string, but WITHOUT using an array formula: =MAX(SEARCH(CHAR(9),SUBSTITUTE("0123456789"&A1,{0,1,2,3,4,5,6,7,8,9},CHAR(9),LEN(A1)+10-LEN(SUBSTITUTE("0123456789"&A1,{0,1,2,3,4,5,6,7,8,9},"")))))-10 The number 10 appearing in this formula, are due to the length of the constant string "0123456789", that is concatenated in this formula.
This comment was minimized by the moderator on the site
Many Thanks , Great
This comment was minimized by the moderator on the site
Hi George, your formula is may meet my requirement. I need similar formula to find out digit position in the string listed in "A" row in B row Required output 8 5 1 4 3 1 3 2 5 5 6 6 1 7 9 9 1 1 6 0 9 3 0 2 7 4 9 3 6 5 5 7 4 9 8 10 2 10 0 8 1 9
This comment was minimized by the moderator on the site
This was exactly what I wanted. Thank you.
This comment was minimized by the moderator on the site
The function 1). Formula 1: =MIN(SEARCH({0,1,2,3,4,5,6,7,8,9},A2&"0123456789")); It's absolutely what i needed and extremely cool! Thanks so much! Jon
This comment was minimized by the moderator on the site
Hats off mate..
There are no comments posted here yet
Please leave your comments in English
Posting as Guest
×
Rate this post:
0   Characters
Suggested Locations