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.

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


5

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:

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 (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.

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

Using TC Fields for Notes

The TC field is normally used in constructing manual Tables of Contents. The way the field works, however, makes it a ...

Discover More

Iterating Circular References

Does your data require that you perform calculations using circular references? If so, then you'll want to be aware of ...

Discover More

Zooming with the Keyboard

Want to zoom in and out without the need to using the ribbon tools? You can create your own handy macros that do the ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 today!

More ExcelTips (ribbon)

Comparing Workbooks for Differences

When working with copies of workbooks--particularly copies derived from a common ancestor workbook--you may be interested ...

Discover More

Needing to Save a Workbook Twice

If you save a workbook and then immediately close the workbook, Excel may ask you to save again. This tip looks at ...

Discover More

Creating Default Formatting for Workbooks and Worksheets

Not satisfied with the way that default workbooks and worksheets look in Excel? You can easily create your own defaults ...

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 four less than 4?

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


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.