VARIANCE

Calculates the population variance value from a set of numbers.

VARIANCE has synonym VAR_POP which is equivalent. VARIANCE returns NULL if there are not matching rows.

May be used as a window function and with the frame clause.

Syntax

Aggregate Function

VARIANCE ( expression )

Window Function & Window Frame Clause

VARIANCE( [ DISTINCT ] expr ) OVER ( [PARTITION BY expr] [ORDER BY expr] [<window_frame_function>])

Arguments

  • expression: any expression. This may be a column name, the result of another function, or a math operation.

Return Type

A double.

Examples

CREATE TABLE player_scores(player_name VARCHAR(50), player_id VARCHAR(10), 
    1st_qtr_score DECIMAL(5,2), 2nd_qtr_score DECIMAL(5,2), 
    3rd_qtr_score DECIMAL(5,2), 4th_qtr_score DECIMAL(5,2), 
    yearly_total AS 1st_qtr_score + 2nd_qtr_score + 3rd_qtr_score + 4th_qtr_score PERSISTED DECIMAL(5,2));
INSERT INTO player_scores VALUES
    ('Steve', '119','22.50','72.00', '63.00', '45.00'),
    ('Jack', '432', '90.10', '78.00','88.20', '92.20'),
    ('Jim', '779','75.00', '68.90','55.70', '72.00'), 
    ('Eve', '189','91.50', '88.10', '95.00', '94.50'),
    ('Shelia','338', '75.60', '72.00', '81.10', '78.40'),
    ('June', '521', '81.00', '87.30','76.80','82.20'),
    ('Martin', '674','98.80', '95.10', '88.00', '96.40');

Aggregate Function

SELECT VARIANCE(yearly_total) FROM player_scores;
+------------------------+
| VARIANCE(yearly_total) |
+------------------------+
|            3258.486939 |
+------------------------+

Window Function

SELECT player_name, 3rd_qtr_score, 4th_qtr_score,
ROUND(VARIANCE(3rd_qtr_score) OVER (ORDER BY player_name)) AS VARIANCE
FROM player_scores
ORDER BY player_name;
+-------------+---------------+---------------+----------+
| player_name | 3rd_qtr_score | 4th_qtr_score | VARIANCE |
+-------------+---------------+---------------+----------+
| Eve         |         95.00 |         94.50 |        0 |
| Jack        |         88.20 |         92.20 |       12 |
| Jim         |         55.70 |         72.00 |      294 |
| June        |         76.80 |         82.20 |      222 |
| Martin      |         88.00 |         96.40 |      191 |
| Shelia      |         81.10 |         78.40 |      159 |
| Steve       |         63.00 |         45.00 |      175 |
+-------------+---------------+---------------+----------+

Window Frame Clause

SELECT player_name, 1st_qtr_score, 2nd_qtr_score,
ROUND(VARIANCE(1st_qtr_score) OVER (ORDER BY player_name, 1st_qtr_score, 2nd_qtr_score ROWS UNBOUNDED PRECEDING)) AS VARIANCE
FROM player_scores
ORDER BY player_name;
+-------------+---------------+---------------+----------+
| player_name | 1st_qtr_score | 2nd_qtr_score | VARIANCE |
+-------------+---------------+---------------+----------+
| Eve         |         91.50 |         88.10 |        0 |
| Jack        |         90.10 |         78.00 |        0 |
| Jim         |         75.00 |         68.90 |       56 |
| June        |         81.00 |         87.30 |       46 |
| Martin      |         98.80 |         95.10 |       70 |
| Shelia      |         75.60 |         72.00 |       77 |
| Steve       |         22.50 |         72.00 |      549 |
+-------------+---------------+---------------+----------+

Last modified: February 23, 2023

Was this article helpful?