Please Note: This article is written for users of the following Microsoft Excel versions: 97, 2000, 2002, and 2003. If you are using a later version (Excel 2007 or later), this tip may not work for you. For a version of this tip written specifically for later versions of Excel, click here: Merging Many Workbooks.

Merging Many Workbooks

Written by Allen Wyatt (last updated June 28, 2025)
This tip applies to Excel 97, 2000, 2002, and 2003


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 form 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
    Dim Outwbk As Workbook

    Set Outwbk = ActiveWorkbook

    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:=Outwbk.Sheets(Outwbk.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 (2409) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) 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

Stepping Through Head Formats

You can use the shortcuts described in this tip to quickly change the heading levels of the headings in your document. ...

Discover More

Crashing when Searching

If you use Excel's Open dialog box to search for files and you notice that doing so ends up crashing your system, you may ...

Discover More

Meaningless Text

Need to quickly put some text into a document, even if that text is essentially meaningless? Here's how to put this type ...

Discover More

Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!

More ExcelTips (menu)

Sorting Files

The Open dialog box allows you to sort the files it presents to you. How you do the sorting depends on the version of ...

Discover More

Saving a Workbook with a Preview

When you save your workbooks, Excel can also save a preview image (thumbnail) that can be displayed in the Open dialog ...

Discover More

Getting Rid of "Copy of"

When you save a read-only workbook file under a new name, Excel automatically adds "copy of" to the beginning of that ...

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 nine more than 1?

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 menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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.