Macro/VBA to reset (show all) in pivot table

djsmarties

Board Regular
Joined
Sep 10, 2002
Messages
95
Hi,

I tried creating a macro that would "reset" a pivot table field to show all items in the list (just clicked on the "show all" button).

With ActiveSheet.PivotTables("PivotTable1").PivotFields("grouping")
.PivotItems("4-5 days").Visible = True
.PivotItems("6-7 days").Visible = True
.PivotItems("8-10 days").Visible = True
End With

The problem is that there isnt data for every list item in the pivot table and when I run the macro I get an error message:

"Unable to set the Visible property of the PivotItem class"

I think this is because it is trying to show data for "6-7 days" but currently there is no data for this list item.

Is there any (other) way a pivot table can be reset to "show all" with VBA code?

Thanks a lot
 

Excel Facts

What is =ROMAN(40) in Excel?
The Roman numeral for 40 is XL. Bill "MrExcel" Jelen's 40th book was called MrExcel XL.
I actually found something myself on another excel website, thought I'd share with you:

Sub PivotShowItemAllVisible()
'sort is set to Manual to prevent errors, e.g.
'unable to set Visible Property of PivotItem class
Dim pt As PivotTable
Dim pf As PivotField
Dim pi As PivotItem
Application.ScreenUpdating = False
Application.DisplayAlerts = False
For Each pt In ActiveSheet.PivotTables
For Each pf In pt.RowFields
pf.AutoSort xlManual, pf.SourceName
For Each pi In pf.PivotItems
pi.Visible = True
Next pi
pf.AutoSort xlAscending, pf.SourceName
Next pf
Next pt
Application.DisplayAlerts = True
Application.ScreenUpdating = True
End Sub

This works perfectly, I tried it on several pivots :) :)
 
Upvote 0

Forum statistics

Threads
1,214,991
Messages
6,122,628
Members
449,095
Latest member
bsb1122

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