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, 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 sTemp = LCase(w.Name) If Instr(sTemp, sSheetName) Then w.Visible = True w.Tab.ColorIndex = 6 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 match, 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 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.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13589) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
Freezing the top rows in a worksheet so that they are always visible is easy to do. Freezing the bottom rows is not so ...
Discover MoreExcel allows you to change the names assigned to the worksheets in a workbook. If you want to have those names appear in ...
Discover MoreMicrosoft added a new feature to Excel that causes a "lock icon" to appear at the left of a worksheet tab if the ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2018-11-28 13:01:45
Eric Maier
Hi, Allen, I've also created an add-in that easily does this via a floating user form. I'm of two minds about selling it or keeping it free so I don't want to post the link here (where all the Excel people are). If you're interested, I can send it privately. I've recently updated it from Excel 2010 to 2016 so it still has a few tweaks I am working out.
2018-11-25 15:05:18
J. Woolley
Here is one example of "adding a new worksheet and then putting hyperlinks on the worksheet...." (Apologies for poor VBA code format when posting comments here.)
1. Add a new worksheet to the workbook, then give it an appropriate name (e.g., Hidden Sheets).
2. Press Alt+F11 to open the VBA Editor. Under VBAProject > Microsoft Excel Objects, double-click the sheet added in step 1.
3. Press F7 to open the Code pane to the right of the Project pane. Paste the following VBA code into the Code pane for the sheet added in step 1:
Private Sub Worksheet_Activate()
Dim oSheet As Object, nRow As Long, nEnd As Long
Cells(1, 1).Value = "Hidden Sheets"
nRow = 1
nEnd = ActiveSheet.UsedRange.Row + ActiveSheet.UsedRange.Rows.Count - 1
If nRow < nEnd Then Range(Cells(nRow + 1, 1), Cells(nEnd, 1)).Delete xlShiftUp
For Each oSheet In ThisWorkbook.Sheets
If oSheet.Visible = xlSheetHidden Then
nRow = nRow + 1
Cells(nRow, 1).Hyperlinks.Add Cells(nRow, 1), "", "", "Click to Unhide and Activate", oSheet.Name
End If
Next oSheet
Cells(1, 1).Select
End Sub
Private Sub Worksheet_FollowHyperlink(ByVal Target As Hyperlink)
Dim oSheet As Object
For Each oSheet In ThisWorkbook.Sheets
If oSheet.Name = Target.Name And oSheet.Visible = xlSheetHidden Then
oSheet.Visible = xlSheetVisible
oSheet.Activate
Exit Sub
End If
Next oSheet
End Sub
Whenever this new worksheet is activated, a list of hidden sheet names will be updated in column A. ('Very hidden' sheets are ignored.) The width of column A, the format of cell A1, and anything beyond column A can be modified as desired, but everything below row 1 in column A will be deleted before the list is updated. Each item in the list is a hyperlink with the following ScreenTip: Click to Unhide and Activate. Therefore, clicking one of the names in the list will make that sheet visible, and it will become the active sheet.
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 © 2022 Sharon Parq Associates, Inc.
Comments