Ranking the difference between two columns

pliskers

Active Member
Joined
Sep 26, 2002
Messages
462
Office Version
  1. 2016
Platform
  1. Windows
If I have two columns of data (A & B, for argument's sake), is it possible to create a rank formula that will calculate the difference between the values in those columns within all the ranked rows, and rank them based on that calculated difference, without actually inserting a field to do the subtractions?

Thanks, I'm sure there is that someone out there knows!
 

Excel Facts

What did Pito Salas invent?
Pito Salas, working for Lotus, popularized what would become to be pivot tables. It was released as Lotus Improv in 1989.
Let me make sure I understand. You want a formula that will calculate the sum of these columns and rank those values? Is that correct?
 
Upvote 0
Not exactly. I want to do the equivalent of putting a formula in column C to subtract in each row the value in Column B from the value in Column A, and then I want to rank the values in column C - only I don't want to have to create the formulas in column C, I want the RANK formula to do that subtraction of "A minus B" for me. Is that clearer?
 
Upvote 0
You are going to either need to use VBA or have a helper column. The problem is that RANK would require being evaluated as an array formula, but it cannot be evaluated in that manner.
 
Upvote 0
Perhaps,

<b>Excel 2007</b><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;;">Field1</td><td style="font-weight: bold;;">Field2</td><td style="font-weight: bold;;">Helper</td><td style="font-weight: bold;;">RANK based on Helper</td><td style="font-weight: bold;;">RANK</td></tr><tr ><td style="color: #161120;text-align: center;">2</td><td style="text-align: right;;">10</td><td style="text-align: right;;">8</td><td style="text-align: right;;">2</td><td style="text-align: right;;">1</td><td style="text-align: right;;">1</td></tr><tr ><td style="color: #161120;text-align: center;">3</td><td style="text-align: right;;">8</td><td style="text-align: right;;">10</td><td style="text-align: right;;">-2</td><td style="text-align: right;;">5</td><td style="text-align: right;;">5</td></tr><tr ><td style="color: #161120;text-align: center;">4</td><td style="text-align: right;;">10</td><td style="text-align: right;;">10</td><td style="text-align: right;;">0</td><td style="text-align: right;;">4</td><td style="text-align: right;;">4</td></tr><tr ><td style="color: #161120;text-align: center;">5</td><td style="text-align: right;;">5</td><td style="text-align: right;;">4</td><td style="text-align: right;;">1</td><td style="text-align: right;;">3</td><td style="text-align: right;;">3</td></tr><tr ><td style="color: #161120;text-align: center;">6</td><td style="text-align: right;;">4</td><td style="text-align: right;;">2</td><td style="text-align: right;;">2</td><td style="text-align: right;;">1</td><td style="text-align: right;;">1</td></tr></tbody></table><p style="width:3.6em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid #A6AAB6;border-top:none;text-align: center;background-color: #E0E0F0;color: #161120">Sheet2</p><br /><br /><table width="85%" 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">=A2-B2</td></tr><tr><th width="10px" style=" background-color: #E0E0F0;color: #161120">D2</th><td style="text-align:left">=RANK(<font color="Blue">C2,$C$2:$C$6</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">A2-B2<(<font color="Green">$A$2:$A$6-$B$2:$B$6</font>)</font>)</font>)+1</td></tr></tbody></table></td></tr></table><br />
Copy down...
 
Upvote 0

Forum statistics

Threads
1,224,506
Messages
6,179,159
Members
452,892
Latest member
yadavagiri

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