+ Reply to Thread
Results 1 to 5 of 5

Need help with functions

  1. #1
    Registered User
    Join Date
    01-10-2007
    Posts
    5

    Need help with functions

    Hello!
    I'm working on a spreadsheet where I have two columns, ID# & Total:

    ID # Total
    0101 250
    0102 137
    0103 250
    0201 360
    0202 124
    0203 188

    There will be more elements, but what I want to do is to find the two largest totals in the 01xx range and add them together. I want to be able to do this with all ID prefixes (ex. 02xx, 03xx, etc).
    I've tried the DMAX function, but I couldn't find a way to do the second largest total. Please keep in mind that there may be duplicate values (as in my example table under 0101 & 0103).
    So basically, I need the sum of the two largest totals for each ID group.

    Thanks so much!
    Richard

  2. #2
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898
    Try

    =SUM(LARGE(IF(LEFT($A$1:$A$6,2)="01",$B$1:$B$6),1),LARGE(IF(LEFT($A$1:$A$6,2)="01",$B$1:$B$6),2))

    confirmed with CTRL+SHIFT+ENTER not just ENTER...

    where your range is A1:B6...adjust to suit.
    Where there is a will there are many ways.

    If you are happy with the results, please add to the contributor's reputation by clicking the reputation icon (star icon) below left corner

    Please also mark the thread as Solved once it is solved. Check the FAQ's to see how.

  3. #3
    Registered User
    Join Date
    01-10-2007
    Posts
    5
    Works great! Thanks!

  4. #4
    Registered User
    Join Date
    01-10-2007
    Posts
    5
    I have a problem now...if the ID # is four digits (1101 as opposed to 0101), how to you include the leading 0 in comparison?


    -----
    Update:
    Nevermind, I think I solved the problem.

    Thanks anyhow!
    Last edited by RDReavis; 01-10-2007 at 10:42 PM.

  5. #5
    Forum Expert NBVC's Avatar
    Join Date
    12-06-2006
    Location
    Mississauga, CANADA
    MS-Off Ver
    2003:2010
    Posts
    34,898
    Quote Originally Posted by RDReavis
    I have a problem now...if the ID # is four digits (1101 as opposed to 0101), how to you include the leading 0 in comparison?


    -----
    Update:
    Nevermind, I think I solved the problem.

    Thanks anyhow!
    ...btw, the previous formula I gave you could be shortened to (I thought about it last night after I went to bed):

    =SUM(LARGE(IF(LEFT($A$1:$A$6,2)="01",$B$1:$B$6),{1,2}))

    confirmed with CTRL+SHIFT+ENTER not just ENTER.

+ Reply to Thread

Thread Information

Users Browsing this Thread

There are currently 1 users browsing this thread. (0 members and 1 guests)

Bookmarks

Posting Permissions

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

Search Engine Friendly URLs by vBSEO 3.6.0 RC 1