Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 2021, 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: Referencing the Last Six Items in a Formula.
Written by Allen Wyatt (last updated September 2, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, and Excel in Microsoft 365
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, 2021, and Excel in Microsoft 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.
Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2019 For Dummies today!
Want to figure out how to do a gift exchange for your family or office? There are a variety of ways you can approach the ...
Discover MoreIf you have a series of consecutive numbers in a column, you may want to know if it really is consecutive. (In other ...
Discover MoreCreating math formulas is a particular strong point of Excel. Not all the functions that you may need are built directly ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2025-09-02 05:18:16
SteveJez
If you have a Office 365 licence you can use the TAKE function.
=Take(array,-6) will the same result.
If you don't know the extent of the range/array use a larger array & use the trim operator to return only the used range. ie. =Take(A5 : . A200,-6) note period after the colon - this removes all the blanks at the end of the array, so if your data only extends to A48 the effective range will be A5:A48
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