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 2015 is in a worksheet named 2015 and your data for 2016 (so far) is in a worksheet named 2016. 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.
Figure 4. The filled-in Select Data Source 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, and 2016.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
When your chart contains dates along one axis, you can set bounds on the way the chart is displayed. What causes, though, ...
Discover MoreWant to change the groupings used by Excel when it creates pie charts? Your options are limited, as you learn in this tip.
Discover MoreNeed to generate a chart in the fastest possible way? Just use this shortcut key and you'll have one faster than you can ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2016-01-30 07:50:49
southofnonorth
A simpler approach might be to use a 3rd column to store an incremental total of rainfall to date ( so C2 = B2, then C3 = B3 + C2 etc) - then you can see an easy comparison to a previous year at any point in the year.
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 © 2022 Sharon Parq Associates, Inc.
Comments