9.3 Statistical Aggregate Functions

9.3.1 CORR()

Available inDSQL, PSQL

Result typeDOUBLE PRECISION

Syntax

  1. CORR ( <expr1>, <expr2> )

Table 9.3.1.1 CORR Function Parameters

ParameterDescription

exprN

Numeric expression. It may contain a table column, a constant, a variable, an expression, a non-aggregate function or a UDF. Aggregate functions are not allowed as expressions.

The CORR function return the correlation coefficient for a pair of numerical expressions.

The function CORR(<expr1>, <expr2>) is equivalent to

  1. COVAR_POP(<expr1>, <expr2>) / (STDDEV_POP(<expr2>) * STDDEV_POP(<expr1>))

This is also known as the Pearson correlation coefficient.

In a statistical sense, correlation is the degree of to which a pair of variables are linearly related. A linear relation between variables means that the value of one variable can to a certain extent predict the value of the other. The correlation coefficient represents the degree of correlation as a number ranging from -1 (high inverse correlation) to 1 (high correlation). A value of 0 corresponds to no correlation.

If the group or window is empty, or contains only NULL values, the result will be NULL.

9.3.1.1 CORR Examples

  1. select
  2. corr(alength, aheight) AS c_corr
  3. from measure

See alsoSection 9.3.2, COVAR_POP(), Section 9.3.4, STDDEV_POP()

9.3.2 COVAR_POP()

Available inDSQL, PSQL

Result typeDOUBLE PRECISION

Syntax

  1. COVAR_POP ( <expr1>, <expr2> )

Table 9.3.2.1 COVAR_POP Function Parameters

ParameterDescription

exprN

Numeric expression. It may contain a table column, a constant, a variable, an expression, a non-aggregate function or a UDF. Aggregate functions are not allowed as expressions.

The function COVAR_POP returns the population covariance for a pair of numerical expressions.

The function COVAR_POP(<expr1>, <expr2>) is equivalent to

  1. (SUM(<expr1> * <expr2>) - SUM(<expr1>) * SUM(<expr2>) / COUNT(*)) / COUNT(*)

If the group or window is empty, or contains only NULL values, the result will be NULL.

9.3.2.1 COVAR_POP Examples

  1. select
  2. covar_pop(alength, aheight) AS c_covar_pop
  3. from measure

See alsoSection 9.3.3, COVAR_SAMP(), Section 9.2.6, SUM(), Section 9.2.2, COUNT()

9.3.3 COVAR_SAMP()

Available inDSQL, PSQL

Result typeDOUBLE PRECISION

Syntax

  1. COVAR_SAMP ( <expr1>, <expr2> )

Table 9.3.3.1 COVAR_SAMP Function Parameters

ParameterDescription

exprN

Numeric expression. It may contain a table column, a constant, a variable, an expression, a non-aggregate function or a UDF. Aggregate functions are not allowed as expressions.

The function COVAR_SAMP returns the sample covariance for a pair of numerical expressions.

The function COVAR_SAMP(<expr1>, <expr2>) is equivalent to

  1. (SUM(<expr1> * <expr2>) - SUM(<expr1>) * SUM(<expr2>) / COUNT(*)) / (COUNT(*) - 1)

If the group or window is empty, contains only 1 row, or contains only NULL values, the result will be NULL.

9.3.3.1 COVAR_SAMP Examples

  1. select
  2. covar_samp(alength, aheight) AS c_covar_samp
  3. from measure

See alsoSection 9.3.2, COVAR_POP(), Section 9.2.6, SUM(), Section 9.2.2, COUNT()

9.3.4 STDDEV_POP()

Available inDSQL, PSQL

Result typeDOUBLE PRECISION or NUMERIC depending on the type of expr

Syntax

  1. STDDEV_POP ( <expr> )

Table 9.3.4.1 STDDEV_POP Function Parameters

ParameterDescription

expr

Numeric expression. It may contain a table column, a constant, a variable, an expression, a non-aggregate function or a UDF. Aggregate functions are not allowed as expressions.

The function STDDEV_POP returns the population standard deviation for a group or window. NULL values are skipped.

The function STDDEV_POP(<expr>) is equivalent to

  1. SQRT(VAR_POP(<expr>))

If the group or window is empty, or contains only NULL values, the result will be NULL.

9.3.4.1 STDDEV_POP Examples

  1. select
  2. dept_no
  3. stddev_pop(salary)
  4. from employee
  5. group by dept_no

See alsoSection 9.3.5, STDDEV_SAMP(), Section 9.3.6, VAR_POP(), SQRT

9.3.5 STDDEV_SAMP()

Available inDSQL, PSQL

Result typeDOUBLE PRECISION or NUMERIC depending on the type of expr

Syntax

  1. STDDEV_POP ( <expr> )

Table 9.3.5.1 STDDEV_SAMP Function Parameters

ParameterDescription

expr

Numeric expression. It may contain a table column, a constant, a variable, an expression, a non-aggregate function or a UDF. Aggregate functions are not allowed as expressions.

The function STDDEV_SAMP returns the sample standard deviation for a group or window. NULL values are skipped.

The function STDDEV_SAMP(<expr>) is equivalent to

  1. SQRT(VAR_SAMP(<expr>))

If the group or window is empty, contains only 1 row, or contains only NULL values, the result will be NULL.

9.3.5.1 STDDEV_SAMP Examples

  1. select
  2. dept_no
  3. stddev_samp(salary)
  4. from employee
  5. group by dept_no

See alsoSection 9.3.4, STDDEV_POP(), Section 9.3.7, VAR_SAMP(), SQRT

9.3.6 VAR_POP()

Available inDSQL, PSQL

Result typeDOUBLE PRECISION or NUMERIC depending on the type of expr

Syntax

  1. VAR_POP ( <expr> )

Table 9.3.6.1 VAR_POP Function Parameters

ParameterDescription

expr

Numeric expression. It may contain a table column, a constant, a variable, an expression, a non-aggregate function or a UDF. Aggregate functions are not allowed as expressions.

The function VAR_POP returns the population variance for a group or window. NULL values are skipped.

The function VAR_POP(<expr>) is equivalent to

  1. (SUM(<expr> * <expr>) - SUM (<expr>) * SUM (<expr>) / COUNT(<expr>))
  2. / COUNT (<expr>)

If the group or window is empty, or contains only NULL values, the result will be NULL.

9.3.6.1 VAR_POP Examples

  1. select
  2. dept_no
  3. var_pop(salary)
  4. from employee
  5. group by dept_no

See alsoSection 9.3.7, VAR_SAMP(), Section 9.2.6, SUM(), Section 9.2.2, COUNT()

9.3.7 VAR_SAMP()

Available inDSQL, PSQL

Result typeDOUBLE PRECISION or NUMERIC depending on the type of expr

Syntax

  1. VAR_SAMP ( <expr> )

Table 9.3.7.1 VAR_SAMP Function Parameters

ParameterDescription

expr

Numeric expression. It may contain a table column, a constant, a variable, an expression, a non-aggregate function or a UDF. Aggregate functions are not allowed as expressions.

The function VAR_POP returns the sample variance for a group or window. NULL values are skipped.

The function VAR_SAMP(<expr>) is equivalent to

  1. (SUM(<expr> * <expr>) - SUM(<expr>) * SUM (<expr>) / COUNT (<expr>))
  2. / (COUNT(<expr>) - 1)

If the group or window is empty, contains only 1 row, or contains only NULL values, the result will be NULL.

9.3.7.1 VAR_SAMP Examples

  1. select
  2. dept_no
  3. var_samp(salary)
  4. from employee
  5. group by dept_no

See alsoSection 9.3.6, VAR_POP(), Section 9.2.6, SUM(), Section 9.2.2, COUNT()