Aggregate functions

The following information applies to all aggregate functions other than COUNT(*) and COUNT_BIG(*).

AVG

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram           .-ALL------.
>>-AVG--(--+----------+--numeric-expression--)-----------------><
           '-DISTINCT-'
 

The AVG function returns the average of a set of numbers.

numeric-expression
The argument values must be any built-in numeric data type and their sum must be within the range of the data type of the result.

The data type of the result is the same as the data type of the argument values, except that:

For information on the values of p, s, ms, and mp, see Decimal arithmetic in SQL.

The function is applied to the set of values derived from the argument values by the elimination of null values. If DISTINCT is used, duplicate values are eliminated.

The result can be null. If set of values is empty, the result is the null value. Otherwise, the result is the average value of the set.

The order in which the values are aggregated is undefined, but every intermediate result must be within the range of the result data type.

If the type of the result is integer, the fractional part of the average is lost.

Examples

COUNT

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram               .-ALL------.
>>-COUNT--(--+-+----------+--expression-+--)-------------------><
             | '-DISTINCT-'             |
             '-*------------------------'
 

The COUNT function returns the number of rows or values in a set of rows or values.

expression
The argument values can be of any built-in data type other than a DataLink. If DISTINCT is used, the resulting expression must not have a length attribute greater than 2000 for a character column or 1000 for a graphic column, and must not be a LOB.

The result of the function is a large integer and it must be within the range of large integers. The result cannot be null. If the table is a distributed table, then the result is DECIMAL(15,0). For more information about distributed tables, see the DB2® Multisystem book.

The argument of COUNT(*) is a set of rows. The result is the number of rows in the set. A row that includes only null values is included in the count.

The argument of COUNT(expression) or COUNT(ALL expression) is a set of values. The function is applied to the set derived from the argument values by the elimination of null values. The result is the number of non-null values in the set including duplicates.

The argument of COUNT(DISTINCT expression) is a set of values. The function is applied to the set of values derived from the argument values by the elimination of null values and duplicate values. The result is the number of values in the set.

If a sort sequence other than *HEX is in effect when the statement that contains the COUNT(DISTINCT expression) is executed and the arguments are SBCS data, mixed data, or Unicode data, then the result is obtained by comparing weighted values for each value in the set. The weighted values are based on the sort sequence.

Examples

COUNT_BIG

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                   .-ALL------.
>>-COUNT_BIG--(--+-+----------+--expression-+--)---------------><
                 | '-DISTINCT-'             |
                 '-*------------------------'
 

The COUNT_BIG function returns the number of rows or values in a set of rows or values. It is similar to COUNT except that the result can be greater than the maximum value of integer.

expression
The argument values can be of any built-in data type other than a DataLink. If DISTINCT is used, the resulting expression must not have a length attribute greater than 2000 for a character column or 1000 for a graphic column, and must not be a LOB.

The result of the function is a decimal with precision 31 and scale 0. The result cannot be null.

The argument of COUNT_BIG(*) is a set of rows. The result is the number of rows in the set. A row that includes only null values is included in the count.

The argument of COUNT_BIG(expression) is a set of values. The function is applied to the set derived from the argument values by the elimination of null values. The result is the number of values in the set.

If a sort sequence other than *HEX is in effect when the statement that contains the COUNT_BIG(DISTINCT expression) is executed and the arguments are SBCS data, mixed data, or Unicode data, then the result is obtained by comparing weighted values for each value in the set. The weighted values are based on the sort sequence.

Examples

MAX

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram           .-ALL------.
>>-MAX--(--+----------+--expression--)-------------------------><
           '-DISTINCT-'
 

The MAX aggregate function returns the maximum value in a set of values in a group.

expression
The argument values can be any built-in data types except LOB and DataLink values.

The data type and length attribute of the result are the same as the data type and length attribute of the argument values. When the argument is a string, the result has the same CCSID as the argument.

If a sort sequence other than *HEX is in effect when the statement that contains the MAX function is executed and the arguments are SBCS data, mixed data, or Unicode data, then the result is obtained by comparing weighted values for each value in the set. The weighted values are based on the sort sequence.

The function is applied to the set of values derived from the argument values by the elimination of null values.

The result can be null. If the function is applied to the empty set, the result is a null value. Otherwise, the result is the maximum value in the set.

The specification of DISTINCT has no effect on the result and is not advised.

Examples

MIN

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram           .-ALL------.
>>-MIN--(--+----------+--expression--)-------------------------><
           '-DISTINCT-'
 

The MIN aggregate function returns the minimum value in a set of values in a group.

expression
The argument values can be any built-in data types except LOB and DataLink values.

The data type and length attribute of the result are the same as the data type and length attribute of the argument values. When the argument is a string, the result has the same CCSID as the argument. The result can be null.

If a sort sequence other than *HEX is in effect when the statement that contains the MIN function is executed and the arguments are SBCS data, mixed data, or Unicode data, then the result is obtained by comparing weighted values for each value in the set.

The function is applied to the set of values derived from the argument values by the elimination of null values.

If the function is applied to the empty set, the result is a null value. Otherwise, the result is the minimum value in the set.

The specification of DISTINCT has no effect on the result and is not advised.

Examples

STDDEV_POP or STDDEV

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                      .-ALL------.
>>-+-STDDEV_POP-+--(--+----------+--numeric-expression--)------><
   '-STDDEV-----'     '-DISTINCT-'
 

The STDDEV_POP function returns the biased standard deviation (/n) of a set of numbers. The formula used to calculate the biased standard deviation is:

STDDEV_POP = SQRT(VAR_POP)

where SQRT(VAR_POP) is the square root of the variance.

numeric-expression
The argument values must be any built-in numeric data type.

The data type of the result is double-precision floating point.

The function is applied to the set of values derived from the argument values by the elimination of null values. If DISTINCT is specified, duplicate values are eliminated.

The result can be null. If the function is applied to the empty set, the result is a null value. Otherwise, the result is the standard deviation of the values in the set.

The order in which the values are added is undefined, but every intermediate result must be within the range of the result data type.

Note

Syntax alternatives: STDEV_POP should be used for conformance to the SQL 1999 standard.

Example

STDDEV_SAMP

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                   .-ALL------.
>>-STDDEV_SAMP--(--+----------+--numeric-expression--)---------><
                   '-DISTINCT-'
 

The STDDEV_SAMP function returns the sample standard deviation (/n-1) of a set of numbers. The formula used to calculate the sample standard deviation is:

STDDEV_SAMP = SQRT(VAR_SAMP)

where SQRT(VAR_SAMP) is the square root of the sample variance.

numeric-expression
The argument values must be any built-in numeric data type.

The data type of the result is double-precision floating point.

The function is applied to the set of values derived from the argument values by the elimination of null values. If DISTINCT is specified, duplicate values are eliminated.

The result can be null. If the function is applied to the empty set or a set with only one row, the result is a null value. Otherwise, the result is the standard deviation of the values in the set.

The order in which the values are added is undefined, but every intermediate result must be within the range of the result data type.

Example

SUM

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram           .-ALL------.
>>-SUM--(--+----------+--numeric-expression--)-----------------><
           '-DISTINCT-'
 

The SUM function returns the sum of a set of numbers.

numeric-expression
The argument values must be any built-in numeric data type.

The data type of the result is the same as the data type of the argument values except that the result is:

For information on the values of p, s, and mp, see Decimal arithmetic in SQL.

The function is applied to the set of values derived from the argument values by the elimination of null values. If DISTINCT is specified, duplicate values are eliminated.

The result can be null. If the function is applied to the empty set, the result is a null value. Otherwise, the result is the sum of the values in the set.

The order in which the values are added is undefined, but every intermediate result must be within the range of the result data type.

Example

VAR_POP or VARIANCE or VAR

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                    .-ALL------.
>>-+-VAR_POP--+--(--+----------+--numeric-expression--)--------><
   +-VARIANCE-+     '-DISTINCT-'
   '-VAR------'
 

The VAR_POP function returns the biased variance (/n) of a set of numbers. The formula used to calculate the biased variance is:

   VAR_POP = SUM(X**2)/COUNT(X) - (SUM(X)/COUNT(X))**2
numeric-expression
The argument values must be any built-in numeric data type.

The data type of the result is double-precision floating point.

The function is applied to the set of values derived from the argument values by the elimination of null values. If DISTINCT is specified, duplicate values are eliminated.

The result can be null. If the function is applied to the empty set, the result is a null value. Otherwise, the result is the variance of the values in the set.

The order in which the values are added is undefined, but every intermediate result must be within the range of the result data type.

Note

Syntax alternatives: VAR_POP should be used for conformance to the SQL 1999 standard.

Example

VARIANCE_SAMP or VAR_SAMP

Click to skip syntax diagram
Read syntax diagramSkip visual syntax diagram                         .-ALL------.
>>-+-VAR_SAMP------+--(--+----------+--numeric-expression--)---><
   '-VARIANCE_SAMP-'     '-DISTINCT-'
 

The VAR_SAMP function returns the sample variance (/n-1) of a set of numbers. The formula used to calculate the sample variance is:

   VAR_SAMP = (SUM(X**2) - ((SUM(X)**2) / (COUNT(*)))) / (COUNT(*) - 1)
numeric-expression
The argument values must be any built-in numeric data type.

The data type of the result is double-precision floating point.

The function is applied to the set of values derived from the argument values by the elimination of null values. If DISTINCT is specified, duplicate values are eliminated.

The result can be null. If the function is applied to the empty set or a set with only one row, the result is a null value. Otherwise, the result is the variance of the values in the set.

The order in which the values are added is undefined, but every intermediate result must be within the range of the result data type.

Note

Syntax alternatives: VAR_SAMP should be used for conformance to the SQL 1999 standard.

Example



[ Top of Page | Previous Page | Next Page | Contents | Index ]