Hide worksheets if a box is checked

austinda

New Member
Joined
Aug 3, 2016
Messages
12
I have a worksheet that has a macro that list all of the active worksheets.
Code:
Sub ListSheetsTab()'downloaded from www.contextures.com
'list all sheets in active workbook
Dim wb As Workbook
Dim ws As Worksheet
Dim wsM As Worksheet
Dim lColorC As Long 'cell color
Dim lColorT As Long 'tab color
Dim lRow As Long
Dim lRowHead As Long
Dim lCol As Long
Dim lCols As Long
Dim lColEnd As Long
Dim lSh As Long
On Error Resume Next
Application.ScreenUpdating = False
Application.EnableEvents = False


Set wb = ActiveWorkbook
Set wsM = Worksheets("Menu")
lRowHead = 4
lCol = 7
lCols = 3
lColEnd = lCol + lCols - 1
lRow = lRowHead + 1


With wsM.Range(wsM.Cells(lRowHead, lCol), _
    wsM.Cells(lRowHead, lColEnd))
  .EntireColumn.Clear
  .Value = Array("ID", "Sheet", "Tab Color")
End With
      
With wsM
  For Each ws In wb.Worksheets
    .Range(.Cells(lRow, lCol), _
      .Cells(lRow, lColEnd - 1)).Value _
      = Array(lRow - lRowHead, ws.Name)
      If ws.Tab.ColorIndex = -4142 Then
        .Cells(lRow, lColEnd) _
          .Interior.ColorIndex _
          = ws.Tab.ColorIndex
      Else
        .Cells(lRow, lColEnd) _
          .Interior.Color _
          = ws.Tab.Color
      End If
      'add hyperlink to sheet name
      .Hyperlinks.Add _
          Anchor:=.Cells(lRow, lCol + 1), _
          Address:="", _
          SubAddress:="'" & ws.Name & "'!A1", _
          ScreenTip:=ws.Name, _
          TextToDisplay:=ws.Name
    lRow = lRow + 1
  Next ws
  
  With .Range(.Cells(lRowHead, lCol), _
      .Cells(lRowHead, lColEnd))
    .Font.Bold = True
    .EntireColumn.AutoFit
  End With
End With
 
Application.ScreenUpdating = True
Application.EnableEvents = True


End Sub
I would like to modify it to also add a column that would have a check box that would allow me to to hide or unhide a workbook if the box is checked.

Any help would be great
 

Excel Facts

Which lookup functions find a value equal or greater than the lookup value?
MATCH uses -1 to find larger value (lookup table must be sorted ZA). XLOOKUP uses 1 to find values greater and does not need to be sorted.
Old post, but it looked interesting.

I have a much smaller code to do that. It selects the first sheet and then lists out what it appears you want.

Code:
Sub TabList()
Dim ctr As Long
Sheets(1).Activate
With Range("G4:J4")
    .Value = Array("ID", "Sheet", "Tab Color", "Hide Sheet")
    .Font.Bold = True
End With
For ctr = 1 To Worksheets.Count
    Range("G4").Offset(ctr) = ctr
    Range("H4").Offset(ctr) = Sheets(ctr).Name
    ActiveSheet.Hyperlinks.Add Anchor:=Range("H4").Offset(ctr), Address:="", SubAddress:=Sheets(ctr).Name & "!A1", TextToDisplay:=Sheets(ctr).Name
    Range("I4").Offset(ctr).Interior.ColorIndex = Sheets(ctr).Tab.ColorIndex
Next
Columns("G:J").Columns.AutoFit
End Sub

Now in the Hide Sheet Column, just put an x if you want to hide the sheet, and take it out if you want to show it again. Note that it won't let you hide the sheet that the list is on.

In the Worksheet Change event for the first sheet.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
Dim c As Range, d As Range
Set d = Intersect(Target, Range("J6:J" & Range("G" & Rows.Count).End(xlUp).Row))
If d Is Nothing Then Exit Sub
Application.EnableEvents = False
For Each c In d
    Sheets(c.Offset(, -2).Text).Visible = Not ((UCase(c) = "X")) + 0
Next
Application.EnableEvents = True
End Sub
 
Upvote 0
Love the shorten code works perfectly. I couldn't get the 2nd code to work. It directed me back to the tablist macro
 
Upvote 0

Forum statistics

Threads
1,214,925
Messages
6,122,298
Members
449,077
Latest member
Rkmenon

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top