Formula to get data with specific logic from a string

PANIGGR

New Member
Joined
Sep 4, 2015
Messages
18
I have below data in column A, in this string suffixed with data like "(12345/A76D7YF)". I need numeric and alphanumeric character in two different columns. Please note that customer names before above section may also contain (, ) and /. Uniqueness of column A is that after the last open bracket "(", the required numeric and alphanumeric data comes which may help is building any logic/VBA code

[TABLE="class: grid, width: 500"]
<tbody>[TR]
[TD]

<colgroup><col width="97"></colgroup><tbody>
[TD="class: xl66, width: 97"]JAMES WALKER (614726/ 8CZNISNS )
[/TD]

</tbody>
[/TD]
[TD]8CZNISNS
[/TD]
[TD]614726
[/TD]
[/TR]
[TR]
[TD]

<colgroup><col width="97"></colgroup><tbody>
[TD="class: xl66, width: 97"]ABC Ltd (306521476/ 3BAX80ZJ )
[/TD]

</tbody>
[/TD]
[TD]3BAX80ZJ
[/TD]
[TD]306521476
[/TD]
[/TR]
[TR]
[TD]

<colgroup><col width="97"></colgroup><tbody>
[TD="class: xl66, width: 97"]Woodside/Ltd (3953084/ MZ0QR1LJ )
[/TD]

</tbody>
[/TD]
[TD]MZ0QR1LJ
[/TD]
[TD]3953084
[/TD]
[/TR]
[TR]
[TD]

<colgroup><col width="97"></colgroup><tbody>
[TD="class: xl66, width: 97"]Smiths) Ltd (467578/ A3RJ67K3K )
[/TD]

</tbody>
[/TD]
[TD]A3RJ67K3K
[/TD]
[TD]467578
[/TD]
[/TR]
[TR]
[TD][TABLE="width: 97"]
<colgroup><col width="97"></colgroup><tbody>[TR]
[TD="class: xl66, width: 97"](Highland/YUYU(5961944/2GN4E1U8)
[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[TD]2GN4E1U8
[/TD]
[TD]5961944
[/TD]
[/TR]
</tbody>[/TABLE]
 
.. building any logic/VBA code
Since you mentioned vba code, here is an option for that. This one should produce the alpha-numeric in column B and the numeric in column C as per your first post.

Code:
Sub ExtractData()
  With Range("B2:B" & Range("A" & Rows.Count).End(xlUp).Row)
    .Value = .Offset(, -1).Value
    .Replace What:="*(", Replacement:="", LookAt:=xlPart
    .TextToColumns Destination:=.Offset(, 1).Cells(1), DataType:=xlDelimited, OtherChar:="/", FieldInfo:=Array(Array(1, 1), Array(2, 9))
    .Replace What:="*/", Replacement:="", LookAt:=xlPart
    .Replace What:=")", Replacement:="", LookAt:=xlPart
  End With
End Sub

If you are happy with the results the other way around as per sandy666's sample in post 2 then it can be a tiny bit shorter:

Code:
Sub ExtractData_v2()
  With Range("B2:B" & Range("A" & Rows.Count).End(xlUp).Row)
    .Value = .Offset(, -1).Value
    .Replace What:="*(", Replacement:="", LookAt:=xlPart
    .Replace What:=")", Replacement:="", LookAt:=xlPart
    .TextToColumns DataType:=xlDelimited, OtherChar:="/"
  End With
End Sub
 
Last edited:
Upvote 0

Excel Facts

How to create a cell-sized chart?
Tiny charts, called Sparklines, were added to Excel 2010. Look for Sparklines on the Insert tab.
Formula option:

Excel 2012
ABC
JAMES WALKER(614726/8CZNISNS)8CZNISNS
ABC Ltd (306521476/3BAX80ZJ)3BAX80ZJ
Woodside/Ltd (3953084/MZ0QR1LJ)MZ0QR1LJ
Smiths) Ltd (467578/A3RJ67K3K)A3RJ67K3K
(Highland/YUYU(5961944/2GN4E1U8)2GN4E1U8
(Highland/abc(ok)(123456/A23B34XX)A23B34XX

<tbody>
[TD="align: center"]1[/TD]

[TD="align: right"]614726[/TD]

[TD="align: center"]2[/TD]

[TD="align: right"]306521476[/TD]

[TD="align: center"]3[/TD]

[TD="align: right"]3953084[/TD]

[TD="align: center"]4[/TD]

[TD="align: right"]467578[/TD]

[TD="align: center"]5[/TD]

[TD="align: right"]5961944[/TD]

[TD="align: center"]6[/TD]

[TD="align: right"]123456[/TD]

</tbody>
Sheet4


[TABLE="width: 85%"]
<tbody>[TR]
[TD]Worksheet Formulas[TABLE="width: 100%"]
<tbody>[TR]
[TH]Cell[/TH]
[TH="align: left"]Formula[/TH]
[/TR]
[TR]
[TH]B1[/TH]
[TD="align: left"]=TRIM(SUBSTITUTE(RIGHT(SUBSTITUTE(A1,"/",REPT(" ",LEN(A1))),LEN(A1)),")",""))[/TD]
[/TR]
[TR]
[TH]C1[/TH]
[TD="align: left"]=TRIM(RIGHT(SUBSTITUTE(LEFT(A1,LEN(A1)-LEN(B1)-2),"(",REPT(" ",LEN(A1))),LEN(A1)))[/TD]
[/TR]
</tbody>[/TABLE]
[/TD]
[/TR]
</tbody>[/TABLE]

Thank you
 
Upvote 0
Since you mentioned vba code, here is an option for that. This one should produce the alpha-numeric in column B and the numeric in column C as per your first post.

Code:
Sub ExtractData()
  With Range("B2:B" & Range("A" & Rows.Count).End(xlUp).Row)
    .Value = .Offset(, -1).Value
    .Replace What:="*(", Replacement:="", LookAt:=xlPart
    .TextToColumns Destination:=.Offset(, 1).Cells(1), DataType:=xlDelimited, OtherChar:="/", FieldInfo:=Array(Array(1, 1), Array(2, 9))
    .Replace What:="*/", Replacement:="", LookAt:=xlPart
    .Replace What:=")", Replacement:="", LookAt:=xlPart
  End With
End Sub

If you are happy with the results the other way around as per sandy666's sample in post 2 then it can a tiny bit shorter:

Code:
Sub ExtractData_v2()
  With Range("B2:B" & Range("A" & Rows.Count).End(xlUp).Row)
    .Value = .Offset(, -1).Value
    .Replace What:="*(", Replacement:="", LookAt:=xlPart
    .Replace What:=")", Replacement:="", LookAt:=xlPart
    .TextToColumns DataType:=xlDelimited, OtherChar:="/"
  End With
End Sub

This worked, thank you logical formula sometime takes time if the data is huge. This is is quite easy as compared to power query and logical formula
 
Upvote 0
This worked, thank you logical formula sometime takes time if the data is huge. This is is quite easy as compared to power query and logical formula
You're welcome.

Of course the 'easiness' of a particular solution also depends on your own individual skills & experience. Anyway, you had a good variety of options to choose from. :)
 
Upvote 0
Of course the 'easiness' of a particular solution also depends on your own individual skills & experience.

clapping2.gif
 
Upvote 0

Forum statistics

Threads
1,223,236
Messages
6,170,917
Members
452,366
Latest member
TePunaBloke

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