×
INTELLIGENT WORK FORUMS
FOR COMPUTER PROFESSIONALS

Log In

Come Join Us!

Are you a
Computer / IT professional?
Join Tek-Tips Forums!
  • Talk With Other Members
  • Be Notified Of Responses
    To Your Posts
  • Keyword Search
  • One-Click Access To Your
    Favorite Forums
  • Automated Signatures
    On Your Posts
  • Best Of All, It's Free!

*Tek-Tips's functionality depends on members receiving e-mail. By joining you are opting in to receive e-mail.

Posting Guidelines

Promoting, selling, recruiting, coursework and thesis posting is forbidden.

Students Click Here

Reference Pivot Tables by name

Reference Pivot Tables by name

Reference Pivot Tables by name

(OP)
Excel provides the GETPIVOTDATA() function.

GETPIVOTDATA(data_field, pivot_table, [field1, item1, field2, item2], ...)

Microsoft defines the pivot_table parameter this way: "A reference to any cell, range of cells, or named range of cells in a PivotTable. This information is used to determine which PivotTable contains the data that you want to retrieve."

So, in use on a sheet it looks like this: =GETPIVOTDATA("Row Cost",'Break Down'!$A$3,"Group",[@Group])

Pivot Tables have names, and I want to be able to use that name on the sheet. So far I have:

CODE --> VBA

Public Function GetPivotTopLeft(mySheet As String, TargetPT As String) As String

Dim PT As PivotTable
Dim TopLeftCell As String
Set PT = Worksheets(mySheet).PivotTables(TargetPT)
TopLeftCell = Split(PT.TableRange1.Address, ":")(0)
GetPivotTopLeft = "'" & Sheets(mySheet).Name & "'" & "!" & TopLeftCell
End Function 

This works, but only by using it inside INDIRECT(), like this:
=GETPIVOTDATA("Hours Allocated",INDIRECT(GetPivotTopLeft("Break Down", "TechBreakDown")))

How can I get away from the need to use INDIRECT()?

=GETPIVOTDATA("Hours Allocated",GetPivotTopLeft("Break Down", "TechBreakDown"))

What VBA variable type does my GetPivotTopLeft() function need to return to make the native GETPIVOTDATA() function happy for the pivot_table parameter?

How do I build that type in my VBA function?

RE: Reference Pivot Tables by name

The second argument in GETPIVOTDATA is range, so:

CODE -->

Public Function GetPivotTopLeft(mySheet As String, TargetPT As String) As Range
Dim PT As PivotTable
Set PT = Worksheets(mySheet).PivotTables(TargetPT)
Set GetPivotTopLeft = PT.TableRange1.Cells(1)
End Function 
In my tests .Cells(1) was not necessary, however it returns the first cell in range.

Pivot table has GetPivotData property, you can extend your function to return final data.

combo

RE: Reference Pivot Tables by name

(OP)
@combo

Thanks, that works.

I had tried something similar earlier, but it missed the need to Set the final value because it's an object.

Set GetPivotTopLeft = PT.TableRange1.Cells(1)

Red Flag This Post

Please let us know here why this post is inappropriate. Reasons such as off-topic, duplicates, flames, illegal, vulgar, or students posting their homework.

Red Flag Submitted

Thank you for helping keep Tek-Tips Forums free from inappropriate posts.
The Tek-Tips staff will check this out and take appropriate action.

Reply To This Thread

Posting in the Tek-Tips forums is a member-only feature.

Click Here to join Tek-Tips and talk with other members! Already a Member? Login


Close Box

Join Tek-Tips® Today!

Join your peers on the Internet's largest technical computer professional community.
It's easy to join and it's free.

Here's Why Members Love Tek-Tips Forums:

Register now while it's still free!

Already a member? Close this window and log in.

Join Us             Close