MAXIFS 函数
返回多个区域中满足多个条件的区域中的单元格的最大值.
MAXIFS(Func_Range; Range1; Criterion[; Range2; Criterion2][; … ; [Range127; Criterion127]])
函数范围 – 必填参数。它是一个单元格区域、命名区域的名称或列/行标签, 包含用于计算最大值的值。
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).
范围2 – 可选。「范围2」和以下所有内容的含义与「区域1」相同。
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 .
When using functions where one or more arguments are search criteria strings that represents a regular expression, the first attempt is to convert the string criteria to numbers. For example, ".0" will convert to 0.0 and so on. If successful, the match will not be a regular expression match but a numeric match. However, when switching to a locale where the decimal separator is not the dot makes the regular expression conversion work. To force the evaluation of the regular expression instead of a numeric expression, use some expression that can not be misread as numeric, such as ".[0]" or ".\0" or "(?i).0".
「Func_Range」和「区域1, 区域2...」必须具有相同的大小, 否则该函数返回错误: 502 - 无效的参数。
条件之间的逻辑关系可以定义为逻辑「与」(联接)。换句话说, 当且仅当所有给定条件均满足的情况下, 给定「Func_Range」函数范围的相应单元格中的值才会纳入计算。
该函数最多可以有 255 个参数, 这意味着您可以为它们指定 127 组条件范围和条件。
如果单元格内容为 TRUE,则视为 1, 如果内容为 FALSE – 则视为 0 (零)。
此功能是「用于 Office 应用程序的开放文档格式 (OpenDocument)」标准 1.2 版本的一部分。(ISO/IEC 26300:2-2015)
考虑下表
|
A
|
B
|
C
|
1
|
产品名称
|
销售
|
收入
|
2
|
铅笔
|
20
|
65
|
3
|
钢笔
|
35
|
85
|
4
|
笔记本
|
20
|
190
|
5
|
图书
|
17
|
180
|
6
|
笔袋
|
not
|
not
|
在下面的所有示例中, 计算范围都包含行 #6, 该行将被忽略, 因为它包含文本。
简单用法
「=MAXIFS(B2:B6;B2:B6;"<35")」
计算范围 B2:B6 中大于或等于 20 的最大值。返回 35。因为第五行不符合条件。
「=MAXIFS(C2:C6;B2:B6;">=20";C2:C6;"<90")」
计算范围 C2:C6 中小于 90、且在 B2:B6 范围内的对应单元格的值大于或等于 20 的值的最大值。返回 85, 因为第四行和第五行不满足至少一个条件。
使用正则表达式和嵌套函数
「=MAXIFS(C2:C6;B2:B6;">"&MIN(B2:B6);B2:B6;"<"&MAX(B2:B6))」
计算范围 C2:C6 中与范围 B2:B6 除最大值外的所有值相对应的数值的最大值。返回 190, 因为只有第四行满足条件。
「=MAXIFS(C2:C6;A2:A6;"pen.*";B2:B6;"<="&MAX(B2:B6))」
计算C2:C6 范围与 A2:A6 范围的所有以「笔」开头的单元格相对应,且与 B2:B6 区域的所有单元格 (最大值除外) 相对应的数值的最大值。返回 85, 因为只有第三行满足所有条件。
引用单元格作为条件
如果您需要轻松地更改一个条件, 可以考虑在单独的单元格中指定条件, 并在 MAXIFS 函数的条件中使用对该单元格的引用。例如, 可以按如下方式重写上述函数:
「=MAXIFS(C2:C6;A2:A6;E2&".*";B2:B6;"<"&MAX(B2:B6))」
如果 E2 = "pen", 函数将返回 65, 因为指向单元格的引用将替换为其内容。
打开文件示例:
This function is available since Collabora Office 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