+ Reply to Thread
Results 1 to 8 of 8

Ranking of two criteria with unique ranking

  1. #1
    Registered User
    Join Date
    08-10-2016
    Location
    singapore
    MS-Off Ver
    Excel 2013
    Posts
    19

    Ranking of two criteria with unique ranking

    Hi Excel Guru,

    Need your help on the formula:

    Conditions:

    1. Likelihood should rank first then followed by impact
    2. Ranking should be unique (1,2,3,4,x) but not 1,2,2,2,

    Thanks.
    Attached Files Attached Files

  2. #2
    Registered User
    Join Date
    08-10-2016
    Location
    singapore
    MS-Off Ver
    Excel 2013
    Posts
    19

    Re: Ranking of two criteria with unique ranking

    Hi Excel Guru,

    Appreciate it if you could assist me on the above.

  3. #3
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,493

    Re: Ranking of two criteria with unique ranking

    In E4 copied down:

    =RANK.EQ($D4, $D$4:$D$27) + COUNTIFS($D$4:$D$27, $D4, $C$4:$C$27, ">" &$C4)+(COUNTIFS(C$4:C4,C4,D$4:D4,D4)/100)

    In F4 copied down:

    =RANK(E4,$E$4:$E$27,1)
    Attached Files Attached Files
    Ali


    Enthusiastic self-taught user of MS Excel who's always learning!
    Don't forget to say "thank you" in your thread to anyone who has offered you help.
    You can reward them by clicking on * Add Reputation below their user name on the left, if you wish.

    Forum Rules (updated August 2023): please read them here.

  4. #4
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,986

    Re: Ranking of two criteria with unique ranking

    I rows 5 to 8... likelihood and impact are identical. On what basis should the tie be broken? Just on the basis of the order of appearance???
    Glenn




    None of us get paid for helping you... we do this for fun. So DON'T FORGET to say "Thank You" to all who have freely given some of their time to help YOU.

    Temporary addition of accented to illustrate ongoing problem to the TT: L? fh?ile P?draig sona dhaoibh

  5. #5
    Registered User
    Join Date
    08-10-2016
    Location
    singapore
    MS-Off Ver
    Excel 2013
    Posts
    19

    Re: Ranking of two criteria with unique ranking

    Hi Glenn,

    It doesnt matter which one rank first, the sequence and condition is likelihood then followed by impact. THanks.

  6. #6
    Registered User
    Join Date
    08-10-2016
    Location
    singapore
    MS-Off Ver
    Excel 2013
    Posts
    19

    Re: Ranking of two criteria with unique ranking

    Hi Ali,

    Thanks for helping me on this.

  7. #7
    Forum Moderator AliGW's Avatar
    Join Date
    08-10-2013
    Location
    Retired in Ipswich, Suffolk, but grew up in Sawley, Derbyshire (England)
    MS-Off Ver
    MS 365 Subscription Insider Beta Channel v. 2404 (Windows 11 22H2 64-bit)
    Posts
    80,493

    Re: Ranking of two criteria with unique ranking

    If that takes care of your original question, please select Thread Tools from the menu link above and mark this thread as SOLVED.

    Also, if you have not already done so, you may not be aware that you can thank those who have helped you by clicking the small star icon located in the lower left corner of the post in which the help was given. By doing so you can add to the reputation(s) of all those who offered help.

  8. #8
    Forum Moderator Glenn Kennedy's Avatar
    Join Date
    07-08-2012
    Location
    Digital Nomad... occasionally based in Ireland.
    MS-Off Ver
    O365 (PC) V 2403
    Posts
    43,986

    Re: Ranking of two criteria with unique ranking

    Back again. Is Ali's solution correct??? Look at Rows 16 & 20. Should they REALLY be ranked 13th and 19th??

    I think that this is what you need:

    =IFERROR(RANK(C4,$C$4:$C$27)+SUMPRODUCT(--(C4=$C$4:$C$27),--(D4<$D$4:$D$27))-1+COUNTIFS($C$4:C4,C4,$D$4:D4,D4),"")
    Attached Files Attached Files
    Last edited by Glenn Kennedy; 01-23-2022 at 11:43 AM.

+ Reply to Thread

Thread Information

Users Browsing this Thread

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

Similar Threads

  1. [SOLVED] Unique list with criteria and ranking
    By TechRetard in forum Excel Formulas & Functions
    Replies: 7
    Last Post: 11-03-2020, 05:27 PM
  2. [SOLVED] RANKING with Multiple Criteria Without Skipping OR Sequential Ranking
    By e4excel in forum Excel Formulas & Functions
    Replies: 4
    Last Post: 01-24-2020, 01:08 AM
  3. [SOLVED] Unique Ranking with Multiple Criteria
    By Chocobo in forum Excel Formulas & Functions
    Replies: 5
    Last Post: 12-01-2018, 01:34 PM
  4. Unique Ranking with Multiple Criteria
    By dglenski in forum Excel General
    Replies: 7
    Last Post: 05-09-2017, 01:05 AM
  5. Unique Ranking with Multiple Criteria
    By dglenski in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 05-09-2017, 12:09 AM
  6. Ranking Question - Ranking based criteria but having forumla value issues
    By harp1983 in forum Excel Formulas & Functions
    Replies: 2
    Last Post: 02-09-2016, 07:03 AM
  7. Unique ranking by multiple criteria
    By reggie1000 in forum Excel Formulas & Functions
    Replies: 6
    Last Post: 04-21-2015, 08:03 AM

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