Procedure to export a text file with both comma and quote delimiters in Excel
Article
Applies to:
Office Excel 2007, Office Excel 2003, Excel 2002
Summary
Microsoft Excel doesn't have a menu command to automatically export data to a text file so that the text file is exported with both quotation marks and commas as delimiters. For example, there's no command to automatically create a text file that contains the following data:
"Text1","Text2","Text3"
However, you can create this functionality in Excel by using a Microsoft Visual Basic for Applications procedure.
More information
Microsoft provides programming examples for illustration only, without warranty either expressed or implied. This includes, but isn't limited to, the implied warranties of merchantability or fitness for a particular purpose. This article assumes that you're familiar with the programming language that is being demonstrated and with the tools that are used to create and to debug procedures. Microsoft support engineers can help explain the functionality of a particular procedure, but they won't modify these examples to provide added functionality or construct procedures to meet your specific requirements.
You can use the Print # statement in a Visual Basic procedure that is similar to the following to export a text file with both quotation marks and commas as the delimiters. For the procedure to function correctly, select the cells that contain your data before you run it.
Before you work with the following sample code, follow these steps:
Open a new workbook.
In Microsoft Office Excel 2003 or in Microsoft Excel 2002, point to Macro on the Tools menu, and then click Visual Basic Editor. Alternatively, press ALT+F11.
In Microsoft Office Excel 2007, click the Developer tab, and then click
Visual Basic in the Code group. Alternatively, press ALT + F11.
Note
To show the Developer tab in the Ribbon, click the Microsoft Office Button, click Excel Options, click thePopular category, click to select the Show Developer tab in the Ribbon check box, and then click OK.
In the Visual Basic Editor, click Module on the Insert menu.
Type or paste the following sample code in the module sheet.
VB
Sub QuoteCommaExport()
' Dimension all variables.Dim DestFile AsStringDim FileNum AsIntegerDim ColumnCount AsLongDim RowCount AsLong' Prompt user for destination file name.
DestFile = InputBox("Enter the destination filename" _
& Chr(10) & "(with complete path):", "Quote-Comma Exporter")
' Obtain next free file handle number.
FileNum = FreeFile()
' Turn error checking off.OnErrorResumeNext' Attempt to open destination file for output.
Open DestFile For Output As#FileNum
' If an error occurs report it and end.
If Err <> 0 Then
MsgBox "Cannot open filename " & DestFile
End
End If
' Turn error checking on.
On Error GoTo 0
' Loop for each row in selection.
For RowCount = 1 To Selection.Rows.Count
' Loop for each column in selection.
For ColumnCount = 1 To Selection.Columns.Count
' Write current cell's text to file with quotation marks.
Print #FileNum, """" & Selection.Cells(RowCount, _
ColumnCount).Text & """";
' Check if cell is in last column.If ColumnCount = Selection.Columns.Count Then' If so, then write a blank line.
Print #FileNum,
Else
' Otherwise, write a comma.
Print #FileNum, ",";
EndIf' Start next iteration of ColumnCount loop.Next ColumnCount
' Start next iteration of RowCount loop.Next RowCount
' Close destination file.
Close #FileNum
End Sub
Before you run the macro, select the data that you want to export, and then run the QuoteCommaExport subroutine.
Demonstrate that you have the advanced skills needed to get the most out of Excel 2016 by earning a Microsoft Office Specialist (MOS) Expert certification.