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)
 

Excel Facts

What is the fastest way to copy a formula?
If A2:A50000 contain data. Enter a formula in B2. Select B2. Double-click the Fill Handle and Excel will shoot the formula down to B50000.
Are you trying to check the value of the target cell? If so, Target = "xxxxxxx" is not correct. You would need to check it like so: Target.Value = "xxxxxxx".
 
Upvote 0
This line of code refers to Sheet2.
Rich (BB code):
Select Case Sheet2.Range("G9").Value
which seems to indicate that G9 is on a different sheet than the L4 cell that this line refers to:
Rich (BB code):
[If Target.Address = "$L$4" Then
Is this the case or are both cells (L4, G9) on the same sheet?
 
Upvote 0
Are you trying to check the value of the target cell? If so, Target = "xxxxxxx" is not correct. You would need to check it like so: Target.Value = "xxxxxxx".
I did this change with no effect on my problem. That code was working on my other file, without the .value extension. Since I have latest version of Excel, perhaps it translated for me. But I do understand this is good practice, so noted.
 
Upvote 0
This line of code refers to Sheet2.
Rich (BB code):
Select Case Sheet2.Range("G9").Value
which seems to indicate that G9 is on a different sheet than the L4 cell that this line refers to:
Rich (BB code):
[If Target.Address = "$L$4" Then
Is this the case or are both cells (L4, G9) on the same sheet?
Yes, both on same sheet. I realize now that the Sheet2 reference in this line is overkill/unneeded and will edit.
 
Upvote 0
It would be easier to help if you could use the XL2BB add-in (icon in the menu) to attach screenshots (not pictures) of your two sheets. Alternately, you could upload a copy of your file to a free site such as www.box.com or www.dropbox.com. Once you do that, mark it for 'Sharing' and you will be given a link to the file that you can post here. Explain in detail what you want to do referring to specific cells, rows, columns and sheets using a few examples from your data (de-sensitized if necessary).
 
Upvote 0
I gave it some more thought. Try this version:
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
                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
        Case Is = 9
            If Target = "B17F" Then
                Sheet21.Visible = xlSheetVisible
                Sheet25.Visible = xlSheetVisible
            Else
                Sheet21.Visible = xlSheetVeryHidden
                Sheet25.Visible = xlSheetVeryHidden
            End If
    End Select
End Sub
If it still doesn't work then review my previous post. Also, you have Sheet23 listed 4 times in the first section of the code.
 
Upvote 0
I did this change with no effect on my problem. That code was working on my other file, without the .value extension. Since I have latest version of Excel, perhaps it translated for me. But I do understand this is good practice, so noted.
I stand corrected then. I don't usually see that and didn't think to research to see if it was correct. My apologies.
 
Upvote 0
I gave it some more thought. Try this version:
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
                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
        Case Is = 9
            If Target = "B17F" Then
                Sheet21.Visible = xlSheetVisible
                Sheet25.Visible = xlSheetVisible
            Else
                Sheet21.Visible = xlSheetVeryHidden
                Sheet25.Visible = xlSheetVeryHidden
            End If
    End Select
End Sub
If it still doesn't work then review my previous post. Also, you have Sheet23 listed 4 times in the first section of the code.
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
 
Upvote 0

Forum statistics

Threads
1,223,099
Messages
6,170,107
Members
452,302
Latest member
TaMere

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