2 column ranking

Tkeller

Board Regular
Joined
Jul 23, 2003
Messages
143
Office Version
  1. 365
Platform
  1. Windows
  2. Mobile
Hello,

I have 10 products that have 3 columns of numbers assigned to them. What I want to do is to rank them by the first column and if the values are the same in the first column, then I would move to the second column for the tie breaker, and in the rare case that the values are the same in both the first and the second columns, then I would move to the third column. I attach below, where I hardcoded what the final rankings should be based on this example. I am looking for a formula for the final rankings column

Product NumberAttribute 1Attribute 2Attribute 3Ranking 1Ranking 2Ranking 3FINAL RANKING
1​
30​
3​
5​
8​
7​
2​
8​
2​
45​
2​
4​
6​
9​
4​
6​
3​
23​
4​
3​
9​
5​
7​
9​
4​
55​
3​
6​
1​
7​
1​
1​
5​
50​
6​
2​
2​
3​
8​
4​
6​
45​
1​
2​
6​
10​
8​
7​
7​
50​
7​
4​
2​
1​
4​
2​
8​
50​
6​
5​
2​
3​
2​
3​
9​
12​
4​
1​
10​
5​
10​
10​
10​
46​
7​
4​
5​
1​
4​
5​
 

Excel Facts

Did you know Excel offers Filter by Selection?
Add the AutoFilter icon to the Quick Access Toolbar. Select a cell containing Apple, click AutoFilter, and you will get all rows with Apple
This should work, as long as none of the values in columns C:D don't exceed 2 digits:

Book1
ABCDEFGH
1Product NumberAttribute 1Attribute 2Attribute 3Final Ranking
2130358
3245246
4323439
5455361
6550624
7645127
8750742
9850653
109124110
111046745
Sheet2
Cell Formulas
RangeFormula
H2:H11H2=SUMPRODUCT(--(10000*B2+100*C2+D2<=10000*B$2:B$11+100*C$2:C$11+D$2:D$11))
 
Upvote 0
Thanks, that seems to work. But, I actually messed this up and want to rank them in ascending order. IIs there a way to change he formula. My sincere apologies

Product NumberAtrribute 1Attribute 2Attribute 3Ranking 1Ranking 2Ranking 3Final Ranking
1​
30​
3​
5​
3​
3​
8​
3​
2​
45​
2​
4​
4​
2​
5​
5​
3​
23​
4​
3​
2​
5​
4​
2​
4​
55​
3​
6​
10​
3​
10​
10​
5​
50​
6​
2​
7​
7​
2​
7​
6​
45​
1​
2​
4​
1​
2​
4​
7​
50​
7​
4​
7​
9​
5​
9​
8​
50​
6​
5​
7​
7​
8​
8​
9​
12​
4​
1​
1​
5​
1​
1​
10​
46​
7​
4​
6​
9​
5​
6​
 
Upvote 0
Easy enough, just change the sign in the formula:

=SUMPRODUCT(--(10000*B2+100*C2+D2>=10000*B$2:B$11+100*C$2:C$11+D$2:D$11))
 
Upvote 0
Solution
Thank you so much. I wish I was smart enough to figure that out.
 
Upvote 0

Forum statistics

Threads
1,215,035
Messages
6,122,785
Members
449,095
Latest member
m_smith_solihull

We've detected that you are using an adblocker.

We have a great community of people providing Excel help here, but the hosting costs are enormous. You can help keep this site running by allowing ads on MrExcel.com.
Allow Ads at MrExcel

Which adblocker are you using?

Disable AdBlock

Follow these easy steps to disable AdBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the icon in the browser’s toolbar.
2)Click on the "Pause on this site" option.
Go back

Disable AdBlock Plus

Follow these easy steps to disable AdBlock Plus

1)Click on the icon in the browser’s toolbar.
2)Click on the toggle to disable it for "mrexcel.com".
Go back

Disable uBlock Origin

Follow these easy steps to disable uBlock Origin

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back

Disable uBlock

Follow these easy steps to disable uBlock

1)Click on the icon in the browser’s toolbar.
2)Click on the "Power" button.
3)Click on the "Refresh" button.
Go back
Back
Top