função MÁXIMO.SE.S
Devolve o máximo dos valores das células de um intervalo que cumpra critérios múltiplos em vários intervalos.
MÁXIMO.SE.S(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 maximum.
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.
The search supports wildcards or regular expressions. With regular expressions enabled, you can enter "all.*", for example to find the first location of "all" followed by any characters. If you want to search for a text that is also a regular expression, you must either precede every regular expression metacharacter or operator with a "\" character, or enclose the text into \Q...\E. You can switch the automatic evaluation of wildcards or regular expression on and off in .
Ao usar funções onde um ou mais argumentos são textos que representem uma expressão regular, a primeira tentativa é de converter o texto do critério em número. Por exemplo, ".0" se converterá em 0.0 e assim por diante. Se tiver sucesso, a verificação não será por expressão regular, mas por conversão numérica. Contudo, se mudar de configuração regional e o separador decimal não for o ponto, a expressão regular será utilizada. Para forçar a avaliação da expressão regular em vez de uma expressão numérica, utilize uma expressão que não possa ser confundida com um número como, por exemplo, .[0]" ou ".\0" or mesmo "(?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.
A função pode ter até 255 argumentos, significando que pode haver 127 intervalos de critérios e critérios correspondentes.
Se a célula contiver VERDADEIRO, será tratada como 1 e se contiver FALSO, será tratada como 0 (zero).
Considere a seguinte tabela
|
A
|
B
|
C
|
1
|
Nome do produto
|
Sales
|
Revenue
|
2
|
pencil
|
20
|
65
|
3
|
pen
|
35
|
85
|
4
|
caderno
|
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.
Utilização
=MÁXIMO.SE.S(B2:B6;B2:B6;"<35")
Calculates the maximum of values of the range B2:B6 that are greater than or equal to 20. Returns 35. The fifth row does not meet the criterion.
=MÁXIMO.SE.S(C2:C6;B2:B6;">=20";C2:C6;"<90")
Calculates the maximum 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 85, because the fourth and fifth rows do not meet at least one criterion.
Using regular expressions and nested functions
=MÁXIMO.SE.S(C2:C6;B2:B6;">"&MÍNIMO(B2:B6);B2:B6;"<"&MÁXIMO(B2:B6))
Calculates the maximum of values of the range C2:C6 that correspond to all values of the range B2:B6 except its minimum and maximum. Returns 190, because only the fourth row meet the criteria.
=MÁXIMO.SE.S(C2:C6;A2:A6;"pen.*";B2:B6;"<="&MÁXIMO(B2:B6))
Calculates the maximum of values of the range C2:C6 that correspond to all cells of the A2:A6 range starting with "pen" and to all cells of the B2:B6 range except its maximum. Returns 85, because only the third row meets all criteria.
Referência a uma célula como critério
Se precisar mudar o critério facilmente, você pode especificá-lo numa célula em separado e utilizar a referência a esta célula na condição da função MÁXIMO.SE.S. Por exemplo, a função acima pode ser reescrita como segue:
=MÁXIMO.SE.S(C2:C6;A2:A6;E2&".*";B2:B6;"<"&MÁXIMO(B2:B6))
If E2 = "pen", the function returns 65, because the reference to the cell is substituted with its content.
Abrir ficheiro com exemplo:
Esta função está disponível desde o 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.MAXIFS