There may be times when you need to derive the smallest (or largest) value from a range, unless the smallest (or largest) value is zero. For instance, you might have a range of values such as {0, 3, 1, 4, 2}. In this case, the lowest value is zero, but the value you really want returned is 1.
There is no intrinsic function within Excel to return a value as stipulated here. However, you can create a formula that will do the trick. Assuming that the range of values you want to analyze are in C4:C8, the following formula will return the lowest non-zero value:
=IF(MIN(C4:C8)=0,SMALL(C4:C8,COUNTIF(C4:C8,"=0")+1),MIN(C4:C8))
This formula uses the MIN function to determine if the lowest value in the range is zero. If it is, then the SMALL function is used to derive the lowest value, excluding the zeros. (The COUNTIF function returns the number of zeros in the range, and therefore tells SMALL which item from the range to pick.)
A small change to the formula allows it to be used to return the largest non-zero number in a range:
=IF(MAX(C4:C8)=0,LARGE(C4:C8,COUNTIF(C4:C8,"=0")+1),MAX(C4:C8))
These formulas will work for any range, unless the range is made up entirely of zeros. In that instance, a #NUM! error is returned.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (2332) applies to Microsoft Excel 97, 2000, 2002, and 2003. You can find a version of this tip for the ribbon interface of Excel (Excel 2007 and later) here: Deriving High and Low Non-Zero Values.
Solve Real Business Problems Master business modeling and analysis techniques with Excel and transform data into bottom-line results. This hands-on, scenario-focused guide shows you how to use the latest Excel tools to integrate data from multiple tables. Check out Microsoft Excel 2013 Data Analysis and Business Modeling today!
Need to count the number of W (win) or L (loss) characters in a range of cells? You can develop a number of formulaic ...
Discover MoreUncovering the lowest value in a range is relatively easy; you can just use the MIN worksheet function. Discovering the ...
Discover MorePostal codes in Canada consist of six characters, separated into two groups. This tip explains the format and then shows ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2015-06-30 11:33:21
Willy Vanhaelen
@Micky,
The MAX function works fine as long as there is at least one positive value in the range but if none of the values are positive it will return zero which is not the goal.
2015-06-29 11:42:29
Michael (Micky) Avidan
@Willy,
I'm more than happy to get feedbacks (and I'm not ashamed for, SOMETIMES, be proven being wrong).
However:
1) I do hope you'll check, again, your remark regarding my suggestion for using the MAX function.
2) As for the MIN suggestion - I used Allen's examples and didn't noticed they are all positive.
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
2015-06-28 12:37:22
Willy Vanhaelen
@Micky
The formulas you propose don't work if the range contains also negative numbers.
These ones do:
{=MIN(IF(C4:C8<>0,C4:C8))}
{=MAX(IF(C4:C8<>0,C4:C8))}
2015-06-27 05:44:52
Michael (Micky) Avidan
For the MIN I would suggest an Array formula, such as:
=MIN(IF(C4:C8>0,C4:C8))
For the MAX value, just use the simplest formula:
=MAX(C4:C8)
--------------
Michael (Micky) Avidan
“Microsoft® Answers" - Wiki author & Forums Moderator
“Microsoft®” MVP – Excel (2009-2015)
ISRAEL
Got a version of Excel that uses the menu interface (Excel 97, Excel 2000, Excel 2002, or Excel 2003)? This site is for you! If you use a later version of Excel, visit our ExcelTips site focusing on the ribbon interface.
FREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
Copyright © 2021 Sharon Parq Associates, Inc.
Comments