Hide/Unhide rows with CASE based on cell value with formula

jvandeliefvoort

New Member
Joined
Nov 10, 2021
Messages
8
Office Version
  1. 365
Platform
  1. Windows
Hi all,

I am quite new to VBA, and I cannot find an answer to my problem. I am using code to hide/unhide rows. It works when I put a value in cel B3, but this value must be a value on another sheet. So B3:
Excel Formula:
='Main Sheet 2.0'!H21
. So it only works if I put for example just the value 7 in B3, but not when I use the formula.

This is the code I used:

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

If Target.Address = ("$B$3") Then
        Select Case Target.Value
        Case "1"
            Rows("7:94").EntireRow.Hidden = True
            Rows("7:13").EntireRow.Hidden = False
        Case "2"
            Rows("7:94").EntireRow.Hidden = True
            Rows("7:22").EntireRow.Hidden = False
        Case "3"
            Rows("7:94").EntireRow.Hidden = True
            Rows("7:31").EntireRow.Hidden = False
        Case "4"
            Rows("7:94").EntireRow.Hidden = True
            Rows("7:40").EntireRow.Hidden = False
        Case "5"
            Rows("7:94").EntireRow.Hidden = True
            Rows("7:49").EntireRow.Hidden = False
        Case "6"
            Rows("7:94").EntireRow.Hidden = True
            Rows("7:58").EntireRow.Hidden = False
        Case "7"
            Rows("7:94").EntireRow.Hidden = True
            Rows("7:67").EntireRow.Hidden = False
        Case "8"
            Rows("7:94").EntireRow.Hidden = True
            Rows("7:76").EntireRow.Hidden = False
        Case "9"
            Rows("7:94").EntireRow.Hidden = True
            Rows("7:85").EntireRow.Hidden = False
        Case "10"
            Rows("7:94").EntireRow.Hidden = True
            Rows("7:94").EntireRow.Hidden = False
End Select
End If
End Sub

Thank you in advance!
 

Excel Facts

Select a hidden cell
Somehide hide payroll data in column G? Press F5. Type G1. Enter. Look in formula bar while you arrow down through G.
What is the name of the sheet you want to hide the rows on?
 
Upvote 0
A formula is not going to work because the worksheet change event requires you to select a cell and then change it. A formula will not trigger it.
 
Upvote 0
Thanks for that, try this in the Main Sheet 2.0 sheet
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

If Target.Address = ("$H$21") Then
   With Sheets("Installation concepts")
      .Rows("7:94").Hidden = True
      Select Case target.Value
        Case "1"
            .Rows("7:13").EntireRow.Hidden = False
        Case "2"
            .Rows("7:22").EntireRow.Hidden = False
        Case "3"
            .Rows("7:31").EntireRow.Hidden = False
        Case "4"
            .Rows("7:40").EntireRow.Hidden = False
        Case "5"
            .Rows("7:49").EntireRow.Hidden = False
        Case "6"
            .Rows("7:58").EntireRow.Hidden = False
        Case "7"
            .Rows("7:67").EntireRow.Hidden = False
        Case "8"
            .Rows("7:76").EntireRow.Hidden = False
        Case "9"
            .Rows("7:85").EntireRow.Hidden = False
        Case "10"
            .Rows("7:94").EntireRow.Hidden = False
      End Select
   End With
End If
End Sub
 
Last edited:
Upvote 0
@jvandeliefvoort What is the point of Case 10? You hide and unhide the same rows.

FYI If you want to use a formula, you probably should use Private Sub Worksheet_Calculate()
 
Upvote 0
You could also reduce the code to this
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

If Target.Address = ("$H$21") Then
   With Sheets("Installation concepts")
      .Rows("7:94").Hidden = True
      .Rows("7:" & Target.Value * 9 + 4).Hidden = False
   End With
End If
End Sub
 
Upvote 0
Solution
You could also reduce the code to this
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

If Target.Address = ("$H$21") Then
   With Sheets("Installation concepts")
      .Rows("7:94").Hidden = True
      .Rows("7:" & Target.Value * 9 + 4).Hidden = False
   End With
End If
End Sub
On it's own this works, thanks a lot! The problem is that in the Main Sheet 2.0 I already have a code with this cell integrated in it. I tried to combine those two to this code, but it doesn't work (the first part I will try to reduce as well).

VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)



If Target.Address = ("$H$21") Then



Select Case Target.Value

Case "1"

Rows("29:68").EntireRow.Hidden = True

Rows("29:31").EntireRow.Hidden = False

Rows("77:86").EntireRow.Hidden = True

Rows("77:77").EntireRow.Hidden = False

Case "2"

Rows("29:68").EntireRow.Hidden = True

Rows("29:35").EntireRow.Hidden = False

Rows("77:86").EntireRow.Hidden = True

Rows("77:78").EntireRow.Hidden = False

Case "3"

Rows("29:68").EntireRow.Hidden = True

Rows("29:39").EntireRow.Hidden = False

Rows("77:86").EntireRow.Hidden = True

Rows("77:79").EntireRow.Hidden = False

Case "4"

Rows("29:68").EntireRow.Hidden = True

Rows("29:43").EntireRow.Hidden = False

Rows("77:86").EntireRow.Hidden = True

Rows("77:80").EntireRow.Hidden = False

Case "5"

Rows("29:68").EntireRow.Hidden = True

Rows("29:47").EntireRow.Hidden = False

Rows("77:86").EntireRow.Hidden = True

Rows("77:81").EntireRow.Hidden = False

Case "6"

Rows("29:68").EntireRow.Hidden = True

Rows("29:51").EntireRow.Hidden = False

Rows("77:86").EntireRow.Hidden = True

Rows("77:82").EntireRow.Hidden = False

Case "7"

Rows("29:68").EntireRow.Hidden = True

Rows("29:55").EntireRow.Hidden = False

Rows("77:86").EntireRow.Hidden = True

Rows("77:83").EntireRow.Hidden = False

Case "8"

Rows("29:68").EntireRow.Hidden = True

Rows("29:59").EntireRow.Hidden = False

Rows("77:86").EntireRow.Hidden = True

Rows("77:84").EntireRow.Hidden = False

Case "9"

Rows("29:68").EntireRow.Hidden = True

Rows("29:63").EntireRow.Hidden = False

Rows("77:86").EntireRow.Hidden = True

Rows("77:85").EntireRow.Hidden = False

Case "10"

Rows("29:68").EntireRow.Hidden = True

Rows("29:67").EntireRow.Hidden = False

Rows("77:86").EntireRow.Hidden = True

Rows("77:86").EntireRow.Hidden = False



With Sheets("Installation concepts")

.Rows("7:94").Hidden = True

.Rows("7:" & Target.Value * 9 + 4).Hidden = False

End With



End Select

End If

End Sub
 
Upvote 0
You need to put the code I suggested after the End Select, not before it.
 
Upvote 0

Forum statistics

Threads
1,213,534
Messages
6,114,184
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