Darryl needs to find the average of the last six entries in a column. The number of items in the column can vary over time as more information is added, but he always wants the average of those last six items.
There are a number of different formulas you can use, probably too many to go over here in detail. With that in mind, it is instructive to look at two particular formulas. The one you choose to use will depend on the characteristics of the data in the column. If there are no blank cells in the column, then finding the average can be done with a relatively simple formula:
=AVERAGE(OFFSET(A1,COUNT(A:A)-6,0,6,1))
This formula uses the OFFSET function to calculate the proper cells to examine, at the bottom of the column. As already mentioned, this formula won't work if there are blank cells in the column. In that case you will need to use a formula that examines the contents of each cell and determines, as part of the calculation process, whether it is blank or not. Array formulas or regular formulas using array functions are great for this purpose. The following example uses the SUMPRODUCT function to accomplish the task:
=SUMPRODUCT((A1:A30*((MAX(ROW(A1:A30)*(A1:A30<>""))-ROW(A1:A30))<6))/6)
This formula assumes that the cells to be evaluated are in the range of A1:A30; it doesn't matter if there are blank cells in this range. The ROW functions are used to create arrays that determine if the individual cells contain values or not. Only those rows containing values end up being counted, and those are divided by 6 and summed, providing the desired average.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10770) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Office 365. You can find a version of this tip for the older menu interface of Excel here: Referencing the Last Six Items in a Formula.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
Excel provides a variety of tools that allow you to perform operations on your data based upon the characteristics of ...
Discover MoreIf you have a special need to find cell values that meet two different criteria, where to start can be daunting. This tip ...
Discover MoreWhen working with large amounts of data, it is a good idea to make sure that the data all consistently follows a pattern. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2016-05-09 16:29:17
Barbara Toosley
THANK YOU. Been trying for 2 years to be able to write a formula calculate our golf handicaps and you have now answered by prays.
2016-04-01 17:48:27
Dennis Costello
To be clear, the SUMPRODUCT formula returns the average of 6 rows, the last of which is the last populated row in the range A1:A30. For example, if there are values in rows 1,2,3,6,7,10,12,13,14 - it will give the average of the cells A9:A14, even though two of those cells are empty.
This array formula (that uses some ideas from yours) returns the proper result:
{=AVERAGE(OFFSET(A1, LARGE(ROW(A1:A30) * (A1:A30 <> ""), 6) - 1, 0, 30, 1))}
2015-09-27 15:39:40
Paul
How about this:
=SUMPRODUCT((A1:A30*(ROW(A1:A30)>=LARGE((ROW(A1:A30)*(A1:A30<>"")),6)))/6)
The Large expression finds the 6th highest non-blank row.
The >= test returns 1 only for rows greater than or equal to the 6th highest non-blank row, so only these values are averaged.
I'm guessing a macro would give a simpler solution.
2015-06-29 12:31:19
Kirk
None of these give the correct result if there is a blank cell within the 6 desired for averaging. Consider alternating values of 2 or 3 with a blank at row 27 (1=2, 2=3,...26=3, 27=blank, 28=2). The average of non-blank cells among the last 6 is 2.4 while the average of the last 6 non-blank cells is 2.5. SUMPRODUCT counts the blank as ZERO and gives an average of 2.0. AVERAGE(INDEX and AVERAGE(OFFSET average rows 24-29 and give 2.6 as the result.
2015-06-29 09:22:09
Rick
Never liked offset much due to the volitile part. Nor do I like the sumproduct array because most folks get confused reading it, so I use something simpler:
=AVERAGE(INDEX(A1:A51,COUNT(A1:A51)-5):INDEX(A1:A51,COUNT(A1:A51)))
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 © 2021 Sharon Parq Associates, Inc.
Comments