Can't get VBA to create a Calculated Field in Pivot Table

TheRedCardinal

Active Member
Joined
Jul 11, 2019
Messages
250
Office Version
  1. 365
  2. 2021
Platform
  1. Windows
I have created a sequence in VBA that makes a Pivot Table out of a named data Range - Data.

The data sections work fine, but I need a new field that calculates the Sum of the two data fields.

I tried this:

Code:
With ActiveSheet.PivotTables("SalesPivotTable").CalculatedFields.Add "Difference", _
        "='VAT Value' + Amount", True

But when I try to proceed, it gives me an error, highlighting the "Difference" bit and saying Expected: End of Statement.

Have I set the syntax up incorrectly?
 

Excel Facts

Can Excel fill bagel flavors?
You can teach Excel a new custom list. Type the list in cells, File, Options, Advanced, Edit Custom Lists, Import, OK
This works for me

Code:
    With ActiveSheet.PivotTables("SalesPivotTable")
    
        .CalculatedFields.Add "Difference", "='VAT Value' +Amount", True
    End With
 
Upvote 0
Nope still not working for me.
I don't get an error now in the VBA module, but running the macro creates the pivot table just fine, but doesn't add the Calculated field.

Here is an extract from my code:

Code:
With ActiveSheet.PivotTables("SalesPivotTable").PivotFields("VAT Value")
.Orientation = xlDataField
.Position = 2
.Function = xlSum
.NumberFormat = "#,##0"
.Name = "Amount (VAT) "
End With


'Insert Calculated Field


With ActiveSheet.PivotTables("SalesPivotTable")
    .CalculatedFields.Add "Difference", "='VAT Value' + Amount", True
    .Orientation = xlDataField
    .Position = 3
End With

I've added the section for one of the data fields just to show the names.

What am I missing?
 
Upvote 0
Slight tweak to include field name works for me

Code:
With ActiveSheet.PivotTables("SalesPivotTable").PivotFields("VAT Value")
    .Orientation = xlDataField
    .Position = 2
    .Function = xlSum
    .NumberFormat = "#,##0"
    .Name = "Amount (VAT) "
End With

'Insert Calculated Field

With ActiveSheet.PivotTables("SalesPivotTable")
    .CalculatedFields.Add "Difference", "='VAT Value' + Amount", True
    .PivotFields("Difference").Orientation = xlDataField
End With
 
Upvote 0

Forum statistics

Threads
1,223,893
Messages
6,175,241
Members
452,622
Latest member
Laura_PinksBTHFT

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