filter a pivot table with values in an array of cells?

mrdobbs

New Member
Joined
Apr 15, 2011
Messages
1
Does anyone know a good way (in Excel 2010) to filter a pivot table to show only certain rows based on the values in an array of cells on another worksheet? <?xml:namespace prefix = o ns = "urn:schemas-microsoft-com:office:office" /><o:p></o:p>
<o:p></o:p>
Say my pivot table has row labels of "SalesRep" and values of "count of Orders", and I want to only see the results for specific (and often arbitrary) SalesRep(s). Is there a way to have Excel filter the pivot table in a way other than unselecting all the values and then hand checking the box next to the SalesRep we want to report on?<o:p></o:p>
<o:p></o:p>
Thanks (long time reader, first time poster),<o:p></o:p>
<o:p></o:p>
Matt<o:p></o:p>
 
I am not sure where to place the code when creating the pivot table. Is the output a variable?

There is no output variable from the function. The result of running the function is to display the items you list in your array and to hide (filter) the other items.

It will probably be easier to find the problem if you test this by itself first before trying to integrate it into other procedures.

If all the names below match up with your existing Pivot Table, you should be able to run this macro and hide all items except those with Wife and Mother in the Major Caption field.

Code:
Sub Filter_Now()
Filter_PivotField _
    pvtField:=Sheets("Dashboard Data").PivotTables("PivotTable1").PivotFields("Major Caption"), _
    varItemList:=Array("Wife", "Mother")
End Sub
 
Upvote 0

Excel Facts

Repeat Last Command
Pressing F4 adds dollar signs when editing a formula. When not editing, F4 repeats last command.
Hi,

The info in this post is very helpful. However, I don't want to manually set the values of the array in VBA,(i.e. varItemList:=Array("Adams", "Baker", "Clark")) I would like to set those values based on an array of data from a second pivot table. Here is the scenario, I have two pivot tables from different source's of data but they both sources share the same Sales Manager and Account Manager fields. By selecting multiple "Sales Manager" in Pivot table #1 - I would like the vba to set Pivot table#2 to the selection of values that were identified in Pivot table #1. This code works to set Pivot Table #2 to a selection of Sales Managers - but I can't figure out how to load the array of data from pivot table #1.

thanks for the help in advance,
Clint
 
Upvote 0
Thanks. That worked extremely well, even helped me clean up some messy code that I had slapped together. Next challenge....can I use the same DataArray from PivotTable#1 to set a filter on a standard Excel Worksheet-Table with filters applied? Similar scenario where I want to filter to a list only where the Sales Managers are in the Array from the original Pivot Table.
 
Upvote 0
Clint,

If we break the Synch_PT_Filters function into two parts, we can save the Visible PivotItems for a specified field to an Array,
then apply that array to other PivotTables or AutoFilter Criteria.

The Functions are pasted below this example showing the calling code.

Rich (BB code):
Sub Xfer_FilterItems_Example()
    Dim PT1 As PivotTable, PT2 As PivotTable
    Dim vItems As Variant, i As Long
    Dim sField As String
    
    sField = "Sales Manager"
    
    With Sheets("MyPT")
        Set PT1 = .PivotTables("PivotTable1")
        Set PT2 = .PivotTables("PivotTable2")
    End With
    
    '---Stores the visible items in an array
    vItems = Store_PT_FilterItems(PT1, sField)
    
    '---Applies same filter items to PivotTable2
    Call Filter_PivotField( _
        pvtField:=PT2.PivotFields(sField), _
        vItems:=vItems)
        
    '---Applies same filter items to Worksheet Range
    Call Filter_AutoFilterField( _
        rAutoFilterCell:=Sheets("MyAutoFilter").Range("A1"), _
        sHeader:=sField, _
        vItems:=vItems)
    
End Sub

Paste these 3 functions in the same standard module as your calling Sub
Rich (BB code):
Private Function Store_PT_FilterItems(PT As PivotTable, _
        sField As String) As Variant
'---Stores visible items in PivotField sField in an array
    Dim sVisibleItems() As String
    Dim pviItem As PivotItem
    Dim i As Long
    
    '---make array of visible items in PT
    With PT.PivotFields(sField)
        If .Orientation = xlPageField And _
            .EnableMultiplePageItems = False Then
                ReDim sVisibleItems(1)
                sVisibleItems(0) = .CurrentPage
        Else
            For Each pviItem In .PivotItems
                If pviItem.Visible Then
                    i = i + 1
                    ReDim Preserve sVisibleItems(i)
                    sVisibleItems(i - 1) = pviItem
                End If
            Next
        End If
    End With
    Store_PT_FilterItems = sVisibleItems
End Function

Private Function Filter_PivotField(pvtField As PivotField, _
        vItems As Variant)
'---Filters the PivotField to make stored vItems Visible
    Dim sItem As String, bTemp As Boolean, i As Long
    On Error Resume Next
    Application.ScreenUpdating = False
    Application.Calculation = xlCalculationManual
    If Not (IsArray(vItems)) Then
         vItems = Array(vItems)
    End If
 
    With pvtField
        .Parent.ManualUpdate = True
        If .Orientation = xlPageField Then .EnableMultiplePageItems = True
        If vItems(0) = "(All)" Then
            For i = 1 To .PivotItems.Count
                If Not .PivotItems(i).Visible Then _
                    .PivotItems(i).Visible = True
            Next i
        Else
            For i = LBound(vItems) To UBound(vItems)
                bTemp = Not (IsError(.PivotItems(vItems(i)).Visible))
                If bTemp Then
                    sItem = .PivotItems(vItems(i))
                    Exit For
                End If
            Next i
            If sItem = "" Then
                MsgBox "None of filter list items found."
                GoTo CleanUp
            End If
            .PivotItems(sItem).Visible = True
            For i = 1 To .PivotItems.Count
                If IsError(Application.Match(.PivotItems(i), _
                    vItems, 0)) = .PivotItems(i).Visible Then
                    .PivotItems(i).Visible = Not (.PivotItems(i).Visible)
                End If
            Next i
        End If
    End With
    
CleanUp:
    pvtField.Parent.ManualUpdate = False
    Application.ScreenUpdating = True
    Application.Calculation = xlCalculationAutomatic
End Function


Private Function Filter_AutoFilterField(rAutoFilterCell As Range, _
    sHeader As String, vItems As Variant)
'---AutoFilters Current Region of rAutoFilterCell using the Field
'       matching sHeader and criteria in array vItems.

    Dim lField As Long
    On Error Resume Next
    
    lField = Application.Match(sHeader, _
        rAutoFilterCell.CurrentRegion.Resize(1), 0)
    If lField = 0 Then
        MsgBox "Header: " & sHeader & " not found"
    Else
        If vItems(0) = "(All)" Then vItems(0) = "*"
        rAutoFilterCell.AutoFilter Field:=lField, _
        Criteria1:=vItems, Operator:=xlFilterValues
    End If
End Function

Please let me know if this does what you wanted. :)
 
Upvote 0
What would the "varItemList" refer to if I was doing a for each loop on a column of values that it selected based on certain criteria and then reset after the loop. So, if the selection of the array was:

myArray = Range(Selection, Selection.Offset(OffsetDown - 1, 0))

How would I reference that in varItemList and it isn't an actual named range in the worksheet?

Thanks!
 
Upvote 0
What would the "varItemList" refer to if I was doing a for each loop on a column of values that it selected based on certain criteria and then reset after the loop. So, if the selection of the array was:

myArray = Range(Selection, Selection.Offset(OffsetDown - 1, 0))

How would I reference that in varItemList and it isn't an actual named range in the worksheet?

Thanks!

Hi,

This function has evolved since this Original Post to address exceptions and variations requested.

The latest version be found in this thread.

http://www.mrexcel.com/forum/showthread.php?t=596418


The function has this Declaration:

Function Filter_PivotField(pvtField As PivotField, vItems As Variant)

The vItems parameter is a Variant Array of PivotItems whose Visible state you want set to True
You can use a one column wide range reference to make vItems parameter like these examples...

Code:
Sub TEST()
    Dim pField as PivotField
    Set pField= Sheets("Sheet1").PivotTables("PivotTable1").PivotFields("MyField")

    Filter_PivotField pvtField:=pField, _
        vItems:=Application.Transpose(Sheets("Sheet2").Range("MyNamedRange"))


    Filter_PivotField pvtField:=pField, _
        vItems:=Application.Transpose(Sheets("Sheet2").Range("C4:C32"))


    Filter_PivotField pvtField:=pField, _
        vItems:=Application.Transpose(Sheets("Sheet2") _
            .Range("D1:D" & Cells(Rows.Count, 4).End(xlUp).Row))

End Sub

If the example you gave returns a valid range, you could use:
Code:
    Filter_PivotField pvtField:=pField, _
        vItems:=Application.Transpose(Range(Selection, _
	    Selection.Offset(OffsetDown - 1, 0)))
 
Upvote 0
So I tried this and the pivot table doesn't budge a bit. Here is my code:

'Loop through specific Brand IDs/Supplier IDs on ID worksheet
srng.Select
For Each Cell In srng

If Cell = 0 And Cell.Offset(0, 3) = 0 Or Cell.Offset(0, 3) = 1 Then
BrandID = Cell.Offset(0, 1).Value

CountBrands = PT.PivotFields("ID").PivotItems.Count
CountID = CountID + 1

Main.Select
PT.PivotFields("ID").CurrentPage = BrandID
'PT.PivotFields("SUPPLIER_ID").CurrentPage = Supply.Value
PT.ManualUpdate = False
PT.ManualUpdate = True

'PT.PivotFields("ID").CurrentPage = x.Value
'PT.PivotFields("SUPPLIER_ID").CurrentPage = Supply.Value
'ActiveSheet.Calculate

Set CurBrand = Range("A16")
Set BrandName = Range("B16")
Sheets("DtDump").Select
If ActiveSheet.AutoFilterMode = True Then ActiveSheet.AutoFilterMode = False
Range("A1:L1").Select
Selection.AutoFilter
ActiveSheet.Range("DumpRng").AutoFilter Field:=5, Criteria1:=BrandID

Dim i As Integer
Dim RowNum As Long
Dim vItems As Variant
Dim myArray As Range
Dim MyCount As Integer

ElseIf Cell <> 0 And Cell.Offset(0, 3) > 1 Then
BrandID = Cell.Offset(0, 1).Value
OffsetDown = Cell.Offset(0, 3).Value
Cell.Select


Dim pField As PivotField
Set pField = Sheets("Main").PivotTables("QtrPiv").PivotFields("Supplier_ID")

Filter_PivotField pvtField:=pField, _
vItems:=Application.Transpose(Range(Selection, _
Selection.Offset(OffsetDown - 1, 0)))

------------------------------------------

Here are the functions I picked up from your description:

Sub trial()
Dim pField As PivotField
Set pField = Sheets("Main").PivotTables("QtrPiv").PivotFields("Supplier_ID")

Filter_PivotField pvtField:=pField, _
vItems:=Application.Transpose(Range(Selection, _
Selection.Offset(OffsetDown - 1, 0)))
End Sub

Public Function Filter_PivotField(pvtField As PivotField, _
vItems As Variant)
'---Filters the PivotField to make stored vItems Visible
Dim sItem As String, bTemp As Boolean, i As Long
On Error Resume Next
Application.ScreenUpdating = True
Application.Calculation = xlCalculationAutomatic
If Not (IsArray(vItems)) Then
vItems = Array(vItems)
End If

With pvtField
.Parent.ManualUpdate = True
If .Orientation = xlPageField Then .EnableMultiplePageItems = True
If vItems(0) = "(All)" Then
For i = 1 To .PivotItems.Count
If Not .PivotItems(i).Visible Then _
.PivotItems(i).Visible = True
Next i
Else
For i = LBound(vItems) To UBound(vItems)
bTemp = Not (IsError(.PivotItems(vItems(i)).Visible))
If bTemp Then
sItem = .PivotItems(vItems(i))
Exit For
End If
Next i
If sItem = "" Then
MsgBox "None of filter list items found."
GoTo CleanUp
End If
.PivotItems(sItem).Visible = True
For i = 1 To .PivotItems.Count
If IsError(Application.Match(.PivotItems(i), _
vItems, 0)) = .PivotItems(i).Visible Then
.PivotItems(i).Visible = Not (.PivotItems(i).Visible)
End If
Next i
End If
End With

CleanUp:
pvtField.Parent.ManualUpdate = False
Application.ScreenUpdating = True
Application.Calculation = xlCalculationAutomatic
End Function



Any help is greatly appreciated. I have no idea what's wrong!
 
Upvote 0
One problem is that you're trying to use the variable OffsetDown inside the Sub Trial, but that variable isn't declared or assigned a value within Sub Trial.

In general, it's not a good practice to use Select, Selection, Activate when you can reference cells by directly address or variable instead. See examples in this thread....
http://www.mrexcel.com/forum/showthread.php?p=2952621

I'd also suggest you use Option Explicit at the beginning of your Code Module which will require you to declare your variables. This might seem like a hassle, but it will save you a lot of time and frustration that can come with not having correct Data Types for variables.
 
Upvote 0

Forum statistics

Threads
1,223,911
Messages
6,175,329
Members
452,635
Latest member
laura12345

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