Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier 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 June 25, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021


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 (11600) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021. You can find a version of this tip for the older menu interface of Excel 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

Setting Your Default Directory

You may want to have all your Excel workbooks stored in a specific location on your system. Here's how to set the default ...

Discover More

Turning Off HTML Conversions

Don't want Word to load up your HTML documents as formatted text? There are a couple of ways you can instruct Word to be ...

Discover More

Searching a Workbook by Default

When you display the Find tab of the Find and Replace dialog box, you'll notice that any search, by default, will be on ...

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 (ribbon)

Copying a Worksheet

Need to make a copy of one of your worksheets? Excel provides a few different ways you can accomplish the task.

Discover More

Lotus Grouped Worksheets

Not all spreadsheet programs are created equal; there are some things that can be done in others that can't be done in ...

Discover More

Creating a Copy without Formulas

Excel makes copying worksheets (duplicating them) rather easy. However, you may want a worksheet copy that differs from ...

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 five more than 3?

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 ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu 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.