Split cell at transition from number to any other character

jlove

New Member
Joined
Aug 7, 2007
Messages
29
Say we have "100112model2", I want to split out the 100112 piece. The kicker for me is its not left(a1, 6) because the count of numbers before the first non-numeric character is variable. Could also "4432/mebb4" - Here again I need the 4432 piece.
Thanks
 

Excel Facts

Can you sort left to right?
To sort left-to-right, use the Sort dialog box. Click Options. Choose "Sort left to right"
Hello try this out.....

=LEFT(A1,MATCH(TRUE,ISERROR(VALUE(MID(A1,ROW(INDIRECT("1:"&LEN(A1))),1))),0)-1)

*This is an array formula which is used by doing CTRL + SHIFT + ENTER while in the formula bar and then drag down your list*
 
Last edited:
Upvote 0
Assuming your number is never longer than 8 digits (formula can be fixed if it is, just tell us what the longest possible number is), here is another formula you can try (one less function call and normally entered)...

=LEFT(A1,SUM(ISNUMBER(-MID(A1,{1,2,3,4,5,6,7,8},1))*NOT(ISNUMBER(-MID(A1,{2,3,4,5,6,7,8,9},1)))*{1,2,3,4,5,6,7,8}))
 
Upvote 0
Again assuming the leading number is no more than 8 digits, here's one with a few less function calls again

=LEFT(A1,AGGREGATE(15,6,{1,2,3,4,5,6,7,8,9}/ISERROR(MID(A1,{1,2,3,4,5,6,7,8,9},1)+0),1)-1)
 
Upvote 0
.. or considerably shorter:

=LEFT(A1,MATCH(TRUE,ISERROR(MID(A1,{1,2,3,4,5,6,7,8,9},1)+0),0)-1)
 
Upvote 0

Forum statistics

Threads
1,216,085
Messages
6,128,733
Members
449,465
Latest member
TAKLAM

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top