vba code or formula to Split string when alphabetic changes to numeric

jsb1921

Board Regular
Joined
Aug 14, 2020
Messages
74
Office Version
  1. 2007
Platform
  1. Windows
  2. Web
I have some alphanumeric data in col A. it has 4 parts.
part 1 starts at char 1 and ends whereever a numeric char is found.
part 2 ends when a alphabetic char is found.
part 3 is only one char always.
part 4 is rest of the string. can be a number or a decimal.

I am looking for a vba code (or excel formula) to split them in the 4 parts in a quick way
thanks in advance

Book1
ABCDE
1TREE200717C1550TREE200717C1550
2ZAN200626C54ZAN200626C54
3ZAN200717C52.5ZAN200717C52.5
4BHC200619C19.5BHC200619C19.5
5C200619C13.5C200619C13.5
6GPS200717C12GPS200717C12
7MAXR200821C20MAXR200821C20
8
9
10ALPHANUMERIC+NUMERIC+ALPHANUMERIC+NUMERIC OR DECIMAL
Sheet1
 

Excel Facts

Spell Check in Excel
Press F7 to start spell check in Excel. Be careful, by default, Excel does not check Capitalized Werds (whoops)
I really hope someone can come along with a better solution than this (VBA using Regex perhaps?)

split.xlsm
ABCDE
1TREE200717C1550TREE200717C1550
2ZAN200626C54ZAN200626C54
3ZAN200717C52.5ZAN200717C52.5
4BHC200619C19.5BHC200619C19.5
5C200619C13.5C200619C13.5
6GPS200717C12GPS200717C12
7MAXR200821C20MAXR200821C20
8
9
10ALPHANUMERIC+NUMERIC+ALPHANUMERIC+NUMERIC OR DECIMAL
Sheet1
Cell Formulas
RangeFormula
B1:B7B1=TRIM(LEFT(A1,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A1&"0123456789"))-1))
C1:C7C1=LOOKUP(10^6,1*MID(A1,MIN(FIND({0,1,2,3,4,5,6,7,8,9},A1&"0123456789",FIND(B1," "&A1))),{2,3,4,5,6}))
D1:D7D1=MID(A1,LOOKUP(2,1/(ISNUMBER(SEARCH(MID(A1,ROW(INDIRECT("1:"&LEN(A1))),1),"abcdefghijklmnopqrstuvwxyz"))),ROW(INDIRECT("1:"&LEN(A1)))),1)
E1:E7E1=RIGHT(A1,LEN(A1)-SEARCH("#",SUBSTITUTE(A1,D1,"#",LEN(A1)-LEN(SUBSTITUTE(A1,D1,"")))))
 
Upvote 0
Solution
Perhaps your sample data is not fully representative but for all of your examples, the second part is a 6-digit number beginning with 2.
If that was so, then

22 06 30.xlsm
ABCDE
1TREE200717C1550TREE200717C1550
2ZAN200626C54ZAN200626C54
3ZAN200717C52.5ZAN200717C52.5
4BHC200619C19.5BHC200619C19.5
5C200619C13.5C200619C13.5
6GPS200717C12GPS200717C12
7MAXR200821C20MAXR200821C20
Split Text
Cell Formulas
RangeFormula
B1:B7B1=LEFT(A1,FIND(C1,A1)-1)
C1:C7C1=MID(A1,FIND(2,A1),6)+0
D1:D7D1=MID(A1,FIND(C1,A1)+6,1)
E1:E7E1=REPLACE(A1,1,LEN(B1&C1&D1),"")+0
 
Upvote 0

Forum statistics

Threads
1,215,408
Messages
6,124,727
Members
449,185
Latest member
ekrause77

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