+ Reply to Thread
Results 1 to 10 of 10

Ranking based on two columns

  1. #1
    Registered User
    Join Date
    06-14-2011
    Location
    Buffalo, NY
    MS-Off Ver
    Excel 2011
    Posts
    16

    Ranking based on two columns

    Hey all, trying to create a ranking column based on two separate columns.

    This is used for an archery league. There's the A score and B score. I need to rank each person first by the A score and then the B score. I can't just do it by sorting because each person will get a point total based on their ranking. If the person is 1st they get 4 points, 2nd through 5th they get 3 points, 6th through 10th they get 2 points, and 11th through 20th they get 1 point.

    Any help would be greatly appreciated. I've attached an example to this post.
    Attached Files Attached Files

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

    Re: Ranking based on two columns

    Try:

    =RANK(D5,$D$5:$D$15)+SUMPRODUCT(--($D$5:$D$15=$D5),--(E5<$E$5:$E$15))

    copied down
    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
    06-14-2011
    Location
    Buffalo, NY
    MS-Off Ver
    Excel 2011
    Posts
    16

    Re: Ranking based on two columns

    NBVC, you're the best! Thanks for the help, looks to be working like a charm.

  4. #4
    Registered User
    Join Date
    06-14-2011
    Location
    Buffalo, NY
    MS-Off Ver
    Excel 2011
    Posts
    16

    Re: Ranking based on two columns

    Ok so I need to do this for a C column too now. Rank on first column A, then column B, and then lastly column C. Any help?

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

    Re: Ranking based on two columns

    Using the same sample sheet provided and adding a C column in F5:F15, try:

    =RANK(D5,$D$5:$D$15)+SUMPRODUCT(--($D$5:$D$15=$D5),--(E5<$E$5:$E$15))+SUMPRODUCT(--($D$5:$D$15=$D5),--(E5=$E$5:$E$15),--(F5<$F$5:$F$15))

    copied down.

  6. #6
    Registered User
    Join Date
    06-14-2011
    Location
    Buffalo, NY
    MS-Off Ver
    Excel 2011
    Posts
    16

    Re: Ranking based on two columns

    NBVC, you sir are the best!

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

    Re: Ranking based on two columns

    Thank you! Glad it worked.

  8. #8
    Registered User
    Join Date
    07-26-2016
    Location
    Chennai
    MS-Off Ver
    2007
    Posts
    1

    Re: Ranking based on 4 or 5 columns

    I want to rank based on the following table. Can anyone help.Untitled.png

  9. #9
    Registered User
    Join Date
    02-19-2014
    Location
    United Kingdom
    MS-Off Ver
    Excel 2010
    Posts
    19

    Re: Ranking based on two columns

    Hi NBVC.

    I'm working on a problem for someone which is pretty similar to this but haven't been able to find reference to the use of -- in a formula. Would you mind telling me what that syntax actually means in Excel?

    Many thanks

    Dave

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

    Re: Ranking based on two columns

    It's called a double unary. It is used to coerce results of "TRUE" or "FALSE" to 1 or 0 so that further math can be done on those results...

+ 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