Macro to hide sheet based on cell value

tedholly

New Member
Joined
Feb 19, 2021
Messages
17
Office Version
  1. 365
Platform
  1. Windows
I have a workbook with about 200 different worksheets in them. Each of the worksheets has cell N9 as either "Active" or "Inactive" If cell N9 says "Inactive" then I want to color code the tab red and hide the worksheet. There are a few worksheets that would be excluded (template, instructions, user form, master project list, payment status, reference, active projects and completed projects) [8 worksheets total that would be excluded from the macro]

Ideally if N9 changes to "active" I would want it to unhide.

What is the best way to achieve this?
 

Excel Facts

Select all contiguous cells
Pressing Ctrl+* (asterisk) will select the "current region" - all contiguous cells in all directions.
Echo MarcL, how does N9 change on these worksheets?
 
Upvote 0
Hi to all.
If I correctly understood the request this macro should do the job:
VBA Code:
Option Explicit
Sub ColorTabHideSheet()
    Dim ws     As Worksheet
    Dim myArr() As String
    Dim x      As Long
    myArr() = Split("template,instructions,user form,master project list,payment status,reference,active projects,completed projects", ",")
    For Each ws In ActiveWorkbook.Worksheets      'loop through worksheets
        For x = 0 To UBound(myArr)
            If ws.Name = myArr(x) Then GoTo skip  'esclude sheets in array
        Next x
        If ws.Range("C9") = "Inactive" Then       'check state of C9
            ws.Tab.Color = vbRed
            ws.Visible = xlSheetHidden
        ElseIf ws.Range("C9") = "Active" Then
            ws.Tab.Color = False
            ws.Visible = xlSheetVisible
        End If
skip:
    Next ws
End Sub
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,251
Members
448,556
Latest member
peterhess2002

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