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.
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:
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.
Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!
Want to know when a workbook was last modified? Want to put that date within the header of your worksheet? Here's how to ...
Discover MoreWhen you use a macro to process data you always run the risk of making that data unusable by Excel. This is especially ...
Discover MoreNeed to know the address of the cell that is currently selected? There is no worksheet function to return this ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2024 Sharon Parq Associates, Inc.
Comments