Worksheet Change - multiple Loops in one sub

bertible

New Member
Joined
Mar 15, 2024
Messages
16
Office Version
  1. 2021
Platform
  1. Windows
Further to the solution in another workbook I was working on, Another VBA question to hide/unhide rows based on cell value in another sheet
I am now working on a very similar template for another product (turbine engine repair). Again, I am using a parameters page (Sheet 2 "Input Page") for users to select a variety of parameters to create several pricing sheets, and this Sub resides on Sheet2.
The Cell L4 test and loop is the same as in the prior solution, to show or hide (veryhide) sheets based on an input method of "Detail" vs "Summary" So I've just inserted that code into this Sub. Cell G9 is a requirement to veryhide two sheets for a particular engine model "B17F" but not for all other engine models. That code worked fine until the above insertion. As my VBA is based on decades old coding knowledge (FORTRAN), cobbling in answers from this board (and learning as I go), the second loop in this subroutine will no longer run.

Rich (BB code):
Private Sub Worksheet_Change(ByVal Target As Range)
'Application.Volatile

If Target.Cells.CountLarge = 1 And Not Intersect(Range("G9,L4"), Target) Is Nothing Then
        On Error GoTo Escape


            Application.EnableEvents = False
        
        If Target.Address = "$L$4" Then
            If Target = "Summary" Then
                Sheet19.Visible = xlSheetVeryHidden
                Sheet23.Visible = xlSheetVeryHidden
                Sheet24.Visible = xlSheetVeryHidden
                Sheet23.Visible = xlSheetVeryHidden
                Sheet25.Visible = xlSheetVeryHidden
                            ElseIf Target = "Detail" Then
                Sheet19.Visible = xlSheetVisible
                Sheet23.Visible = xlSheetVisible
                Sheet24.Visible = xlSheetVisible
                Sheet23.Visible = xlSheetVisible
                Sheet25.Visible = xlSheetVisible
                                
            End If
        End If
End If
        
Continue:
    Application.EnableEvents = True
    Exit Sub
'Moved B17 Hide to after Detail Summary Sub  Didn't work,  Sheet 25 ends up visible whenever "Detail" case above
Select Case Sheet2.Range("G9").Value
        Case "B17F"
            Sheet21.Visible = xlSheetVisible
            Sheet25.Visible = xlSheetVisible
        Case Else
            Sheet21.Visible = xlSheetVeryHidden
            Sheet25.Visible = xlSheetVeryHidden
   End Select
Escape:
    MsgBox "Error " & Err.Number & ": " & Err.Description
    Resume Continue
End Sub

The first loop runs fine for the most part, with L4 selection of Summary vs Detail except Sheet25 which is also in the 2nd loop. But changing G9 has no effect: Sheet21 stays hidden in all cases of G9 & L4, and Sheet25 stays visible in all cases. (PS, I did try changing the Case statement to If statement, no effect)

TIA
Gary (bertible)
 
Oops, I discovered one situation where this code doesn't quite cover me. If cell L4 = "Detail" and cell G9 <> "B17F", then Sheet25 stays visible even though I would like the second Case & If statements to make it veryhidden. (G9 ="B17F" or not should take precedence over L4) See my added comment lines 1/ and 2/ below. I've tried nesting Ifs but no luckso far. I guess I need some sort of boolean Or/And logic?


It worked! Very nice and clean code with obvious (to this newbie) logic with nested IF's within the two case statements. Thanks for pointing out the duplicate Sheet references (one of them should have been Sheet7)

Gary/bertible
Rich (BB code):
Private Sub Worksheet_Change(ByVal Target As Range)
'Application.Volatile

If Target.CountLarge > 1 Then Exit Sub
If Intersect(Target, Range("L4", "G9")) Is Nothing Then Exit Sub
       
    Select Case Target.Row
        Case Is = 4
            If Target = "Summary" Then
                Sheet19.Visible = xlSheetVeryHidden
                Sheet7.Visible = xlSheetVeryHidden
                Sheet24.Visible = xlSheetVeryHidden
                Sheet23.Visible = xlSheetVeryHidden
                Sheet25.Visible = xlSheetVeryHidden
            ElseIf Target = "Detail" Then
                Sheet19.Visible = xlSheetVisible
                Sheet7.Visible = xlSheetVisible
                Sheet24.Visible = xlSheetVisible
                Sheet23.Visible = xlSheetVisible
               '1/  The statement below is taking precedence over the #2 statement below
               Sheet25.Visible = xlSheetVisible
            End If
        Case Is = 9
            If Target = "B17F" Then
                Sheet21.Visible = xlSheetVisible
                Sheet25.Visible = xlSheetVisible
            Else
                Sheet21.Visible = xlSheetVeryHidden
                '2/ The statement below is not being followed if Target in Row 4 is detail (#1 above)
                Sheet25.Visible = xlSheetVeryHidden
            End If
    End Select
End Sub
 
Upvote 0

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
Are you saying that if cell L4 = "Detail" and cell G9 <> "B17F", you want Sheet25 to be xlSheetVeryHidden?
 
Upvote 0
Yes. To put it another way, Sheet25 should be visible ONLY when both of G9 = “B17” AND L4 = “Detail” are true.
And Sheet21 visible when [G9 = “B17F” AND (L4 = “Detail” OR “Summary”)]
 
Upvote 0
Try:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
    If Target.CountLarge > 1 Then Exit Sub
    If Intersect(Target, Range("L4,G9")) Is Nothing Then Exit Sub
    Select Case Target.Row
        Case Is = 4
            If Target = "Summary" Then
                Sheet19.Visible = xlSheetVeryHidden
                If Range("G9") = "B17F" Then
                    Sheet21.Visible = xlSheetVisible
                Else
                    Sheet21.Visible = xlSheetVeryHidden
                End If
                Sheet23.Visible = xlSheetVeryHidden
                Sheet24.Visible = xlSheetVeryHidden
                Sheet25.Visible = xlSheetVeryHidden
            ElseIf Target = "Detail" Then
                Sheet19.Visible = xlSheetVisible
                If Range("G9") = "B17F" Then
                    Sheet21.Visible = xlSheetVisible
                Else
                    Sheet21.Visible = xlSheetVeryHidden
                End If
                Sheet23.Visible = xlSheetVisible
                Sheet24.Visible = xlSheetVisible
                If Range("G9") = "B17F" Then
                    Sheet25.Visible = xlSheetVisible
                Else
                    Sheet25.Visible = xlSheetVeryHidden
                End If
            End If
        Case Is = 9
            If Target = "B17F" Then
                If Range("L4") = "Detail" Or Range("L4") = "Summary" Then
                    Sheet21.Visible = xlSheetVisible
                Else
                    Sheet21.Visible = xlSheetVeryHidden
                End If              
                If Range("L4") = "Detail" Then
                    Sheet25.Visible = xlSheetVisible
                Else
                    Sheet25.Visible = xlSheetVeryHidden
                End If
            End If
    End Select
End Sub
 
Upvote 0
Solution
Thanks, I've been off for a few days so just returned to this. I used your code, Mumps, and still had a lagging visible Sheet21 but adding an ELSE to the end of Case 9 fixed it, as follows:

Rich (BB code):
Case Is = 9
            If Target = "B17F" Then
                If Range("L4") = "Detail" Or Range("L4") = "Summary" Then
                    Sheet21.Visible = xlSheetVisible
                Else
                    Sheet21.Visible = xlSheetVeryHidden
                End If
                If Range("L4") = "Detail" Then
                    Sheet25.Visible = xlSheetVisible
                Else
                    Sheet25.Visible = xlSheetVeryHidden
                End If
            Else
                Sheet21.Visible = xlSheetVeryHidden
                Sheet25.Visible = xlSheetVeryHidden
            End If

Now working for all the test iterations I've been able to derive.
Thanks Gary
 
Upvote 0

Forum statistics

Threads
1,215,212
Messages
6,123,651
Members
449,111
Latest member
ghennedy

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