Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. If you are using an earlier version (Excel 2003 or earlier), this tip may not work for you. For a version of this tip written specifically for earlier versions of Excel, click here: Averaging Values for a Given Month and Year.

Averaging Values for a Given Month and Year

Written by Allen Wyatt (last updated March 14, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365


4

George has a worksheet that includes dates (in column A) and values associated with those dates (in column B). The worksheet includes values for the last several years. He would like to calculate the average of all the values for a given month in a given year. For instance, George would like to calculate the average of all the values for February 2020.

There are several different ways to approach this problem. One way is to create a PivotTable based on your data. (PivotTables are great for aggregating and analyzing huge amounts of data.) You can easily set the value field to Average (instead of the default Sum) and group the Dates column by whatever you want.

If you'd rather not use a PivotTable, there are any number of formulas you can add to your worksheet. For instance, the following formula uses the SUMPRODUCT function to calculate the average:

=SUMPRODUCT((MONTH(A2:A1000)=5)*(YEAR(A2:A1000)=2020)*(B2:B1000)) /
(SUMPRODUCT((MONTH(A2:A1000)=5)*(YEAR(A2:A1000)=2020)*1))

The formula assumes your dates and values begin in row 2 (to allow for headings) and don't go past row 1000. If there are no dates in the data that are in the month of February 2020, then the formula returns a #DIV/0! error.

Another approach is to use an array formula, such as the following:

=AVERAGE(IF((MONTH(A2:A1000)=5)*(YEAR(A2:A1000)=2020),B2:B1000))

This approach is shorter than the SUMPRODUCT formula, but you've got to remember to hold down Ctrl+Shift+Enter as you enter the formula. You'll also get the division by zero error if there is no data for the desired month and year.

Still another approach is to use one of the database functions of Excel, DAVERAGE. All you need to do is set up a criteria table that defines what you are looking for. Assume, for example, that the headings on the columns are something original, like Date (cell A1) and Value (cell B1). You could set up a criteria table in another place, such as D1:E2. The table could look like this:

Date         Date
>1/31/20     <3/1/20

The criteria table says that you want DAVERAGE to use anything in which the Date column contains a date greater than 1/31/20 and a date less than 3/1/20. Here's the formula:

=DAVERAGE(A1:B1000,"Value",D1:E2)

The first parameter defines your database, the second parameter indicates that you want to average the information in the Value column (column B), and the third parameter tells DAVERAGE where your criteria table is located.

One quite easy way is to apply filtering of dates and use the SUBTOTAL function. Enter the following formula into a cell:

=SUBTOTAL(101,B2:B1000)

Select a cell in your data range and filter your data (display the Data tab of the ribbon and click the Filter tool). Click the filtering arrow at the top of column A and then choose Date Filters | Custom Filter from the drop-down list. Excel displays the Custom AutoFilter dialog box. (See Figure 1.)

Figure 1. The Custom AutoFilter dialog box.

Use the controls in the dialog box to specify that you want records greater than 1/31/20 and less than 3/1/20. When you click on OK, only those records within February 2020 are displayed, and the subtotal formula shows the average of those visible records.

Perhaps the simplest approach, however, is to use the AVERAGEIFS function. It allows you to calculate an average of some values depending on whether an associated value (the date, in this case) meets the criteria you specify. Here's how the formula looks:

=AVERAGEIFS(B2:B1000,A2:A1000,">31 Jan 2020",A2:A1000,"<01 Mar 2020")

Notice that this is not an array formula and you don't need to define a criteria table for your criteria—they are built directly into the formula.

ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10671) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Averaging Values for a Given Month and Year.

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

The Case of the Disappearing MRU File List

If the MRU list has disappeared, follow this tip to reactivate the list in Word.

Discover More

Changing Fonts in Multiple Workbooks

If you need to change fonts used in a lot of different workbooks, the task can be daunting, if you need to do it ...

Discover More

Restarting Footnote Numbering after Page Breaks

Footnotes can be handled many different ways in a document. If you want to restart the numbering of your footnotes every ...

Discover More

Professional Development Guidance! Four world-class developers offer start-to-finish guidance for building powerful, robust, and secure applications with Excel. The authors show how to consistently make the right design decisions and make the most of Excel's powerful features. Check out Professional Excel Development today!

More ExcelTips (ribbon)

Excluding Values from Averaging

Calculating an average of a group of numbers is easy. What if you want to exclude a couple of the numbers from the group ...

Discover More

Averaging a Non-Contiguous Range

Figuring out how to average data that is in a contiguous range of cells is easy. When the data is spread over a group of ...

Discover More

Determining a Simple Moving Average

A moving average can be a great way to analyze a series of data points that you've collected over time. Setting up a ...

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 two more than 9?

2020-05-07 08:37:58

Peter Atherton

Pawel
I should have mentioned that you would use the AVERAGEIFS function for your stuff and the Data validation is not really flexible so, you might just prefer to type the start & end dates in a cell.


2020-05-07 06:28:15

Peter Atherton

Pawel
You might like to convert your data to a table by selecting a cell in the list and pressing Ctrl + T. You can rename the table to say data or sales. Tables expand as more row are added. I'm running a query on covid-19 deaths at the moment so these are a way you can get some information from the list.

In G6 I inserted a data validation from list for the dates. Data, Data Tools group, Data Validation and select your dates. I copied this to G7. You can select the Star Date & the End date from these. Make sure that you leave space in the reference for more data.

To get the sum for the last two-weeks deaths you the following formula
=SUMIFS(data[deaths],data[dateRep],"<="&G5,data[dateRep],">="&G6,data[countriesAndTerritories],"="&B8)
B8 contains the country name I was investigating.

The Name of the Table is Data and the columns in square brackets are the Column Headngs.

I have not used these formulas in the model but they work with the data I was getting. Finally the last variable used for the country is not needed for your model unless you want to find the sum for a particular sales item.

HTH


2020-05-06 04:08:06

Pawel

Hi! So I tried your array formula, {=AVERAGE(IF((MONTH($A$2:$A$585)=1)*(YEAR($A$2:$A$585)=2018),$B$2:$B$585))}, and it worked! Thank you. But then when I tried to make the formula dynamic, it didn't!!

So whereas the column A had the daily dates, I wrote in column C months (eg. jan-18, feb-18, etc.) so that I could replace =1 and =2018 with =Month(C2), and =Year(C2), but it didn't work!!! Why?? when I highlighted Month(C2) and pressed F9, I got 1. So if the value is the same, why doesn't it work????


2020-03-16 05:56:55

David Robinson

The AVERAGEIFS function at the end is what I use and I generally make reference to a cell that says which month I'm averaging. Say cell D2 is set to the first of the month, the formula can be written like this to return everything that is at least the first of the month, but less than the first of the next month ...

=AVERAGEIFS(B2:B1000,A2:A1000,">="&D2,A2:A1000,"<"&EDATE(D2,1))

Here I use EDATE to get the first of the next month. I love the way you can append the less-than and greater-than symbols to your cell values!


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.