VBA: Hide different non-contiguous rows dependent on drop-down selection

Brumspur

New Member
Joined
Nov 3, 2020
Messages
3
Office Version
  1. 365
Platform
  1. Windows
Hi, I need to hide a variety of rows dependent on the selection from a dropdown. Very new to VBA and tried the below from another forum which seems to work but only for the last line of code. Each time I add another line for another of the dropdown options the previous one stops working so probably something very basic.

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
   If Not Intersect(Target, Range("C8")) Is Nothing Then
      With Range("$C$8")
         Range("20:20,25:28,30:30,36:38").EntireRow.Hidden = .Value = "Option 1"
         Range("20:20,25:28,30:30,37:38").EntireRow.Hidden = .Value = "Option 2"
         Range("20:20,22:28,30:30,33:33,36:38").EntireRow.Hidden = .Value = "Option 3"
         Range("20:20,24:26,28:28,33:33,36:37").EntireRow.Hidden = .Value = "Option 4"
         Range("20:20,25:28,30:30,33:33,36:38").EntireRow.Hidden = .Value = "Option 5"
         Range("20:20,28:28,30:30,36:36,38:38").EntireRow.Hidden = .Value = "Option 6"
         Range("20:22,25:30,36:38").EntireRow.Hidden = .Value = "Option 7"
         Range("25:27,30:30,36:38").EntireRow.Hidden = .Value = "Option 8"
         Range("25:27,30:30,37:38").EntireRow.Hidden = .Value = "Option 9"
      End With
   End If
End Sub

Thanks in advance!
 

Excel Facts

How to fill five years of quarters?
Type 1Q-2023 in a cell. Grab the fill handle and drag down or right. After 4Q-2023, Excel will jump to 1Q-2024. Dash can be any character.
Hi & welcome to MrExcel.
You need to do it separately for each criteria like
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
   If Not Intersect(Target, Range("C8")) Is Nothing Then
      Rows("20:30").Hidden = False
      Select Case Target
         Case "Option 1"
            Range("20:20,25:28,30:30,36:38").Hidden = True
         Case "Option 2"
            Range("20:20,25:28,30:30,37:38").Hidden = True
      End Select
   End If
End Sub
 
Upvote 0
Thank you, I've replaced my coding with yours but now I get a runtime error "run time error 1004 unable to set the hidden property of the range class".

Having searched a bit this may relate to the protection on the sheet (there is none) or comments in the cell range (there are none). There are drop downs within the range which I thought may be affecting it but having removed these it still errors.

Code is below as it stands, I've checked it against yours and seems ok? The debug highlights the range selected if that helps?

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
   If Not Intersect(Target, Range("C8")) Is Nothing Then
      Rows("20:38").Hidden = False
      Select Case Target
         Case "Option 1"
            Range("20:20,25:28,30:30,36:38").Hidden = True
         Case "Option 2"
            Range("20:20,25:28,30:30,37:38").Hidden = True
         Case "Option 3"
            Range("20:20,22:28,30:30,33:33,36:38").Hidden = True
         Case "Option 4"
            Range("20:20,24:26,28:28,33:33,36:37").Hidden = True
         Case "Option 5"
            Range("20:20,25:28,30:30,33:33,36:38").Hidden = True
         Case "Option 6"
            Range("20:20,28:28,30:30,36:36,38:38").Hidden = True
         Case "Option 7"
            Range("20:22,25:30,36:38").Hidden = True
         Case "Option 8"
            Range("25:27,30:30,36:38").Hidden = True
         Case "Option 9"
            Range("25:27,30:30,37:38").Hidden = True
      End Select
   End If
End Sub

Thanks again
 
Upvote 0
Change this:

Code:
Range("20:20,25:28,30:30,36:38").Hidden = True

to this:

Code:
Range("20:20,25:28,30:30,36:38").Entirerow.Hidden = True

and do the same for the other similar lines.
 
Upvote 0
Solution
Glad we could help & thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,213,546
Messages
6,114,254
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