Written by Allen Wyatt (last updated October 11, 2025)
This tip applies to Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, 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.
So far, the suggestions are great if the values you are evaluating are relatively small. Christian's question dealt with only 18 values, but the approach needs to be modified if you are dealing with hundreds of values. In that case, the following formula would be more helpful:
=SUMPRODUCT(LARGE(A1:A200,ROW(1:12)))
If you are using Excel in Microsoft 365, you can rely on some of the newer worksheet functions, as in this formula:
=SUM(TAKE(SORT(A1:A200),-12))
The SORT function is used to provide a sorted array of the cells, then TAKE returns just the last 12 cells in that array, which are summed. If there might be potential blank cells in the original range, then the following will work:
=SUM(TAKE(TRIMRANGE(SORT(A1:A200)),-12))
The only addition is TRIMRANGE, which lops off any blanks in the sorted cell range.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (9422) applies to Microsoft Excel 2007, 2010, 2013, 2016, 2019, 2021, 2024, 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.
Dive Deep into Macros! Make Excel do things you thought were impossible, discover techniques you won't find anywhere else, and create powerful automated reports. Bill Jelen and Tracy Syrstad help you instantly visualize information to make it actionable. You’ll find step-by-step instructions, real-world case studies, and 50 workbooks packed with examples and solutions. Check out Microsoft Excel 2019 VBA and Macros today!
Do you need to figure out the rightmost value within a row in which not all cells may contain values? This tip provides a ...
Discover MoreYou can use some of Excel's worksheet functions across a range or worksheets, but not all of them. One that has problems ...
Discover MoreExcel is great at manipulating data, but sometimes it is difficult to figure out the best way to do the manipulation. ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
There are currently no comments for this tip. (Be the first to leave your comment—just use the simple form above!)
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 © 2025 Sharon Parq Associates, Inc.
Comments