Running a Macro in a Number of Workbooks

Written by Allen Wyatt (last updated February 6, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003


If you have quite a number of workbooks that you want to process through the use of macros, you may be tempted to place the processing macro within each workbook (as an Auto_Open macro), and then write some type of routine to load each workbook, in turn, and save it.

While this may sound good in theory, it won't work in practice. Why? Because when you open a workbook under macro control, the Auto_Open macro in the workbook being opened will not automatically run. There are three ways around this problem.

The first is to redo your macro so that you don't rely on Auto_Open macros in each workbook. If the Auto_Open macro in each workbook is the same, then why not simply move the code to a separate procedure in the controlling workbook? For instance, let's say you were using code that followed this process:

Sub MyMacro()
    Dim J As Integer
    Dim sTarget As String

    Application.ScreenUpdating = False
    For J = 1 To 999
        sTarget = "Book" & Format(J, "000") & ".xls"
        Workbooks.Open sTarget
        'Auto_Open runs here
        Workbooks(sTarget).Save
    Next J
    Application.ScreenUpdating = True
End Sub

This won't work, for reasons already explained. One solution is to simply move the common Auto_Open code into another procedure, and then call it after opening the workbook, as shown here:

Sub MyMacro()
    Dim J As Integer
    Dim sTarget As String

    Application.ScreenUpdating = False
    For J = 1 To 999
        sTarget = "Book" & Format(J, "000") & ".xls"
        Workbooks.Open sTarget
        Workbooks(sTarget).Activate
        DoCommonCode
        Workbooks(sTarget).Save
    Next J
    Application.ScreenUpdating = True
End Sub
Sub DoCommonCode()
    'Common code goes here
End Sub

This approach works fine, provided the routine is the same that will be run on all your different workbooks. If the routines are different in each workbook, then you can force VBA to run the Auto_Open macro. This is done by using the RunAutoMacros method right after opening the workbooks:

Workbooks.Open sTarget
ActiveWorkbook.RunAutoMacros xlAutoOpen

Given this approach, you could easily come up with a macro that would simply open each workbook (so the Auto_Open macros could run) and then save them. Such a macro would appear as follows:

Sub RunAutoOpenMacrosInBooks()
    Dim J As Integer
    Dim sTarget As String

    Application.ScreenUpdating = False
    For J = 1 To 999
        sTarget = "Book" & Format(J, "000") & ".xls"
        On Error Resume Next
        Workbooks.Open sTarget
        Windows(sTarget).Activate
        With ActiveWorkbook
            If .Name <> ThisWorkbook.Name Then
                .RunAutoMacros xlAutoOpen
                .Save
                .Close
            End If
        End With
    Next i
    Application.ScreenUpdating = True
End Sub

A third, and even better, approach is to not rely upon Auto_Open macros in each of your workbooks. Instead, rely on the Workbook_open event as a way to run your macro. The Workbook_open event is triggered automatically, regardless of whether the workbook is opened manually or in another macro. The code that the event contains is run automatically, just as you would expect of an Auto_Open macro.

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 (2278) applies to Microsoft Excel 97, 2000, 2002, and 2003.

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

Controlling Sorting Order

When you sort information either in a table or the body of you document, Word follows a very specific set of rules to do ...

Discover More

Generating Unique Sequential Numbers

Using Excel to generate unique sequential numbers for invoices or company statements can be a challenge. Here's ...

Discover More

Picking a Group of Cells

Excel makes it easy to select a group of contiguous cells. However, it also makes it easy to select non-contiguous groups ...

Discover More

Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!

More ExcelTips (menu)

Counting All Characters

Need to know how many characters there are in a workbook? You can find out easily with the handy macro introduced in this ...

Discover More

Counting Cells with Text Colors

Got a bunch of cells that have different colored text in them? Here's a great way to count the occurrences of certain ...

Discover More

Adjusting Values with Formulas

Paste Special is a great tool that allows you to modify the values in a range of cells in your worksheets. You may want, ...

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 9 + 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.