Using Multiple Private Sub Worksheet_Change(ByVal Target As Range)

XrayLemi

Board Regular
Joined
Aug 1, 2018
Messages
153
Office Version
  1. 365
Platform
  1. Windows
Hello All. I did not see an answer to my question already posted. If it has been posted Let me know . I have A workbook with multiple sheets. Except sheet 1, all are nearly carbon copies of each other. I already have one set of "Private Sub Worksheet_Change(ByVal Target As Range)" code on each sheet. It locks cells in column H until the values in G are entered. It will delete and re-lock H if the value in G is removed. It is as follows:
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim r As Range, c As Range
  Set r = Range("G6:G5000")
  Set r = Intersect(Target, r)
  If r Is Nothing Then Exit Sub
  
  Application.EnableEvents = False
  
  For Each c In r
    Select Case True
      Case 7 = c.Column 'G
        If c.Value = "" Then
          Cells(c.Row, "H").Value = ""
          Cells(c.Row, "H").Locked = True
          Else
          Cells(c.Row, "H").Locked = False
        End If
      Case Else
    End Select
  Next c
  
  Application.EnableEvents = True
End Sub

I then tried to add the following code to automatically add the date in another column.
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)

  If Target.Cells.Count > 4 Then Exit Sub

  If Not Intersect(Target, Range("B6:B5000")) Is Nothing Then

                       With Target(1, 4)

                        .Value = Date

                        .EntireColumn.AutoFit

                       End With

             End If

End Sub
Until now, I did not know I could not have two "Private Sub Worksheet_Change codes in the same sheet. How do I get around this? There is also other code on the worksheet. Some for an active x button, some for opening and closing a master file. I did not add all the code in this initial post. If I need to let me know.
Thanks in advance,
Jim
 

Excel Facts

How to find 2nd largest value in a column?
MAX finds the largest value. =LARGE(A:A,2) will find the second largest. =SMALL(A:A,3) will find the third smallest
The two procedures can be combined. Untested, but this combination compiles.
VBA Code:
Private Sub Worksheet_Change(ByVal Target As Range)
  Dim r As Range, c As Range
  Set r = Range("G6:G5000")
  Set r = Intersect(Target, r)
  If Not r Is Nothing Then
  Application.EnableEvents = False
  For Each c In r
    Select Case True
      Case 7 = c.Column 'G
        If c.Value = "" Then
          Cells(c.Row, "H").Value = ""
          Cells(c.Row, "H").Locked = True
          Else
          Cells(c.Row, "H").Locked = False
        End If
      Case Else
    End Select
  Next c
  End If
  If Target.Cells.Count > 4 Then Exit Sub
  If Not Intersect(Target, Range("B6:B5000")) Is Nothing Then
    With Target(1, 4)
     .Value = Date
     .EntireColumn.AutoFit
    End With
    End If
  Application.EnableEvents = True
End Sub
 
Upvote 0
Solution
This seems to work perfectly! If I see this right, and understand it, You added an additional end if after next c This "closes" the last part of the original end if without ending the sub. Then you go right into the new If statement with the new code. After the final end if, the Application.Events = True is added to end all the end if statements. Only then do you End Sub. If I got it, Is this how you handle all the cases where you need more than one Multiple Private worksheet_Change?
Thanks Again,
Jim
 
Upvote 0
This seems to work perfectly! If I see this right, and understand it, You added an additional end if after next c This "closes" the last part of the original end if without ending the sub. Then you go right into the new If statement with the new code. After the final end if, the Application.Events = True is added to end all the end if statements. Only then do you End Sub. If I got it, Is this how you handle all the cases where you need more than one Multiple Private worksheet_Change?
Thanks Again,
Jim
You are welcome - thanks for the reply. To answer your question, it's almost always possible to combine multiple change events in a way that can be accommodated in a single worksheet-change procedure.
 
Upvote 0
I have the following and need assistance. So cells D2-D7 will show "yes" or "no" or can be blank and need multiple worksheet_change for the same sheet
Private Sub Worksheet_Change(ByVal Target As Range)
ActiveSheet.Activate
If Not Application.Intersect(Range("D3"), Range(Target.Address)) Is Nothing Then
Select Case Target.Value
Case Is = "Yes": Rows("9:75").EntireRow.Hidden = True
Rows("18:28").EntireRow.Hidden = False
Case Is = "No": Rows("9:75").EntireRow.Hidden = False
Case Is = "": Rows("9:75").EntireRow.Hidden = False
End Select
End If
End Sub
 
Upvote 0
I have the following and need assistance. So cells D2-D7 will show "yes" or "no" or can be blank and need multiple worksheet_change for the same sheet
Private Sub Worksheet_Change(ByVal Target As Range)
ActiveSheet.Activate
If Not Application.Intersect(Range("D3"), Range(Target.Address)) Is Nothing Then
Select Case Target.Value
Case Is = "Yes": Rows("9:75").EntireRow.Hidden = True
Rows("18:28").EntireRow.Hidden = False
Case Is = "No": Rows("9:75").EntireRow.Hidden = False
Case Is = "": Rows("9:75").EntireRow.Hidden = False
End Select
End If
End Sub
Need to compile multiple like
Private Sub Worksheet_Change(ByVal Target As Range)
ActiveSheet.Activate
If Not Application.Intersect(Range("D2"), Range(Target.Address)) Is Nothing Then
Select Case Target.Value
Case Is = "Yes": Rows("9:75").EntireRow.Hidden = True
Rows("50:60").EntireRow.Hidden = False
Case Is = "No": Rows("9:75").EntireRow.Hidden = False
Case Is = "": Rows("9:75").EntireRow.Hidden = False
End Select
End If
 
Upvote 0
I recommend you start a new thread and provide a full explanation of what you need.
 
Upvote 0
I recommend you start a new thread and provide a full explanation of what you need.
Joe is right. You shouldn't post your questions on to other threads. You should start a new thread for your question.
Then your question will show up on the "Unanswered threads" listing, and get more views, and a better chance of getting answered.
 
Upvote 0

Forum statistics

Threads
1,213,553
Messages
6,114,279
Members
448,562
Latest member
Flashbond

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