Auto Hide/Unhide rows based on value/ no value in cells on different sheet

tyschr

New Member
Joined
Sep 10, 2018
Messages
2
Apologies for what may be a redundant post- I've tried to piece together a solution to my problem from other answers I've seen but haven't been fully successful.
Speaking generically, I have a workbook that's used to calculate and print results for reports, input information is entered on sheet X which then fills values on sheets Y,Z, etc. I don't know VBA but have a grasp on how programming operations work, I've had some trouble trying to dissect the responses on similar posts that I've seen to find the pieces I need.

Basic concept:

If there is a value in sheet X, A1:A5 then sheet Y Rows 1:5 are shown. If sheet X A1:A5 is empty then sheet Y Rows 1:5 are hidden. If the value/ no value state of Sheet X A1:A5 changes the corresponding rows on other sheets hide/ unhide accordingly.

I've been able to hide the cells but have not had any luck with a code that will also unhide hidden cells if the cells on the input sheet change. Any help would be much appreciated!
 

Excel Facts

VLOOKUP to Left?
Use =VLOOKUP(A2,CHOOSE({1,2},$Z$1:$Z$99,$Y$1:$Y$99),2,False) to lookup Y values to left of Z values.
Copy and paste this macro into the worksheet code module. Do the following: right click the tab for your sheet X and click 'View Code'. Paste the macro into the empty code window that opens up. Close the code window to return to your sheet. Enter or delete a value in A1:A5 in sheet X and exit the cell.

Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Intersect(Target, Range("A1:A5")) Is Nothing Then Exit Sub
    If Target = "" Then
        Sheets("Y").Rows(Target.Row).Hidden = True
    Else
        Sheets("Y").Rows(Target.Row).Hidden = False
    End If
End Sub
 
Last edited:
Upvote 0
@mumps thanks for the reply! Is there a way to perform this operation with cells/ rows that aren't in the same range? For instance:

If Sheet X B15:B19 are empty then Sheets Y&Z Rows 22:30 are hidden (& vice-versa)

If Sheet X B41 is empty then Sheet Z Rows 10:15 are hidden (& vice-versa)

I thought I'd be able to reverse engineer the code but I don't know enough about the various commands. Thank you again for the help.
 
Upvote 0
How about
Code:
Private Sub Worksheet_Change(ByVal Target As Range)
   If Not Intersect(Target, Range("A1:A5")) Is Nothing Then
      Sheets("Y").Rows(Target.Row).Hidden = Target.Value = ""
   ElseIf Not Intersect(Target, Range("B15:B19")) Is Nothing Then
      Sheets("Y").Rows(Target.Row).Hidden = Target.Value = ""
      Sheets("Z").Rows(Target.Row).Hidden = Target.Value = ""
   ElseIf Not Intersect(Target, Range("B41")) Is Nothing Then
      Sheets("Z").Rows(Target.Row).Hidden = Target.Value = ""
   End If
End Sub
 
Upvote 0

Forum statistics

Threads
1,224,828
Messages
6,181,209
Members
453,022
Latest member
RobertV1609

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