VBA Pivot Table Errors

mreman81

New Member
Joined
Oct 14, 2010
Messages
43
Hi all, I can't seem to figure out why this code is not working to create a pivot table. I'm using Excel 2013 and will be updating to 2019 soon.

When I get to the last line of code, I get Runtime Error 5: Invalid Procedure Call or Argument


VBA Code:
Sub Auto_Pivot()

Dim PBook As Workbook
Dim PSheet As Worksheet
Dim DSheet As Worksheet
Dim PCache As PivotCache
Dim PTable As PivotTable
Dim DRange As String
Dim ShtName As String
Dim LastRow As Integer
Dim LastColumn As Integer


Sheets.Add Before:=ActiveSheet
Set PSheet = ActiveSheet
PSheet.Name = "Preparer Summary"
ShtName = "Data"


Set PBook = ThisWorkbook
Set DSheet = Worksheets(ShtName)

LastColumn = DSheet.Cells(7, DSheet.Columns.Count).End(xlToLeft).Column
LastRow = DSheet.Cells(DSheet.Rows.Count, "A").End(xlUp).Row
DRange = Range(Cells(6, 1), Cells(LastRow, LastColumn)).Address

'Define Pivot Cache
Set PCache = PBook.PivotCaches.Create(xlDatabase, ShtName & "!" & DRange, xlPivotTableVersion15)

'Insert Blank Pivot Table
Set PTable = PCache.CreatePivotTable _
(TableDestination:=PSheet.Cells(2, 2), TableName:="PrepSumPivot")

End Sub
 

Excel Facts

Do you hate GETPIVOTDATA?
Prevent GETPIVOTDATA. Select inside a PivotTable. In the Analyze tab of the ribbon, open the dropown next to Options and turn it off
@Alex Blakenburg that didn't seem to work either ? So I went the unsophisticated route of using the macro recorder and then just modified the code for the variables I created and it worked... Go figure LOL... Here's the code that worked:

VBA Code:
ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:= _
        ShtName & "!" & DRange, Version:=xlPivotTableVersion15).CreatePivotTable _
        TableDestination:=PSheet.Cells(2, 2), TableName:="PrepSumPivot", DefaultVersion _
        :=xlPivotTableVersion15

If you have any insights into the "why" behind this, I would greatly appreciate it. As of now I didn't really learn anything, just to rely on the macro recorder more hahaha
 
Upvote 0
Thanks for the update. I will have another look at it tomorrow. Not sure I will find anything since it worked fine for me.
 
Upvote 0
Is the code in a different workbook to the pivot table and data? That would cause the error you describe, and explain why your fix worked, since you refer to ActiveWorkbook not ThisWorkbook when creating the pivot cache.
 
Upvote 0
Yes - in your original code you should have used:

VBA Code:
Set PBook = ActiveWorkbook
 
Upvote 0
Solution
@RoryA Got it!!! That makes sense :0) Thanks for the assist guys...
@mreman81 - What makes sense is mostly the answer of the question. :) I was going to switch the answer when I first read this thread earlier today, but wanted to see your reply first. Since we all know what was the actual problem now and have a solution with explanation, I switched the solution post with the obvious one to help future readers better.
 
Upvote 0

Forum statistics

Threads
1,223,910
Messages
6,175,316
Members
452,634
Latest member
cpostell

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