Results 1 to 7 of 7
  1. #1
    3 Star Lounger
    Join Date
    Jan 2001
    Location
    Las Vegas, Nevada, USA
    Posts
    334
    Thanks
    8
    Thanked 0 Times in 0 Posts

    Sum of N Largest Numbers in a List

    I would like to sum the largest 15 numbers in a list selected by using LARGE and criteria for a date range.

    I have attached a wks with sample data and some very simple formulas which work. I created a LARGE formula and manually selected a range to coincide with the date range I need to sum. Is there a way to incorporate the LARGE formula within the SUMIFS formula so that I don't need to manually select the date ranges to work within? My actual data table is over 100k rows.
    Attached Files Attached Files

  2. #2
    Super Moderator RetiredGeek's Avatar
    Join Date
    Mar 2004
    Location
    Manning, South Carolina
    Posts
    9,433
    Thanks
    371
    Thanked 1,456 Times in 1,325 Posts
    Arcturus,

    How about this:

    C3: =SUMIFS($B$11:$B$70,$A$11:$A$70,">"&DATE(2012,12,3 1),$A$11:$A$70,"<"&DATE(2014,1,1),$B$11:$B$70,">=" &$B3)
    C4: =SUMIFS($B$11:$B$70,$A$11:$A$70,">"&DATE(2013,12,3 1),$A$11:$A$70,"<"&DATE(2015,1,1),$B$11:$B$70,">=" &$B4)

    Articus.JPG

    HTH
    Last edited by RetiredGeek; 2014-12-21 at 23:00. Reason: Fixed date value changed 21 to 12!
    May the Forces of good computing be with you!

    RG

    PowerShell & VBA Rule!

    My Systems: Desktop Specs
    Laptop Specs

  3. #3
    Super Moderator RetiredGeek's Avatar
    Join Date
    Mar 2004
    Location
    Manning, South Carolina
    Posts
    9,433
    Thanks
    371
    Thanked 1,456 Times in 1,325 Posts
    Hey Y'all,

    A funny thing. Maud pointed out that I had a typo in the post above (it's fixed now) where I had Date(2012,21,31) vs Date(2012,12,31)!

    The interesting thing is that those formulas were copied out of a worksheet (as depicted) and they returned the correct values! I tested by changing the 21 to 12 and it still calculated the same answer!

    Well this worked because =Date(2012,21,31) will translate to 10/1/2013! the range being tested comes out to 10/1/2013 - 1/1/2014 and all the entries were dated 11/30/2013 so they fell within the range calculating the expected result.

    The reason I bothered to post about this is to reinforce the need to do EDGE testing, e.g. testing using values just outside & inside of the limits of the parameters to make sure the formulas are correct. This type of testing would have caught the error.

    Thanks again to Maud for catching the error and pointing it out to me in a PM. HTH
    Last edited by RetiredGeek; 2014-12-21 at 22:24.
    May the Forces of good computing be with you!

    RG

    PowerShell & VBA Rule!

    My Systems: Desktop Specs
    Laptop Specs

  4. The Following User Says Thank You to RetiredGeek For This Useful Post:

    Maudibe (2014-12-21)

  5. #4
    Gold Lounger Maudibe's Avatar
    Join Date
    Aug 2010
    Location
    Pa, USA
    Posts
    2,631
    Thanks
    115
    Thanked 645 Times in 589 Posts
    Is there a way to incorporate the LARGE formula within the SUMIFS formula
    Your more than welcome RG.

    A tweak to RG's formula that sums the values by year but finds the largest 15 values within the formula without having to reference a cell for the values (B3 and B4). The formulas also work if the dates are not in order.

    C3: =SUMIFS($B$11:$B$70,$A$11:$A$70,">"&DATE(2012,12,3 1),$A$11:$A$70,"<"&DATE(2014,1,1),$B$11:$B$70,">=" &LARGE(IF(YEAR(A11:A70)=2013,B11:B70,""),15))

    C4: =SUMIFS($B$11:$B$70,$A$11:$A$70,">"&DATE(2013,12,3 1),$A$11:$A$70,"<"&DATE(2015,1,1),$B$11:$B$70,">=" &LARGE(IF(YEAR(A11:A70)=2014,B11:B70,""),15))

    NOTE: These are array formulas and { } must be added using Ctrl-Shift-Enter

    Array1.png

    HTH,
    Maud
    Last edited by RetiredGeek; 2014-12-21 at 22:57. Reason: Added noparse tags!

  6. The Following User Says Thank You to Maudibe For This Useful Post:

    Arcturus16a (2014-12-22)

  7. #5
    Gold Lounger Maudibe's Avatar
    Join Date
    Aug 2010
    Location
    Pa, USA
    Posts
    2,631
    Thanks
    115
    Thanked 645 Times in 589 Posts
    Is it just my computer that in my post #4 and RG's Post #2, a space was inserted between the 3 and the 1:

    DATE(2012,12,3 1)
    Last edited by RetiredGeek; 2014-12-21 at 22:59.

  8. #6
    Super Moderator RetiredGeek's Avatar
    Join Date
    Mar 2004
    Location
    Manning, South Carolina
    Posts
    9,433
    Thanks
    371
    Thanked 1,456 Times in 1,325 Posts
    Maud,

    I try to remember to always include formulas in [noparse] [/noparse] tags to prevent that sort of thing but it doesn't always work!. HTH
    May the Forces of good computing be with you!

    RG

    PowerShell & VBA Rule!

    My Systems: Desktop Specs
    Laptop Specs

  9. The Following User Says Thank You to RetiredGeek For This Useful Post:

    Arcturus16a (2014-12-22)

  10. #7
    3 Star Lounger
    Join Date
    Jan 2001
    Location
    Las Vegas, Nevada, USA
    Posts
    334
    Thanks
    8
    Thanked 0 Times in 0 Posts
    Excel alerted me to the extra space in the formula so I knew right away how to fix it. Thanks to you Maudibe for the all-in-one solution.

    RG Thanks for explaing about the testing around the edges. I already try that a little but never knew a name for it.


    Now I can replace this formula in B3: =LARGE(B11:B40,15) with this B3: {=LARGE(IF(YEAR(A11:A70)=2013,B11:B70,""),15)}
    which allows me to select the entire range to evaluate without first having to determine the "2013" range manually.

    You guys are great! Thanks again.
    Last edited by Arcturus16a; 2014-12-22 at 14:27.

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •