Changing the Default Text Import Delimiter

Written by Allen Wyatt (last updated December 18, 2021)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


1

Bill's solar inverter saves a daily file in which the fields are delimited by a semicolon (;). When he imports it into Excel using the Text Import Wizard, the default delimiter is a tab character. Bill has to uncheck Tab and check Semicolon each time he imports, so he is wondering if there is a way to change the default delimiter character.

There are several different ways you could approach this issue, as described in the following sections.

Changing Your Regional Settings

If you want to have Excel always recognize the semicolon as a delimiter, then you can make a change in the regional settings used by Windows. Follow these steps:

  1. Press the Windows key and immediately start typing "con" (without the quote marks). Windows should show you that the best match for your typing is the Control Panel app.
  2. Press Enter. Windows opens the Control Panel.
  3. Using the View By drop-down list (upper-right corner of the Control Panel), make sure you are viewing by Category.
  4. Click the "Change Date, Time, or Number Formats" option, just under the Clock and Region heading. Windows displays the Region dialog box.
  5. Click the Additional Settings option. Windows displays the Customize Format dialog box. (See Figure 1.)
  6. Figure 1. The Customize Format dialog box.

  7. Change the List Separator setting to a semicolon.
  8. Click OK to close the Customize Format dialog box.
  9. Click OK to close the Region dialog box.
  10. Close the Control Panel

At this point you can restart Excel and use the Text Import Wizard to import your file. Excel should default to using the semicolon as a delimiter. And, interestingly enough, if you open a CSV file that uses commas as a delimiter, then the Text Import Wizard will default to using a comma.

Remember that any changes you make in your regional settings can affect the operation of other programs in addition to Excel. If you make a change like that above, you'll want to check those programs to make sure there are no adverse effects from the change.

Changing the Text to Column Settings

Notice that the heading to this approach indicates you are changing the "Text to Column" settings, and Bill specifically asked about the "Text Import Wizard." Despite what may initially seem to be a conflation of the two tools, it is important to realize that the Text Import Wizard relies upon the Text to Column tool as part of the import process. Thus, if you can change the settings in the Text to Column tool, you'll also affect how the Text Import Wizard works.

The problem is that the Text to Column settings are not persistent from one session of Excel to another. They are persistent within the same session, however. Thus, you could write a quick little macro that would change the settings so that whenever you start using Excel, you are good to go. This is an example:

Private Sub Workbook_Open()
    Worksheets.Add
    Range("A1").Value = "TEST"

    Application.ScreenUpdating = False
    Range("A1").TextToColumns Destination:=Range("A1"), _
      DataType:=xlDelimited, TextQualifier:=xlDoubleQuote, _
      ConsecutiveDelimiter:=False, Tab:=False, Semicolon:=True, _
      Comma:=False, Space:=False, Other:=False, FieldInfo:=Array(1,1), _
      TrailingMinusNumbers:=True

    Application.DisplayAlerts = False
    ActiveSheet.Delete
    Application.DisplayAlerts = True
    Application.ScreenUpdating = True
End Sub

When stored in the ThisWorkbook module of a workbook, this event handler will fire every time the workbook is opened. It adds a new worksheet, puts some dummy text in cell A1 of that worksheet, and then does a Text to Columns operation on that dummy text. The worksheet is then deleted. Since the TextToColumns method sets the semicolon as the delimiter, that is remembered for the entire Excel session (unless it is later changed). This means that you can then use the Text Import Wizard to grab your data, and the desired delimiter is already set for you.

Writing Your Own Import Routine

Of course, you could bypass the Text Import Wizard completely and use your own macro to do the importing. This is a particularly good approach if (1) you know how the incoming data is structured and (2) you need to do the import quite often. Here's an example of a macro that could be used to do the importing:

Sub ImportDailyFile()
    Dim R As Range
    Dim S As String

    Const F = "C:\Users\Your Name\Documents\DailyFile.txt"

    Worksheets.Add
    Open F For Input As #1
    Set R = ActiveCell
    Do Until EOF(1)
        Line Input #1, S
        R.Value = S
        Set R = R.Offset(1, 0)
    Loop
    Close #1

    Set R = R.Offset(-1, 0)
    Set R = Range(ActiveCell.Address, R.Address)
    R.TextToColumns Semicolon:=True
End Sub

In order to use the macro, you'll need to change the constant value to reflect the full path to your data file. The macro adds a new worksheet into which your data will be placed. It will then open the data file, read each line, and place those lines in column A of the new worksheet. Once all the data has been read and saved, the macro then selects all cells in column A and performs a Text To Columns operation on that data, using the semicolon as a delimiter.

Using Power Query

Many people like to use Power Query to import data from external files. If you fall into this growing camp, then you can use Power Query to define how Excel should treat the information it imports. Here are the general steps:

  1. Display the Data tab of the ribbon.
  2. Click the Get Data tool. Excel displays a drop-down menu.
  3. Choose Launch Power Query Editor. Excel displays the Power Query Editor.
  4. In the Power Query Editor, make sure the Home tab of the ribbon is displayed. (It should be displayed by default.)
  5. Click the New Source tool, in the New Query group at the right side of the ribbon. Excel displays some options for types of sources you can use.
  6. Choose File | Text/CSV. Excel displays the Import Data dialog box. (This looks very similar to a standard Open dialog box.)
  7. Using the controls in the dialog box, locate and select the file you want to use as your data source.
  8. Click the Open button. Excel thinks for a moment and displays the traditional Text Import Wizard window.
  9. Click OK to dismiss the window. Excel displays your data in the Power Query Editor.
  10. Display the Transform tab of the ribbon.
  11. Click the Use First Row as Headers tool and then choose Use First Row as Headers. (Yes, it's the same wording twice.)
  12. If appropriate, select columns and use the options under the Text Column tool to modify the format of your data columns or make other alterations in the imported data.
  13. On the Home tab of the ribbon, click the Close & Load tool. Excel displays the imported data in a data table.

Now you can work with the data as you desire.

Note:

If you would like to know how to use the macros described on this page (or on any other page on the ExcelTips sites), I've prepared a special page that includes helpful information. Click here to open that special page in a new browser tab.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12708) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Displaying the Print Dialog Box in a Macro

Want to print a document by using a macro? One way is to display the Print dialog box and allow the user to interact with ...

Discover More

Mixing Note Numbering

When inserting footnotes and endnotes in a document, most of us don't give much thought to the format used in the ...

Discover More

Using a Standard Format in a Suggested File Name

Many companies (and some individuals) use specific formats for naming their documents. If you want Word to recognize your ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Is It Worth Converting Data to a Table?

Excel allows you to work with your data in many different ways. One way is to convert your data to a structured table. ...

Discover More

Taking Pictures

Have you ever wanted to take a "picture" of a part of a worksheet and put it in another section? This tip explains how to ...

Discover More

Inserting a Sound File in Your Worksheet

Some worksheets are better understood through the spoken word or with musical accompaniment. Sound files can be easily ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is 4 + 5?

2021-12-20 12:01:59

Alex Nejako

This was a good one!


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.