Written by Allen Wyatt (last updated May 1, 2020)
This tip applies to Excel 97, 2000, 2002, and 2003
Emma has a list of numbers in a worksheet (let's say in column A) that are added to on a weekly basis. She needs to calculate the average of the last 12 numbers in the column. She wonders how she can do this and have the average always reflect the last 12 numbers, even when she keeps adding numbers each week.
Assuming that there are no gaps in your range of numbers, you can calculate the average of the last 12 numbers with this formula:
=AVERAGE(OFFSET(A1,COUNTA(A:A)-12,0,12,1))
This formula should, of course, be placed in some cell that is not in column A. It uses the COUNTA function to figure out how many cells contain something in column A. If there are 100 cells in use in column A, this means that you end up with a formula being evaluated in this way:
=AVERAGE(OFFSET(A1,100-12,0,12,1))
Of course, 100 minus 12 is 88, and this number is used as an offset from the starting cell (A2) to say that the range to be averaged should start at A89 and extend down 12 cells. That means that the average ends up being for the range A89:A100. As more numbers are added at the bottom of column A, the formula always reflects the last 12 numbers.
The formula will return an error if column A has fewer than 12 rows worth of data in it. To accommodate that possibility, you may want to alter the formula just a bit:
=AVERAGE(OFFSET(A1,COUNTA(A:A)-MIN(COUNTA(A:A),12),0,MIN(COUNTA(A:A),12),1))
Instead of using a hard-and-fast value of 12 rows, the MIN function (in two places) returns the minimum of either the actual number of rows or 12. So, if your worksheet only has numbers in cells A1:A5, the MIN function would ensure that the formula only averaged those 5 values.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10277) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Averaging the Last Numbers in a Column.
Create Custom Apps with VBA! Discover how to extend the capabilities of Office 365 applications with VBA programming. Written in clear terms and understandable language, the book includes systematic tutorials and contains both intermediate and advanced content for experienced VB developers. Designed to be comprehensive, the book addresses not just one Office application, but the entire Office suite. Check out Mastering VBA for Microsoft Office 365 today!
When processing data in a worksheet, you may have a need to know what the smallest (lowest) even value in a range is. You ...
Discover MoreWant to know how to move pieces of information contained in one cell into individual cells? This option exists in using ...
Discover MoreAdding row numbers to a column of your worksheet is easy; you just need to use a formula to do it. Here's a quick look at ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2015-11-01 02:14:19
Thomas Papavasiliou
Mind that column A should not contain any empty cells that precedes the last twelve, as the COUNTA function returns the count of non empty cells in the reference.
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon 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