Ranking only if criteria met

Misono

New Member
Joined
Dec 2, 2016
Messages
9
I've been playing around trying to solve this, but not been able to structure my Countifs, and was wondering if someone could assist.

I have data within a table in Excel 2016, and need to rank these. Table looks like this:

Site Type Quantity Use Data In Main Report Rank

Office 50 TRUE
Warehouse 280 TRUE
Office 90 FALSE
Office 108 TRUE
Office 664 TRUE
Warehouse 1485 TRUE


I need the formula to rank the quantity column, but only if the Use Data column is TRUE and the site type is an Office. I'ev done this with COUNTIFS, but I'm either getting errors or when it's ranking it is including the quantity of the warehouses in assigning the rank, e.g office 664 is returning as "2" when it should be "1".

Any ideas?
 

Excel Facts

Excel Wisdom
Using a mouse in Excel is the work equivalent of wearing a lanyard when you first get to college
Hi, something like this maybe..


Excel 2013/2016
ABCD
2Office50TRUE3
3Warehouse280TRUE
4Office90FALSE
5Office108TRUE2
6Office664TRUE1
7Warehouse1485TRUE
Sheet1
Cell Formulas
RangeFormula
D2=IF(AND(A2="Office",C2),COUNTIFS($A$2:$A$7,A2,$C$2:$C$7,TRUE,$B$2:$B$7,">"&B2)+1,"")
 
Upvote 0
The following array formula can help you for a tie break.

<table border="1" cellspacing="0" style="font-family:Calibri,Arial; font-size:11pt; background-color:#ffffff; "> <colgroup><col style="font-weight:bold; width:30px; " /><col style="width:85.54px;" /><col style="width:76.99px;" /><col style="width:177.74px;" /><col style="width:67.49px;" /></colgroup><tr style="background-color:#cacaca; text-align:center; font-weight:bold; font-size:8pt; "><td > </td><td >A</td><td >B</td><td >C</td><td >D</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >1</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Site Type</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Quantity</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Use Data In Main Report</td><td style="background-color:#92d050; font-weight:bold; text-align:center; ">Rank</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >2</td><td >Office</td><td style="text-align:right; ">50</td><td style="text-align:right; ">TRUE</td><td style="text-align:right; ">4</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >3</td><td >Warehouse</td><td style="text-align:right; ">280</td><td style="text-align:right; ">TRUE</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >4</td><td >Office</td><td style="text-align:right; ">90</td><td style="text-align:right; ">FALSO</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >5</td><td >Office</td><td style="background-color:#dbeef3; text-align:right; ">108</td><td style="text-align:right; ">TRUE</td><td style="text-align:right; ">3</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >6</td><td >Office</td><td style="text-align:right; ">664</td><td style="text-align:right; ">TRUE</td><td style="text-align:right; ">1</td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >7</td><td >Warehouse</td><td style="text-align:right; ">1485</td><td style="text-align:right; ">TRUE</td><td > </td></tr><tr style="height:19px ;" ><td style="font-size:8pt; background-color:#cacaca; text-align:center; " >8</td><td >Office</td><td style="background-color:#dbeef3; text-align:right; ">108</td><td style="text-align:right; ">TRUE</td><td style="text-align:right; ">2</td></tr></table><br /><table style="font-family:Arial; font-size:10pt; border-style: groove ;border-color:#00ff00;background-color:#fffcf9; color:#000000; "><tr><td ><b></b></td></tr><tr><td ><table border = "1" cellspacing="0" cellpadding="2" style="font-family:Arial; font-size:9pt;"><tr style="background-color:#cacaca; font-size:10pt;"><td >Cell</td><td >Formula</td></tr><tr><td >D2</td><td >{=IF(AND(A2="Office",C2=TRUE),COUNT(IF(($A$2:$A$8="Office")*($C$2:$C$8=TRUE)*(B2+(ROW()/100)<$B$2:$B$8+ROW($B$2:$B$8)/100),1))+1,"")}</td></tr></table></td></tr></table>




Array formulas
Entered with Ctrl+Shift+Enter. If entered correctly, Excel will surround with curly braces {}.
Note: Do not try and enter the {} manually yourself
 
Upvote 0
Hi, you can also break ties in the same way using this normally entered formula.


Excel 2013/2016
ABCD
2Office50TRUE4
3Warehouse280TRUE
4Office90FALSE
5Office108TRUE2
6Office664TRUE1
7Warehouse1485TRUE
8Office108TRUE3
Sheet1
Cell Formulas
RangeFormula
D2=IF(AND(A2="Office",C2),COUNTIFS($A$2:$A$8,A2,$C$2:$C$8,TRUE,$B$2:$B$8,">"&B2)+COUNTIFS(A$2:A2,A2,B$2:B2,B2,C$2:C2,TRUE),"")
 
Upvote 0

Forum statistics

Threads
1,213,484
Messages
6,113,923
Members
448,533
Latest member
thietbibeboiwasaco

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