The following information applies to all aggregate functions other than COUNT(*) and COUNT_BIG(*).
SELECT COUNT(DISTINCT JOB) FROM EMPLOYEE WHERE WORKDEPT = 'D01'
The AVG function returns the average of a set of numbers.
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.
SELECT AVG(PRSTAFF) INTO :AVERAGE FROM PROJECT WHERE DEPTNO = 'D11'Results in AVERAGE being set to 4.25 (that is, 17/4).
SELECT AVG(DISTINCT PRSTAFF) INTO :ANY_CALC FROM PROJECT WHERE DEPTNO = 'D11'Results in ANY_CALC being set to 4.66 (that is, 14/3).
.-ALL------. >>-COUNT--(--+-+----------+--expression-+--)------------------->< | '-DISTINCT-' | '-*------------------------'
The COUNT function returns the number of rows or values in a set of rows or values.
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.
SELECT COUNT(*) INTO :FEMALE FROM EMPLOYEE WHERE SEX = 'F'Results in FEMALE being set to 19.
SELECT COUNT(DISTINCT WORKDEPT) INTO :FEMALE_IN_DEPT FROM EMPLOYEE WHERE SEX='F'Results in FEMALE_IN_DEPT being set to 6. (There is at least one female in departments A00, C01, D11, D21, E11, and E21.)
.-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.
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.
CREATE FUNCTION RICK.COUNT(CHAR()) RETURNS DOUBLE SOURCE QSYS2.COUNT_BIG(CHAR()); SET CURRENT PATH RICK, SYSTEM PATH SELECT COUNT(DISTINCT WORKDEPT FROM EMPLOYEE;The empty parenthesis in the parameter list for the new function (RICK.COUNT) means that the input parameter for the new function is the same type as the input parameter for the function named in the SOURCE clause. The empty parenthesis in the parameter list in the SOURCE clause (COUNT_BIG) means that the length attribute of the CHAR parameter of the COUNT_BIG function is ignored when DB2 locates the COUNT_BIG function.
The MAX aggregate function returns the maximum value in a set of values in a group.
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.
SELECT MAX(SALARY) /12 INTO :MAX_SALARY FROM EMPLOYEEResults in MAX_SALARY being set to 4395.83.
SELECT MAX(PROJNAME) INTO :LAST_PROJ FROM PROJECTResults in LAST_PROJ being set to 'WELD LINE PLANNING '.
The MIN aggregate function returns the minimum value in a set of values in a group.
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.
SELECT MAX(COMM) - MIN(COMM) INTO :COMM_SPREAD FROM EMPLOYEE WHERE WORKDEPT = 'D11'Results in COMM_SPREAD being set to 1118 (that is, 2580 - 1462).
SELECT MIN(PRENDATE) INTO :FIRST_FINISHED FROM PROJECTResults in FIRST_FINISHED being set to '1982-09-15'.
.-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.
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.
Syntax alternatives: STDEV_POP should be used for conformance to the SQL 1999 standard.
SELECT STDDEV_POP(SALARY) INTO :DEV FROM EMPLOYEE WHERE WORKDEPT = 'A00';Results in DEV being set to approximately 9742.43.
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.
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.
SELECT STDDEV_SAMP(SALARY) INTO :DEV FROM EMPLOYEE WHERE WORKDEPT = 'A00';Results in DEV being set to approximately 10892.37.
The SUM function returns the sum of a set of numbers.
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.
SELECT SUM(BONUS) INTO :JOB_BONUS FROM EMPLOYEE WHERE JOB = 'CLERK'Results in JOB_BONUS being set to 4000.
.-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
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.
Syntax alternatives: VAR_POP should be used for conformance to the SQL 1999 standard.
SELECT VAR_POP(SALARY) INTO :VARNCE FROM EMPLOYEE WHERE WORKDEPT = 'A00';Results in VARNCE being set to approximately 94 915 000.
.-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)
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.
Syntax alternatives: VAR_SAMP should be used for conformance to the SQL 1999 standard.
SELECT VAR_SAMP(SALARY) INTO :VARNCE FROM EMPLOYEE WHERE WORKDEPT = 'A00';Results in VARNCE being set to approximately 1 186 437 500.