Often we face the challenge of having to merge csv files or txt files in a folder, into a single file. Excel is the obvious tool for such tasks and today I will show a couple of easy ways for merging multiple files, in a single or even a whole structure of folders, into a single CSV or text file. To merge csv files or other text files it is often best to use Visual Basic for Applications in Excel.
Let’s start with the simplest approach using Windows Command line without having to use Excel.
Merge CSV files using Windows CMD
This approach uses the Windows Command line Copy command.
Open the folder which should contain your CSV or TXT files
Open in Windows Explorer the folder containing CSV or TXT files to be merged. These should be without headers or only the first file should be with headers.
Open CMD command line within folder
Click on the filepath of the Windows Explorer window and type cmd and hit ENTER.
Merge the files using COPY command
The CMD Windows command line Window should open. Type the following command and hit ENTER to merge files
copy *.csv merge.csv
The result will be the newly created merge.csv file with merged data across all CSV files within the directory.
Merge list of csv, txt files
The previous method was very simple and didn’t require the use of Excel or MS Office. The below and the following approaches will provided you with more flexibility when merging files. If you don’t know how to use Macros in Excel read my Tutorial first.
Assuming you want to merge a list of files in a String Array you can use the procedure below. It will merge all provided csv or text files into a single new text file.
Sub MergeFiles(fileNames() As String, newFileName As String, Optional headers As Boolean = True, Optional addNewLine As Boolean = False) Dim fileName As Variant, textData As String, fileNo As Integer, result As String, firstHeader As Boolean firstHeader = True For Each fileName In fileNames fileNo = FreeFile Open fileName For Input As #fileNo textData = Input$(LOF(fileNo), fileNo) Close #fileNo If headers Then result = result & IIf(addNewLine, vbNewLine, "") & IIf(firstHeader, textData, Right(textData, Len(textData) - InStr(textData, vbNewLine))) firstHeader = False Else result = result & IIf(addNewLine, vbNewLine, "") & textData End If Next fileName fileNo = FreeFile Open newFileName For Output As #fileNo Print #fileNo, result Close #fileNo End Sub
Merge csv, txt files example
See an example below of how to use the MergeFiles procedure:
Dim fileNames(0 To 1) As String fileNames(0) = "C:\somefolder\test.csv" fileNames(1) = "C:\somefolder\test1.csv" MergeFiles fileNames, "C:\Merged.csv", True, False
MergeFiles Parameters
fileNames()
Array of Strings representing full file paths to files that are to be merged
newFileName
The name of the new merged file that is to be created
headers
Optional. True by default. This is meant for CSV TXT files (HDR). If True assumes that all files have headers (first row with columns). Only first header will be merged into the new file (newFileName)
addNewLine
Optional. False by default. If True a new line (vbNewLine) character will be added between each merged file
Merge csv, txt files within specified folder
Another case is when you want to merge all csv files within a single folder. This procedure is similar to the previous one with the exception that it runs through all files within a single directory (excluding subdirectories – for that scroll to next procedure). You can also use wildcards such as “*.csv” to be sure that only csv files are merged a not other files – read my post on the VBA Dir function to learn more.
Sub MergeFilesInFolder(folderName As String, newFileName As String, Optional headers As Boolean = True, Optional addNewLine As Boolean = False) Dim fileName As Variant, textData As String, fileNo As Integer, result As String, firstHeader As Boolean firstHeader = True fileName = Dir(folderName) Do Until fileName = "" fileNo = FreeFile Open (Left(folderName, InStrRev(folderName, "\")) & fileName) For Input As #fileNo textData = Input$(LOF(fileNo), fileNo) Close #fileNo If headers Then result = result & IIf(addNewLine, vbNewLine, "") & IIf(firstHeader, textData, Right(textData, Len(textData) - InStr(textData, vbNewLine))) firstHeader = False Else result = result & IIf(addNewLine, vbNewLine, "") & textData End If fileName = Dir Loop fileNo = FreeFile Open newFileName For Output As #fileNo Print #fileNo, result Close #fileNo End Sub
Merge csv, txt files in folder example
See an example below of how to use the MergeFilesInFolder procedure:
MergeFilesInFolder "C:\somefolder\*.csv", "C:\MergedFolder.csv", True, False
MergeFilesInFolder Parameters
folderName
A folder including all files to be merged. Wildcards are permitted if supported by the VBA Dir function
newFileName
The name of the new merged file that is to be created
headers
Optional. True by default. This is meant for csv files (HDR). If True assumes that all files have headers (first row with columns). Only first header will be merged into the new file (newFileName)
addNewLine
Optional. False by default. If True a new line (vbNewLine) character will be added between each merged file
Merge csv, txt files within all subfolders
The most complex case is when you want to merge files not only within a certain directory but also within all subdirectories. This will equally work for a scenario when there are no subfolders.
Sub MergeFilesInSubFolders(folderName As String, pattern As String, newFileName As String, Optional headers As Boolean = True, Optional addNewLine As Boolean = False) Dim fileName As Variant, folder As Variant, textData As String, fileNo As Integer, result As String, firstHeader As Boolean firstHeader = True Dim col As Collection Set col = New Collection col.Add folderName TraversePath folderName, col For Each folder In col fileName = Dir(folder & pattern) Do Until fileName = "" fileNo = FreeFile Open (Left(folder, InStrRev(folder, "\")) & fileName) For Input As #fileNo textData = Input$(LOF(fileNo), fileNo) Close #fileNo If headers Then result = result & IIf(addNewLine, vbNewLine, "") & IIf(firstHeader, textData, Right(textData, Len(textData) - InStr(textData, vbNewLine))) firstHeader = False Else result = result & IIf(addNewLine, vbNewLine, "") & textData End If fileName = Dir Loop Next folder fileNo = FreeFile Open newFileName For Output As #fileNo Print #fileNo, result Close #fileNo End Sub Function TraversePath(path As Variant, allDirCollection As Collection) Dim currentPath As String, directory As Variant Dim dirCollection As Collection Set dirCollection = New Collection currentPath = Dir(path, vbDirectory) 'Explore current directory Do Until currentPath = vbNullString If Left(currentPath, 1) <> "." And Left(currentPath, 2) <> ".." And _ (GetAttr(path & currentPath) And vbDirectory) = vbDirectory Then dirCollection.Add path & currentPath & "\" allDirCollection.Add path & currentPath & "\" End If currentPath = Dir() Loop 'Explore subsequent directories For Each directory In dirCollection TraversePath directory, allDirCollection Next directory End Function
Merge csv, txt files within subfolders example
See an example below of how to use the MergeFilesInSubFoldersprocedure:
MergeFilesInSubFolders "C:\somefolder\", "C:\MergedSubFolders.csv", True, False
MergeFilesInSubFolders Parameters
folderName
A folder with or without subfolders including all files to be merged. Use wildcards with pattern parameter
pattern
If needed a pattern using wildcards permitted by the VBA Dir function
newFileName
The name of the new merged file that is to be created
headers
Optional. True by default. This is meant for csv files (HDR). If True assumes that all files have headers (first row with columns). Only first header will be merged into the new file (newFileName)
addNewLine
Optional. False by default. If True a new line (vbNewLine) character will be added between each merged file
Merge CSV files – filter records
Sometimes we want to download just a subset of records in our CSV files. One way is uploading the data and then filtering it in Excel. But why not do it in one go? See my SQL AddIn or my read CSV file using SQL example in this post here.