Formula to find minimum of column with condition

Bolter LAC

Board Regular
Joined
Aug 13, 2008
Messages
140
Hello all,

I have a formula that records the minimum of a column in C7 with an exception to ignore a cell where an adjacent cell in Col B = "REGION". I also want it to ignore the cell in Col C which is adjacent to Col B ="OPEN". I have tried a number of variations but keep getting a 0.00 answer. In the attached example I want C7 to = 9.20 (lowest time other than Region/Open). I am sure it is simple but I can't get it. Any suggestions.

Thanks Bolter

16B9

<TABLE style="PADDING-RIGHT: 2pt; PADDING-LEFT: 2pt; FONT-SIZE: 11pt; FONT-FAMILY: Calibri,Arial; BACKGROUND-COLOR: #ffffff" cellSpacing=0 cellPadding=0 border=1><COLGROUP><COL style="FONT-WEIGHT: bold; WIDTH: 30px"><COL style="WIDTH: 35px"><COL style="WIDTH: 117px"><COL style="WIDTH: 64px"></COLGROUP><TBODY><TR style="FONT-WEIGHT: bold; FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center"><TD></TD><TD>A</TD><TD>B</TD><TD>C</TD></TR><TR style="HEIGHT: 23px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">7</TD><TD style="FONT-WEIGHT: bold; FONT-SIZE: 10pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-WEIGHT: bold; FONT-SIZE: 14pt; COLOR: #ff0000; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">PB</TD><TD style="FONT-WEIGHT: bold; FONT-SIZE: 14pt; COLOR: #ff0000; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">9.19</TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">8</TD><TD style="FONT-WEIGHT: bold; FONT-SIZE: 10pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-WEIGHT: bold; FONT-SIZE: 14pt; COLOR: #99cc00; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">CLUB REC</TD><TD style="FONT-WEIGHT: bold; FONT-SIZE: 14pt; COLOR: #99cc00; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">8.38</TD></TR><TR style="HEIGHT: 23px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">9</TD><TD style="FONT-WEIGHT: bold; FONT-SIZE: 10pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-WEIGHT: bold; FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #d8d8d8; TEXT-ALIGN: center">DATE</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">10</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">4/10/2008</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">9.50</TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">11</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">11/10/2008</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">9.48</TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">12</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">18/10/2008</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 23px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">13</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">24/10/2008</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">9.47</TD></TR><TR style="HEIGHT: 23px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">14</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">1/11/2008</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">9.46</TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">15</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">8/11/2008</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">16</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">14/11/2008</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">9.45</TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">17</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">22/11/2008</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 23px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">18</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">29/11/2008</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 23px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">19</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">6/12/2008</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">DNF</TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">20</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">12/12/2008</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">21</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">10/01/2009</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">22</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">17/01/2009</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">9.20</TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">23</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">OPEN</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">9.19</TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">24</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">31/01/2009</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">25</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">7/02/2009</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">9.44</TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">26</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">13/02/2009</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8"></TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">27</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">REGION</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">9.18</TD></TR><TR style="HEIGHT: 22px"><TD style="FONT-SIZE: 8pt; BACKGROUND-COLOR: #cacaca; TEXT-ALIGN: center">28</TD><TD style="BACKGROUND-COLOR: #33cccc"></TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8; TEXT-ALIGN: center">21/02/2009</TD><TD style="FONT-SIZE: 14pt; FONT-FAMILY: Arial; BACKGROUND-COLOR: #ece9d8"></TD></TR></TBODY></TABLE>
<TABLE style="FONT-SIZE: 10pt; BORDER-LEFT-COLOR: #00ff00; BORDER-BOTTOM-COLOR: #00ff00; COLOR: #000000; BORDER-TOP-STYLE: groove; BORDER-TOP-COLOR: #00ff00; FONT-FAMILY: Arial; BORDER-RIGHT-STYLE: groove; BORDER-LEFT-STYLE: groove; BACKGROUND-COLOR: #fffcf9; BORDER-RIGHT-COLOR: #00ff00; BORDER-BOTTOM-STYLE: groove"><TBODY><TR><TD>Spreadsheet Formulas</TD></TR><TR><TD><TABLE style="FONT-SIZE: 9pt; FONT-FAMILY: Arial" cellSpacing=0 cellPadding=2 border=1><TBODY><TR style="FONT-SIZE: 10pt; BACKGROUND-COLOR: #cacaca"><TD>Cell</TD><TD>Formula</TD></TR><TR><TD>C7</TD><TD>=MIN(IF(MATCH("REGION",B10:B31,0)>1,OFFSET(C10,,,
MATCH("REGION",B10:B31,0)-1),10^99)
,IF(MATCH("REGION",B10:B31,0)<22,
OFFSET(C10,MATCH("REGION",B10:B31,0),,22-MATCH("REGION",B10:B31,0)),10^99)
)

</TD></TR><TR><TD>C8</TD><TD>='Club Record'!D35</TD></TR><TR><TD>B10</TD><TD>='Program Dates'!B4</TD></TR><TR><TD>B11</TD><TD>='Program Dates'!B5</TD></TR><TR><TD>B12</TD><TD>='Program Dates'!B6</TD></TR><TR><TD>B13</TD><TD>='Program Dates'!B7</TD></TR><TR><TD>B14</TD><TD>='Program Dates'!B8</TD></TR><TR><TD>B15</TD><TD>='Program Dates'!B9</TD></TR><TR><TD>B16</TD><TD>='Program Dates'!B10</TD></TR><TR><TD>B17</TD><TD>='Program Dates'!B11</TD></TR><TR><TD>B18</TD><TD>='Program Dates'!B12</TD></TR><TR><TD>B19</TD><TD>='Program Dates'!B13</TD></TR><TR><TD>B20</TD><TD>='Program Dates'!B14</TD></TR><TR><TD>B21</TD><TD>='Program Dates'!B15</TD></TR><TR><TD>B22</TD><TD>='Program Dates'!B16</TD></TR><TR><TD>B23</TD><TD>='Program Dates'!B17</TD></TR><TR><TD>B24</TD><TD>='Program Dates'!B18</TD></TR><TR><TD>B25</TD><TD>='Program Dates'!B19</TD></TR><TR><TD>B26</TD><TD>='Program Dates'!B20</TD></TR><TR><TD>B27</TD><TD>='Program Dates'!B21</TD></TR><TR><TD>B28</TD><TD>='Program Dates'!B22</TD></TR></TBODY></TABLE></TD></TR></TBODY></TABLE>

Excel tables to the web >> http://www.excel-jeanie-html.de/index.php?f=1" target="_blank"> Excel Jeanie HTML 4
 

Excel Facts

Test for Multiple Conditions in IF?
Use AND(test, test, test, test) or OR(test, test, test, ...) as the logical_test argument of IF.

sanrv1f

MrExcel MVP
Joined
Jan 1, 2009
Messages
3,474
Office Version
  1. 2016
Platform
  1. Windows
You also need to exclude the blank cells in Column C

try this formula

=MIN(IF(B10:B100<>"Region",IF(B10:B100<>"Open",IF(C10:C100<>"",C10:C100,MAX(C10:C100)),MAX(C10:C100)),MAX(C10:C100)))
 
Upvote 0

Bolter LAC

Board Regular
Joined
Aug 13, 2008
Messages
140
Sanrv1f,

I have tried the formula and I get a #Value not recognised in the result which indicates the first part of the formula.

Bolter
 
Upvote 0

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,210
Try...

Control+shift+enter, not just enter...

=MIN(IF(1-ISNUMBER(MATCH(B10:B28,{"OPEN","REGION"},0)),C10:C28))
 
Upvote 0

Bolter LAC

Board Regular
Joined
Aug 13, 2008
Messages
140
Aladin,

Tried that and I am getting the result of 0 now rather than 0.00. Could it be that it is counting blank cells and coming up with the 0.


Bolters
 
Upvote 0

Aladin Akyurek

MrExcel MVP
Joined
Feb 14, 2002
Messages
85,210
Sal & Bolters...

I did not take the empty cells into account...

Re-try:

Control+shift+enter, not just enter...
Code:
=MIN(IF(1-ISNUMBER(MATCH(B10:B28,{"OPEN","REGION"},0)),
         IF(ISNUMBER(C10:C28),C10:C28)))
 
Upvote 0

Bolter LAC

Board Regular
Joined
Aug 13, 2008
Messages
140
Aladin,Sal

Sal, thanks for the input. Aladin big thanks for the solution. Very much appreciated once again.


Bolter
 
Upvote 0

Forum statistics

Threads
1,191,092
Messages
5,984,629
Members
439,896
Latest member
SquareCare

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
Top