Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, and 2013. 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

by Allen Wyatt
(last updated June 28, 2014)

5

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 May 2014.

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)=2011)*(B2:B1000)) /
(SUMPRODUCT((MONTH(A2:A1000)=5)*(YEAR(A2:A1000)=2011)*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 May 2014, 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)=2014),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
>4/30/14     <6/1/14

The criteria table says that you want DAVERAGE to use anything in which the Date column contains a date greater than 4/30/14 and a date less than 6/1/14. 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 4/30/14 and less than 6/1/14. When you click on OK, only those records within May 2014 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,">30 Apr 2014",A2:A1000,"<01 Jun 2014")

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, and 2013. 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

Showing Only Added Text with Track Changes

Do you want to change how Track Changes displays the markup in your document? Here's how you can completely hide deleted text ...

Discover More

Rows in a PivotTable

PivotTables are used to analyze huge amounts of data. The number of rows used in a PivotTable depends on the type of analysis ...

Discover More

Searching for Non-Black Text

Searching for text having (or not having) specific formatting is generally pretty easy. It is more difficult to search for ...

Discover More

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!

MORE EXCELTIPS (RIBBON)

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

Averaging the Last Numbers in a Column

Need to calculate a running average for the last twelve values in a constantly changing range of values? The formula ...

Discover More

Averaging without Hidden Cells

Grabbing an average of a range of cells is easy using Excel functions. If you want that average to ignore hidden cells when ...

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 for this tip:

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}] in your comment text. You’ll be prompted to upload your image when you submit the comment. 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 7 + 8?

2015-12-24 05:44:37

Michael (Micky) Avidan

@Suparag,
What do you, exactly, mean by the term "WEEK" ?
Do you mean 7 consecutive dates OR Monday-Friday ?
By presenting a sample Workbook, which has some hand-types results, you can make our support-efforts much easier.
You can upload such a B to some File Hosting site and return to present the download link to us.
--------------------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2016)
ISRAEL


2015-12-23 14:34:04

Suparag

Allen,

Your ideas here work if we are looking for average for a certain given months. I am tracking blood glucose levels for different patients. I need a weekly average and monthly average. There are 2 to 4 readings per day at different times. I just cannot average over previous x number of readings as the number of readings/day varies.

Thanks for you feedback.

Suparag


2015-01-24 07:07:18

Michael (Micky) Avidan

@Alvina & Anber,
For dates in Column A and values in column B - the following ARRAY FORMULA is one option to calculate the Average for the year 2015:
=SUM((YEAR(A:A)=2015)*B:B)/SUM(N(YEAR(A:A)=2015))
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL


2015-01-24 04:15:03

Amber

Dear Allen,

I have the same problem like Alvina. Normally I use Filter and then AVERAGE function to calculate averages in each year and it's too boring and time-consuming when I have to do that for 30 years. Would you please show an easier method to calculate annual average automatically?

Best Regards
Amber


2014-07-23 05:19:59

Alvina

Hi Allen,

Thank you very much for the wonderful tip.
If i want to calculate the average values for 12 months of each year instead of one particular month, how should the array formula look like?

Many thanks,
Alvina


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.

Links and Sharing
Share