Equivalent to GETPIVOTDATA in PP?

BakerUK

New Member
Joined
Nov 19, 2015
Messages
28
Hi all

Done a bit of Googling and looked at things like CUBEVALUE etc but haven't quite worked out how to get GETPIVOTDATA working when some of the values come from cell references.

I've had to de-personalise this but basically I have:

=GETPIVOTDATA("[Measures].[Vol]",PivotTableName,"[TableResults].[ResultScored]","[TableResults].[ResultScored].&[Gold]","[TableDates].[Year]","[TableDates].[Year].&[Y2017]")

Which returns all the Gold results from Y2017. All I want to change is that the [Gold] and [Y2017] are based on values from cells rather than hard-coded. So that when filters are applied the formula will dynamically update if it needs to look at Silver in Y2016 for example.

Hope that makes sense - I'm sure there must be an obvious change to the syntax but I can't get it to work!

Thanks
 

Some videos you may like

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
36,463
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2010
Platform
  1. Windows
  2. MacOS
Assuming values in A1 and A2:

=GETPIVOTDATA("[Measures].[Vol]",PivotTableName,"[TableResults].[ResultScored]","[TableResults].[ResultScored].&["&A1&"]","[TableDates].[Year]","[TableDates].[Year].&["&A2&"]")
 

BakerUK

New Member
Joined
Nov 19, 2015
Messages
28
Hi guys,

The above solution works fine for text, I'm just trying to get my head round it for numbers. Ideally I just want it to lookup a number in the cell but it looks like GETPIVOTDATA reads PP pivots differently.

E.g.
80 reads as [8.E1]
81 as [8.1E1]
133 as [1.33E2]
500 as [5.E2]

So I'm struggling to write a formula that translates all numbers to a format GETPIVOTDATA can read.

Can anyone help?

Thanks
 

RoryA

MrExcel MVP, Moderator
Joined
May 2, 2008
Messages
36,463
Office Version
  1. 365
  2. 2019
  3. 2016
  4. 2010
Platform
  1. Windows
  2. MacOS
I can't say I've seen that before but maybe I've just been lucky. See if this does it for you:

SUBSTITUTE(TEXT(A1,"0.#######E##),"+","")
 

BakerUK

New Member
Joined
Nov 19, 2015
Messages
28
Thanks Rory - works and much more succinct than the big IF statement I had put in place.

Thanks again for your help!
 

Watch MrExcel Video

Forum statistics

Threads
1,127,529
Messages
5,625,341
Members
416,096
Latest member
forevans

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
Top