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
 

Some videos you may like

Excel Facts

Can you AutoAverage in Excel?
There is a drop-down next to the AutoSum symbol. Open the drop-down to choose AVERAGE, COUNT, MAX, or MIN

ParamRay

Well-known Member
Joined
Aug 6, 2014
Messages
1,195
.
.

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
 

storm925

Board Regular
Joined
Jan 20, 2010
Messages
226
gpeacock,

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

Watch MrExcel Video

Forum statistics

Threads
1,109,426
Messages
5,528,690
Members
409,830
Latest member
KT50

This Week's Hot Topics

  • Change military grades into rank
    Afternoon all Need help with formula that will change military rank (i.e. 1, 2, 3 into Amn, A1C, SrA). Running IF formula that does not work...
  • VBA COUNTIF SOLUTION
    Hi The following are the errors spread across the several columns from E to Q ie. 13 columns across several sheets with more than 500 rows per...
  • INSERT ROW WITH SPECIFIS TEXT IN A COLUMN
    Hi All! How can identify that that the row to be inserted has to be inserted before 1st row with specific text in column F. If I record the...
  • Auto-Create a monthly Sign in sheet for preschool students
    The image below is what each page looks like. Above is space for the "Child Name" "Month" "Class" School days are obviously Monday-Friday but...
  • VBA vlookup multiple results
    Hi folks, Hopefully someone out there can help. I have a list to vlookup which works (ish). the lookup only picks up the first instance of the...
  • Extract values for earliest/latest times
    I am trying to put together a formula to get the earliest start time, the latest end time from column A for each person in Column B-F without the...
Top