Check if forfields present in pivot table, then remove

RiaM

Board Regular
Joined
Jun 5, 2009
Messages
67
Hi guys

I've got a pivot table setup. The user can then play around with it i.e. drag and drop page fields into rowfields and columnfields and vice versa. Now I want to write a macro that checks if there are any rowfields or column fields present in the pivot table, and if so then relocate them to the page field area. The desired end result is that the pivot table is now empty (except for datafields). Any ideas?

I'm guessing its a loop to check if a rowfield is present, and if so relocate to the page field area. Same for column fields. Just now quite sure how to code this.

Blue skies!
 

Excel Facts

Is there a shortcut key for strikethrough?
Ctrl+S is used for Save. Ctrl+5 is used for Strikethrough. Why Ctrl+5? When you use hashmarks to count |||| is 4, strike through to mean 5.
Something like:
Code:
   Dim pt As PivotTable, pf As PivotField
   Set pt = ActiveSheet.PivotTables(1)
   For Each pf In pt.RowFields
      pf.Orientation = xlPageField
   Next pf
   For Each pf In pt.ColumnFields
      pf.Orientation = xlPageField
   Next pf
should work.
 
Upvote 0
Hey Rory! Thanks, I'm starting to get the hang of this vb stuff :). Came up with the following just before I read your reply

Dim pf As PivotField, PT As PivotTable
Dim RowFieldName As String

Set PT = ActiveSheet.PivotTables("PivotTable1")

'Check if row field present, if not add it
For Each pf In PT.RowFields
If pf.SourceName <> "" Then
RowFieldName = pf.SourceName
With PT.PivotFields(RowFieldName)
.Orientation = xlPageField
.Position = 1
End With
End If
Next pf
 
Upvote 0
Not bad (;)), but the middle bit is unnecessary - pf is already a reference to the field, so you can just change its orientation directly.
 
Upvote 0
I'm trying to do the same thing with data fields. It works fine when there's no calcualted fields present, but if there are calculated fields present then it bombs out. I think this is because calculated fields cannot be turned off (xlhidden) but need to be deleted. Any ideas. The ffg code works for removing just the datafields:

Dim pf As PivotField, PT As PivotTable

Set PT = ActiveSheet.PivotTables("PivotTable1")

For Each pf In PT.DataFields
pf.Orientation = xlHidden
Next pf
 
Upvote 0
Believe it or not, this is the only method I can get to work (as ludicrous as it seems):
Code:
Dim pf As PivotField, PT As PivotTable
Dim strOldName, strOldCalc
Application.ScreenUpdating = False
Set PT = ActiveSheet.PivotTables(1)
PT.ManualUpdate = True
For Each pf In PT.DataFields
   strOldName = pf.SourceName
   With PT.PivotFields(strOldName)
      If .IsCalculated Then
         strOldCalc = .StandardFormula
         .Delete
         PT.CalculatedFields.Add strOldName, strOldCalc
      Else
         pf.Orientation = xlHidden
      End If
   End With
Next pf
PT.ManualUpdate = False
Application.ScreenUpdating = True
 
Upvote 0

Forum statistics

Threads
1,223,249
Messages
6,171,031
Members
452,374
Latest member
keccles

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