Macro that refresh pivot tables by multiple dates

banneduser123

Banned - Rules violations
Joined
Mar 29, 2006
Messages
181
Hi, I have a pivot table in my spreadsheet. I would like have a macro that when run will update the date in the pivot tables according to what is in cell C4 and C5 in the sheet.
So after the macro is run, it will have selected multiple dates in the pivot table (in this case the two dates identifies in cells C4 and C5.


This is the macro I am currently using:


Sub PivotRefresh()
Dim pv As String
Dim dt As String


ThisWorkbook.Activate
Sheets("Sheer1").Select
cob = Sheets("Sheet1").Range("J1").Value
dt = "[PL Accounting Date].[Yearly Calendar].[Date].&[" & cob & "]"

ActiveWorkbook.RefreshAll

Sheets("Sheet").Select
For i = 1 To 6

pv = "PivotTable" & i

ActiveSheet.PivotTables(pv).PivotFields( _
"[PL Accounting Date].[Yearly Calendar].[Year]").CurrentPageName = _
dt




End Sub
 

Excel Facts

What do {} around a formula in the formula bar mean?
{Formula} means the formula was entered using Ctrl+Shift+Enter signifying an old-style array formula.
Hi rishijain,

1. Are you trying to filter to show just the two dates in C4 and C5, or all the dates between C4 and C5 (inclusive)?

2. Will data always exist for the dates selected? (for OLAP PivotTable sources like yours, missing items need to be handled differently than for regular PivotTable sources).

3. Is that date field always in the Report Filter section of all PivotTables to be filtered?
 
Last edited:
Upvote 0
Hi Jerry, thanks for responding...

1 - All the dates between C4 and C5 would be great
2 - Yes, data will always exist for the dates selected
3 - Yes it is.

Thanks again
 
Upvote 0
Hi rishijain, I saw your response on my phone, but then lost track of this as an unanswered thread. My apologies.

Below is some code you can try. Copy all the code into a Standard Code Module (like Module1).

Before testing, check the sheet names to make sure they match yours. The code in your OP uses names "Sheer1", "Sheet1" and "Sheet". I've assumed your cells C4:C5 are on sheet "Sheet1" and your PivotTables are on sheet "Sheet".

Code:
Sub PivotRefresh()
'--filters PivotTables to show only dates between start and
'    end dates (inclusive), read from two cells in the worksheet.

 Dim dtStartDate As Date, dtEndDate As Date
 Dim lNdx As Long
 Dim pvt As PivotTable
 Dim sErrMsg As String
 Dim vItemsToBeVisible As Variant

 On Error GoTo ErrProc
 With Application
   .EnableCancelKey = xlErrorHandler
   .ScreenUpdating = False
   .DisplayStatusBar = False
   .EnableEvents = False
 End With
   
 '--build array of dates to be shown after filtering
 With Sheets("Sheet1")
   dtStartDate = .Range("C4").Value
   dtEndDate = .Range("C5").Value
 End With
   
 If dtStartDate > dtEndDate Then
   sErrMsg = "End date must be after start date."
   GoTo ExitProc
 End If
 
 ReDim vItemsToBeVisible(1 To dtEndDate - dtStartDate + 1)

 For lNdx = LBound(vItemsToBeVisible) To UBound(vItemsToBeVisible)
   '--edit the date format to match that used by your OLAP datasource
   vItemsToBeVisible(lNdx) = Format(dtStartDate + lNdx - 1, "m-d-yyyy")
 Next lNdx

 '--if all PivotTables linked to Slicer, only need to change one.
 '--otherwise, replace with code to step through each PivotTable.
 Set pvt = Sheets("Sheet").PivotTables("PivotTable1")

 sErrMsg = sOLAP_FilterByItemList( _
   pvf:=pvt.PivotFields("[PL Accounting Date].[Yearly Calendar].[Year]"), _
   vItemsToBeVisible:=vItemsToBeVisible, _
   sItemPattern:="[PL Accounting Date].[Yearly Calendar].[Date].&[ThisItem]")

ExitProc:
 On Error Resume Next
 With Application
   .EnableEvents = True
   .DisplayStatusBar = True
   .ScreenUpdating = True
 End With
 If Len(sErrMsg) > 0 Then MsgBox sErrMsg
 Exit Sub
 
ErrProc:
 sErrMsg = Err.Number & " - " & Err.Description
 Resume ExitProc
End Sub


Private Function sOLAP_FilterByItemList(ByVal pvf As PivotField, _
   ByVal vItemsToBeVisible As Variant, _
   ByVal sItemPattern As String) As String

'--filters an OLAP pivotTable to display a list of items,
'    where some of the items might not exist
'--works by testing whether each pivotitem exists, then building an
'    array of existing items to be used with the VisibleItemsList property
'--requires Excel 2007 or later

'--Input Parameters:
'  pvf                pivotfield object to be filtered
'  vItemsToBeVisible  array of strings representing items to be visible
'  sItemPattern       string that has MDX pattern of pivotItem reference
'                     where the text "ThisItem" will be replaced by each
'                     item in vItemsToBeVisible to make pivotItem references.
'                     e.g.: "[tblSales].[product_name].&[ThisItem]"
   
 Dim lFilterItemCount As Long, lNdx As Long
 Dim vFilterArray As Variant
 Dim vSaveVisibleItemsList As Variant
 Dim sReturnMsg As String, sPivotItemName As String
 
 '--store existing visible items
 vSaveVisibleItemsList = pvf.VisibleItemsList
 
 If Not (IsArray(vItemsToBeVisible)) Then _
   vItemsToBeVisible = Array(vItemsToBeVisible)
 ReDim vFilterArray(1 To _
   UBound(vItemsToBeVisible) - LBound(vItemsToBeVisible) + 1)
 pvf.Parent.ManualUpdate = True
 
 '--check if pivotitem exists then build array of items that exist
 For lNdx = LBound(vItemsToBeVisible) To UBound(vItemsToBeVisible)
   '--create MDX format pivotItem reference by substituting item into pattern
   sPivotItemName = Replace(sItemPattern, "ThisItem", vItemsToBeVisible(lNdx))
   
   '--attempt to make specified item the only visible item
   On Error Resume Next
   pvf.VisibleItemsList = Array(sPivotItemName)
   On Error GoTo 0
   
   '--if item doesn't exist in field, this will be false
   If LCase$(sPivotItemName) = LCase$(pvf.VisibleItemsList(1)) Then
      lFilterItemCount = lFilterItemCount + 1
      vFilterArray(lFilterItemCount) = sPivotItemName
   End If
 Next lNdx
 
 '--if at least one existing item found, filter pivot using array
 If lFilterItemCount > 0 Then
   ReDim Preserve vFilterArray(1 To lFilterItemCount)
   pvf.VisibleItemsList = vFilterArray
 Else
   sReturnMsg = "No matching items found."
   pvf.VisibleItemsList = vSaveVisibleItemsList
 End If
 pvf.Parent.ManualUpdate = False

 sOLAP_FilterByItemList = sReturnMsg
End Function

Have you considered linking this date field in PivotTable1 to PivotTable6? That would be more efficient to that stepping through 6 PivotTables in the code.
I've assumed you'll take that approach. That code can be modified if you can't use Slicers because your version of Excel is before 2010, or the Pivots don't share the same PivotCache).
 
Upvote 0

Forum statistics

Threads
1,215,461
Messages
6,124,955
Members
449,199
Latest member
Riley Johnson

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