Dhanabalan

New Member
Joined
Sep 21, 2018
Messages
3
Hi Just copy the code from online for Pivot table filter base on Cell Reference. Its working fine f no ("blank") in filter. Its blanks its shows Error so i add this Code pf.PivotItems("(blank)").Visible = False Now i getting Run time error 13. Its Date filter base on cell Reference, Any one can help to fix this code

Code:
Sub Filter_PivotField()

 With ActiveSheet.PivotTables("PivotTable1").PivotFields("Date Audited")
        .PivotItems("(blank)").Visible = False
    End With


'Description: Filter a pivot table for a specific date or period
Dim sSheetName As String
Dim sPivotName As String
Dim sFieldName As String
Dim sFilterCrit As Double
Dim pt As PivotTable
Dim pf As PivotField
Dim pi As PivotItem


'Set the variables
sSheetName = "Sheet4"
sPivotName = "PivotTable1"
sFieldName = "Date Audited"
'sFilterCrit = "22/08/2017" --most recent date
sFilterCrit = ThisWorkbook.Worksheets("Sheet4").Range("C2").Value


Set pt = ThisWorkbook.Worksheets("Sheet4").PivotTables("PivotTable1")
Set pf = pt.PivotFields("Date Audited")
pf.ClearAllFilters
pf.PivotItems("(blank)").Visible = False


For Each pi In pf.PivotItems
    If CDbl(DateValue(pi)) = sFilterCrit Then
        pi.Visible = True
    Else
        pi.Visible = False
    End If
Next pi


End Sub
 

Excel Facts

Lock one reference in a formula
Need 1 part of a formula to always point to the same range? use $ signs: $V$2:$Z$99 will always point to V2:Z99, even after copying
Try testing for blanks within your For Each/Next loop...

Code:
For Each pi In pf.PivotItems
    If pi.Name <> "(blank)" Then
        If CDbl(DateValue(pi)) = sFilterCrit Then
            pi.Visible = True
        Else
            pi.Visible = False
        End If
    Else
        pi.Visible = False
    End If
Next pi

Hope this helps!
 
Upvote 0

Forum statistics

Threads
1,215,047
Messages
6,122,858
Members
449,096
Latest member
Erald

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