Results 1 to 6 of 6
  1. #1
    3 Star Lounger
    Join Date
    Jul 2002
    Location
    Ankeny, Iowa, USA
    Posts
    344
    Thanks
    8
    Thanked 0 Times in 0 Posts

    Macro to Change Pivot Table's CurrentPage

    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!!

  2. #2
    WS Lounge VIP sdckapr's Avatar
    Join Date
    Jul 2002
    Location
    Pittsburgh, Pennsylvania, USA
    Posts
    11,225
    Thanks
    14
    Thanked 342 Times in 335 Posts
    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

    End If
    End Sub

    If the pivot tables are not on sheet1, change "Activesheet" to be the worksheet containing the pivot tables...

    Steve

  3. The Following User Says Thank You to sdckapr For This Useful Post:

    LJM (2011-10-07)

  4. #3
    Super Moderator RetiredGeek's Avatar
    Join Date
    Mar 2004
    Location
    Manning, South Carolina
    Posts
    9,433
    Thanks
    371
    Thanked 1,456 Times in 1,325 Posts
    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.

    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!

    My Systems: Desktop Specs
    Laptop Specs

  5. The Following User Says Thank You to RetiredGeek For This Useful Post:

    LJM (2011-10-07)

  6. #4
    WS Lounge VIP sdckapr's Avatar
    Join Date
    Jul 2002
    Location
    Pittsburgh, Pennsylvania, USA
    Posts
    11,225
    Thanks
    14
    Thanked 342 Times in 335 Posts
    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

  7. #5
    Super Moderator RetiredGeek's Avatar
    Join Date
    Mar 2004
    Location
    Manning, South Carolina
    Posts
    9,433
    Thanks
    371
    Thanked 1,456 Times in 1,325 Posts
    Steve,

    It gave me an Object Required message.

    I went back and tried it again and it worked.
    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.
    Last edited by RetiredGeek; 2011-10-07 at 20:02.
    May the Forces of good computing be with you!

    RG

    PowerShell & VBA Rule!

    My Systems: Desktop Specs
    Laptop Specs

  8. #6
    WS Lounge VIP sdckapr's Avatar
    Join Date
    Jul 2002
    Location
    Pittsburgh, Pennsylvania, USA
    Posts
    11,225
    Thanks
    14
    Thanked 342 Times in 335 Posts
    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

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •