Ranking only if criteria met

Misono

New Member
Joined
Dec 2, 2016
Messages
5
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?
 

FormR

MrExcel MVP
Joined
Aug 18, 2011
Messages
6,219
Office Version
365
Platform
Windows
Hi, something like this maybe..

<b>Excel 2013/2016</b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th><th>D</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style=";">Office</td><td style="text-align: right;;">50</td><td style="text-align: right;;">TRUE</td><td style="text-align: right;background-color: #FFFF00;;">3</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style=";">Warehouse</td><td style="text-align: right;;">280</td><td style="text-align: right;;">TRUE</td><td style=";"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style=";">Office</td><td style="text-align: right;;">90</td><td style="text-align: right;;">FALSE</td><td style=";"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">5</td><td style=";">Office</td><td style="text-align: right;;">108</td><td style="text-align: right;;">TRUE</td><td style="text-align: right;;">2</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">6</td><td style=";">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 ><td style="color: rgb(22,17,32);text-align: center;">7</td><td style=";">Warehouse</td><td style="text-align: right;;">1485</td><td style="text-align: right;;">TRUE</td><td style=";"></td></tr></tbody></table><p style="width:4.8em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><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: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><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: rgb(218,231,245);color: rgb(22,17,32)">D2</th><td style="text-align:left">=IF(<font color="Blue">AND(<font color="Red">A2="Office",C2</font>),COUNTIFS(<font color="Red">$A$2:$A$7,A2,$C$2:$C$7,TRUE,$B$2:$B$7,">"&B2</font>)+1,""</font>)</td></tr></tbody></table></td></tr></table><br />
 

DanteAmor

Well-known Member
Joined
Dec 3, 2018
Messages
8,878
Office Version
2007
Platform
Windows
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
 

FormR

MrExcel MVP
Joined
Aug 18, 2011
Messages
6,219
Office Version
365
Platform
Windows
Hi, you can also break ties in the same way using this normally entered formula.

<b>Excel 2013/2016</b><table cellpadding="2.5px" rules="all" style=";background-color: rgb(255,255,255);border: 1px solid;border-collapse: collapse; border-color: rgb(187,187,187)"><colgroup><col width="25px" style="background-color: rgb(218,231,245)" /><col /><col /><col /><col /></colgroup><thead><tr style=" background-color: rgb(218,231,245);text-align: center;color: rgb(22,17,32)"><th></th><th>A</th><th>B</th><th>C</th><th>D</th></tr></thead><tbody><tr ><td style="color: rgb(22,17,32);text-align: center;">2</td><td style=";">Office</td><td style="text-align: right;;">50</td><td style="text-align: right;;">TRUE</td><td style="text-align: right;color: #333333;background-color: #FFFF00;;">4</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">3</td><td style=";">Warehouse</td><td style="text-align: right;;">280</td><td style="text-align: right;;">TRUE</td><td style="color: #333333;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">4</td><td style=";">Office</td><td style="text-align: right;;">90</td><td style="text-align: right;;">FALSE</td><td style="color: #333333;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">5</td><td style=";">Office</td><td style="text-align: right;;">108</td><td style="text-align: right;;">TRUE</td><td style="text-align: right;color: #333333;;">2</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">6</td><td style=";">Office</td><td style="text-align: right;;">664</td><td style="text-align: right;;">TRUE</td><td style="text-align: right;color: #333333;;">1</td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">7</td><td style=";">Warehouse</td><td style="text-align: right;;">1485</td><td style="text-align: right;;">TRUE</td><td style="color: #333333;;"></td></tr><tr ><td style="color: rgb(22,17,32);text-align: center;">8</td><td style=";">Office</td><td style="text-align: right;;">108</td><td style="text-align: right;;">TRUE</td><td style="text-align: right;color: #333333;;">3</td></tr></tbody></table><p style="width:4.8em;font-weight:bold;margin:0;padding:0.2em 0.6em 0.2em 0.5em;border: 1px solid rgb(187,187,187);border-top:none;text-align: center;background-color: rgb(218,231,245);color: rgb(22,17,32)">Sheet1</p><br /><br /><table width="85%" cellpadding="2.5px" rules="all" style=";border: 2px solid black;border-collapse:collapse;padding: 0.4em;background-color: rgb(255,255,255)" ><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: rgb(255,255,255);border-collapse: collapse; border-color: rgb(187,187,187)"><thead><tr style=" background-color: rgb(218,231,245);color: rgb(22,17,32)"><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: rgb(218,231,245);color: rgb(22,17,32)">D2</th><td style="text-align:left">=IF(<font color="Blue">AND(<font color="Red">A2="Office",C2</font>),COUNTIFS(<font color="Red">$A$2:$A$8,A2,$C$2:$C$8,TRUE,$B$2:$B$8,">"&B2</font>)+COUNTIFS(<font color="Red">A$2:A2,A2,B$2:B2,B2,C$2:C2,TRUE</font>),""</font>)</td></tr></tbody></table></td></tr></table><br />
 

Forum statistics

Threads
1,082,243
Messages
5,363,972
Members
400,772
Latest member
solbebe

Some videos you may like

This Week's Hot Topics

  • populate from drop list with multiple tables
    Hi All, i have a drop list that displays data, what i want is when i select one of those from the list to populate text from different tables on...
  • Find list of words from sheet2 in sheet1 before a comma and extract text vba
    Hi Friends, Trying to find the solution on my task. But did not find suitable one to the need. Here is my query and sample file with details...
  • Dynamic Formula entry - VBA code sought
    Hello, really hope one of you experts can help with this - i've spent hours on this and getting no-where. .I have a set of data (more rows than...
  • Listbox Header
    Have a named range called "AccidentsHeader" Within my code I have: [CODE]Private Sub CommandButton1_Click() ListBox1.RowSource =...
  • Complex Heat Map using conditional formatting
    Good day excel world. I have a concern. Below link have a list of countries that carries each country unique data. [URL...
  • Conditional formatting
    Hi good morning, hope you can help me please, I have cells P4:P54 and if this cell is equal to 1 then i want row O to say "Fully Utilised" and to...
Top