SMALL problem is a big issue.

GAJITCS

Board Regular
Joined
Apr 21, 2015
Messages
66
Cells D4:I8 as listed.

XX
Text1Text2Text3Text4Text5Lowest
1.122.232.211.223.211.22
1.292.121.890.002.012.01
1.170.002.172.882.901.34

<tbody>
</tbody>









Cells D4:H4 are a named range of EX_C

Cells I6 contains the following formula:
{=SMALL(IF(EX_C<>"X",D7:H7,""),COUNTIF(D7:H7,"<=0")+1)}

The idea is that where cells D4:H4 are empty, this formula returns the lowest non zero value in the cells in the same row from columns D:H. It works, though it does give a #NUM error if all cells have a zero value, which is most unlikely.

Where D4:H4 might contain an X, this denotes that the cells in that column should be excluded from the workings of the formula, hence the table above does not show any of the values from columns D or E in the result of the formula in column I.

This works as long as at least two of the columns from D through H are not exlcuded with an X. If only one column is not excluded, the formula displays #NUM ! where it should show the last remaining value from the unchecked column.

XXXX
Text1Text2Text3Text4Text5Lowest
1.122.232.211.223.213.21
1.292.121.890.002.012.01
1.170.002.172.882.902.90

<tbody>
</tbody>









If there anything I can do within the formula to correct this or do i need to inject another column of trash data and hide it (yuk).

Many thanks.
 

Excel Facts

Which Excel functions can ignore hidden rows?
The SUBTOTAL and AGGREGATE functions ignore hidden rows. AGGREGATE can also exclude error cells and more.
Try:
Excel Workbook
DEFGHI
4XxXx
5Text1Text2Text3Text4Text5Lowest
61.122.232.211.223.213.21
71.292.121.8902.012.01
81.1702.172.882.92.9
Sheet
 
Upvote 0
Try:

DEFGHI
4XxXx
5Text1Text2Text3Text4Text5Lowest
61.122.232.211.223.213.21
71.292.121.8902.012.01
81.1702.172.882.92.9

<colgroup><col style="width:30px; "><col style="width:64px;"><col style="width:64px;"><col style="width:64px;"><col style="width:64px;"><col style="width:64px;"><col style="width:64px;"></colgroup><tbody>
</tbody>

Spreadsheet Formulas
CellFormula
I6{=SMALL(IF($D$4:$H$4<>"x",IF($D6:$H6<>0,$D6:$H6)),1)}

<tbody>
</tbody>
Formula Array:
Produce enclosing
{ } by entering
formula with CTRL+SHIFT+ENTER!

<tbody>
</tbody>


Excel tables to the web >> Excel Jeanie HTML 4

Thank you AhoyNC.

This is a step closer. It cures the problem unless the unchecked column has a cell value of Zero. So if G4 was empty and H4 had the X, I7 will read #NUM !

Can I trap this with an ISError check and return a "" result in a more elegant way than:

=IF(ISERROR(SMALL(IF(Ex_C<>"X",IF(D6:H6<>0,D6:H6)),1)),"",SMALL(IF(Ex_C<>"X",IF(D6:H6<>0,D6:H6)),1))
 
Upvote 0
If you have later ver. of Excel (can't remember if it was 2007 or 2010 when IFERROR was added) you could use.

Code:
[TABLE="width: 483"]
<colgroup><col width="483"></colgroup><tbody>[TR]
   [TD="width: 483"]IFERROR(SMALL(IF($D$4:$H$4<>"x",IF($D6:$H6<>0,$D6:$H6)),1),"")[/TD]
 [/TR]
</tbody>[/TABLE]
 
Upvote 0
If you have later ver. of Excel (can't remember if it was 2007 or 2010 when IFERROR was added) you could use.

Code:
[TABLE="width: 483"]
<tbody>[TR]
[TD="width: 483"]IFERROR(SMALL(IF($D$4:$H$4<>"x",IF($D6:$H6<>0,$D6:$H6)),1),"")[/TD]
[/TR]
</tbody>[/TABLE]

Spot on.

Many thanks.
 
Upvote 0

Forum statistics

Threads
1,214,919
Messages
6,122,260
Members
449,075
Latest member
staticfluids

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