Written by Allen Wyatt (last updated February 3, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Steve has a workbook in which he creates a new worksheet tab for each project he works on. To keep things manageable, he hides the completed tabs/projects. Steve now has 100+ hidden worksheets. On a regular basis he has a need to revisit a completed project. To do this, Steve chooses to unhide worksheets. This displays the Unhide dialog box which contains the hidden worksheet names, in no apparent order. To find a tab/project, he needs to scroll through this very small dialog box and look for the right tab. Steve finds this very laborious and time-consuming, so he is wondering if there is a a better way to find and unhide the worksheet for a completed project.
One solution to this all-too-common problem is that you could create an index or table of contents for the worksheets in your workbook. You do this by adding a new worksheet and then putting hyperlinks on the worksheet to all the various worksheets in your workbook. It could include just about any information you want about the worksheets (in addition to the hyperlink). Click the hyperlink and your desired worksheet is displayed, without the need of scrolling through any dialog boxes.
You could also create a second workbook that contains just your completed projects. It is quite easy to move worksheets from one workbook to another, so using two workbooks ("active" and "completed") would be a snap. Plus, you wouldn't need to hide any of the worksheets in the workbook containing the completed projects, and you could put them in any order desired.
If you prefer to keep your workbook as is, then you may want to consider creating a macro that would make displaying your hidden worksheets a snap. Consider the following example:
Sub UnHideWorksheets() Dim sSheetName As String Dim w As Worksheet Dim sTemp As String sTemp = "Name (or partial) of sheet to show?" sSheetName = InputBox(sTemp, "Show Hidden Sheet") If sSheetName > "" Then sSheetName = LCase(sSheetName) For Each w In Sheets w.Tab.ColorIndex = xlColorIndexNone If w.Visible = False Then sTemp = LCase(w.Name) If Instr(sTemp, sSheetName) Then w.Visible = True w.Tab.ColorIndex = 6 End If End If Next w End If End Sub
The macro asks the user for a worksheet name, and then steps through all the worksheets. If it finds a hidden worksheet and the worksheet's name matches, then the worksheet is displayed and the color of the worksheet's tab is set to yellow. The macro actually works with partial matches, meaning that you can enter just a part of a worksheet name, and any hidden worksheets that contain the partial match will be unhidden. You could easily assign the macro to a shortcut key or your Quick Access Toolbar so you could call it into action in a snap.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13589) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
Save Time and Supercharge Excel! Automate virtually any routine task and save yourself hours, days, maybe even weeks. Then, learn how to make Excel do things you thought were simply impossible! Mastering advanced Excel macros has never been easier. Check out Excel 2010 VBA and Macros today!
Excel provides ways to reference the column or row number of a cell, but it doesn't provide a built-in way to reference a ...
Discover MoreIf your workbook contains a multitude of worksheets, the worksheet tabs at the bottom of the program window start to lose ...
Discover MoreNeed to know which cells in a column are the widest? There are a few ways you can approach the task, and three of those ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-02-04 12:18:10
J. Woolley
My Excel Toolbox includes the following function:
=SheetListUpdateLink([Friendly_Name], [Screen_Tip])
This function uses SuperLink to create a hyperlink that runs a private macro to list/update all the workbook's sheets in subsequent rows (replacing their previous contents). Hidden sheets will have gray fill. Each sheet in the list includes a hyperlink that will hide or unhide the sheet when clicked. If the sheet becomes visible (not hidden), its cell will change to no fill and the sheet will be activated; otherwise, the sheet will be hidden, the cell’s fill will change to gray, and the active sheet will remain the same. Clicking an unhidden sheet's hyperlink twice will first hide then unhide and activate it.
If a sheet is added or deleted or a sheet’s name or visibility is changed, the list of sheets will not automatically update; therefore, it is advisable to click the SheetListUpdateLink function's hyperlink (which updates the list) before using any of the hyperlinks in the list. But remember, necessary rows in the column below the list will be replaced without warning whenever the list is updated.
For more information, review the PDF file UseSheetList.pdf.
See https://sites.google.com/view/MyExcelToolbox
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.
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