Written by Allen Wyatt (last updated July 17, 2021)
This tip applies to Excel 97, 2000, 2002, and 2003
Mark is hoping to find the smallest non-zero value in a set of values. For example, if he has the values 0,0,3,0,6,8, he would want the value 3 (the smallest non-zero value) returned by a formula. Mark knows he can use the SMALL function with the second argument calculated by using a COUNTIF to count the number of zeroes in the range. However, he wants to use this inside of an array formula, and Excel can't handle COUNTIFs inside of array formulas.
Since Mark is only interested in array formulas (entered by pressing Ctrl+Shift+Enter), then there are a couple that could be used. The following array formula is worth looking at first:
=MIN(IF(A1:A5=0,MAX(A1:A5),A1:A5))
Assuming the values to be examined are in A1:A5, this formula puts together an array of non-zero values from that range. If the value in one of the cells is 0, then the MAX function kicks in, returning the largest value from the range. (This essentially kicks the value at that cell—originally 0—out of consideration as the smallest value.) If the value in one of the cells is not 0, then the actual value is returned. The MIN function then returns the lowest value from the array.
You can make the formula even shorter by turning it around in this manner:
=MIN(IF(A1:A5<>0,A1:A5))
Note that in this version, the value in each cell of the range is checked to see if it isn't 0. If it isn't, then the value is returned. If it is 0, then nothing is returned. Again, the MIN function is used to return the lowest value from the array.
ExcelTips is your source for cost-effective Microsoft Excel training. This tip (3260) 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: Returning the Smallest Non-Zero Value.
Program Successfully in Excel! This guide will provide you with all the information you need to automate any task in Excel and save time and effort. Learn how to extend Excel's functionality with VBA to create solutions not possible with the standard features. Includes latest information for Excel 2024 and Microsoft 365. Check out Mastering Excel VBA Programming today!
Want to figure out how far it is between two points on the globe? If you know the points by latitude and longitude, you ...
Discover MoreWant to sum the values in the same cell on a range of worksheets? It's not as easy as summing a range on the same ...
Discover MoreWhen you've got a column full of names, you may want to get a count of how many of those names are unique. You can make ...
Discover MoreFREE SERVICE: Get tips like this every week in ExcelTips, a free productivity newsletter. Enter your address and click "Subscribe."
2022-05-02 17:42:58
Greg Miller
Allen,
Thank you for this helpful tip. I came across while search for solutions to finding the three smallest non-zero values.
Since both SMALL and MIN ignore logical values, the solution works well. For example,
when A1:A5 is { 2; 0; 1; 14; 9 }
then A1:A5<>0
returns { 2; FALSE; 1; 14; 9 }
Since SMALL will ignore the logical value, SMALL(A1:A5<>0,{1;2;3}) will return 1; 2; 9. Since I am using EXCEL 365, I used SEQUENCE(3) instead of the hard-coded array.
I have commonly used the "double unary" of two negatives to coax numerical values out of logical values, but it was a pleasant discovery to realize that the trait of many EXCEL functions to ignore text, empty cells, and logical values can be put to good use.
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 © 2025 Sharon Parq Associates, Inc.
Comments