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: Running a Macro in a Number of Workbooks.

Running a Macro in a Number of Workbooks

by Allen Wyatt
(last updated August 31, 2013)

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.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2278) 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: Running a Macro in a Number of 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

Changing the Default Font

If you don't like the font that Excel uses, by default, in a workbook, you can change it. Here's how.

Discover More

Adjusting the VLOOKUP Function

The VLOOKUP function is very powerful, but it will only return values that meet a very limited set of criteria. If you want ...

Discover More

Protecting Headers and Footers

If you don't want the information in a header of footer to be changed by users of your document, there are a couple of things ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

MORE EXCELTIPS (MENU)

Finding and Deleting Links

A VBA macro to find and delete external links.

Discover More

Using BIN2DEC In a Macro

Need a way, in a macro, to convert binary numbers into their decimal equivalents? There are two ways you can get the desired ...

Discover More

Self-Aware Macros

Sometimes it may be helpful for a macro to know exactly where it is being executed. This tip provides a way that you can ...

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 for this tip:

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.

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.

Links and Sharing
Share