Formula to slipt data into 3 parts

tonywatsonhelp

Well-known Member
Joined
Feb 24, 2014
Messages
3,210
Office Version
  1. 365
  2. 2019
  3. 2016
Platform
  1. Windows
Hi everyone,
Just had a nightmare download, and need to get this out asap.
hope some can help me
all my data has come in in one cell per row

It looks like this

[TABLE="width: 169"]
<colgroup><col></colgroup><tbody>[TR]
[TD]"127FsFredsmith(257)"[/TD]
[/TR]
</tbody>[/TABLE]
Now what I need is 3 columns

"127" "Fs" "Fredsmith(257)"
so the first part is always a number, could be any number,
the second Always starts with a Capital and ends at the Next Capital, will always be letters and only ever 1 or 2 long, then everything else left
please help if you can,
formula or VBA its all in column A at the mo.

Thanks
Tony
 

Excel Facts

Last used cell?
Press Ctrl+End to move to what Excel thinks is the last used cell.
Hi Tony,

Got somewhat of a fix, but the assumption I have made is that the "Fs" part is always 2 characters long... I'll try fix this but try this in the mean time:
Define the following UDF:
Code:
Function NumberSeparator(txt As String) As String
    With CreateObject("VBScript.RegExp")
        .Global = True
        .Pattern = "\D"
        NumberSeparator = .Replace(txt, ".")
    End With
End Function
Then assuming "127FsFredSmith(257)" is in cell A1 then try these 3 formula's in B1, C1 & D1:
B1: =LEFT(NumberSeparator(A1),SEARCH(".",NumberSeparator(A1))-1)
C1: =MID(A1,SEARCH(".",NumberSeparator(A1)),2)
D1: =MID(A1,LEN(B1)+LEN(C1)+1,100)
 
Last edited:
Upvote 0
Here's another option, note that they rely on each other to return the correct result.


Excel 2013/2016
ABCD
1127FsFredsmith(257)127FsFredsmith(257)
212345678GFfdsfmds 1ds1a212345678GFfdsfmds 1ds1a2
Sheet1
Cell Formulas
RangeFormula
B1=LEFT(A1,AGGREGATE(15,6,FIND(CHAR(ROW(INDIRECT("65:90"))),$A1),1)-1)
C1=MID(A1,LEN(B1)+1,AGGREGATE(15,6,FIND(CHAR(ROW(INDIRECT("65:90"))),MID($A1,LEN(B1)+2,LEN(A1))),1))
D1=MID(A1,LEN(B1)+LEN(C1)+1,LEN(A1))
 
Upvote 0
Tried a similar but slightly different approach to my first solution which seems to work (if you are interested in using regular expressions with VBA) then you can also try this formula:

Code:
Function CountCapitals(txt As String) As String
    With CreateObject("VBScript.RegExp")
        .Global = True
        .Pattern = "[A-Z]"
        CountCapitals = .Replace(txt, "#")
    End With
End Function

B1:
=LEFT(CountCapitals(A1),SEARCH("#",CountCapitals(A1))-1)

C1:
=SUBSTITUTE(MID(CountCapitals(A1),LEN(B1)+1,SEARCH("#",MID(CountCapitals(A1),LEN(B1)+1,100),2)-1),"#",MID(A1,LEN(B1)+1,1))

D1:
=SUBSTITUTE(MID(CountCapitals(A1),LEN(B1)+LEN(C1)+1,100),"#",MID(A1,LEN(B1)+LEN(C1)+1,1))

Where A1 is the text extracted e.g. 127FsFredsmith(257)
B1 will show: 127
C1 will show: Fs
D1 will show: Fredsmith(257)
 
Upvote 0
FormR Thank you, worked great,
Tyija, great idea, i love the functions as they can be used in so many different ways, thank you
Big thank you for this i am in time for my 12 noon deadline :-)
Tony
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,176
Members
453,021
Latest member
Justyna P

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