Purpose
STDDEV_POP() returns the population standard deviation of a set of numeric values. The population standard deviation is the arithmetic square root of the population variance. You can use this function as an aggregate or analytic function.
Note
- When you use this function as an analytic function, use the
OVERclause to define a window over the data on which the function operates. The function operates on a group of rows to return a list of values. - When you use this function as an aggregate function, the function operates on a set of rows and returns a single value. You do not need to add the
OVERclause.
Syntax
STDDEV_POP( [ALL] expr) [ OVER (analytic_clause) ]
Parameters
| Parameter | Description |
|---|---|
| ALL | (Optional) Indicates that the function operates on all values in the column. Default value: ALL. |
| expr | An expression of a numeric data type (NUMBER, FLOAT, BINARY_FLOAT, or BINARY_DOUBLE) or a data type that can be converted to a numeric data type. |
| OVER | You can use the OVER clause to define a window over the data on which the function operates. For more information, see Analytic functions. |
Return type
The return type is the same as the data type of the expr parameter.
Examples
The table employees has been created.
obclient> SELECT * FROM employees;
+---------------+-----------+------------+--------+
| DEPARTMENT_ID | LAST_NAME | HIREDATE | SALARY |
+---------------+-----------+------------+--------+
| 30 | Raphaely | 2017-07-01 | 1700 |
| 30 | De Haan | 2018-05-01 | 11000 |
| 40 | Errazuriz | 2017-07-21 | 1400 |
| 50 | Hartstein | 2019-10-05 | 14000 |
| 50 | Raphaely | 2017-07-22 | 1700 |
| 50 | Weiss | 2019-10-05 | 13500 |
| 90 | Russell | 2019-07-11 | 13000 |
| 90 | Partners | 2018-12-01 | 14000 |
+---------------+-----------+------------+--------+
8 rows in set
Example of an aggregate function
Calculate the population standard deviation for the salary column.
obclient> SELECT STDDEV_POP(salary) FROM employees;
+-------------------------------------------+
| STDDEV_POP(SALARY) |
+-------------------------------------------+
| 5637.250548804798333699350384281939588505 |
+-------------------------------------------+
1 row in set
Example of an analytic function
Group the data records in the table by the department_id column. Return the standard deviation for the salary column.
obclient> SELECT department_id,last_name,salary,STDDEV_POP(salary) OVER (PARTITION BY department_id) AS pop_std
FROM employees
ORDER BY department_id,last_name,salary;
+---------------+-----------+--------+-------------------------------------------+
| DEPARTMENT_ID | LAST_NAME | SALARY | POP_STD |
+---------------+-----------+--------+-------------------------------------------+
| 30 | De Haan | 11000 | 4650 |
| 30 | Raphaely | 1700 | 4650 |
| 40 | Errazuriz | 1400 | 0 |
| 50 | Hartstein | 14000 | 5684.090858606052304285807872404592677763 |
| 50 | Raphaely | 1700 | 5684.090858606052304285807872404592677763 |
| 50 | Weiss | 13500 | 5684.090858606052304285807872404592677763 |
| 90 | Partners | 14000 | 500 |
| 90 | Russell | 13000 | 500 |
+---------------+-----------+--------+-------------------------------------------+
8 rows in set