Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365. 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: Merging Many Workbooks.
Written by Allen Wyatt (last updated July 20, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
Joy ran into a problem merging quite a few workbooks together. The majority of the workbooks—about 200 of them, all in a single folder—each contain a single worksheet, but some contain more. The worksheets forming each of these workbooks needs to be added to a single workbook.
The easiest way to do merges of this magnitude—particularly if you have to do it often—is with a macro. The following macro displays a dialog box asking you to select the files to merge. (You can select multiple workbooks by holding down the Ctrl key as you click each one.) It loops thru the list you select, opening each one and moving all its worksheets to the end of the workbook with the code.
Sub CombineWorkbooks()
Dim FilesToOpen
Dim x As Integer
On Error GoTo ErrHandler
Application.ScreenUpdating = False
FilesToOpen = Application.GetOpenFilename _
(FileFilter:="Microsoft Excel Files (*.xls?), *.xls?", _
MultiSelect:=True, Title:="Files to Merge")
If TypeName(FilesToOpen) = "Boolean" Then
MsgBox "No Files were selected"
GoTo ExitHandler
End If
x = 1
While x <= UBound(FilesToOpen)
Workbooks.Open FileName:=FilesToOpen(x)
Sheets().Move After:=ThisWorkbook.Sheets _
(ThisWorkbook.Sheets.Count)
x = x + 1
Wend
ExitHandler:
Application.ScreenUpdating = True
Exit Sub
ErrHandler:
MsgBox Err.Description
Resume ExitHandler
End Sub
In the process of adding the worksheets to the end of the workbook, Excel will automatically append a (2), (3), etc. when duplicates worksheet names are detected. Any formulas in the book referring to other sheets will also be updated to reflect the new names.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12652) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Merging Many Workbooks.
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 Data Analysis and Business Modeling today!
Have you ever tried to save a workbook, only to be notified that someone else has made changes in it? What if you are the ...
Discover MoreWhen you save a workbook, you have the opportunity to save a thumbnail image that can be displayed within Windows. Here's ...
Discover MoreNeed to allow others to contribute to your Excel workbook? It's easy to do if you just share it. This tip provides an ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2025-07-05 21:34:32
Rich M
@J. Wolley
Thanks very much! Extremely helpful !
2025-07-01 10:44:44
J. Woolley
@Rich M
If I understand your question, try this (based on my previous comment below):
Dim AWB As Workbook
Set AWB = ActiveWorkbook
For x = LBound(FilesToOpen) To UBound(FilesToOpen)
With Workbooks.Open(FilesToOpen(x))
Select Case FilesToOpen(x)
Case FileName1
.Sheets(SheetName1).Copy After:=AWB.Sheets(AWB.Sheets.Count)
Case FileName2
.Sheets(SheetName2).Copy After:=AWB.Sheets(AWB.Sheets.Count)
Case FileName3
.Sheets(SheetName3).Copy After:=AWB.Sheets(AWB.Sheets.Count)
Case Else
.Sheets.Copy After:=AWB.Sheets(AWB.Sheets.Count)
End Select
.Close SaveChanges:=False
End With
Next x
Replace FileName1, ...2, ...3 and SheetName1, ...2, ...3 with your expected names.
2025-06-30 15:01:42
Rich M
Hi. I submitted a comment for the 2003 version, but I’ve got O365, so I belong here actually.
In my case, I’m going to be adding files with one of three predictable, fixed names. Could I set the Macro to check each incoming file for one of the expected names, then change the worksheet exported to a specific name ‘needed’ by Outwbk ?
Thanks.
2025-06-30 11:33:38
Rich M
Hi. I submitted a comment for the 2003 version, but I’ve got O365, so I belong here actually.
In my case, I’m going to be adding files with one of three predictable, fixed names. Could I set the Macro to check each incoming file for one of the expected names, then change the worksheet exported to a specific name ‘needed’ by Outwbk ?
Thanks.
2024-07-21 14:59:42
J. Woolley
The Tip's macro references ThisWorkbook, which is the location of the macro; that will be a problem if the macro is relocated to Personal.xlsb or an add-in. Here is a recommended replacement for the macro's While loop:
Dim AWB As Workbook
Set AWB = ActiveWorkbook
For x = LBound(FilesToOpen) To UBound(FilesToOpen)
Workbooks.Open(FilesToOpen(x)).Sheets.Move _
After:=AWB.Sheets(AWB.Sheets.Count)
Next x
Notice the macro opens workbooks but doesn't close them. Apparently they close automatically after all their sheets are moved, but they retain their sheets as if the sheets were only copied. Here is another version that is more specific:
Dim AWB As Workbook
Set AWB = ActiveWorkbook
For x = LBound(FilesToOpen) To UBound(FilesToOpen)
With Workbooks.Open(FilesToOpen(x))
.Sheets.Copy After:=AWB.Sheets(AWB.Sheets.Count)
.Close SaveChanges:=False
End With
Next x
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