Extract multiple text from string

Pinkoko

New Member
Joined
Dec 15, 2016
Messages
3
Hi all,

I have been searching for vba code that could extract multiple string which begin with the symbol "$".

However the pattern for the text is valid, sometime have a few hyphen "-", sometime only 1 hyphen "-".

Sometime it end with a spacing sometime is not.

Another condition would be, if the string contain multiple text begin with "$", need to auto add another cell below then extract the text.

For example:

ORIGINAL:

Name Type
A ( $WERT-X1-ERT - $RFV-XC )
B $QAZ-OKP - ( UJN-HHJ-:OPK )
C (( RFG-IJN-ERTTY + $IJKKL-RF-ASDFG - $VGT-BN6678 ) / $NJIO-ZXC6789
D ( HUJB-BN-MN ) - $UJ-HJI876

EXPECTED RESULT:

Name Type
A $WERT-X1-ERT
A $RFV-XC
B $QAZ-OKP
C $IJKKL-RF-ASDFG
C $VGT-BN6678
C $NJIO-ZXC6789
D $UJ-HJI876
 

Excel Facts

How can you turn a range sideways?
Copy the range. Select a blank cell. Right-click, Paste Special, then choose Transpose.
Pinkoko,

Welcome to the MrExcel forum.

Here is a macro solution for you to consider that is based on your displayed flat text, and, results.

You can change the raw data worksheet name in the macro.

Sample raw data:


Excel 2007
ABCDEF
1NameType
2A( $WERT-X1-ERT - $RFV-XC )
3B$QAZ-OKP - ( UJN-HHJ-:OPK )
4C(( RFG-IJN-ERTTY + $IJKKL-RF-ASDFG - $VGT-BN6678 ) / $NJIO-ZXC6789
5D( HUJB-BN-MN ) - $UJ-HJI876
6
7
8
9
Sheet1


And, after the macro:


Excel 2007
ABCDEF
1NameTypeNameType
2A( $WERT-X1-ERT - $RFV-XC )A$WERT-X1-ERT
3B$QAZ-OKP - ( UJN-HHJ-:OPK )A$RFV-XC
4C(( RFG-IJN-ERTTY + $IJKKL-RF-ASDFG - $VGT-BN6678 ) / $NJIO-ZXC6789B$QAZ-OKP
5D( HUJB-BN-MN ) - $UJ-HJI876C$IJKKL-RF-ASDFG
6C$VGT-BN6678
7C$NJIO-ZXC6789
8D$UJ-HJI876
9
Sheet1


Please TEST this FIRST in a COPY of your workbook (always make a backup copy before trying new code, you never know what you might lose).

1. Copy the below code
2. Open your NEW workbook
3. Press the keys ALT + F11 to open the Visual Basic Editor
4. Press the keys ALT + I to activate the Insert menu
5. Press M to insert a Standard Module
6. Where the cursor is flashing, paste the code
7. Press the keys ALT + Q to exit the Editor, and return to Excel
8. To run the macro from Excel press ALT + F8 to display the Run Macro Dialog. Double Click the macro's name to Run it.

Code:
Sub ExtractMultipleText()
' hiker95, 12/15/2016, ME981131
Dim b As Range, s, i As Long
Dim nr As Long
Application.ScreenUpdating = False
With Sheets("Sheet1")   '<-- you can change the sheet name here
  .Columns("E:F").ClearContents
  .Cells(1, 5).Resize(, 2).Value = Array("Name", "Type")
  nr = 1
  For Each b In .Range("B2", .Range("B" & Rows.Count).End(xlUp))
    If InStr(b, "$") Then
      s = Split(b, " ")
      For i = LBound(s) To UBound(s)
        If Left(s(i), 1) = "$" Then
          nr = nr + 1
          .Cells(nr, 5).Value = b.Offset(, -1).Value
          .Cells(nr, 6).Value = s(i)
        End If
      Next i
    End If
  Next b
  .Columns("E:F").AutoFit
End With
Application.ScreenUpdating = True
End Sub

Before you use the macro with Excel 2007 or newer, save your workbook, Save As, a macro enabled workbook with the file extension .xlsm, and, answer the "do you want to enable macros" question as "yes" or "OK" (depending on the button label for your version of Excel) the next time you open your workbook.

Then run the ExtractMultipleText macro.
 
Upvote 0
Here is the code I came up with... it assumes header text in cells A1:B1 and sends output to Column E:F).
Code:
[table="width: 500"]
[tr]
	[td]Sub ExtractAtDollarSign()
  Dim R As Long, X As Long, Fixed As Variant, Data As Variant, Tmp() As String
  Data = Range("A1", Cells(Rows.Count, "B").End(xlUp))
  ReDim Fixed(1 To UBound(Data))
  For R = 2 To UBound(Data)
    Tmp = Split(Mid(Data(R, 2), InStr(Data(R, 2), "$") + 1), "$")
    For X = 0 To UBound(Tmp)
      Tmp(X) = "$" & Left(Tmp(X), InStr(Tmp(X) & " ", " ") - 1)
    Next
    Fixed(R) = Data(R, 1) & Chr(1) & Join(Tmp, Chr(2) & Data(R, 1) & Chr(1))
  Next
  Application.ScreenUpdating = False
  With Range("E1")
    .Resize(, 2).EntireColumn.ClearContents
    Fixed = Split(Join(Fixed, Chr(2)), Chr(2))
    .Resize(UBound(Fixed) + 1) = Application.Transpose(Fixed)
    .EntireColumn.TextToColumns , xlDelimited, , , False, False, False, False, True, Chr(1)
    .Resize(, 2) = Array("Name", "Type")
  End With
  Application.ScreenUpdating = True
End Sub[/td]
[/tr]
[/table]
 
Last edited:
Upvote 0
Hi, hiker95,

Thanks a million, it works like gem!
For you consideration...

I don't know how many cells you have to process, and the time difference may not matter to you even if you have a lot of cells to process, but the code I posted in Message #3 is 20 times faster than the code hike95 posted (10,000 rows of data... hiker95's code took 3.15 seconds, mine took 0.15 seconds). As I said, that time difference (in human terms) may not be enough to warrant your changing procedures... I just figured I would point it out.
 
Upvote 0

Forum statistics

Threads
1,214,881
Messages
6,122,074
Members
449,064
Latest member
MattDRT

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