Please Note: This article is written for users of the following Microsoft Excel versions: 2007, 2010, 2013, 2016, 2019, 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: Excluding Values from Averaging.
Written by Allen Wyatt (last updated February 21, 2024)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
You've seen it on the Olympics and in other sporting events: The average score for an athlete is determined by throwing out the highest score and the lowest score, and then averaging the rest. You may have a need to do similar types of averages. For instance, you may be a teacher and need to exclude the two lowest assignment scores before calculating an average.
To perform this type of averaging, all you need to remember is that an average is calculated by summing all the values in a range and then dividing that sum by the number of items in that range. The SUM function easily provides the sum, and the COUNT function can be used to find out the number of items in the range. How to exclude the two lowest values in the range? You can use the SMALL function.
Consider the following formula, which assumes you want to find an adjusted average of the range A10:A14:
=(SUM(A10:A14)-SMALL(A10:A14,1)-SMALL(A10:A14,2))/(COUNT(A10:A14)-2)
The SMALL function is used to determine the two lowest values in the range, and these are subtracted from the overall sum of the range. The resulting value is then divided by the COUNT of values in the range. Note, as well, that the COUNT value is decreased by 2 to compensate for the fact you are ignoring the two lowest values.
Another way to calculate the same average is to use an array formula. The following one does the trick:
=AVERAGE(IF(A10:A14>SMALL(A10:A14,2),A10:A14))
Since this is an array formula, you need to enter it by pressing Ctrl+Shift+Enter instead of just pressing Enter. This formula still relies on the use of the SMALL function, but it also uses the actual AVERAGE function to return a result. Since this is an array formula, it examines each of the values in the array (the range) and only considers them for use in the average if they are larger than the second smallest value in the array.
While the array formula is shorter than the longer regular formula, there is one caveat to keep in mind: The array formula will produce an undesired result if there is a two-way "tie" in the second-lowest value in the range, or a three-way tie in the lowest value. For instance, if the values being averaged are 3, 2, 10, 3, and 7, then the array formula will produce an average of 8.5. Why? Because only the values 10 and 7 are above the second-lowest value, and the average of those two is 8.5. If you use the longer formula, first presented above, then the average returned is 6.666667, which is the average of 10, 3, and 7.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (10697) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365. You can find a version of this tip for the older menu interface of Excel here: Excluding Values from Averaging.
Comprehensive VBA Guide Visual Basic for Applications (VBA) is the language used for writing macros in all Office programs. This complete guide shows both professionals and novices how to master VBA in order to customize the entire Office suite for their needs. Check out Mastering VBA for Office 2010 today!
Need to calculate a running average for the last twelve values in a constantly changing range of values? The formula ...
Discover MoreGrabbing an average of a range of cells is easy using Excel functions. If you want that average to ignore hidden cells ...
Discover MoreExcel is often used to analyze data collected over time. In doing the analysis, you may want to only look at data ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2024-02-22 03:43:35
Mike J
@Kiwerry
Oops! No, there isn't. I did read it but it obviously didn't really register properly - so my error.
Mind you, I still think it's strange that the tip should even offer, indeed end with, a solution and then explain that it doesn't work. Especially, as the tip states "Another way to calculate the same average is to use an array formula. The following one does the trick:"
2024-02-21 14:31:48
Kiwerry
@Mike J: Is there any difference between your comment and the caveat in the last paragraph of the tip?
2024-02-21 05:52:21
Mike J
I don't think the second formula in this tip works as intended.
Consider the 'athlete' had scores of 10,9,5,5,3.
The first formula correctly drops two lowest scores, and returns 8
The second formula drops all the scores equal to or less than the second lowest, and returns 9.5
2020-06-01 11:57:29
Peter Atherton
Dimitris
You might be better with two functions one to calculate the average and call the sum function.
Function sumNLarge(ByVal ref, n)
Dim i As Long, counter As Long
counter = ref.Count
For i = 1 To n + 1
sumNLarge = sumNLarge + WorksheetFunction.Large(ref, i)
Next i
End Function
Function nLARGEMEAN2(ByVal ref, n)
Dim counter As Long
counter = ref.Count - n + 1
nLARGEMEAN2 = sumNLarge(ref, n) / counter
End Function
Regarding excluding the top and bottom values in Allen's post better is:
=(SUM(A1:A14)-(SUM(MIN(A1:A14)+MAX(A1:A14))))/(COUNT(A1:A14)-2)
2020-06-01 09:45:56
Peter Atherton
Dimitris
Try this
=(SUM(A1:A20)-SUM(SMALL(A1:A20,{1,2,3,4,5,6,7,8,9})))/(COUNT(A1:A20)-9)
This UDF is easier to enter:
Function nLargeSUM(ByVal ref, n As Long)
Dim tmp As Double, i As Long, counter
counter = ref.Count - n
nLargeSUM = WorksheetFunction.Sum(ref)
For i = 1 To n
tmp = tmp + WorksheetFunction.Small(ref, i)
Next
nLargeSUM = (nLargeSUM - tmp) / counter
End Function
Just enter the range and the number to exclude e.g =nLARGESUM(A1:A20,9)
2020-06-01 09:38:49
Peter Atherton
Dimitris
Try this
=(SUM(A1:A20)-SUM(SMALL(A1:A20,{1,2,3,4,5,6,7,8,9})))/(COUNT(A1:A20)-9)
This UDF is easier to enter:
Function nLargeSUM(ByVal ref, n As Long)
Dim tmp As Double, i As Long, counter
counter = ref.Count - n
nLargeSUM = WorksheetFunction.Sum(ref)
For i = 1 To n
tmp = tmp + WorksheetFunction.Small(ref, i)
Next
nLargeSUM = (nLargeSUM - tmp) / counter
End Function
Just enter the range and the number to exclude e.g =nLARGESUM(A1:A20,9)
2020-05-31 02:35:42
Dimitris
In column A I have the numbers 1-2-3-4-5-6-7-8-9-10-11-12-13-14-15-16-17-18-19-20
if i want to exclude the 9 lowest values ( 1,2,3,4,5,6,7,8,9) what formula solve my problem;
Ih the formula =(SUM(A1:A20)-SMALL(A1:A20,1)-SMALL(A1:A20,2))/(COUNT(A1:A20)-2)
what i must shange;
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 © 2024 Sharon Parq Associates, Inc.
Comments