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:
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.
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!
Ever want to know how many cells in a worksheet (or a selection) are shaded in some way? You can create a handy little ...
Discover MoreNeed to select a cell using a macro? Need that selection to be relative to the cell you currently have selected? Here's ...
Discover MoreIf someone sends you a worksheet that has lots of data in it, you might want to "spread out" the data so you can have ...
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 © 2025 Sharon Parq Associates, Inc.
Comments