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: Summing Only the Largest Portion of a Range.
Written by Allen Wyatt (last updated October 19, 2022)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, and Excel in Microsoft 365
Christian has a range of 18 cells that contain values. He would like to find the sum of the 12 largest values in that range and wonders how to accomplish the task.
There are several ways you can approach this problem. You could, for instance, filter the values so you only have the top twelve values, and then sum those. Other approaches involve using additional columns to store intermediate values, but I'll assume that you would prefer an approach that didn't use additional columns.
To start, let's assume that your range of 18 cells is A1:A18. You can use the LARGE function to find the largest values. For instance, using this formula would find the second-largest value in the range:
=LARGE(A1:A18,2)
It is the function's second parameter that specifies which largest value, in order, you want. Thus, you could find out the sum of the 12 largest values by using a formula such as this:
=LARGE(A1:A18,1)+LARGE(A1:A18,2)+LARGE(A1:A18,3)+LARGE(A1:A18,4) +LARGE(A1:A18,5)+LARGE(A1:A18,6)+LARGE(A1:A18,7)+LARGE(A1:A18,8) +LARGE(A1:A18,9)+LARGE(A1:A18,10)+LARGE(A1:A18,11)+LARGE(A1:A18,12)
There are shorter formulas you can use to accomplish the task, however. For instance, you could simply subtract the six smallest values from the sum of the range, in this manner:
=SUM(A1:A18)-SMALL(A1:A18,1)-SMALL(A1:A18,2)-SMALL(A1:A18,3) -SMALL(A1:A18,4)-SMALL(A1:A18,5)-SMALL(A1:A18,6)
You can also, if you desire, use the SUMIF function to do a comparison of the values and sum them only if the criterion you specify is met. For instance, consider these two formulas:
=SUMIF(A1:A18,">="&LARGE(A1:A18,12)) =SUMIF(A1:A18,">"&SMALL(A1:A18,6))
The first formula will sum all the values that are greater than or equal to the twelfth largest value in the range. The second is similar in effect; it sums all the values that are greater than the sixth smallest value.
These two formulas work great if there are no duplicate values at the "boundary" established. If, however, there are more than one value that qualify as the twelfth largest or the sixth smallest, then the formulas won't return the sums you expect. In the first formula the sum will be too large (since all of the duplicate values are added to the sum) and the second formula the sum will be too small (since all of the duplicate values are excluded from the sum).
The way around this is to either go back to one of the earlier formulas (the ones that don't use SUMIF), or modify the SUMIF formula so that it takes the possibility of duplicate values into account:
=SUMIF(A1:A18,">"&LARGE(A1:A18,12))+LARGE(A1:A18,12) *(12-COUNTIF(A1:A18,">"&LARGE(A1:A18,12)))
Perhaps the best formula to get the desired result places a twist on the earlier use of the LARGE function:
=SUM(LARGE(A1:A18,{1,2,3,4,5,6,7,8,9,10,11,12}))
This formula uses an array (the part within braces), but it is not an array formula. What it does is to use the array as the second parameter of the LARGE function, thus returning all twelve largest values. These are then summed, and a single value returned.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9422) 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: Summing Only the Largest Portion of a Range.
Program Successfully in Excel! John Walkenbach's name is synonymous with excellence in deciphering complex technical topics. With this comprehensive guide, "Mr. Spreadsheet" shows how to maximize your Excel experience using professional spreadsheet application development tips from his own personal bookshelf. Check out Excel 2013 Power Programming with VBA today!
Need to count the number of W (win) or L (loss) characters in a range of cells? You can develop a number of formulaic ...
Discover MoreDo you need to know how many precedents or dependents there are on a worksheet? You could count them manually, or you ...
Discover MoreSearching for a value using Excel's Find tool is easy; searching for that same value using a formula or a macro is more ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-10-20 09:58:04
J. Woolley
@Daniel
Here is a simpler version of your formula:
=SUMPRODUCT(LARGE(A1:A18,ROW(1:12)))
2022-10-20 03:25:05
Thomas Papavasiliou
A rather simple way:
If our data does not contain a column filled with the order of the data, create one.
Then sort the column we want to sum large or small values and use the SUM function on the desired range.
Once the sum is obtained, bring the data to the original order
2022-10-19 14:54:19
Alec W
Here's another way (there's always another way in Excel..)
I want to sum the 6 largest values in my range
=SUM(LARGE(G3:G10,SEQUENCE(6,,1)))
2019-03-04 12:15:34
Dave Bonin
One trick I've used in the past to get rid of ties was to add tiny value to the number based on (typically) the row number.
Let's assume cells A1:A100 contain a whole bunch of integers and that there may be duplicates.
Let's also assume that they are all between 1 and 80. This guarantees we'll have duplicates.
If we add a tiny -- but different -- amount to each value in A1:A100, then we no longer have exact duplicates.
We can use column B as a helper column. Let's put the following formula in B1:
= A1 + ROW( ) / 100000
And then copy that formula down B1:B100.
Column B now contains unique values. If cells A1:A4 contained the integers 2, 5, 2 and 15, then cells B1:B4 now contain the values 2.00001, 5.00002, 2.00003 and 15.00004.
When I sum up any batch of column B numbers, I round the values to the nearest integer, such as:
= ROUND( SUMIF( B1:B100, ">="&LARGE( B1:B100, 12 )), 0 )
As you can see, we no longer have to worry about duplicates.
If you're a little more clever (or fussy), you can use formulas like SUMPRODUCT() to eliminate the need to use a helper column.
2019-03-04 10:32:05
Daniel
The last summation is great for a small number of largest values. If you want 100 of the largest values, this could take some time to enter. In which case, there is a trick to make excel count using the construct:
ROW(INDIRECT("1:12"))
Substituting that in the array would make the formula into an array formula needing ctrl-shift-enter but there is another trick to use so that Excel can handle it using SUMPRODUCT. The resulting formula would be:
=SUMPRODUCT(LARGE(A1:A18,ROW(INDIRECT("1:12"))))
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