Macro to expand all in a Pivot Table

storm925

Board Regular
Joined
Jan 20, 2010
Messages
226
Hello All,
I'm trying to write a macro to expand all pivot fields (without having to name each one), but can't figure it out. Just need some help from the forum.
Here is my first attempt, but it's not working...
Code:
Dim PT As PivotTable
Dim PF As PivotField
Set PT = ActiveSheet.PivotTables(1)

For Each PF In PT.PivotFields
    PF.ShowDetail = True
Next PF

Here is my second try--trying out something new, but with no success...
Code:
Dim PT As PivotTable

Set PT = ActiveSheet.PivotTables(1)

With PT.DataBodyRange
    .Cells(.Count).ShowDetail = True
End With

Any help on this would be greatly appreciated. Thank you for reading my post, --Ben
 

Excel Facts

How to show all formulas in Excel?
Press Ctrl+` to show all formulas. Press it again to toggle back to numbers. The grave accent is often under the tilde on US keyboards.
.
.

Try something like this:

Code:
Sub ShowDetail()
    
    Dim pt As PivotTable
    Dim rf As PivotField
    Dim cf As PivotField
    
    'set pivot table
    Set pt = ActiveSheet.PivotTables(1)
    
    'loop through row fields
    For Each rf In pt.RowFields
        If rf.Position <> pt.RowFields.Count Then
            rf.ShowDetail = True
        End If
    Next rf
    
    'loop through column fields
    For Each cf In pt.ColumnFields
        If cf.Position <> pt.ColumnFields.Count Then
            cf.ShowDetail = True
        End If
    Next cf

End Sub
 
Upvote 0
gpeacock,

Thank you so much for your reply. It worked beautifully! It was just what I was looking for. --Ben
 
Upvote 0

Forum statistics

Threads
1,214,429
Messages
6,119,433
Members
448,897
Latest member
ksjohnson1970

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