• Macro to Change Pivot Table’s CurrentPage

    Home » Forums » AskWoody support » Productivity software by function » MS Excel and spreadsheet help » Macro to Change Pivot Table’s CurrentPage

    Author
    Topic
    #479373

    Hello,

    I have the following macro which changes the CurrentPage based on what is in cell A1 for TWO different pivot tables:

    Sub Testing()
    ActiveSheet.PivotTables(“PivotTable2”).PivotFields(“Expense Category”). _
    CurrentPage = Sheet1.Range(“A1”).Value


    ActiveSheet.PivotTables(“PivotTable3”).PivotFields(“Expense Category”). _
    CurrentPage = Sheet1.Range(“A1”).Value

    End Sub

    I’d like to have the macro automatically run when cell A1 is changed. I’m trying to avoid having the user change the CurrentPage on BOTH pivot tables (or they might forget to change both pivot tables). Does anyone know how I need to tweak the macro to make it do this? Thank you!!

    Viewing 3 reply threads
    Author
    Replies
    • #1301234

      You could create a change event, by adding this the sheet1 module (warning aircode):

      Private Sub Worksheet_Change(ByVal Target As Range)
      If Not Intersect(Target, Range(“A1”)) Is Nothing Then
      ActiveSheet.PivotTables(“PivotTable2”).PivotFields (“Expense Category”). _
      CurrentPage = Sheet1.Range(“A1”).Value
      ActiveSheet.PivotTables(“PivotTable3”).PivotFields (“Expense Category”). _
      CurrentPage = Sheet1.Range(“A1”).Value[/COLOR]
      End If
      End Sub

      If the pivot tables are not on sheet1, change “Activesheet” to be the worksheet containing the pivot tables…

      Steve[/COLOR]

    • #1301236

      Steve beat me to it but this is tested code.

      Code:
      Option Explicit
      
      Private Sub Worksheet_Change(ByVal Target As Range)
      
         Dim isect As Range
         
         Set isect = Application.Intersect(Range(“A1”), Range(Target.Address(xlA1)))
         If isect Is Nothing Then
           MsgBox “Ranges do not intersect”
         Else
           MsgBox “A1 Changed”, vbOKOnly + vbInformation, “Cell Changed”
         End If
      
      End Sub
      
      

      Just call your macro from the ELSE clause, after deleting both MSGBOX statements, or copy your code in the ELSE clause. :cheers:

      Steve,

      I thought I should just be able to use Target directly but it kept giving me errors (Excel 2007) so I made the adjustment shown.

      May the Forces of good computing be with you!

      RG

      PowerShell & VBA Rule!
      Computer Specs

    • #1301242

      RetiredGeek,
      You should be able to use Target directly as a range (as I did in my code).

      I can not test in XL2007, but the line:

      Set isect = Application.Intersect(Range(“A1”), Target)

      works for me in XL2010 and I recall it working for me in versions of XL previous to XL2007 that I used…

      What was the code that gave the error?

      Steve

      • #1301244

        Steve,

        It gave me an Object Required message. :cheers:

        I went back and tried it again and it worked. :confused:
        I think I may have gotten that message when I tried to put it all in the IF clause. Probably goofed something I didn’t see. Thanks Steve.

        May the Forces of good computing be with you!

        RG

        PowerShell & VBA Rule!
        Computer Specs

    • #1301276

      Just idle speculation, but you may have gotten it in the IF if the ranges did not intersect and you tried using isect. When there is no intersection, isect is NOTHING so is not a range object…

      Steve

    Viewing 3 reply threads
    Reply To: Macro to Change Pivot Table’s CurrentPage

    You can use BBCodes to format your content.
    Your account can't use all available BBCodes, they will be stripped before saving.

    Your information: