VBA Code to Auto-Hide Rows based on Values

BigRusty82

New Member
Joined
Jan 28, 2021
Messages
5
Office Version
  1. 365
Platform
  1. Windows
Hi, this is my first post and my first venture into VBA and whilst I am learning VBA I would apricate some help with the following situation.

I want to hide rows in this worksheet based on values within a cell, whilst I can make this work for one set, i know that I cant just repeat this for the others as it gives an error. This is the code below with named ranges:

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
ActiveSheet.Activate
If Not Application.Intersect(Range("NUM_AUTH"), Range(Target.Address)) Is Nothing Then
        Select Case Target.Value
        Case Is = "1": Range("AUTH_2,AUTH_3,AUTH_4,AUTH_5,AUTH_6").EntireRow.Hidden = True
                       Range("AUTH_1").EntireRow.Hidden = False
        Case Is = "2": Range("AUTH_3,AUTH_4,AUTH_5,AUTH_6").EntireRow.Hidden = True
                       Range("AUTH_1,AUTH_2").EntireRow.Hidden = False
        Case Is = "3": Range("AUTH_4,AUTH_5,AUTH_6").EntireRow.Hidden = True
                       Range("AUTH_1,AUTH_2,AUTH_3").EntireRow.Hidden = False
        Case Is = "4": Range("AUTH_5,AUTH_6").EntireRow.Hidden = True
                       Range("AUTH_1,AUTH_2,AUTH_3,AUTH_4").EntireRow.Hidden = False
        Case Is = "5": Range("AUTH_6").EntireRow.Hidden = True
                       Range("AUTH_1,AUTH_2,AUTH_3,AUTH_4,AUTH_5").EntireRow.Hidden = False
        Case Is = "6": Range("AUTH_1,AUTH_2,AUTH_3,AUTH_4,AUTH_5,AUTH_6").EntireRow.Hidden = False
        End Select
            
End If

End Sub

The NUM_AUTH and AUTH_x will change based on the value lookup and rows i want to hide. This I need to happen 4 times on one sheet.

Thanks

Rusty
 

Excel Facts

Bring active cell back into view
Start at A1 and select to A9999 while writing a formula, you can't see A1 anymore. Press Ctrl+Backspace to bring active cell into view.
Hi
and welcome
If I understand right
you might use some thing like
VBA Code:
Union(Range(bla1), Range(bla2), Range(bla3)).EntireRow.Hidden = True
 
Upvote 0
What are the other cells?
 
Upvote 0
For ex
VBA Code:
 Case Is = "1": Union(Range("AUTH_2"), Range("AUTH_3"), Range("AUTH_4"), Range("AUTH_5"), Range("AUTH_6")).EntireRow.Hidden = True
                       Range("AUTH_1").EntireRow.Hidden = False
 
Upvote 0
@mohadin
There is no need for the union, the OP's code will work fine as-is.
 
Upvote 0
Hi Fluff,

The other named ranges are:

MAT_SELECT as the variable and MAT_1, MAT_2... MAT_6 are the rows
COLL_OPT as var, OPT_1, OPT_2... OPT_4
DEP_SELECT as var, DEP_1, DEP_2... DEP_6

Thanks

Rusty
 
Upvote 0
Ok you can do that like
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
ActiveSheet.Activate
If Not Application.Intersect(Range("NUM_AUTH"), Range(Target.Address)) Is Nothing Then
        Select Case Target.Value
        Case Is = "1": Range("AUTH_2,AUTH_3,AUTH_4,AUTH_5,AUTH_6").EntireRow.Hidden = True
                       Range("AUTH_1").EntireRow.Hidden = False
        Case Is = "2": Range("AUTH_3,AUTH_4,AUTH_5,AUTH_6").EntireRow.Hidden = True
                       Range("AUTH_1,AUTH_2").EntireRow.Hidden = False
        Case Is = "3": Range("AUTH_4,AUTH_5,AUTH_6").EntireRow.Hidden = True
                       Range("AUTH_1,AUTH_2,AUTH_3").EntireRow.Hidden = False
        Case Is = "4": Range("AUTH_5,AUTH_6").EntireRow.Hidden = True
                       Range("AUTH_1,AUTH_2,AUTH_3,AUTH_4").EntireRow.Hidden = False
        Case Is = "5": Range("AUTH_6").EntireRow.Hidden = True
                       Range("AUTH_1,AUTH_2,AUTH_3,AUTH_4,AUTH_5").EntireRow.Hidden = False
        Case Is = "6": Range("AUTH_1,AUTH_2,AUTH_3,AUTH_4,AUTH_5,AUTH_6").EntireRow.Hidden = False
        End Select
            
ElseIf Not Intersect(Target, Range("MAT_SELECT")) Is Nothing Then
   Select Case Target.Value
   'etc
ElseIf Not Intersect(Target, Range("COLL_OPT")) Is Nothing Then
   Select Case Target.Value
   'etc
End If
End Sub
 
Upvote 0
Solution
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,532
Messages
6,114,177
Members
448,554
Latest member
Gleisner2

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