Create pivot table using VBA?

TheWennerWoman

Active Member
Joined
Aug 1, 2019
Messages
303
Office Version
  1. 365
Platform
  1. Windows
I have tried using the macro recorder to create a pivot table and nothing appears. The code (about 80 lines of it) runs through without error but there's no pivot table created......does the macro recorder not work properly for pivot table creation?

I have a sheet called Variances - column A is called suffix, column B is called Source_A and column C is called Source_B. There's about 70 rows of data, all I'm looking to do is put the data into a pivot on the same sheet, suffix on the rows ,Sum Of Source_A, Sum Of Source_B as columns and then I'm adding a calculated field Sum Of Source A - Sum Of Source B so I can compare the two.

Does this have to be written from scratch?

Thank you for reading.
 

Excel Facts

Links? Where??
If Excel says you have links but you can't find them, go to Formulas, Name Manager. Look for old links to dead workbooks & delete.
The macro recorder can certainly record creating a pivot table, although the code won't be particularly nice. If it runs again without any errors (which is unusual unless you remember to delete the previously created pivot table first) then it must be creating a pivot table somewhere. Hard to comment further without seeing the code you have now.
 
Upvote 0
The macro recorder can certainly record creating a pivot table, although the code won't be particularly nice. If it runs again without any errors (which is unusual unless you remember to delete the previously created pivot table first) then it must be creating a pivot table somewhere. Hard to comment further without seeing the code you have now.
Code:
ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:= _
        "Variance Pivot!R1C1:R77C3", Version:=8).CreatePivotTable TableDestination _
        :="Variance Pivot!R3C5", TableName:="PivotTable2", DefaultVersion:=8
    Sheets("Variance Pivot").Select
    Cells(3, 5).Select
    With ActiveSheet.PivotTables("PivotTable2")
        .ColumnGrand = True
        .HasAutoFormat = True
        .DisplayErrorString = False
        .DisplayNullString = True
        .EnableDrilldown = True
        .ErrorString = ""
        .MergeLabels = False
        .NullString = ""
        .PageFieldOrder = 2
        .PageFieldWrapCount = 0
        .PreserveFormatting = True
        .RowGrand = True
        .SaveData = True
        .PrintTitles = False
        .RepeatItemsOnEachPrintedPage = True
        .TotalsAnnotation = False
        .CompactRowIndent = 1
        .InGridDropZones = False
        .DisplayFieldCaptions = True
        .DisplayMemberPropertyTooltips = False
        .DisplayContextTooltips = True
        .ShowDrillIndicators = True
        .PrintDrillIndicators = False
        .AllowMultipleFilters = False
        .SortUsingCustomLists = True
        .FieldListSortAscending = False
        .ShowValuesRow = False
        .CalculatedMembersInFilters = False
        .RowAxisLayout xlCompactRow
    End With
    With ActiveSheet.PivotTables("PivotTable2").PivotCache
        .RefreshOnFileOpen = False
        .MissingItemsLimit = xlMissingItemsDefault
    End With
    ActiveSheet.PivotTables("PivotTable2").RepeatAllLabels xlRepeatLabels
    With ActiveSheet.PivotTables("PivotTable2").PivotFields("Suffix")
        .Orientation = xlRowField
        .Position = 1
    End With
    ActiveSheet.PivotTables("PivotTable2").AddDataField ActiveSheet.PivotTables( _
        "PivotTable2").PivotFields("Per Instanda"), "Sum of Per Instanda", xlSum
   Range("G2").Select
    ActiveSheet.PivotTables("PivotTable2").CalculatedFields.Add "Field1", _
        "='Per Instanda' -'Per Go Cardless'", True
    ActiveSheet.PivotTables("PivotTable2").PivotFields("Field1").Orientation = _
        xlDataField

That's the relevant bit. Ugly, isn't it? :-)
 
Upvote 0
I'd use some variables as they will make debugging in case of errors easier:

VBA Code:
   Dim pivotSheet As Worksheet
   Set pivotSheet = Worksheets("Variance Pivot")
   
   With pivotSheet
      Dim pc As PivotCache
      Set pc = .Parent.PivotCaches.Create(SourceType:=xlDatabase, _
               SourceData:="'" & .Name & "'!" & .Range("A1").CurrentRegion.Address(ReferenceStyle:=xlR1C1))
   End With
      
   With pc
   
      .RefreshOnFileOpen = False
      .MissingItemsLimit = xlMissingItemsDefault
      Dim pt As PivotTable
      Set pt = .CreatePivotTable(TableDestination:=pivotSheet.Range("E3"))
      
   End With
       
   With pt
      .ColumnGrand = True
      .HasAutoFormat = True
      .DisplayErrorString = False
      .DisplayNullString = True
      .EnableDrilldown = True
      .ErrorString = ""
      .MergeLabels = False
      .NullString = ""
      .PageFieldOrder = 2
      .PageFieldWrapCount = 0
      .PreserveFormatting = True
      .RowGrand = True
      .SaveData = True
      .PrintTitles = False
      .RepeatItemsOnEachPrintedPage = True
      .TotalsAnnotation = False
      .CompactRowIndent = 1
      .InGridDropZones = False
      .DisplayFieldCaptions = True
      .DisplayMemberPropertyTooltips = False
      .DisplayContextTooltips = True
      .ShowDrillIndicators = True
      .PrintDrillIndicators = False
      .AllowMultipleFilters = False
      .SortUsingCustomLists = True
      .FieldListSortAscending = False
      .ShowValuesRow = False
      .CalculatedMembersInFilters = False
      .RowAxisLayout xlCompactRow
      .RepeatAllLabels xlRepeatLabels
      
      With .PivotFields("Suffix")
         .Orientation = xlRowField
         .Position = 1
      End With
      
      .AddDataField .PivotFields("Per Instanda"), "Sum of Per Instanda", xlSum
      .CalculatedFields.Add "Field1", "='Per Instanda' -'Per Go Cardless'", True
      .PivotFields("Field1").Orientation = xlDataField
    
   End With

A lot of those pivot table settings are probably your defaults and could possibly be removed if you like.
 
Upvote 0
Solution

Forum statistics

Threads
1,223,903
Messages
6,175,289
Members
452,631
Latest member
a_potato

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