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: Referencing the Last Six Items in a Formula.

Referencing the Last Six Items in a Formula

by Allen Wyatt
(last updated June 27, 2015)

5

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

Updating Multiple PivotTables at Once

PivotTables are a great way to process huge amounts of data and make sense of that data. If you have a number of PivotTables ...

Discover More

Displaying the Full Ribbon

The ribbon, displayed at the top of the Word window, is very handy with all the tools it allows you to access, but it can ...

Discover More

Aligning Paragraphs in a Macro

Using a macro to format your document (or portions of your document) is not all that uncommon. If you want your macro to ...

Discover More

Create Custom Apps with VBA! Discover how to extend the capabilities of Office 2013 (Word, Excel, PowerPoint, Outlook, and Access) with VBA programming, using it for writing macros, automating Office applications, and creating custom applications. Check out Mastering VBA for Office 2013 today!

More ExcelTips (ribbon)

Hiding Rows Based on Two Values

It's easy to use filtering to hide rows based on the value in a cell, but how do you hide rows based on the values in two ...

Discover More

Formulas Don't Calculate as Formulas

Enter a formula (starting with an equal sign) and you may be surprised if Excel doesn't calculate the formula. Here's a good ...

Discover More

Changing the Reference in a Named Range

Define a named range today and you may want to change the definition at some future point. It's rather easy to do, as ...

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}] 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 4 + 2?

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)))


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.