I don't think I'd do this--The reason I hide sheets is to keep the workbook less
cluttered. Stuff that I need, but don't need to see goes on those hidden
sheets.
But if you want, this worked for me. But don't use a worksheet name like:
sheet1--hidden
I use that to indicate the hidden-ness of the sheet.
Option Explicit
Sub Auto_Close()
On Error Resume Next
Application.CommandBars("MyNavigator").Delete
On Error GoTo 0
End Sub
Sub Auto_Open()
'code written by Dave Peterson 2005-12-21
'creates a toolbar with list of sheets in active workbook
Dim cb As CommandBar
Dim ctrl As CommandBarControl
On Error Resume Next
Application.CommandBars("MyNavigator").Delete
On Error GoTo 0
Set cb = Application.CommandBars.Add(Name:="myNavigator", temporary:=True)
With cb
.Visible = True
Set ctrl = .Controls.Add(Type:=msoControlButton, temporary:=True)
With ctrl
.Style = msoButtonCaption
.Caption = "Refresh Worksheet List"
.OnAction = ThisWorkbook.Name & "!refreshthesheets"
End With
Set ctrl = .Controls.Add(Type:=msoControlComboBox, temporary:=True)
With ctrl
.Width = 300
.AddItem "Click Refresh First"
.OnAction = ThisWorkbook.Name & "!changethesheet"
.Tag = "__wksnames__"
End With
End With
End Sub
Sub ChangeTheSheet()
Dim myWksName As String
Dim wks As Object
Dim IsHidden As Boolean
With Application.CommandBars.ActionControl
If .ListIndex = 0 Then
MsgBox "Please select an existing sheet"
Exit Sub
Else
myWksName = .List(.ListIndex)
End If
End With
If LCase(myWksName) Like LCase("*--hidden") Then
myWksName = Left(myWksName, Len(myWksName) - Len("--hidden"))
End If
Set wks = Nothing
On Error Resume Next
Set wks = Sheets(myWksName)
On Error GoTo 0
If wks Is Nothing Then
Call RefreshTheSheets
MsgBox "Please try again"
Else
wks.Visible = xlSheetVisible
wks.Select
End If
End Sub
Sub RefreshTheSheets()
Dim ctrl As CommandBarControl
Dim wks As Object
Dim myMsg As String
Set ctrl = Application.CommandBars("myNavigator") _
.FindControl(Tag:="__wksnames__")
ctrl.Clear
For Each wks In ActiveWorkbook.Sheets
If wks.Visible = xlSheetVisible Then
myMsg = ""
Else
myMsg = "--Hidden"
End If
ctrl.AddItem wks.Name & myMsg
Next wks
End Sub