Creating a Year-to-Date Comparison Chart

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


1

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:

  1. Display the Formulas tab of the ribbon.
  2. In the Defined Names group, click the Name Manager tool. Excel displays the Name Manager dialog box.
  3. Click the New button. Excel displays the New Name dialog box. (See Figure 1.)
  4. Figure 1. The New Name dialog box.

  5. In the Name field, enter the name CurrentYear (note that this is a single word, with no spaces).
  6. In the Refers To field, enter the following formula:
  7. =OFFSET(INDIRECT(YEAR(NOW())&"!A1"),1,1,TODAY()-DATE(YEAR(NOW()),1,1)+1,1)
    
  8. Click the OK button to finish creating the named range. The new range should appear in the Name Manager dialog box.
  9. Click the New button again. Excel (again) displays the New Name dialog box.
  10. In the Name field, enter the name PreviousYear (note that this is, again, a single word, with no spaces).
  11. In the Refers To field, enter the following formula:
  12. =OFFSET(INDIRECT(YEAR(NOW())-1&"!A1"),1,1,TODAY()-DATE(YEAR(NOW()),1,1)+1,1)
    
  13. Click the OK button. The new range should appear in the Name Manager dialog box.
  14. Click the New button a third time. Excel displays the New Name dialog box.
  15. In the Name field, enter the name Dates.
  16. In the Refers To field, enter the following formula:
  17. =OFFSET(INDIRECT(YEAR(NOW())&"!A1"),1,0,TODAY()-DATE(YEAR(NOW()),1,1)+1,1)
    
  18. Click the Close button to dismiss the Name Manager dialog box.

With the ranges defined, you can now create the chart using those ranges:

  1. Display the Insert tab of the ribbon.
  2. In the Charts group click the Column option. Excel displays a drop-down list.
  3. Click once on the Clustered Column format. (This is the first option under the 2-D Column heading.) Excel creates a blank chart object in your worksheet.
  4. Right-click the chart object. Excel displays a Context menu.
  5. Choose Select Data from the Context menu. Excel displays the Select Data Source dialog box, which should be completely empty because you've not added any data ranges to the chart.
  6. At the left side of the dialog box, under the Legend Entries (Series) heading, click the Add button. Excel displays the Edit Series dialog box. (See Figure 2.)
  7. Figure 2. The Edit Series dialog box.

  8. In the Series Name field, enter 2022.
  9. In the Series Values field, enter this: '2022'!PreviousYear.
  10. Click the OK button. The data series now appears in the Select Data Source dialog box.
  11. Click, again, the same Add button you clicked in step 6. Excel again displays the Edit Data Series dialog box.
  12. In the Series Name field, enter 2023.
  13. In the Series Values field, enter this: '2023'!CurrentYear.
  14. Click the OK button. This second data series now appears in the Select Data Source dialog box.
  15. At the right side of the dialog box, under the Horizontal (Category) Axis Labels heading, click the Edit button. Excel displays the Axis Labels dialog box. (See Figure 3.)
  16. Figure 3. The Axis Labels dialog box.

  17. In the Axis Label Range, enter this: '2023'!Dates.
  18. Click the OK button. The Select Data Source dialog box should be fully filled out with the necessary information.
  19. Click OK to dismiss the 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, 2016, 2019, Excel in Microsoft 365, and 2021.

Author Bio

Allen Wyatt

With more than 50 non-fiction books and numerous magazine articles to his credit, Allen Wyatt is an internationally recognized author. He is president of Sharon Parq Associates, a computer and publishing services company. ...

MORE FROM ALLEN

Automatic Blank Pages at the End of a Section

If you want to have a blank page at the end of a document section, you can insert one manually or you can use the ...

Discover More

Changing Table Cell Text Direction

When creating a table, you can turn the orientation of the text, within a cell, by ninety degrees in either direction ...

Discover More

Formatting a PivotTable

You can format PivotTables using either manual formatting or automatic formatting. You need to be careful, however, as ...

Discover More

Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!

More ExcelTips (ribbon)

Changing the Axis and Gridline Default Color

When you want to change the defaults used for charts, a chart template is the way to go. This tip shows how easy it is to ...

Discover More

Reliable Display of X-Y Values in a Chart

Excel can display both values and names for data points in a chart, when you hover the mouse over the data point. This ...

Discover More

Making Sure that Data Accompanies a Chart

When sending a chart to someone else, it can be frustrating for the other person to open the workbook and see errors ...

Discover More
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

View most recent newsletter.

Comments

If you would like to add an image to your comment (not an avatar, but an image to help in making the point of your comment), include the characters [{fig}] (all 7 characters, in the sequence shown) in your comment text. You’ll be prompted to upload your image when you submit the comment. Maximum image size is 6Mpixels. Images larger than 600px wide or 1000px tall will be reduced. Up to three images may be included in a comment. All images are subject to review. Commenting privileges may be curtailed if inappropriate images are posted.

What is three less than 3?

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


This Site

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.

Newest Tips
Subscribe

FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."

(Your e-mail address is not shared with anyone, ever.)

View the most recent newsletter.