How to use the MIN function
What is the MIN function?
The MIN function allows you to retrieve the smallest number in a cell range.
When is the MIN function useful in statistics?
The MIN function allows you to find the minimum or lowest value in a set of data points. This can be helpful when you want to identify outliers or extreme values in your dataset.
The range of a dataset is the difference between the maximum and minimum values. You can use the MIN function in combination with the MAX function to calculate the range which is a measure of the spread of the data.
Table of Contents
1. MIN Function Syntax
MIN(number1, [number2], ...)
2. MIN Function Arguments
Argument | Text |
number1 | You need at least one argument. Required. |
[number2] | Up to 254 arguments are possible. Optional. |
3. MIN Function Example
The image above shows the MIN function in cell D3, Cell range B3:B10 contains random text, numbers, and boolean values. Here is the data in cell range B3:B10:
182 |
36 |
A |
93 |
TRUE |
78 |
72 |
194 |
The MIN function ignores text and boolean values, however not errors.
Formula in cell E3:
Arguments can be constants, named ranges, cell references, and arrays.
MIN(B3:B10) becomes
MIN({182; 36; "A"; 93; TRUE; 78; 72; 194}) and returns 36. Number 36 is the smallest number in the data set.
4. MIN function ignore zero
The image above demonstrates a formula that extracts the smallest number in a given cell range also ignoring zeros. Cell range B2:B10 contains the following data:
Numbers |
182 |
36 |
0 |
93 |
0 |
78 |
72 |
194 |
Note that cells B5 and B7 contains 0 (zero), the formula below removes zeros from the calculation and replaces them with a blank that the MIN function ignores.
Array formula in cell D3:
The smallest value of this data set ignoring zeros: {182;36;0;93;0;78;72;194} is 36.
4.1 How to enter an array formula
- Copy the array formula above.
- Double press with the left mouse button on cell D3, a prompt appears.
- Paste it to cell D3, shortcut keys are CTRL + v.
- Press and hold CTRL + SHIFT keys simultaneously.
- Press Enter once.
- Release all keys.
The formula bar shows a beginning and ending curly bracket, don't enter these characters yourself.
They appear automatically if you followed the above steps.
4.2 Explaining formula
The Evaluate Formula tool is located on the Formulas tab in the Ribbon. It is a useful feature that allows you to step through and evaluate complex formulas to understand how the calculation is being performed and identify any errors or issues. The following steps shows these detailed evaluations for the formula above.
Step 1 - Find numbers not equal to zero
The less than and larger than signs combined evaluates to not equal to, the result is a boolean value TRUE or FALSE.
B3:B10<>0
becomes
{182; 36; 0; 93; 0; 78; 72; 194}<>0
and returns
{TRUE; TRUE; FALSE; TRUE; FALSE; TRUE; TRUE; TRUE}.
Step 2 - Replace TRUE with nothing
The IF function returns one value if the logical test is TRUE and another value if the logical test is FALSE.
IF(logical_test, [value_if_true], [value_if_false])
IF(B3:B10<>0, B3:B10, "")
becomes
IF({TRUE; TRUE; FALSE; TRUE; FALSE; TRUE; TRUE; TRUE}, B3:B10, "")
becomes
IF({TRUE; TRUE; FALSE; TRUE; FALSE; TRUE; TRUE; TRUE}, {182; 36; 0; 93; 0; 78; 72; 194}, "")
and returns {182; 36; ""; 93; ""; 78; 72; 194}.
Step 3 - Extract smallest number in array
MIN(IF(B3:B10<>0, B3:B10, ""))
becomes
MIN({182; 36; ""; 93; ""; 78; 72; 194})
and returns 36.
5. MIN function returns 0 (zero)
The image above shows a scenario where the MIN function returns zero and the data source contains no zeros, at least, that is what it looks like.
Formula in cell D3:
Cell B3:B10 contains blank cells but when we check the cell formatting dialog box, zeros have been hidden. See the image below.
Here is how to check if zeros are hidden.
- Select your data. Cell range B3:B10 in this example.
- Press CTRL + 1 to open the "Format Cells" dialog box.
- Select category "General".
- Press with the left mouse button on the "OK" button to apply changes.
Check the Excel options if this is not working for you. Here is how to do that in Excel 365:
- Press with the left mouse button on tab "File" on the ribbon.
- Press with left mouse button on "Options".
- Go to "Advanced", see the image below.
- Scroll down until you find "Show a zero in cells that have zero value". Make sure the checkbox is enabled.
- Press with the left mouse button on the "OK" button to apply changes.
Check the next section if this is also not a solution for you.
6. MIN function not working
This example demonstrates numbers stored as text may make the MIN function return 0 (zero). Numbers stored as text are left-aligned (default), a green arrow in the top left corner is an indication of numbers stored as text.
Formula in cell D3:
Here is how to convert numbers stored as text.
- Select the data, this is cell range B3:B10 in the example above.
- An "exclamation" sign appears.
- Press with left mouse button on the "Exclamation" sign to open a context menu.
- Press with left mouse button on "Convert to Number".
The MIN function is now working.
7. MIN function ignore errors
The formula in cell D3 extracts the smallest number in cell range B3:B10 ignoring error values. Cell range B2:B10 contains the following values:
Numbers |
182 |
36 |
#N/A |
93 |
#DIV/0! |
78 |
72 |
194 |
Note that cells B5 and B7 contain error values.
Array formula in cell D3:
The smallest number in this data set: {182;36;#N/A;93;#DIV/0!;78;72;194} is 36.
7.1 Explaining formula
The Evaluate Formula tool is located on the Formulas tab in the Ribbon. It is a useful feature that allows you to step through and evaluate complex formulas to understand how the calculation is being performed and identify any errors or issues. The following steps shows these detailed evaluations for the formula above.
Step 1 - Replace error values with nothing
The IFERROR function introduced in Excel 2007 lets you handle most errors in Excel formulas.
IFERROR(value, value_if_error)
IFERROR(B3:B10,"")
becomes
IFERROR({182; 36; #N/A; 93; #DIV/0!; 78; 72; 194})
and returns
{182; 36; ""; 93; ""; 78; 72; 194}
Step 2 - Extract smallest number
MIN(IFERROR(B3:B10,""))
becomes
MIN({182; 36; ""; 93; ""; 78; 72; 194})
and returns 36.
8. MIN function ignoring negative numbers
This example demonstrates an array formula in cell D3 that extracts the smallest number in cell range B3:B10 if equal to or larger than zero. Cell range B3:B10 contains these values:
Numbers |
182 |
36 |
-5 |
93 |
-11 |
78 |
72 |
194 |
The formula filters values larger than or equal to zero, then finds the smallest number.
Array formula in cell D3:
182, 36, -5, 93, -11, 78, 72, and 194 contains two negative values -5 and -11. IF we ignore the negative values the smallest number in the remaining group is 36 which is the value displayed in cell D3.
Explaining formula
The Evaluate Formula tool is located on the Formulas tab in the Ribbon. It is a useful feature that allows you to step through and evaluate complex formulas to understand how the calculation is being performed and identify any errors or issues. The following steps shows these detailed evaluations for the formula above.
Step 1 - Filter out negative numbers
The larger than and the equal sign lets you identify numbers larger than or equal to zero, the result is a boolean value TRUE or FALSE.
B3:B10>=0
becomes
{182; 36; -5; 93; -11; 78; 72; 194}>=0
and returns
{TRUE; TRUE; FALSE; TRUE; FALSE; TRUE; TRUE; TRUE}.
Step 2 - Replce TRUE with corresponding number
The IF function returns one value if the logical test is TRUE and another value if the logical test is FALSE.
IF(logical_test, [value_if_true], [value_if_false])
IF(B3:B10>=0, B3:B10, "")
becomes
IF({TRUE; TRUE; FALSE; TRUE; FALSE; TRUE; TRUE; TRUE}, {182; 36; -5; 93; -11; 78; 72; 194}, "")
and returns
{182; 36; ""; 93; ""; 78; 72; 194}.
Step 3 - Extract the smallest number
MIN(IF(B3:B10>=0,B3:B10,""))
becomes
MIN({182; 36; ""; 93; ""; 78; 72; 194})
and returns 36.
9. MIN function ignore text
The MIN function ignores text values out of the box, there is no need for you to do anything about it. The example above demonstrates two text values in cells B5 and B7, the formula in cell D3 extracts the smallest number in B3:B10 ignoring the text values. The values in cell range B3:B10 are:
Numbers |
182 |
36 |
A |
93 |
B |
78 |
72 |
194 |
Formula in cell D3:
The formula in cell D3 returns 36 which is the smallest number in B3:B10.
10. MIN function ignore #NA error
This example demonstrates a formula that ignores #N/A error values.Cell range B3:B10 contains these values:
Numbers |
182 |
36 |
#N/A |
93 |
#N/A |
78 |
72 |
194 |
Note that cells B5 and B7 contain #N/A errors.
Array formula in cell D3:
The formula ignores the #N/A errors and returns the smallest number in B3:B10 which is 36.
Explaining formula
The Evaluate Formula tool is located on the Formulas tab in the Ribbon. It is a useful feature that allows you to step through and evaluate complex formulas to understand how the calculation is being performed and identify any errors or issues. The following steps shows these detailed evaluations for the formula above.
Step 1 - Identify #N/A errors
The ISNA function returns TRUE if a given value is #N/A.
ISNA(value)
ISNA(B3:B10)
becomes
ISNA({182; 36; #N/A; 93; #N/A; 78; 72; 194})
and returns
{FALSE; FALSE; TRUE; FALSE; TRUE; FALSE; FALSE; FALSE}.
Step 2 - Replace TRUE with nothing
The IF function returns one value if the logical test is TRUE and another value if the logical test is FALSE.
IF(logical_test, [value_if_true], [value_if_false])
IF(ISNA(B3:B10), "", B3:B10)
becomes
IF({FALSE; FALSE; TRUE; FALSE; TRUE; FALSE; FALSE; FALSE}, "", B3:B10)
becomes
IF({FALSE; FALSE; TRUE; FALSE; TRUE; FALSE; FALSE; FALSE}, "", {182; 36; #N/A; 93; #N/A; 78; 72; 194})
and returns
{182; 36; ""; 93; ""; 78; 72; 194}.
Step 3 - Extract minimum number
MIN(IF(ISNA(B3:B10), "", B3:B10))
becomes
MIN({182; 36; ""; 93; ""; 78; 72; 194})
and returns 36.
'MIN' function examples
Array formulas allows you to do advanced calculations not possible with regular formulas.
This article demonstrates a macro that changes y-axis range programmatically, this can be useful if you are working with stock […]
This article describes an array formula that compares values from two different columns in two worksheets twice and returns a […]
Functions in 'Statistical' category
The MIN function function is one of 73 functions in the 'Statistical' category.
Excel function categories
Excel categories
One Response to “How to use the MIN function”
Leave a Reply
How to comment
How to add a formula to your comment
<code>Insert your formula here.</code>
Convert less than and larger than signs
Use html character entities instead of less than and larger than signs.
< becomes < and > becomes >
How to add VBA code to your comment
[vb 1="vbnet" language=","]
Put your VBA code here.
[/vb]
How to add a picture to your comment:
Upload picture to postimage.org or imgur
Paste image link to your comment.
Contact Oscar
You can contact me through this contact form
hola buen dia necesito sacar el minimo ejemplo de la columna (C5,D5,E5) ya utilice la formula =MIN(C5:E5) y no me funciona ya que en estas 3 columnas ahi filas que no tienen valor o el valor es 0 me podrias dar el informe o la formula para sacar este dato gracias..