Written by Allen Wyatt (last updated August 13, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
One of the handiest features in Excel is the Text to Columns feature, which allows you to easily split cell contents into individual cells according to any criteria you specify. One method of using the feature is to allow it to recognize characters within the cells and use those characters to trigger where the split should take place. This type of splitting is referred to as a delimited split.
You may be wondering how you can perform a delimited text-to-columns operation in a macro you may be writing. This is easy enough to do by using the TextToColumns method on a selection you set up. Consider the following very simple macro:
Sub ExampleSplit1() Selection.TextToColumns _ Destination:=Range("A2"), _ DataType:=xlDelimited, _ TextQualifier:=xlDoubleQuote, _ ConsecutiveDelimiter:=False, _ Tab:=True, _ Semicolon:=False, _ Comma:=False, _ Space:=False, _ Other:=True, _ OtherChar:="-" End Sub
Notice all the variables that you can set for the TextToColumns method. Most of these variables are only necessary because this is a delimited split; the variables set what is used as a delimiter by the method. Beginning with the Tab line, the variables correspond directly to the settings you would make in Step 2 of the Convert Text to Columns Wizard, if you were manually using the feature. You can set Tab, Semicolon, Comma, and Space to either True or False, depending on whether you want that character used as a delimiter.
You can also set the Other variable to True or False, depending on whether you want to have a "user defined" delimiter. If you set it to True, then you should set the OtherChar variable equal to the character you want used as a delimiter.
If you use the TextToColumns method multiple times in the same macro, the only thing you need to do on invocations subsequent to the first is to change variables that differ from the previous invocation. For instance, let's say that you are calling the method twice in the same macro, and the first time you want the split to be on an instance of the dash character, but the second you want it to be on any instance of a lowercase x. You can put the macro together like this:
Sub ExampleSplit2() Dim objRange1 As Range Dim objRange2 As Range 'Set up the ranges Set objRange1 = Range("A2:A20") Set objRange2 = Range("A21:A35") 'Do the first parse objRange1.TextToColumns _ Destination:=Range("A2"), _ DataType:=xlDelimited, _ Tab:=False, _ Semicolon:=False, _ Comma:=False, _ Space:=False, _ Other:=True, _ OtherChar:="-" 'Do the second parse objRange2.TextToColumns _ Destination:=Range("A21"), _ DataType:=xlDelimited, _ OtherChar:="x" End Sub
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (8317) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021. You can find a version of this tip for the older menu interface of Excel here: Delimited Text-to-Columns in a Macro.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
Need to know how many characters there are in a workbook? You can find out easily with the handy macro introduced in this ...
Discover MoreDo you get tired of the dialog box that says "do you want to enable macros" that is displayed when you open a workbook. ...
Discover MoreWhen creating macros, you'll often have a need to select different cells in the worksheet. Here's how to select the first ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2019-08-02 09:01:07
Dennis Costello
The fact that the parameters are "sticky" - that TextToColumns - e.g. if the comma parameter is elided, it will have the same value as the last time it was invoked. That stickiness extends to the spreadsheet action, too - if you do TextToColumns with space delimiting in VBA, space delimiting will be in place the next time you do a TextToColumns in the DataTools box on the Data ribbon. More insidiously, it will also apply the next time you just paste something into a column. So it's a good practice in VBA to do a "null" TextToColumns at the end of your macro, turning off all these parameters.
Been burned by this in the past...
On a related note, one might wish, when using TextToColumns in a macro, to find out what the current sticky settings are before changing them in your invocation, so you can do the "null" TextToColumns in a way that restores those parameters. I'm sure there's a set of properties somewhere containing this (perhaps read-only), but I've never been able to find them.
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments