Ranking Values that meet criteria in another column

pliskers

Active Member
Joined
Sep 26, 2002
Messages
462
Office Version
  1. 2016
Platform
  1. Windows
I have a column that includes four separate category names, and another column containing values. I want to put within a single column formulas to separately rank the values that contain each of the four categories. In other words, four separate groups of rankings. I know it's a SUMPRODUCT combination formula, but can't get it quite right.

Some help, please?
 

Excel Facts

Format cells as time
Select range and press Ctrl+Shift+2 to format cells as time. (Shift 2 is the @ sign).
<br /><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;text-align: center;;">Category</td><td style="font-weight: bold;text-align: center;;">Value</td><td style="font-weight: bold;text-align: center;;">Category Rank</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: center;;">Cat 1</td><td style="text-align: center;;">2</td><td style="text-align: center;;">3</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: center;;">Cat 2</td><td style="text-align: center;;">4</td><td style="text-align: center;;">3</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: center;;">Cat 3</td><td style="text-align: center;;">3</td><td style="text-align: center;;">3</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: center;;">Cat 4</td><td style="text-align: center;;">9</td><td style="text-align: center;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: center;;">Cat 1</td><td style="text-align: center;;">5</td><td style="text-align: center;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: center;;">Cat 2</td><td style="text-align: center;;">6</td><td style="text-align: center;;">2</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: center;;">Cat 3</td><td style="text-align: center;;">8</td><td style="text-align: center;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: center;;">Cat 4</td><td style="text-align: center;;">1</td><td style="text-align: center;;">3</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: center;;">Cat 1</td><td style="text-align: center;;">3</td><td style="text-align: center;;">2</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: center;;">Cat 2</td><td style="text-align: center;;">11</td><td style="text-align: center;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: center;;">Cat 3</td><td style="text-align: center;;">4</td><td style="text-align: center;;">2</td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="text-align: center;;">Cat 4</td><td style="text-align: center;;">7</td><td style="text-align: center;;">2</td></tr></tbody></table><br /><br /><table cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C2</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">--(<font color="Red">$A$2:$A$13=A2</font>),--(<font color="Red">B$2:B$13>=B2</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
 
Upvote 0
I think you need a slight modification if ties are possible - see the green rows.

Excel Workbook
ABCD
1CategoryValuePeter_SSsAlphaFrog
2Cat 1233
3Cat 2433
4Cat 3333
5Cat 4911
6Cat 1312
7Cat 2622
8Cat 3811
9Cat 4133
10Cat 1312
11Cat 21111
12Cat 3422
13Cat 4722
Rank in Groups
 
Upvote 0
Good point Peter.

Here's yet one more alternative with a tie breaker.
<br /><table cellpadding="2.5px" rules="all" style=";background-color: #FFFFFF;border: 1px solid;border-collapse: collapse; border-color: #A6AAB6"><colgroup><col width="25px" style="background-color: #E0E0F0" /><col /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: #E0E0F0;text-align: center;color: #161120"><th></th><th>A</th><th>B</th><th>C</th><th>D</th><th>E</th></tr></thead><tbody><tr ><td style="color: #161120;text-align: center;">1</td><td style="font-weight: bold;text-align: center;;">Category</td><td style="font-weight: bold;text-align: center;;">Value</td><td style="font-weight: bold;text-align: center;;">Peter_SSs</td><td style="font-weight: bold;text-align: center;;">AlphaFrog</td><td style="font-weight: bold;text-align: center;;">AlphaFrog w/ Tie Breaker</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: center;background-color: #99CC00;;">Cat 1</td><td style="text-align: center;background-color: #99CC00;;">2</td><td style="text-align: center;background-color: #99CC00;;">3</td><td style="text-align: center;background-color: #99CC00;;">3</td><td style="text-align: center;background-color: #99CC00;;">3</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: center;;">Cat 2</td><td style="text-align: center;;">4</td><td style="text-align: center;;">3</td><td style="text-align: center;;">3</td><td style="text-align: center;;">3</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: center;;">Cat 3</td><td style="text-align: center;;">3</td><td style="text-align: center;;">3</td><td style="text-align: center;;">3</td><td style="text-align: center;;">3</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: center;;">Cat 4</td><td style="text-align: center;;">9</td><td style="text-align: center;;">1</td><td style="text-align: center;;">1</td><td style="text-align: center;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: center;background-color: #99CC00;;">Cat 1</td><td style="text-align: center;background-color: #99CC00;;">3</td><td style="text-align: center;background-color: #99CC00;;">1</td><td style="text-align: center;background-color: #99CC00;;">2</td><td style="text-align: center;background-color: #99CC00;;">2</td></tr><tr ><td style="color: #161120;text-align: center;">7</td><td style="text-align: center;;">Cat 2</td><td style="text-align: center;;">6</td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td></tr><tr ><td style="color: #161120;text-align: center;">8</td><td style="text-align: center;;">Cat 3</td><td style="text-align: center;;">8</td><td style="text-align: center;;">1</td><td style="text-align: center;;">1</td><td style="text-align: center;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">9</td><td style="text-align: center;;">Cat 4</td><td style="text-align: center;;">1</td><td style="text-align: center;;">3</td><td style="text-align: center;;">3</td><td style="text-align: center;;">3</td></tr><tr ><td style="color: #161120;text-align: center;">10</td><td style="text-align: center;background-color: #99CC00;;">Cat 1</td><td style="text-align: center;background-color: #99CC00;;">3</td><td style="text-align: center;background-color: #99CC00;;">1</td><td style="text-align: center;background-color: #99CC00;;">2</td><td style="text-align: center;background-color: #99CC00;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">11</td><td style="text-align: center;;">Cat 2</td><td style="text-align: center;;">11</td><td style="text-align: center;;">1</td><td style="text-align: center;;">1</td><td style="text-align: center;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">12</td><td style="text-align: center;;">Cat 3</td><td style="text-align: center;;">4</td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td></tr><tr ><td style="color: #161120;text-align: center;">13</td><td style="text-align: center;;">Cat 4</td><td style="text-align: center;;">7</td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td><td style="text-align: center;;">2</td></tr></tbody></table><br /><br /><table cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: #FFFFFF" ><tr><td style="padding:6px" ><b>Worksheet Formulas</b><table cellpadding="2.5px" width="100%" rules="all" style="border: 1px solid;text-align:center;background-color: #FFFFFF;border-collapse: collapse; border-color: #A6AAB6"><thead><tr style=" background-color: #E0E0F0;color: #161120"><th width="10px">Cell</th><th style="text-align:left;padding-left:5px;">Formula</th></tr></thead><tbody><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">C2</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">--(<font color="Red">$A$2:$A$13=A2</font>),--(<font color="Red">$B$2:$B$13>B2</font>)</font>)+1</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">D2</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">--(<font color="Red">$A$2:$A$13=A2</font>),--(<font color="Red">B$2:B$13>=B2</font>)</font>)</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">E2</th><td style="text-align:left">=SUMPRODUCT(<font color="Blue">--(<font color="Red">$A$2:$A$13=A2</font>),--(<font color="Red">(<font color="Green">B$2:B$13+ROW(<font color="Purple">B$2:B$13</font>)/1000</font>)>=(<font color="Green">B2+ROW(<font color="Purple">B2</font>)/1000</font>)</font>)</font>)</td></tr></tbody></table></td></tr></table><br />
 
Upvote 0

Forum statistics

Threads
1,224,884
Messages
6,181,555
Members
453,053
Latest member
Kiranm13

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