Run Time Error 5 - Macro for Pivot Table

larinda4

Board Regular
Joined
Nov 15, 2021
Messages
73
Office Version
  1. 365
Platform
  1. Windows
I'm not the greatest with macros and I generally use the record a macro and play around with it until it does what I want. I recorded creating a pivot table, placing it in an existing sheet and when I delete the pivot table and try to run the macro again to confirm it works, I am receiving a Run Time Error 5, invalid procedure call or argument.

Here is my code:
Range("A1:U7591").Select
VBA Code:
    ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:= _
        "Firm Listing!R1C1:R7591C21", Version:=15).CreatePivotTable TableDestination _
        :="my-benefits!R1C1", TableName:="PivotTable6", DefaultVersion:=6
    Sheets("my-benefits").Select

Anyone know what I'm doing wrong? I also want to make the row count automatic, as it changes every month when I do my reporting. It will always be column U, but a different row number.

Any help is greatly appreciated!
 

Excel Facts

Enter current date or time
Ctrl+: enters current time. Ctrl+; enters current date. Use Ctrl+: Ctrl+; Enter for current date & time.
You could use:

VBA Code:
Dim dataSheet As Worksheet
Set dataSheet = Sheets("Firm Listing")

ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, _
               SourceData:="'" & dataSheet.Name & "!'" & dataSheet.Range("A1").CurrentRegion.Address(ReferenceStyle:=xlR1C1)).CreatePivotTable _
                  TableDestination:=Sheets("my-benefits").Range("A1")
 
Upvote 0
You could use:

VBA Code:
Dim dataSheet As Worksheet
Set dataSheet = Sheets("Firm Listing")

ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, _
               SourceData:="'" & dataSheet.Name & "!'" & dataSheet.Range("A1").CurrentRegion.Address(ReferenceStyle:=xlR1C1)).CreatePivotTable _
                  TableDestination:=Sheets("my-benefits").Range("A1")
Hi Rory! Thanks for the suggestion.

I'm still receiving the same error, except the yellow highlight is on "TableDestination:=Sheets("my-benefits").Range("A1")"
 
Upvote 0
Sorry - I typed an apostrophe in the wrong place - it should be:

VBA Code:
Dim dataSheet As Worksheet
Set dataSheet = Sheets("Firm Listing")

ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, _
               SourceData:="'" & dataSheet.Name & "'!" & dataSheet.Range("A1").CurrentRegion.Address(ReferenceStyle:=xlR1C1)).CreatePivotTable _
                  TableDestination:=Sheets("my-benefits").Range("A1")
 
Upvote 0
Solution
Sorry - I typed an apostrophe in the wrong place - it should be:

VBA Code:
Dim dataSheet As Worksheet
Set dataSheet = Sheets("Firm Listing")

ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, _
               SourceData:="'" & dataSheet.Name & "'!" & dataSheet.Range("A1").CurrentRegion.Address(ReferenceStyle:=xlR1C1)).CreatePivotTable _
                  TableDestination:=Sheets("my-benefits").Range("A1")
It worked!! Thank you so very much!

Do you know happen to know what I did wrong in mine?
 
Upvote 0
Do you know happen to know what I did wrong in mine?

It looks like it doesn't like the table destination specified in a R1C1 reference style. Instead, it seems to accept an A1 reference style, as @RoryA has shown...

VBA Code:
TableDestination:=Sheets("my-benefits").Range("A1")

Hope this helps!
 
Upvote 0
R1C1 format is actually OK, but for both the sourcedata and the tabledestination, you need to use the syntax that would work in a formula. Since the sheet names contain special characters (a space and a hyphen) they both need to be in single quotes. Also, Version:=15 was not valid. So this would have worked:

Rich (BB code):
ActiveWorkbook.PivotCaches.Create(SourceType:=xlDatabase, SourceData:= _
        "'Firm Listing'!R1C1:R7591C21").CreatePivotTable TableDestination _
        :="'my-benefits'!R1C1", TableName:="PivotTable6"
 
Upvote 0
@RoryA

You're absolutely right. TableDestination does accept the R1C1 format, and it requires the single quotes. I thought I tested it, my apologies.

Interestingly enough, though, SourceData does not seem to require the single quotes.

There seems to be no consistency. Oh well.
 
Upvote 0
Hi @RoryA

already tried your solution but it seems the error still persist. can u help me?

1662516106550.png
 
Upvote 0
If "Sheet7" already has a pivot table by the same name, that is "PivotTable2", you'll get an error. If this is the case, simply omit the TableName argument, and your pivot table will automatically be named. You can always re-name it afterwards, if you so desired.

If a pivot table at the table destination already exists, you'll also get an error.

Which error are you getting?
 
Upvote 0

Forum statistics

Threads
1,223,894
Messages
6,175,254
Members
452,623
Latest member
Techenthusiast

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