MINIFS function
Returns the minimum of the values of cells in a range that meets multiple criteria in multiple ranges.
MINIFS(Func_Range; Range1; Criterion[; Range2; Criterion2][; … ; [Range127; Criterion127]])
Func_Range – required argument. A range of cells, a name of a named range or a label of a column or a row containing values for calculating the minimum.
Range1 – required argument. It is a range of cells, a name of a named range, or a label of a column or a row, to which the corresponding criterion is to be applied.
Criterion: A criterion is a single cell Reference, Number or Text. It is used in comparisons with cell contents.
A reference to an empty cell is interpreted as the numeric value 0.
A matching expression can be:
-
A number or logical value. A matching cell content equals the number or logical value.
-
A value beginning with a comparator (<, <=, =, >, >=, <>).
For =, if the value is empty it matches empty cells.
For <>, if the value is empty it matches non-empty cells.
For <>, if the value is not empty it matches any cell content except the value, including empty cells.
Note: "=0" does not match empty cells.
For = and <>, if the value is not empty and can not be interpreted as a number type or one of its subtypes and the property Search criteria = and <> must apply to whole cells is checked, comparison is against the entire cell contents, if unchecked, comparison is against any subpart of the field that matches the criteria. For = and <>, if the value is not empty and can not be interpreted as a Number type or one of its subtypes applies.
-
Other Text value. If the property Search criteria = and <> must apply to whole cells is true, the comparison is against the entire cell contents, if false, comparison is against any subpart of the field that matches the criteria. The expression can contain text, numbers, regular expressions or wildcards (if enabled in calculation options).
Range2 – Optional. Range2 and all the following mean the same as Range1.
Criterion2 – Optional. Criterion2 and all the following mean the same as Criterion.
Sökningen stöder jokertecken eller reguljära uttryck. Med reguljära uttryck aktiverat, kan du skriva "all.*", för att hitta första platsen för "all" följt av vilka bokstäver som helst (eller inga). Om du vill söka efter en text som också är ett reguljärt uttryck, anger du "\"-tecknet (bakstreck), eller omger texten med \Q...\E. Du kan stänga av eller aktivera automatisk evaluering av jokertecken och reguljära uttryck i inställningarna under .
Att använda funktioner där ett eller flera argument är sök-kritierier som representerar reguljära uttryck, ger ett första försök att konvertera söksträngen till ett tal. Till exempel, ".0" konverteras till 0.0 och så vidare. Om det lyckas så gör ett försök att matcha numeriskt istället för strängbaserat. Men om en locale används där decimalskiljetecknet inte är punkt kommer det att evalueras som reguljärt uttryck. För att tvinga en matchning som strängbaserat reguljärt uttryck istället för numeriskt som ett tal kan du använda något som inte kan tolkas som ett tal, till exmpel ".[0]", ".\0" eller "(?i).0".
Func_Range and Range1, Range2... must have the same size, otherwise the function returns err:502 - Invalid argument.
The logical relation between criteria can be defined as logical AND (conjunction). In other words, if and only if all given criteria are met, a value from the corresponding cell of the given Func_Range is taken into calculation.
The function can have up to 255 arguments, meaning that you can specify 127 criteria ranges and criteria for them.
If a cell contains TRUE, it is treated as 1, if a cell contains FALSE – as 0 (zero).
Consider the following table
|
A
|
B
|
C
|
1
|
Product Name
|
Sales
|
Revenue
|
2
|
pencil
|
20
|
65
|
3
|
pen
|
35
|
85
|
4
|
notebook
|
20
|
190
|
5
|
book
|
17
|
180
|
6
|
pencil-case
|
not
|
not
|
In all examples below, ranges for calculation contain the row #6, which is ignored because it contains text.
Simple usage
=MINIFS(B2:B6;B2:B6;"<35")
Calculates the minimum of values of the range B2:B6 that are lower than or equal to 20. Returns 17.
=MINIFS(C2:C6;B2:B6;">=20";C2:C6;">90")
Calculates the minimum of values of the range C2:C6 that are lower than 90 and correspond to cells of the B2:B6 range with values greater than or equal to 20. Returns 190.
Using regular expressions and nested functions
=MINIFS(C2:C6;B2:B6;">"&MIN(B2:B6);B2:B6;"<"&MAX(B2:B6))
Calculates the minimum of values of the range C2:C6 that correspond to all values of the range B2:B6 except its minimum and maximum. Returns 65.
=MINIFS(C2:C6;A2:A6;".*book";B2:B6;">"&MIN(B2:B6))
Calculates the minimum of values of the range C2:C6 that correspond to all cells of the A2:A6 range ending with "book" and to all cells of the B2:B6 range except its minimum. Returns 190.
Reference to a cell as a criterion
If you need to change a criterion easily, you may want to specify it in a separate cell and use a reference to this cell in the condition of the MINIFS function. For example, the above function can be rewritten as follows:
=MINIFS(C2:C6;A2:A6;".*"&E2;B2:B6;"<"&MAX(B2:B6))
If E2 = "book", the function returns 180, because the reference to the cell is substituted with its content.
Öppna fil med exempel:
This function is available since LibreOffice 5.2.
This function is not part of the Open Document Format for Office Applications (OpenDocument) Version 1.3. Part 4: Recalculated Formula (OpenFormula) Format standard. The name space is
COM.MICROSOFT.MINIFS