Written by Allen Wyatt (last updated April 18, 2020)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and 2021
Suppose that you have a huge worksheet that contains all the rainfall readings for a given locale for the past hundred years or so. In cells A2:A42733 you have the dates, 1 January 1903 through 31 December 2019. In cells B2:B42733 you have the measurements for each date. Further, some of the measurements can be zero (if there is no rainfall for the day) or blank (if no reading was taken that particular day). With all this information, you want to calculate the average historic rainfall for any given day of the year.
One solution involves the use of array formulas, as detailed here:
=SUM((MONTH(Dates)=MONTH(D2))*(DAY(Dates)=DAY(D2))*Rainfall)
=SUM((MONTH(Dates)=MONTH(D2))*(DAY(Dates)=DAY(D2))*(Rainfall<>""))
=IF(F2<>0,E2/F2,"")
This approach works, but it takes quite a while to calculate. This is because you effectively entered 822 array formulas, each checking over 42,000 cells. This is a lot of work, and consequently it may appear like your machine has "hung" after you complete step 7. It has not hung; it will just take it a while to complete the calculations.
To decrease the number of calculations that must be performed, you can use a variation on the above steps. Follow steps 1 through 3, as noted, and then place the following array formula into cell E2:
=AVERAGE(IF((Dates<>0)*(Rainfall<>0)*(MONTH(Dates)=MONTH(D2))*(DAY(Dates)=DAY(D2)),Rainfall))
You can then copy the formula down for all the dates shown in column D. The result of this formula is the actual average rainfall, the same as had been shown in column G in the previous approach.
You can reduce the calculation overhead even further by simply getting rid of all the table that calculates the averages for every day of the year. With your dates and rainfall in columns A and B, follow these steps:
=AVERAGE(IF((Dates<>0)*(Rainfall<>0)*(MONTH(Dates)=MONTH(D2))*(DAY(Dates)=DAY(D2)),Rainfall))
That's it. Now, you can change the date in cell D2 as desired, and cell E2 will always indicate the average rainfall for that date. The formula in cell E2 is the same as the formula used in the last approach; the difference is that you aren't calculating it for all the days in a year, and thus the calculation is done much quicker.
Another approach involves the use of Excel's filtering capabilities. Before you can use them properly, however, you must create a column that shows only the month and day for each date in your data. Use this formula in cell C2:
=MONTH(A2) & "-" & DAY(A2)
Now, turn on AutoFiltering (display the Data tab on the ribbon | Sort & Filter group | Filter) and use the drop-down list at the top of the new column to select the date for which you want an average. You then use the following formula, placed in any cell desired, to show the average rainfall for the selected date:
=SUBTOTAL(1,B:B)
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10319) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and 2021. You can find a version of this tip for the older menu interface of Excel here: Calculating Averages by Date.
Best-Selling VBA Tutorial for Beginners Take your Excel knowledge to the next level. With a little background in VBA programming, you can go well beyond basic spreadsheets and functions. Use macros to reduce errors, save time, and integrate with other Microsoft applications. Fully updated for the latest version of Office 365. Check out Microsoft 365 Excel VBA Programming For Dummies today!
Excel works very well with dates and times. One thing you cannot do, however, is to create a custom format that displays ...
Discover MoreGiven a starting date and an ending date, you may want to generate the names of all the months between those two dates. ...
Discover MoreNeed to calculate the date that is a certain number of workdays in the future? You can do so using a couple of different ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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 © 2025 Sharon Parq Associates, Inc.
Comments