TextToColumns, VBA to uncheck "Treat consecutive delimiters as one"

realtoast

New Member
Joined
Nov 24, 2015
Messages
47
Office Version
  1. 365
Platform
  1. Windows
  2. MacOS
  3. Mobile
  4. Web
The below code parses a single column address to dedicated columns for Address1, Address2, City, State, Zip. The code first tests the original column and places commas so that TextToColumns can do its work with commas as the delimeter. My problem is, Excel keeps returning the TextToColumns selection for "Treat consecutive delimiters as one" as True. This causes the function to fail because, where people do not have an apartment number (Address2), the code places two commas. With the above checkbox selected as True, TTC ignores what should be a blank cell and moves City to where the blank cell should be. It basically shuffles the output.

VBA Code:
    Application.DisplayAlerts = False
    Columns("O:W").Select
    Selection.Insert Shift:=xlToRight, CopyOrigin:=xlFormatFromLeftOrAbove
    
    With Range("N1", Range("N" & Rows.Count).End(xlUp)).Columns(3)
        .Columns("O:W").ClearContents
        .Value = Evaluate(Replace("if(len(#)-len(substitute(#,"","",""""))<4,substitute(#,"","","",,"",1),if(#<>"""",#,""""))", "#", .Columns(-1).Address))
        .TextToColumns .Cells(1), 1, comma:=True, Tab:=False, Space:=False
        .CurrentRegion.Columns.AutoFit
    End With



I've tried unchecking the box before running the script, but it keeps returning to True.

Delimiter.PNG
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Here is the code I get from recording my actions for TTC:
VBA Code:
Sub Macro2()
'
' Macro2 Macro
'

'
    Selection.TextToColumns Destination:=Range("A1"), DataType:=xlDelimited, _
        TextQualifier:=xlDoubleQuote, ConsecutiveDelimiter:=False, Tab:=False, _
        Semicolon:=False, Comma:=True, Space:=False, Other:=False, FieldInfo _
        :=Array(Array(1, 1), Array(2, 1)), TrailingMinusNumbers:=True
End Sub
 
Upvote 0
Try adding that argument directly into your script, i.e.
change this line:
Rich (BB code):
        .TextToColumns .Cells(1), 1, comma:=True, Tab:=False, Space:=False
to this:
Rich (BB code):
        .TextToColumns .Cells(1), 1, ConsecutiveDelimiter:=False, comma:=True, Tab:=False, Space:=False
 
Upvote 0
Solution
Try adding that argument directly into your script, i.e.
change this line:
Rich (BB code):
        .TextToColumns .Cells(1), 1, comma:=True, Tab:=False, Space:=False
to this:
Rich (BB code):
        .TextToColumns .Cells(1), 1, ConsecutiveDelimiter:=False, comma:=True, Tab:=False, Space:=False
Thank you. This works!
 
Upvote 0
You are welcome.
Glad we could help (we were all really saying the same thing!)
 
Upvote 0

Forum statistics

Threads
1,223,099
Messages
6,170,114
Members
452,302
Latest member
TaMere

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