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: Summing Only the Largest Portion of a Range.

Summing Only the Largest Portion of a Range

by Allen Wyatt
(last updated November 2, 2013)

2

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, and 2013. You can find a version of this tip for the older menu interface of Excel here: Summing Only the Largest Portion of a Range.

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

Scanning and Fixing System Files

Is your system running a bit flakey at times? If you think the culprit might be a problem with some of your system files, ...

Discover More

Rounding Time

Need to round the time in a cell to a certain value? There are a couple of ways you can do this with a formula.

Discover More

Referencing Worksheet Tabs

Ever want to use the name of a worksheet tab within a cell? Here's how you can access that information using the CELL ...

Discover More

Excel Smarts for Beginners! Featuring the friendly and trusted For Dummies style, this popular guide shows beginners how to get up and running with Excel while also helping more experienced users get comfortable with the newest features. Check out Excel 2013 For Dummies today!

More ExcelTips (ribbon)

Simulating Alt+Enter in a Formula

You can use the Alt+Enter keyboard shortcut while entering information in order to force your data onto multiple lines in ...

Discover More

Adjusting Test Scores Proportionately

Teachers often grade on what is affectionately referred to as "the curve." The problem is, it can be a bit difficult to ...

Discover More

Determining If a Value is Out of Limits

Need to figure out if a value is outside of some arbitrary limit related to a different value? There are a number of ways ...

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 8 + 0?

2016-02-07 11:15:51

Bob Snow

Tricky problem troops. Hopefully someone will have a solution.
I am building a very comprehensive rota for crew onboard a cruise liner showing 1 for every half of work and a zero for every half hour of rest.
International law says that nobody is allowed to have less than ten hours of rest a day. That bit is easy to show. So is the amount of hours worked in one day.
However; the law states that of those ten hours six of them must be unbroken rest.
I am looking for a formula that will show either a Yes or No response or even red or green to say that enough rest has been given, or not. The problem is that there may be multiple sequences of zero's.
How do I add the longest sequence of zero's and ignore the other sequences?
Sorry it's a bit of a wordy question but I'm desperate to get a result!


2013-11-04 15:04:52

Bryan

If typing out the array in the last formula is a pain, you can instead use

=SUM(LARGE(A1:A18,ROW(A1:A12))

However, it is now an array formula (CTRL+SHIFT+ENTER). Also, you can now make the formula dynamic. Say your max number is listed in B1, you could use the (array) formula:

=SUM(LARGE(A1:A18,ROW(A1:INDEX(A:A,B1))))

There's no way to make the manually-entered array version dynamic.


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.