Text to Columns on Two, or more, blank spaces?

blbat

Active Member
Joined
Mar 24, 2010
Messages
338
Office Version
  1. 2016
  2. 2013
In Cell A1 I have a Huge Text String that originated in a .pdf file.

There are no useful delimiters, such as commas or semi-colons.

any text that has two or more spaces between is a field in the original .pdf

is there a way to split this out is by using two or more blank spaces as the delimiter?
 
Here is a macro that will do what I think you want...
Code:
Sub SplitOnMultipleSpaces()
  Dim V As Variant, Txt As String
  Txt = Replace(Replace(Range("A1").Value, Chr(160), " "), vbLf, Space(2))
  For Each V In Array(121, 13, 5, 3, 3)
    Txt = Replace(Txt, Space(V), Space(2))
  Next
  V = Split(Txt, Space(2))
  Range("B1").Resize(, UBound(V) + 1) = V
End Sub

HOW TO INSTALL MACROs
------------------------------------
If you are new to macros, they are easy to install and use. To install it, simply press ALT+F11 to go into the VB editor and, once there, click Insert/Module on its menu bar, then copy/paste the above code into the code window that just opened up. That's it.... you are done. To use the macro, go back to the worksheet with your data on it and press ALT+F8, select the macro name (SplitOnMultipleSpaces) from the list that appears and click the Run button. The macro will execute and perform the action(s) you asked for. If you will need to do this again in this same workbook, and if you are using XL2007 or above, make sure you save your file as an "Excel Macro-Enabled Workbook (*.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.
 
Upvote 0

Excel Facts

Excel Can Read to You
Customize Quick Access Toolbar. From All Commands, add Speak Cells or Speak Cells on Enter to QAT. Select cells. Press Speak Cells.
If you are looking for a manual method (& assuming the spaces are 'normal' spaces), try these steps
1. Find/Replace Find what: Enter 2 space characters, Replace with: |
2. Find/Replace Find what: "| " (without the ") Replace with: |
3. Now do Text to Columns with | as the delimiter and 'Treat consecutive delimiters as one'
 
Last edited:
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,175
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