Capturing Range for Pivot table

davidhall80

Well-known Member
Joined
Jul 8, 2006
Messages
663
I am trying to put a pivot table in my macro, but each week, the amount of data I have will change. My data that UI want to use is in columns A to E. How do I select all of the data in columns A to E if my row amount varies.
 

Excel Facts

Pivot Table Drill Down
Double-click any number in a pivot table to create a new report showing all detail rows that make up that number
Hi

How about something like

activesheet.PivotTables("Address").SourceData = "A1:E" & Cells(Rows.Count, 1).End(xlUp).Row

This assumes that the pivot table is on the activesheet, it is called "Address" and that column E will have an entry in the last cell.

HTH

Tony
 
Upvote 0
Here's a sample of code that I have used more than once...

Code:
    Dim WSD As Worksheet, WSD2 As Worksheet
    Dim PTCache As PivotCache
    Dim PT As PivotTable, PTbl As PivotTable
    Dim PRange As Range
    Dim LastRow As Long
    
    Set WSD = Worksheets("Main Data")
    Set WSD2 = Worksheets("Pivot Detail")
    vFields = Range("Table_PivotData").Value
   
    'define input area and set up a Pivot Cache
    LastRow = WSD.Cells(65536, 1).End(xlUp).Row
    WSD.Activate
    WSD.Cells(1, 1).Resize(LastRow, 37).Select
    ActiveWorkbook.Names.Add Name:="PData", RefersTo:=Selection
    Set PRange = WSD.Cells(1, 1).Resize(LastRow, 37)
    Set PTCache = ActiveWorkbook.PivotCaches.Add(xlDatabase, Range("PData"))
    Set PT = PTCache.CreatePivotTable(WSD2.Range("A10"), "Detail Pivot")
    PT.ManualUpdate = True
    
    WSD2.Activate

    '...continue to play with the pivot table
This is the beginning of code that works with about 40 fields, so I put the fields in a table and loaded them into an array to simplify referencing them. The bottom line is to create the range name on the fly, and use that as the data source for the pivot table.

Hope this helps

Denis
 
Upvote 0

Forum statistics

Threads
1,214,649
Messages
6,120,732
Members
448,987
Latest member
marion_davis

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