Pivot table - filter by VBA

mrmaso

New Member
Joined
Oct 10, 2017
Messages
16
Hello,
could somebody help me with this issue:
- I have pivot table where I would like to apply automatic filter by macro. All needed values which should be used are in cells B5:B55. Is it possible to write macro which will use these cells to set up filter?

Thank you.
 

Excel Facts

Copy PDF to Excel
Select data in PDF. Paste to Microsoft Word. Copy from Word and paste to Excel.
Change the red data by your information

Code:
Sub Set_Sales_History_Time_Period()
    Dim pvt As PivotTable, pi As PivotItem, n As Long, Rng As Range, f As Range
    
    Set Rng = Range("[COLOR=#ff0000]B5:B55[/COLOR]")
    n = 0
    Application.ScreenUpdating = False
    Set pvt = ActiveSheet.PivotTables("[COLOR=#ff0000]Table1[/COLOR]")  [COLOR=#006400]'Table name[/COLOR]
    With pvt.PivotFields("[COLOR=#ff0000]Name[/COLOR]")   [COLOR=#006400]'Name of the field to filter[/COLOR]
        .ClearAllFilters
        For Each pi In .PivotItems
          Set f = Rng.Find(pi, , xlValues, xlWhole)
          If f Is Nothing Then
            n = n + 1
            If n < .PivotItems.Count Then
              pi.Visible = False
            Else
              MsgBox "No match"
              .ClearAllFilters
            End If
          End If
        Next
    End With
End Sub
 
Upvote 0
I'm glad to help you. Thanks for the feedback.
 
Upvote 0

Forum statistics

Threads
1,214,583
Messages
6,120,378
Members
448,955
Latest member
BatCoder

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