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: Making Changes in a Group of Workbooks.

Making Changes in a Group of Workbooks

by Allen Wyatt
(last updated December 20, 2014)

Over time, it is very easy to create and collect a huge number of Excel workbooks. Suppose that you had a whole bunch of workbooks in which you needed to make the same change. For instance, you might need to change the value stored in cell A10 of each of the worksheets in each of the workbooks.

If you had only a few workbooks to change, the task is pretty easy: Load each workbook and, in turn, make the change to each of them. If you have a couple hundred workbooks in which the change needs to be made, then the task becomes more formidable.

If you anticipate only needing to do this task once, then the easiest solution is to create a text file that contains the path and filename of each of the workbooks, one workbook per line. For instance, you might end up with a file that had entries such as this:

c:\myfiles\first workbook.xls
c:\myfiles\second workbook.xls
c:\myfiles\third workbook.xls

The file could have as many lines in it as necessary; it doesn't really matter. The important thing is that each line be a valid path and file name, and that there be no blank lines in the file.

You could most easily create such a file by displaying a command-prompt window, navigating to the directory containing the workbooks, and issuing the following command:

dir /b > myfilelist.txt

Each file in the directory ends up in the myfilelist.txt file. You will need to load the text file into a text editor and check it out so you can delete extraneous entries. (For instance, myfilelist.txt will end up in the listing.) You will also need to add the path name to the beginning of each line in the file.

Once the file is complete, you can start Excel and use a macro to read the text file, load each workbook listed in the text file, step through each worksheet in that workbook, make the appropriate change, and save the workbook. The following macro will perform these tasks nicely.

Sub ChangeFiles1()
    Dim sFilename As String
    Dim wks As Worksheet

    Open "c:\myfiles\myfilelist.txt" For Input As #1
    Do While Not EOF(1)
        Input #1, sFilename  ' Get workbook path and name
        Workbooks.Open sFilename

        With ActiveWorkbook
            For Each wks In .Worksheets
                ' Specify the change to make
                wks.Range("A1").Value = "A1 Changed"
            Next
        End With

        ActiveWorkbook.Close SaveChanges:=True
    Loop
    Close #1
End Sub

While this approach works great if you only have to process a single batch of workbook files, it can be made much more flexible if you anticipate needing to make such changes in the future. The biggest hassle, of course, is putting together the myfilelist.txt file each time you want to process a batch of files. Flexibility is added if the macro could simply use a directory and then load each workbook from that directory.

Sub ChangeFiles2()
    Dim MyPath As String
    Dim MyFile As String
    Dim dirName As String
    Dim wks As Worksheet

    ' Change directory path as desired
    dirName = "c:\myfiles\"

    MyPath = dirName & "*.xls"
    MyFile = Dir(MyPath)
    If MyFile > "" Then MyFile = dirName & MyFile

    Do While MyFile <> ""
        If Len(MyFile) = 0 Then Exit Do 

        Workbooks.Open MyFile

        With ActiveWorkbook
            For Each wks In .Worksheets
                ' Specify the change to make
                wks.Range("A1").Value = "A1 Changed"
            Next
        End With

        ActiveWorkbook.Close SaveChanges:=True

        MyFile = Dir
        If MyFile > "" Then MyFile = dirName & MyFile
    Loop
End Sub 

This macro uses whatever directory you specify for the dirName variable. Any workbook file (ending with the .Xls extension) is loaded and processed.

Another approach is to have the macro ask the user which directory should be processed. You ca use the standard Excel File dialog box to do this, in the manner shown in the following macro.

Public Sub ChangeFiles3()
    Dim MyPath As String
    Dim MyFile As String
    Dim dirName As String

    With Application.FileDialog(msoFileDialogFolderPicker)
        ' Optional: set folder to start in
        .InitialFileName = "C:\Excel\"
        .Title = "Select the folder to process"
        If .Show = True Then
            dirName = .SelectedItems(1)
        End If
    End With

    MyPath = dirName & "\*.xls"
    myFile = Dir(MyPath)
    If MyFile > "" Then MyFile = dirName & MyFile

    Do While MyFile <> ""
        If Len(MyFile) = 0 Then Exit Do 

        Workbooks.Open MyFile

        With ActiveWorkbook
            For Each wks In .Worksheets
                ' Specify the change to make
                wks.Range("A1").Value = "A1 Changed"
            Next
        End With

        ActiveWorkbook.Close SaveChanges:=True

        MyFile = Dir
        If MyFile > "" Then MyFile = dirName & MyFile
    Loop
End Sub

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3176) 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: Making Changes in a Group 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

Pasting Leading Zeroes

Paste information into a worksheet, and you may be surprised to see leading zeroes disappear before your eyes. Here's how to ...

Discover More

Printing Return Address Labels

Want an easy way to create your own return address labels? Word provides the tool as a feature of the program.

Discover More

Opening a Workbook to a Specific Worksheet

When you open a workbook, Excel displays the worksheet that was visible when the workbook was last saved. You may want, ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

MORE EXCELTIPS (MENU)

Correctly Saving Delimited Files

Delimited files are often created through Excel so that your data can be exported to other programs. If the delimited data ...

Discover More

Opening Non-Excel Files

Not all data is created in Excel. Indeed, you may have data in files created by many other types of programs. You might be ...

Discover More

Merging Many Workbooks

If you need to combine the contents of a bunch of workbooks into a single workbook, the process can get tedious. Here's a ...

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