Trouble creating pivot table in VBA

jasonfish11

Board Regular
Joined
May 14, 2015
Messages
56
All,
I've searched for the answer to my question and haven't found much help. I was hoping someone could point out where I'm missing something as the below coding fails at the last line and never creates a pivot table.

Code:
'Create pivot tables
Dim pvtCache As PivotCache
Dim pvt As PivotTable
Dim StartPvt As String
Dim SrcData As String


Worksheets("Combined").Select
SrcData = ActiveSheet.Name & "!" & Range("A1:E" & comLR2).Address(ReferenceStyle:=xlR1C1)


Worksheets("Recon Pivot").Select
StartPvt = ActiveSheet.Name & "!" & Range("A2").Address(ReferenceStyle:=xlR1C1)
Set pvtCache = ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:=SrcData)
Set pvt = pvtCache.CreatePivotTable(TableDestination:=StartPvt, TableName:="PivotTable1")

The variables of SrcData and StartPvt both appear correctly when I hover over them in VBA.
Any help would be much appreciated.
 
Last edited:

Excel Facts

Highlight Duplicates
Home, Conditional Formatting, Highlight Cells, Duplicate records, OK to add pink formatting to any duplicates in selected range.
try below code, its very simple:)

Code:
Sub t()


'xlSum           -4157
'xlAverage      -4106
'xlCount          -4112
'xlMax            -4136
'xlMin             -4139


Dim shtrng As String, x As Integer, lblcolpos As Integer, lblcolval As String, lblrowpos As Integer, lblrowval As String, lbldatapos As Integer, lbldataval As String, lbldataval1 As String


'sheet Data contains actual data, which you used to create pivot table
shtrng = Sheets("Data").Name & "!" & Sheets("Data").UsedRange.Address


Sheets.Add.Name = "Pivot"


ActiveWorkbook.PivotCaches.Create(xlDatabase, shtrng).CreatePivotTable TableDestination:="Pivot!R5C2", TableName:="PivotTable1"


'create sheet Labels and place the field names as per below (below are example)
'row 1 contains heading as Row, Column, Data, and Function. below that field names will be mentioned
Row	Column	Data	Function
field1	field1	field1	-4157	'xlsum
field2	field2	field2	-4136	'xlmax


lblcolpos = 1
For x = 2 To Sheets("Labels").Cells(Rows.Count, 2).End(xlUp).Row
    lblcolval = Sheets("Labels").Cells(x, 2)
        With ActiveSheet.PivotTables("PivotTable1").PivotFields(lblcolval)
            .Orientation = xlColumnField
            .Position = lblcolpos
        End With
    lblcolpos = lblcolpos + 1
Next x


lblrowpos = 1
For x = 2 To Sheets("Labels").Cells(Rows.Count, 1).End(xlUp).Row
    lblrowval = Sheets("Labels").Cells(x, 1)
        With ActiveSheet.PivotTables("PivotTable1").PivotFields(lblrowval)
            .Orientation = xlRowField
            .Position = lblrowpos
        End With
    lblrowpos = lblrowpos + 1
Next x


lbldatapos = 1
For x = 2 To Sheets("Labels").Cells(Rows.Count, 3).End(xlUp).Row
    lbldataval = Sheets("Labels").Cells(x, 3)
        With ActiveSheet.PivotTables("PivotTable1").PivotFields(lbldataval)
            .Orientation = xlDataField
            .Function = Sheets("Labels").Cells(x, 4).Value
            .NumberFormat = "$#,##0.00"
            .Position = lbldatapos
        End With
    lbldatapos = lbldatapos + 1
Next x


'removing subtotals
Dim pt As PivotTable, pf As PivotField


On Error Resume Next


For Each pt In ActiveSheet.PivotTables
For Each pf In pt.PivotFields


pf.Subtotals(1) = True
pf.Subtotals(1) = False


Next pf
Next pt
 
Last edited by a moderator:
Upvote 0
Sorry comLR2 is a variable set up earlier in the macro to find the last row in the "Combined" tab.
 
Last edited:
Upvote 0
what is the error?
there are no pivottables on reconpivot?
 
Upvote 0
Try this:

Code:
'Create pivot tables
Dim pvtCache As PivotCache
Dim pvt As PivotTable
Dim StartPvt As Range
Dim SrcData As String


Worksheets("Combined").Select
SrcData = ActiveSheet.Name & "!" & Range("A1:E" & comLR2).Address(ReferenceStyle:=xlR1C1)


Worksheets("Recon Pivot").Select
Set StartPvt = Worksheets("Recon Pivot").Range("A2")
Set pvtCache = ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:=SrcData)
Set pvt = pvtCache.CreatePivotTable(TableDestination:=StartPvt, TableName:="PivotTable1")
 
Upvote 0

Forum statistics

Threads
1,224,823
Messages
6,181,181
Members
453,022
Latest member
Mohamed Magdi Tawfiq Emam

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