GETPIVOTDATA Value From Specific Row

Jamsandwich

New Member
Joined
Sep 25, 2014
Messages
44
Hey guys,

I am currently using the below formula to pull data from a pivot table -

Code:
=PivotSheet!J5

However, the column that I want to get the data from may be dynamic. As an example, I may have 5 columns in my new table: AB, CH, FR, BL, RN. Columns in the pivot table will have the same headers, but not necessarily in the same order, and it is possible that the order may change. So a GETPIVOTDATA formula that looks at the specific column header is required.

I now have -

Code:
=GETPIVOTDATA("Rejects",PivotSheet!$A$3,"Code","CH",[COLOR=#ff0000]"StopTime",61,"Years",2016[/COLOR])

My next problem is the row reference in that formula. The rows are dynamic too. Currently the "StopTime" column goes from 01-Mar to 15-Jun but these will change each time the workbook is updated, rendering my formulas useless on the new table.

Is it possible to reference row numbers as part of the GetPivotTable function, instead of "StopTime" & "Years"?
 

Excel Facts

Format cells as currency
Select range and press Ctrl+Shift+4 to format cells as currency. (Shift 4 is the $ sign).
I think I've just resolved my own issue by looking at things from a different angle.

I used the INDEX function.

Code:
=INDEX(PivotSheet!C5:AZ5,0,MATCH("CH",PivotSheet!C$4:AZ$4,0))

This uses the Pivot Table's first data row as an index and then matches the value under the relevant header ("CH") with that index to pull it into the new table.

Then I just copy the formula down.

"CH" can be changed to whatever I need for the other columns.
 
Upvote 0
You can replace the hard coded values with any formulas returning the same values.

For text values I'd use INDEX and MATCH and for numbers & dates something like MAX, MIN, SMALL or LARGE. Also, you can put the formulas in your GETPIVOTDATA function but I'd put them in separate cells - at least when I'm building the formula - and use cell links for easier evaluation.
 
Upvote 0

Forum statistics

Threads
1,213,526
Messages
6,114,136
Members
448,551
Latest member
Sienna de Souza

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