Written by Allen Wyatt (last updated March 4, 2023)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021
Nora has kept a weather log for years. Each sheet of the workbook is a separate year, with column A on each sheet being the dates in the year and column B being the amount of precipitation on that day, if any. Nora would like to create a chart showing this year's precipitation vs. last year's precipitation, to date. She wonders if there is a way to automatically have this chart reference the correct precipitation values for both years based on today's date.
There are a couple of ways that this need can be filled, depending on exactly what you want to achieve. If you just want to compare rainfall this year to rainfall last year, by date, then you can easily do it by setting up some dynamic named ranges that define the data you want to use.
To begin with, let's assume that your data for 2022 is in a worksheet named 2022 and your data for 2023 (so far) is in a worksheet named 2023. On each worksheet, row 1 contains headings, which means that your dates actually start in cell A2 and your precipitation readings in cell B2. Follow these steps to set up the ranges:
Figure 1. The New Name dialog box.
=OFFSET(INDIRECT(YEAR(NOW())&"!A1"),1,1,TODAY()-DATE(YEAR(NOW()),1,1)+1,1)
=OFFSET(INDIRECT(YEAR(NOW())-1&"!A1"),1,1,TODAY()-DATE(YEAR(NOW()),1,1)+1,1)
=OFFSET(INDIRECT(YEAR(NOW())&"!A1"),1,0,TODAY()-DATE(YEAR(NOW()),1,1)+1,1)
With the ranges defined, you can now create the chart using those ranges:
Figure 2. The Edit Series dialog box.
Figure 3. The Axis Labels dialog box.
Your updated chart, showing only the dates up through today's date, should now be visible. You can continue to format the chart, as desired. (For instance, you'll probably want to format the dates in the chart so they don't include a year.) Further, the chart is dynamic, so that when you open the workbook tomorrow it will reflect one more day than it did today.
Another way to handle it is to reconsider how you are storing your data. Instead of storing all your precipitation readings on separate worksheets (by year), put them all on a single worksheet. Since Excel can handle over a million rows of data in a worksheet, you won't run up against any practical limitations. (A million rows represents well over 2,700 years.)
Now, on a different worksheet, you can use two array formulas to calculate the cumulative rainfall for both years, to date. The following array formula will provide the rainfall for the previous year:
=SUM(Data!B2:B1000*IF(Data!A2:A1000>=DATE(YEAR(NOW())-1,1,1),IF(Data!A2:A1000<=EDATE(NOW(),-12),1,0)))
This assumes that the original precipitation readings are on a worksheet named Data and that they don't extend beyond 1000 rows. (You can modify either of these, as necessary.) To get the to-date rainfall for this year, you can use this array formula:
=SUM(Data!B2:B1000*IF(Data!A2:A1000>=DATE(YEAR(NOW()),1,1),IF(Data!A2:A1000<=NOW(),1,0)))
Remember: These are both array formulas, so they should be entered using Ctrl+Shift+Enter. The single value returned by each formula represents the cumulative rainfall from each year, to date. These two values can then be used in any chart that you want.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (13427) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, Excel in Microsoft 365, and 2021.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!
Macros allow you to make changes to virtually anything you can see in Excel. This tip examines how to make changes (even ...
Discover MoreWhen formatting a chart, you might want to change the characteristics of the font used in various chart elements. This ...
Discover MoreUnhappy with the default size that Excel uses for embedded chart objects? You can't change the size at which they are ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2023-03-05 11:31:59
J. Woolley
When the Tip defines names in steps 3-6, 7-10, and 11-14, they presumably have Workbook (default) scope. But when it selects data for the chart in steps 8, 12, and 15, the Tip enters qualified names as if they had Sheet scope like '2022'!PreviousYear, '2023'!CurrentYear, and '2023'!Dates. One reason for this is that the chart data dialogs will not accept unqualified Workbook scope names like PreviousYear, CurrentYear, and Dates. However, after arbitrarily qualifying the defined name with the name of an existing sheet, Excel recognizes the defined name does not have Sheet scope and converts it into a qualified name with Workbook scope by adding the workbook's name (like 'Book1.xlsx'!...). This can be confirmed for the Series and Category data by picking Edit in the Select Data Source dialog at step 16. The Tip might be more accurate if it specified Workbook instead of Sheet qualified names for the chart data in steps 8, 12, and 15, like 'Book1.xlsx'!PreviousYear, 'Book1.xlsx'!CurrentYear, and 'Book1.xlsx'!Dates. (Of course, the actual workbook name must be substituted for Book1.xlsx.)
This demonstrates one of the idiosyncrasies of using a defined name (named range) with Workbook scope. For more, see my comment dated 2023-03-03 here: https://excelribbon.tips.net/T010338_Getting_Rid_of_Unused_Range_Names.html
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 © 2024 Sharon Parq Associates, Inc.
Comments