How to use the MIN function
The MIN function allows you to retrieve the smallest number in a cell range.
The formula in cell D3 extracts the smallest number in cell range B3:B10, see picture above.
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. 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.
4. MIN function ignore zero
The image above demonstartes a formula that extracts the smallest number in a given cell range ignoring zeros.
Array formula in cell D3:
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
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.
Array formula in cell D3:
7.1 Explaining formula
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
The array formula in cell D3 extracts the smallest number in cell range B3:B10 if equal to or larger than zero.
Array formula in cell D3:
Explaining formula
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.
Formula in cell D3:
10. MIN function ignore #NA error
Array formula in cell D3:
Explaining formula
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
The following 56 articles have formulas containing the MIN function.
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 […]
The array formula in cell B3 creates a list of dates based on the date ranges displayed in D3:E7, it […]
This post demonstrates a formula in cell D16 that counts overlapping dates across multiple date ranges. The date ranges are […]
In the previous post I explained how to count overlapping dates comparing a single date range against multiple date ranges. […]
The following array formula extracts duplicate values sorted from A to Z from cell range B3:B21. Excel array formula in […]
The image above shows an array formula in cell B8 that extracts unique distinct values sorted alphabetically from cell range […]
The array formula in cell B3 extracts overlapping dates based on the date ranges in column D and E. Array […]
The following array formula in cell B11 extracts duplicates from cell range B3:E8, only one instance of each duplicate is […]
The array formula in cell D3 returns the the length of longest consecutive sequence of a value in column A. Cell […]
The formula in cell B10 extracts unique distinct values from cell range B2:d4 that contains the string specified in cell […]
This is an answer to a question in this blog post: Extract a unique distinct list sorted from A-Z from […]
Question: I have cell values spanning over several columns and I want to create a unique list from that range. […]
The array formula in cell B10 extracts unique distinct values from cell range B2:D4 that begins with a given condition […]
The image above shows an array formula in cell B12 that extracts values shared by cell range B2:D4 (One) and […]
The array formula in cell B10 extracts duplicate values from cell range B2:D4 if they begin with the condition specified […]
The array formula in cell B10 extracts duplicate values from cell range B2:D4 if they contain string specified in cell […]
EEK asks: I am looking for the same formula on this page, but targeting a range of MxN (spanning multiple […]
Unique values are values occurring only once in cell range. This is what I am going to demonstrate in this blog […]
The formulas above extracts values that exists only in one or the other cell range, if you are looking for […]
This article describes how to filter records based on the maximum value of a specific item. There are names in […]
Table of Contents Find closest value How to enter an array formula Find closest value - Excel 365 Find closest […]
This article explains how to create a formula that returns the earliest (smallest) and the latest (largest) date of overlapping […]
The formula in cell B8, shown above, extracts dates not included in the specified date ranges, in other words, dates […]
Bill Truax asks: Hello Oscar, I am building a spreadsheet for tracking calls for my local fire department. I have a […]
The image above shows a formula in cell D3 that extracts the latest date in cell range B3:B15. =MAX(B3:B15) The MAX […]
Table of Contents Extract largest duplicate number Extract largest duplicate number - Excel 365 Extract smallest duplicate number Extract smallest […]
Excelxor is such a great website for inspiration, I am really impressed by this post Which numbers add up to […]
This article explains how to calculate the largest and smallest number based on a condition which is if the number […]
This post Find the longest/smallest consecutive sequence of a value has a few really big array formulas. Today I would like to […]
Problem: Find the smallest value in a list but it has to be bigger than 45? Answer: MINIFS function [Excel […]
This time I want to demonstrate an alternative way to identify a major trend in the stock market. The previous post […]
This article demonstrates how to extract the smallest number larger than a condition and the largest number smaller than a […]
This article demonstrates how to change chart series while hovering with mouse cursor over a series name. The image above […]
Question: How to extract email addresses from this sheet? (See pic below) Answer: It depends on how the emails are […]
Column B contains numbers, the formula in cell D3 calculates the smallest value excluding zeros. Note that all numbers are […]
Table of Contents How to highlight duplicate values Highlight the smallest duplicate number 1. How to highlight duplicate values The […]
The image above shows rows highlighted based on value in column C being the largest or smallest in that particular […]
This article demonstrates formulas that will return the largest and smallest numbers, the corresponding column headers, the cell addresses, and […]
The worksheet above shows four different time ranges in column B and C, the formula in cell C10 counts the […]
I will in this article demonstrate how to use the VLOOKUP function with multiple conditions. The function was not built […]
Michael asks: I need to identify the duplicates based on the Columns D:H and put in Column C a small […]
The image above demonstrates an array formula in cell E4 that searches for the closest date in column A to the […]
Formula in B14: =INDEX(D3:D6, SUMPRODUCT(--(C10=B3:B6), --(C11=C3:C6), ROW(D3:D6)-MIN(ROW(D3:D6))+1)) Alternative array formula #1 in B15: =INDEX(D3:D6, MATCH(C10&"-"&C11, B3:B6&"-"&C3:C6, 0)) Alternative array formula […]
This article demonstrates a formula that searches a cell (partial match) based on values in a table and returns a […]
This article explains how to repeat specific values based on a table, the table contains the items to be repeated […]
This article demonstrates a few different formulas that extract values from the table column header names and the right-most column. […]
This article demonstrates ways to sort numbers from smallest to largest ignoring duplicate numbers. Table of Contents SMALL function with […]
The formula in cell B8 extracts a list sorted based on frequency. Array formula in B8: =TEXTJOIN("", TRUE, IF(MIN(IF((MAX(IF(COUNTIF($B$7:B7, $B$2:$E$5)=0, […]
Question: How do I sort a range alphabetically using excel array formula? Answer: Cell range $B$2:$E$5 contains text values in random […]
This article demonstrates how to sort a data set by multipe columns using the SORTBY function, Ecel Table and Excel […]
This article demonstrates two ways to calculate expenses evenly split across multiple people. The first one is a formula solution, […]
This is follow up post to: Tracking a stock portfolio in excel (auto update) In this post we are going to […]
Question: How do I create a unique distinct list from a column sorted A to Z using array formula? Array […]
This article demonstrates formulas that calculate the number of overlapping ranges for all ranges, finds the most overlapped range and […]
Functions in 'Statistical' category
The MIN function function is one of many functions in the 'Statistical' category.
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