If you put a blank column before every column of sheet names, this code (in the Master sheet code module) will turn the cell to the left into a Marlett check box.
Click on a cell to the left of a sheet name and the sheet's visibility will be changed accordingly.
' in MasterSheet code module
Private Sub Worksheet_SelectionChange(ByVal Target As Range)
With Target
If .Cells.Count = 1 Then
If SheetExists(.Offset(0, 1).Value) Then
.Value = IIf(.Value = vbNullString, "a", vbNullString)
.Font.Name = "Marlett"
Application.EnableEvents = False
.Offset(0, 1).Select
Application.EnableEvents = True
ShowSheets
End If
End If
End With
End Sub
Function SheetExists(SheetName As String) As Boolean
On Error Resume Next
SheetExists = (LCase(ThisWorkbook.Sheets(SheetName).Name) = LCase(SheetName))
On Error GoTo 0
End Function
Function CheckChainValue(ByVal rIndex As Long, ByVal cIndex As Long) As Boolean
Dim nextR, nextC
If rIndex < 1 Or cIndex < 2 Then
CheckChainValue = True
ElseIf rIndex = 1 Or cIndex = 2 Then
CheckChainValue = (Cells(rIndex, cIndex - 1).Value = "a")
Else
CheckChainValue = (Cells(rIndex, cIndex - 1).Value = "a")
nextR = rIndex
nextC = cIndex - 2
Do Until (Cells(nextR, nextC) <> vbNullString) Or nextR < 1
nextR = nextR - 1
Loop
CheckChainValue = CheckChainValue And CheckChainValue(nextR, nextC)
End If
End Function
Sub ShowSheets()
Dim oneWorksheet As Worksheet
Dim foundcell As Range
For Each oneWorksheet In ThisWorkbook.Sheets
Set foundcell = Me.Cells.Find(oneWorksheet.Name)
If Not foundcell Is Nothing Then
oneWorksheet.Visible = IIf(CheckChainValue(foundcell.Row, foundcell.Column), xlSheetVisible, xlSheetHidden)
End If
Next oneWorksheet
End Sub