VARIANCE

2023-08-01 06:02:28  Updated

Purpose

VARIANCE() returns the variance from the specified column. You can use this function as an aggregate or analytic function.

Note

  • When you use this function as an analytic function, use the OVER clause 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 OVER clause.

Syntax

VARIANCE([ DISTINCT | UNIQUE | ALL ] expr) [ OVER (analytic_clause) ]

Parameters

Parameter Description
DISTINCT | UNIQUE | ALL Specifies whether to remove duplicates during the execution of the query. This parameter is optional. Default value: ALL.
  • ALL: indicates to accept duplicate values and ignore NULLs in the data.
  • DISTINCT: indicates to remove duplicates and ignore NULLs in the data.
  • UNIQUE: indicates to remove duplicates and ignore NULLs in the data.
expr An expression of a numeric data type or a data type that can be implicitly 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.

Notice

If you specify the DISTINCT or UNIQUE keyword, you can specify only analytic_clause. order_by_clause and windowing_clause are not allowed.

Return type

The return type is the same as the data type of the expr parameter.

Examples

Assume that you have created the table employees.

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 variance of all values in the salary column.

obclient> SELECT SUM(salary) FROM employees;
+-------------+
| SUM(SALARY) |
+-------------+
|       70300 |
+-------------+
1 row in set

Example of an analytic function

Sort the data records in the table by the hiredate column in ascending order, and return the cumulative variance for the salary column.

obclient> SELECT last_name,hiredate,salary,VARIANCE(salary) OVER (ORDER BY hiredate) "Variance"
          FROM employees;
+-----------+------------+--------+-------------------------------------------+
| LAST_NAME | HIREDATE   | SALARY | Variance                                  |
+-----------+------------+--------+-------------------------------------------+
| Raphaely  | 2017-07-01 |   1700 |                                         0 |
| Errazuriz | 2017-07-21 |   1400 |                                     45000 |
| Raphaely  | 2017-07-22 |   1700 |                                     30000 |
| De Haan   | 2018-05-01 |  11000 |                                  22110000 |
| Partners  | 2018-12-01 |  14000 |                                  36783000 |
| Russell   | 2019-07-11 |  13000 |  37686666.6666666666666666666666666666666 |
| Hartstein | 2019-10-05 |  14000 | 36318392.85714285714285714285714285714286 |
| Weiss     | 2019-10-05 |  13500 | 36318392.85714285714285714285714285714286 |
+-----------+------------+--------+-------------------------------------------+
8 rows in set

Contact Us