Purpose
STDDEV_SAMP() returns the sample standard deviation of a set of numeric values. The sample standard deviation is the arithmetic square root of the sample variance. The difference between STDDEV() and STDDEV_SAMP() is that the STDDEV() function returns 0 for only one row of input data, whereas STDDEV_SAMP() returns NULL. 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_SAMP([ALL] expr) [ OVER (analytic_clause) ]
Parameters
| Parameter | Description |
|---|---|
| ALL | The entire column. This parameter is optional. 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 expr.
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 standard deviation for the salary column.
obclient> SELECT STDDEV_SAMP(salary) FROM employees;
+-------------------------------------------+
| STDDEV_SAMP(SALARY) |
+-------------------------------------------+
| 6026.474330580265330900400184969999384459 |
+-------------------------------------------+
1 row in set
Example of an analytic function
Group the data records in the table by the department_id column and sort the data records by the hiredate column in ascending order. Return the standard deviation for the salary column.
obclient> SELECT department_id, last_name, hiredate, salary,
STDDEV_SAMP(salary) OVER (PARTITION BY department_id
ORDER BY hiredate ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS s_samp
FROM employees;
+---------------+-----------+------------+--------+-------------------------------------------+
| DEPARTMENT_ID | LAST_NAME | HIREDATE | SALARY | S_SAMP |
+---------------+-----------+------------+--------+-------------------------------------------+
| 30 | Raphaely | 2017-07-01 | 1700 | NULL |
| 30 | De Haan | 2018-05-01 | 11000 | 6576.093065034891976927852567575096065349 |
| 40 | Errazuriz | 2017-07-21 | 1400 | NULL |
| 50 | Raphaely | 2017-07-22 | 1700 | NULL |
| 50 | Hartstein | 2019-10-05 | 14000 | 8697.413408594534550130385653889643183203 |
| 50 | Weiss | 2019-10-05 | 13500 | 6961.561127601576503543602300090640831831 |
| 90 | Partners | 2018-12-01 | 14000 | NULL |
| 90 | Russell | 2019-07-11 | 13000 | 707.106781186547524400844362104849039285 |
+---------------+-----------+------------+--------+-------------------------------------------+
8 rows in set