COUNT aggregate function

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

Note: The result of the function can be affected by the enablement of the large_aggregation configuration parameter.
Read syntax diagramSkip visual syntax diagramCOUNT(ALLDISTINCTexpression*)

The schema is SYSIBM.

expression

If ALL is implied or specified, an expression that returns a value of any built-in data type. If DISTINCT is specified, an expression that returns a value of any built-in data type except BLOB, CLOB, DBCLOB, or XML.

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

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(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 and duplicate values. The result is the number of different non-null values in the set.

The argument of COUNT(expression) or COUNT(ALL 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. The result is the number of non-null values in the set, including duplicates.

Examples

  • Example 1: Using the EMPLOYEE table, set the host variable FEMALE (int) to the number of rows where the value of the SEX column is 'F'.
       SELECT COUNT(*)
         INTO :FEMALE
         FROM EMPLOYEE
         WHERE SEX = 'F'

    Results in FEMALE being set to 13 when using the sample table.

  • Example 2: Using the EMPLOYEE table, set the host variable FEMALE_IN_DEPT (int) to the number of departments (WORKDEPT) that have at least one female as a member.
       SELECT COUNT(DISTINCT WORKDEPT)
         INTO :FEMALE_IN_DEPT
         FROM EMPLOYEE
         WHERE SEX = 'F'

    Results in FEMALE_IN_DEPT being set to 5 when using the sample table. (There is at least one female in departments A00, C01, D11, D21, and E11.)