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.

Referencing the Last Six Items in a Formula

Written by Allen Wyatt (last updated February 19, 2022)
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.

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

Printing an Outline

Outlining is a great way to develop the content of your document. If you need to, you can even print the outline and only ...

Discover More

Editing Macros

Even if you do nothing but record macros, sooner or later you will have a need to edit what you record. Here's how to get ...

Discover More

Jumping to the End of Page after Enter

Imagine you start typing in a new document, and when you press the Enter key the cursor jumps a huge distance to the ...

Discover More

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!

More ExcelTips (ribbon)

Creating a Static Cell Reference

When you edit a worksheet, adding and deleting rows and columns, Excel automatically updates references to cells ...

Discover More

Pulling Initial Letters from a String

When working with names or a different series of words, you may need to pull the initial letters from each word in the ...

Discover More

Counting Cells Containing a Formula

Cells in a worksheet can contain different types of information, such as numbers, text, and formulas. If you want to ...

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 7 - 2?

There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)


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.