From fa9b83defffcd6a10aacf8f97106cd17054855cc Mon Sep 17 00:00:00 2001 From: tagezi Date: Thu, 24 Sep 2015 08:39:22 +0300 Subject: tdf#85228 Added description of AGGREGATE function UPD: Changed in accordance with the comment of Regina (10:36 PM) UPD: Corrected separators in the syntax UPD: set up tags Change-Id: I05993ffec8af8dd1e997b3d2ae92ba0226b1bf28 Reviewed-on: https://gerrit.libreoffice.org/18821 Reviewed-by: Regina Henschel Reviewed-by: Olivier Hallot Tested-by: Olivier Hallot --- source/text/scalc/01/func_aggregate.xhp | 454 ++++++++++++++++++++++++++++++++ 1 file changed, 454 insertions(+) create mode 100644 source/text/scalc/01/func_aggregate.xhp (limited to 'source/text/scalc/01/func_aggregate.xhp') diff --git a/source/text/scalc/01/func_aggregate.xhp b/source/text/scalc/01/func_aggregate.xhp new file mode 100644 index 0000000000..4d8e26b82f --- /dev/null +++ b/source/text/scalc/01/func_aggregate.xhp @@ -0,0 +1,454 @@ + + + + + + + AGGREGATE function + /text/scalc/01/func_aggregate.xhp + + + + + + +
+ + + AGGREGATE function + + + +AGGREGATE function +This function returns an aggregate result of the calculations in the range. You can use different aggregate functions listed below. The Aggregate function enables you to omit hidden rows, errors, SUBTOTAL and other AGGREGATE function results in the calculation. +
+AGGREGATE function is applied to vertical ranges of data with activated AutoFilter. If AutoFilter is not activated, automatic recalculation of the function result does not work for newly hidden rows. It is not supposed to work with horizontal ranges, however it can be applied to them as well, but with limitations. In particular, the AGGREGATE function applied to a horizontal data range does not recognize hiding columns, however correctly omits errors and results of SUBTOTAL and other AGGREGATE functions embedded into the row. + +Syntax +AGGREGATE(Function; Option; Ref1 [; Ref2 [; …]]) +or +AGGREGATE(Function; Option; Array [; k]) +Function – obligatory argument. A function index or a reference to a cell with value from 1 to 19, in accordance with the following table. + + + + + Function index + + + Function applied + + + + + 1 + + + AVERAGE + + + + + 2 + + + COUNT + + + + + 3 + + + COUNTA + + + + + 4 + + + MAX + + + + + 5 + + + MIN + + + + + 6 + + + PRODUCT + + + + + 7 + + + STDEV.S + + + + + 8 + + + STDEV.P + + + + + 9 + + + SUM + + + + + 10 + + + VAR.S + + + + + 11 + + + VAR.P + + + + + 12 + + + MEDIAN + + + + + 13 + + + MODE.SNGL + + + + + 14 + + + LARGE + + + + + 15 + + + SMALL + + + + + 16 + + + PERCENTILE.INC + + + + + 17 + + + QUARTILE.INC + + + + + 18 + + + PERCENTILE.EXC + + + + + 19 + + + QUARTILE.EXC + + +
+ +Option – obligatory argument. An option index or reference to a cell with value from 0 to 7 determines what to ignore in the range for the function. + + + + + Option index + + + Option applied + + + + + 0 + + + Ignore only nested SUBTOTAL and AGGREGATE functions + + + + + 1 + + + Ignore only hidden rows, nested SUBTOTAL and AGGREGATE functions + + + + + 2 + + + Ignore only errors, nested SUBTOTAL and AGGREGATE functions + + + + + 3 + + + Ignore hidden rows, errors, nested SUBTOTAL and AGGREGATE functions + + + + + 4 + + + Ignore nothing + + + + + 5 + + + Ignore only hidden rows + + + + + 6 + + + Ignore only errors + + + + + 7 + + + Ignore only hidden rows and errors + + +
+ +Ref1 – obligatory argument. The first numeric argument (if the range is set by a list of values inside the function) or a reference to a cell that contains it. +Ref2,3,... – optional. A numeric argument or a reference to a cell (up to 253 arguments), for which you need the aggregate value. +Array – obligatory argument. The array can be specified by the boundaries of the range, the name of the named range or the column label. +For using column labels “Automatically find columns and rows labels” function needs to be enabled. +k – obligatory argument for the following functions: LARGE, SMALL, PERCENTILE.INC, QUARTILE.INC, PERCENTILE.EXC, QUARTILE.EXC. It is a numeric argument, which must correspond to the second argument of these functions. +If the second argument is necessary, but not specified, the function returns the error Err:511.
If the second argument specified not correctly, the function returns the error Err:502.
+ +Examples + + + + + + + A + + + B + + + C + + + + + 1 + + + ColumnOne + + + ColumnTwo + + + ColumnThree + + + + + 2 + + + 34 + + + 11 + + + 12 + + + + + 3 + + + 10 + + + 56 + + + 35 + + + + + 4 + + + #DIV/0! + + + 5 + + + 3 + + + + + 5 + + + 20 + + + 8 + + + 1 + + + + + 6 + + + 0 + + + 8 + + + 9 + + + + + 7 + + + #VALUE! + + + 20 + + + 21 + + + + + 8 + + + 5 + + + 7 + + + 8 + + + + + 9 + + + 14 + + + 0 + + + 5 + + +
+ +=AGGREGATE(4;1;A2:A9)
Returns maximum value for the range A2:A9 =34, whereas =MAX(A2:A9) returns the error Err:511.
+=AGGREGATE(9;5;A5:C5)
Returns sum for the range A5:C5 =29, even if the some of the columns are hidden.
+=AGGREGATE(9;5;B2:B9)
Returns sum of the column B =115. If any row is hidden, the function omit its value, for example if the 7th row is hidden, the function returns 95.
+If you need to apply the function with a 3-D range, this example shows how to do it. +=AGGREGATE(13;3;Sheet1.B2:B9:Sheet3.B2:B9)
The function returns mode of the values of second columns through sheets 1:3 (that have the same data) =8.
+You can use reference to a cell or a range for every argument in the formula. The following example shows how it works. Besides, it shows that you can use column labels to specify an array. +=AGGREGATE(E3;E5;'ColumnOne')
If E5 =13 and E7 =5, the function returns mode of the first column =10.
+ +
+AVERAGE, COUNT, COUNTA, MAX, MIN, PRODUCT, STDEV.S, STDEV.P, SUM, VAR.S, VAR.P, MEDIAN, MODE.SNGL, LARGE, SMALL, PERCENTILE.INC , QUARTILE.INC, PERCENTILE.EXC, QUARTILE.EXC +Automatically find column and row labels +
+ + +
\ No newline at end of file -- cgit