Written by Allen Wyatt (last updated February 24, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
David has many PivotTables that are filtered by year. In his data there is a separate field for year (values 2021, 2022, 2023, etc., derived via the Year function). He excludes older years in most cases and reports on more recent years. When a new year arrives, it is a tedious process for David to edit every PivotTable and select the most recent year. He wonders if there is a way to specify the selection values for a PivotTable filter so he doesn't need to go through the tedious editing.
Perhaps the easiest way to do this would be to add a single column to the source data for your PivotTable. The column could contain a simple formula that designates whether the row is within the desired range for inclusion in the PivotTable. For instance, if column A contains the transaction date for the row, then you could include the following in the added column:
=YEAR(A2)>YEAR(NOW())-3
The result of the formula is either True or False, depending on whether the transaction is within the previous three years or not. Thus, if this formula is evaluated in 2023, then any transactions within 2021, 2022, and 2023 would return True; all others would be False. Then, within your PivotTable definition you could filter based on the contents of this particular column, thereby ensuring that only those True rows are included in the PivotTable.
If you prefer a macro-based solution, you could easily develop one that examined each of the PivotTables and changed the PivotField named "Year" so that it was equal to a desired year. The following shows how easy it is to make such a change:
Sub ChangePivotYear() Dim sht As Worksheet Dim pvt As PivotTable Dim iYear as Integer iYear = 2023 ' Change to desired year For Each sht In Worksheets For Each pvt In sht.PivotTables pvt.PivotFields("Year").ClearAllFilters pvt.PivotFields("Year").CurrentPage = iYear Next pvt Next sht End Sub
The macro sets the field to 2023; if you want to use a different year, just change what is assigned to the iYear variable. Note, as well, that the macro affects all the PivotTables in the entire workbook.
Note:
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (12571) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365.
Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!
If you modify the data on which a PivotTable is based, you'll need to refresh the table so it reflects the modified data. ...
Discover MoreTired of your data being sorted when you create a PivotTable? Excel allows you to specify how the sorting should occur by ...
Discover MorePivotTables can be a great tool for analyzing large amounts of data. If you have a PivotTable that is pulling information ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
Got a version of Excel that uses the ribbon interface (Excel 2007 or later)? This site is for you! If you use an earlier version of Excel, visit our ExcelTips site focusing on the menu interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2025 Sharon Parq Associates, Inc.
Comments