×

Dynamically Change Every Pivot Table Data Source Range Inside A Workbook With This VBA Macro Code

By Chris Newman •  Updated: 10/16/14 •  4 min read
Dynamically Change Every Pivot Table Data Source Range Inside A Workbook With This VBA Macro Code

What This Does

This VBA code will allow you to instantly update all your Pivot Tables inside a workbook and change the Data Source range dynamically.  This macro is perfect for instances where you have an ever-changing data set that is feeding in a bunch of Pivot Tables.  It can be a pain to readjust the Data Source range and that is where this VBA macro can come in handy.  Enjoy!

Learn More About Pivot Table VBA Coding! Check Out My Blog Post Guide On This Topic!

Sub AdjustAllPivotDataRanges()
'PURPOSE: Dynamically change every pivot table's data source range in the workbook
'SOURCE: www.TheSpreadsheetGuru.com/the-code-vault

Dim sht As Worksheet
Dim pvt As PivotTable
Dim StartPoint As Range
Dim rng As Range
Dim SourceAddress As String

'Enter Worksheet Name that holds your Pivot data source
  Set sht = ActiveWorkbook.Worksheets("Scrubbed MTD Dataset")

'Enter first cell in your Pivot data source
  Set StartPoint = sht.Range("A1")

'Create SourceData address
  Set rng = sht.Range(StartPoint, StartPoint.SpecialCells(xlLastCell))
  SourceAddress = sht.Name & "!" & rng.Address(ReferenceStyle:=xlR1C1)

'Loop through and update pivot tables with new data source range
  For Each sht In ThisWorkbook.Worksheets
    For Each pvt In sht.PivotTables
      
      'Change Pivot Table's data source range address
        pvt.ChangePivotCache _
          ThisWorkbook.PivotCaches.Create( _
          SourceType:=xlDatabase, _
          SourceData:=SourceAddress)
        
      'Ensure Pivot Table is refreshed
        pvt.RefreshTable
        
    Next pvt
  Next sht

'Completion Message
  MsgBox "All Pivot Table Data Source Ranges have been updated in this workbook!", vbInformation

End Sub

Using VBA Code Found On The Internet

Now that you’ve found some VBA code that could potentially solve your Excel automation problem, what do you do with it? If you don’t necessarily want to learn how to code VBA and are just looking for the fastest way to implement this code into your spreadsheet, I wrote an article (with video) that explains how to get the VBA code you’ve found running on your spreadsheet.

Getting Started Automating Excel

Are you new to VBA and not sure where to begin? Check out my quickstart guide to learning VBA. This article won’t overwhelm you with fancy coding jargon, as it provides you with a simplistic and straightforward approach to the basic things I wish I knew when trying to teach myself how to automate tasks in Excel with VBA Macros.

Also, if you haven’t checked out Excel’s latest automation feature called Power Query, I have put together a beginner’s guide for automating with Excel’s Power Query feature as well! This little-known built-in Excel feature allows you to merge and clean data automatically with little to no coding!

How Do I Modify This To Fit My Specific Needs?

Chances are this post did not give you the exact answer you were looking for. We all have different situations and it’s impossible to account for every particular need one might have. That’s why I want to share with you: My Guide to Getting the Solution to your Problems FAST! In this article, I explain the best strategies I have come up with over the years to get quick answers to complex problems in Excel, PowerPoint, VBA, you name it

I highly recommend that you check this guide out before asking me or anyone else in the comments section to solve your specific problem. I can guarantee that 9 times out of 10, one of my strategies will get you the answer(s) you are needing faster than it will take me to get back to you with a possible solution. I try my best to help everyone out, but sometimes I don’t have time to fit everyone’s questions in (there never seem to be quite enough hours in the day!).

I wish you the best of luck and I hope this tutorial gets you heading in the right direction!

Keep Learning

Chris Newman

Chris Newman

Chris is a finance professional and Excel MVP recognized by Microsoft since 2016. With his expertise, he founded TheSpreadsheetGuru blog to help fellow Excel users, where he shares his vast creative solutions & expertise. In addition, he has developed over 7 widely-used Excel Add-ins that have been embraced by individuals and companies worldwide.

[FREE Training] 10 Amazing Excel Efficiency Tricks. Why Don't People Know These?!

X