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: Selecting All Visible Worksheets in a Macro.

Selecting All Visible Worksheets in a Macro

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


In Excel, selecting all the visible worksheets is as easy as right-clicking on any sheet tab and choosing Select All Sheets. However, accomplishing the same task with VBA code is more difficult.

Excel's online help suggests using the Array function with the Sheets collection to select sheets by name. This works great when you know the names of each sheet in the workbook. This poses a problem when you want to create generic code to select all sheets for any workbook. The good news is that you can use a variant of Microsoft's technique to reference sheets by index number. Below is the code:

Sub SelectSheets()
    Dim myArray() As Variant
    Dim i As Integer
    For i = 1 To Sheets.Count
        ReDim Preserve myArray(i - 1)
        myArray(i - 1) = i
    Next i
    Sheets(myArray).Select
End Sub

This works great, unless the workbook contains hidden sheets, where Sheets(i).Visible = False. Of course, the above code can be adapted to ignore hidden worksheets:

Sub SelectSheets()
    Dim myArray() As Variant
    Dim i As Integer
    Dim j As Integer
    j = 0
    For i = 1 To Sheets.Count
        If Sheets(i).Visible = True Then
            ReDim Preserve myArray(j)
            myArray(j) = i
            j = j + 1
        End If
    Next i
    Sheets(myArray).Select
End Sub

However, there is a little known parameter of the Select method: the Replace parameter. By using the Replace parameter, selecting all visible sheets becomes much easier:

Sub SelectSheets1()
    Dim mySheet As Object
    For Each mySheet In Sheets
        With mySheet
            If .Visible = True Then .Select Replace:=False
        End With
    Next mySheet
End Sub

Note that mySheet is defined as an Object data type, instead of a Worksheet data type. This is done because in testing I encountered a problem with Chart sheets—they wouldn't be selected because they weren't of a Worksheet type.

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 (3058) 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: Selecting All Visible Worksheets in a Macro.

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

Editing Reports

The Report Manager allows you to create specialized reports that can be easily printed from your worksheet data. This tip ...

Discover More

Changing a Field Parameter

Fields are a powerful way to add dynamic content to your documents. Some fields rely on the use of parameters to control ...

Discover More

Adding Common Line Spacing Options

Sometimes the options presented by Word's tools don't exactly meet our formatting needs. Rather than changing the tools ...

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)

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

Unprotecting Groups of Worksheets

Unprotecting a single worksheet is relatively easy. Unprotecting a whole lot of worksheets is harder. Here's how you can ...

Discover More

Making a Cell's Contents Bold within a Macro

When your macro is processing information in a worksheet, do you need to periodically make the contents of a cell bold? ...

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 seven 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.