Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Specifying a Delimiter when Saving a CSV File in a Macro.

Specifying a Delimiter when Saving a CSV File in a Macro

Written by Allen Wyatt (last updated February 29, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021


When using the tools available from the ribbon to export a worksheet, as a CSV file, Arkadiusz noted that he can specify that he wants to use a semicolon (;) as a field delimiter. However, if he saves a CSV file using a macro (FileFormat:=xlCSV or xlCSVWindows), then he cannot specify a semicolon as a delimiter.

This works this way by design in VBA. The Excel implementation of the export routines for VBA always use whatever the Windows regional settings are to determine how items in a CSV should be separated. Specifically, the routine looks at the List Separator field for the delimiter. This means that you can, if desired, change the delimiter to a semicolon by changing the List Separator setting in your regional settings configuration.

If you don't want to change the regional settings, then you can instead write your own macro that will output the file in any way you desire. Consider, for a moment, the following macro, which will output the file:

Sub CreateFile()
    Dim sFName As String
    Dim Rows As Long
    Dim Cols As Long
    Dim J As Long
    Dim K As Long
    Dim sTemp As String
    Dim sSep As String

    sSep = ";"  'Specify the separator to be used

    sFName = ActiveWorkbook.FullName
    If Right(sFName, 5) = ".xlsx" Then
        sFName = Mid(sFName, 1, Len(sFName) - 5)
        sFName = sFName & ".txt"
        Open sFName For Output As 1

        With ActiveSheet
            'Number of rows to export is based on the contents
            'of column B. If it should be based on a different
            'column, change the following line to reflect the
            'column desired.
            Rows = .Cells(.Rows.Count, "B").End(xlUp).Row
            For J = 1 To Rows
                sTemp = ""
                Cols = .Cells(J, .Columns.Count).End(xlToLeft).Column
                For K = 2 To Cols
                    sTemp = sTemp & .Cells(J, K).Value
                    If K < Cols Then sTemp = sTemp & sSep
                Next
                Print #1, sTemp
            Next J
        End With

        Close 1

        sTemp = "There were " & Rows & " rows of data written "
        sTemp = sTemp & "to this file:" & vbCrLf & sFName
    Else
        sTemp = "This macro needs to be run on a workbook "
        sTemp = sTemp & "stored in the XLSX format."
    End If

    MsgBox sTemp
End Sub

This macro opens a text file that has the same name as your workbook. It then steps through each row and starts putting together a string of the cell contents. (This is put into the sTemp variable.) Each cell has a semicolon placed between it, as defined by the sSep variable. Each row's concatenated values are stored in the text file, and when done the text file is closed. The routine is very quick, and when done it displays a message indicating how many rows were exported to the file.

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 (9243) 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: Specifying a Delimiter when Saving a CSV File in a Macro.

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

Determining the Upper Bounds of an Array

When working with variables in a macro, you may need to know the upper boundary dimension for an array. This can be ...

Discover More

Making Your Formulas Check for Errors

Want to use a formula to check if there is an error in your formula? (Sounds confusing, but it's not that bad.) You'll ...

Discover More

Handling Negative Numbers in a Complex Custom Format

Custom formats are great for defining how a specific value in a cell should look. They aren't that great at doing complex ...

Discover More

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!

More ExcelTips (ribbon)

Finding the Path to the Desktop

Figuring out where Windows places certain items (such as the user's desktop) can be a bit frustrating. Fortunately, there ...

Discover More

Converting Text to Numbers

Import information from a program external to Excel, and your numbers may be treated as text because of the way that the ...

Discover More

Understanding the While...Wend Structure

Logical structures are important in programming, as they allow you to control how the programming statements are ...

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 six more than 6?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.