Two Worksheet_Change on same Worksheet

happyhungarian

Active Member
Joined
Jul 19, 2011
Messages
252
Office Version
  1. 365
Platform
  1. Windows
Hi, I have two different change events I'd like to run on the same sheet. I'm having trouble having the second one run. Here's the first change:

Private Sub Worksheet_Change(ByVal Target As Range)

If Intersect(Target, Range("C3")) Is Nothing Then Exit Sub

Application.CutCopyMode = False
ActiveWorkbook.RefreshAll
DoEvents

Sheets("Pivots").PivotTables("PivotTable1").PivotCache.Refresh
DoEvents

MsgBox "Queries Complete"

End Sub


And here's the second:

Private Sub Worksheet_Change(ByVal Target As Range)


If Intersect(Target, Range("C5")) Is Nothing Then Exit Sub



Dim pt As PivotTable
Dim FieldContract_Date As PivotField
Dim NewContract_Date As String




Set pt = Worksheets("Pivots").PivotTables("PivotTable2")
Set FieldContract_Date = pt.PivotFields("Contract_Date")
NewContract_Date = Worksheets("Worksheet").Range("C5").Value

pt.RefreshTable


With pt
FieldContract_Date.ClearAllFilters
FieldContract_Date.CurrentPage = NewContract_Date
pt.RefreshTable

End With

End Sub
 

Excel Facts

Show numbers in thousands?
Use a custom number format of #,##0,K. Each comma after the final 0 will divide the displayed number by another thousand
My first thought is that you need to put the second code within the first Worksheet_Change event.

Like this:

Rich (BB code):
Private Sub Worksheet_Change(ByVal Target As Range)
If Intersect(Target, Range("C3")) Is Nothing Then 
Exit Sub
Else
    Application.CutCopyMode = False
    ActiveWorkbook.RefreshAll
    DoEvents

    Sheets("Pivots").PivotTables("PivotTable1").PivotCache.Refresh
    DoEvents

    MsgBox "Queries Complete"
End If

If Intersect(Target, Range("C5")) Is Nothing Then 
Exit Sub
Else
Dim pt As PivotTable
Dim FieldContract_Date As PivotField
Dim NewContract_Date As String




Set pt = Worksheets("Pivots").PivotTables("PivotTable2")
Set FieldContract_Date = pt.PivotFields("Contract_Date")
NewContract_Date = Worksheets("Worksheet").Range("C5").Value

pt.RefreshTable


With pt
FieldContract_Date.ClearAllFilters
FieldContract_Date.CurrentPage = NewContract_Date
pt.RefreshTable

End With
End If
End Sub

Your IF statements checking which cell is Target will determine which part of the code is run.
 
Last edited:
Upvote 0
The second Worksheet_Change isn't triggering. Is it become of the first If Intersect(Target, Range("C3")) Is Nothing Then Exit Sub? Since C3 isn't changing the macro stops?
 
Upvote 0
You can only have one Worksheet_Change event per sheet, but you can combine multiple functions within one macro:

Code:
Private Sub Worksheet_Change(ByVal Target As Range)

' If C3 is changed, execute this
    If Not Intersect(Target, Range("C3")) Is Nothing Then

        Application.CutCopyMode = False
        ActiveWorkbook.RefreshAll
        DoEvents

        Sheets("Pivots").PivotTables("PivotTable1").PivotCache.Refresh
        DoEvents

        MsgBox "Queries Complete"
    End If

' If C5 is changed, execute this
    If Not Intersect(Target, Range("C5")) Is Nothing Then

        Dim pt As PivotTable
        Dim FieldContract_Date As PivotField
        Dim NewContract_Date As String

        Set pt = Worksheets("Pivots").PivotTables("PivotTable2")
        Set FieldContract_Date = pt.PivotFields("Contract_Date")
        NewContract_Date = Worksheets("Worksheet").Range("C5").Value

        pt.RefreshTable

        With pt
            FieldContract_Date.ClearAllFilters
            FieldContract_Date.CurrentPage = NewContract_Date
            pt.RefreshTable
        End With
    
    End If

End Sub

dreid1011, you have the basic concept correct, but if I'm reading your code correctly, then if C5 is changed, the second part of your macro will never be executed.
 
Upvote 0
dreid1011, you have the basic concept correct, but if I'm reading your code correctly, then if C5 is changed, the second part of your macro will never be executed.

Yes, I realized that now. I wasn't paying much attention to the 'Exit Sub' lines that well. I seem to overlook small details like that ;)
 
Upvote 0

Forum statistics

Threads
1,223,894
Messages
6,175,250
Members
452,623
Latest member
Techenthusiast

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