Pivot Table Options

sunrise06

Active Member
Joined
Oct 27, 2006
Messages
264
Office Version
  1. 365
Platform
  1. Windows
I have created a pivot table which I added to the Data Model so I could perform distinct counts. However, I want to now be able to go to Show Report Filter Page but it is grayed out. Is there a way to now break out my pivot table by a filtered field?
 

Excel Facts

Does the VLOOKUP table have to be sorted?
No! when you are using an exact match, the VLOOKUP table can be in any order. Best-selling items at the top is actually the best.
OLAP tables have limitations, and this is one of them.However, VBA can be used to emulate the SRFP feature, would you like that?
For a simple filtering task, do it manually.
 
Upvote 0
I will have to write it. I am going offline now, it is Carnival here, but will be back soon…
 
Upvote 0
This worked for me:


Code:
Sub ShowRep()
Dim pt As PivotTable, i%, pf As PivotField, ws As Worksheet, _
pttemp As PivotTable, pf2 As PivotField, itar
Set pt = ActiveSheet.PivotTables("PivotTable2")                     ' source pivot
If ActiveWorkbook.PivotCaches(pt.CacheIndex).OLAP Then MsgBox "OLAP table!"
Set pf = pt.PageFields(1)                                           ' the page field
Set ws = ActiveWorkbook.Worksheets.Add                              ' add temp sheet
pf.Parent.TableRange2.Copy ws.[a1]                                  ' copy table
Set pttemp = ws.Range("A1").PivotTable                              ' temp table
pttemp.PivotFields(pf.Name).CubeField.Orientation = xlRowField      ' page field to row field
Set pf2 = pttemp.PivotFields(pf.Name)
ReDim itar(1 To pf2.PivotItems.Count)
For i = 1 To pf2.PivotItems.Count
    itar(i) = pf2.PivotItems(i).Name                                ' array of items
Next
ws.Delete                                                           ' delete temp sheet
For i = LBound(itar) To UBound(itar)                                ' all items
    Set ws = ActiveWorkbook.Worksheets.Add                          ' add sheet
    pf.Parent.TableRange2.Copy ws.[a1]                              ' copy table
    Set pt = ws.[a1].PivotTable
    pt.PivotFields(pf.Name).CurrentPageName = itar(i)               ' filter
    ws.Name = Replace(Replace(itar(i), "[", "_"), "]", "_")         ' rename sheet
Next
End Sub
 
Upvote 0
Thank you so much! I can't wait to use it out tomorrow at work!
 
Upvote 0
OK, I couldn't wait. I am getting an error at this line - ws.Name = Replace(Replace(itar(i), "[", "_"), "]", "_") ' rename sheet

Error - You've typed an invalid name for sheet or chart.

The name it is stuck on is the first one and it is Paul Smith. That seems to be an acceptable sheet name.
 
Upvote 0
I think the issue is the naming of the tab. It is currently "_Range_._Manager Name_.&_BLANK_" rather than, in this case, it should be just BLANK. Any other name makes it too many characters for the tab name.
 
Upvote 0
New version:

Code:
Sub ShowRep()
Dim pt As PivotTable, i%, pf As PivotField, ws As Worksheet, _
pttemp As PivotTable, pf2 As PivotField, itar, sn
Set pt = ActiveSheet.PivotTables("PivotTable2")                     ' source pivot
If ActiveWorkbook.PivotCaches(pt.CacheIndex).OLAP Then MsgBox "OLAP table!"
Set pf = pt.PageFields(1)                                           ' the page field
Set ws = ActiveWorkbook.Worksheets.Add                              ' add temp sheet
pf.Parent.TableRange2.Copy ws.[a1]                                  ' copy table
Set pttemp = ws.Range("A1").PivotTable                              ' temp table
pttemp.PivotFields(pf.Name).CubeField.Orientation = xlRowField      ' page field to row field
Set pf2 = pttemp.PivotFields(pf.Name)
ReDim itar(1 To pf2.PivotItems.Count)
For i = 1 To pf2.PivotItems.Count
    itar(i) = pf2.PivotItems(i).Name                                ' array of items
Next
ws.Delete                                                           ' delete temp sheet
For i = LBound(itar) To UBound(itar)                                ' all items
    Set ws = ActiveWorkbook.Worksheets.Add                          ' add sheet
    pf.Parent.TableRange2.Copy ws.[a1]                              ' copy table
    ws.[a1].PivotTable.PivotFields(pf.Name).CurrentPageName = itar(i)
    sn = Split(itar(i), "&")
    ws.Name = Replace(Replace(sn(UBound(sn)), "[", ""), "]", "")
Next
End Sub
 
Upvote 0
Thank you. The tab names are now in an odd order. Is it possible to make them alpha?
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

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