STDDEV_POP
Returns the population standard deviation for non-NULL values.
May be used as a window function and with the frame clause.
Syntax
Aggregate Function
STDDEV_POP ( [ DISTINCT ] <expression> )
Window Function & Window Frame Clause
STDDEV_POP ( [ DISTINCT ] expr ) OVER ([ PARTITION BY expr][ ORDER BY expr ] [<window_frame>])
Arguments
expression: numeric, uses standard deviation for calculating .
Return Type
A double.
Examples
The following table and values were used for the examples:
Aggregate Function
CREATE TABLE coordinates( x_axis decimal (5,2), y_axis decimal (7,2), z_axis decimal (10,2)); INSERT INTO coordinates VALUES (2, 5, 9), (7, 15, null), (8, 1, 12), (5, 7, 0), (8, 6, 1), (null, 7, 11);
SELECT x_axis, STDDEV_POP(z_axis), STDDEV_POP(y_axis) FROM coordinates GROUP BY x_axis; **** +--------+-------------------+--------------------+ | x_axis | STDDEV_POP(z_axis)| STDDEV_POP(y_axis) | +--------+-------------------+--------------------+ | 5.00 | 0.000000 | 0.000000 | | 2.00 | 0.000000 | 0.000000 | | NULL | 0.000000 | 0.000000 | | 8.00 | 5.500000 | 2.500000 | | 7.00 | NULL | 0.000000 | +--------+-------------------+--------------------+
Window Function
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');
SELECT player_name, 1st_qtr_score, ROUND(STDDEV_POP(yearly_total) OVER (ORDER BY player_name, yearly_total)) AS STDDEV_POP FROM player_scores ORDER BY player_name; **** +-------------+---------------+------------+ | player_name | 1st_qtr_score | STDDEV_POP | +-------------+---------------+------------+ | Eve | 91.50 | 0 | | Jack | 90.10 | 10 | | Jim | 75.00 | 42 | | June | 81.00 | 36 | | Martin | 98.80 | 38 | | Shelia | 75.60 | 37 | | Steve | 22.50 | 57 | +-------------+---------------+------------+
Window Frame Clause
SELECT player_name, 1st_qtr_score, 2nd_qtr_score, ROUND(STDDEV_POP(1st_qtr_score) OVER (ORDER BY player_name, 1st_qtr_score, 2nd_qtr_score ROWS UNBOUNDED PRECEDING)) AS STDDEV_POP FROM player_scores ORDER BY player_name; **** +-------------+---------------+---------------+------------+ | player_name | 1st_qtr_score | 2nd_qtr_score | STDDEV_POP | +-------------+---------------+---------------+------------+ | Eve | 91.50 | 88.10 | 0 | | Jack | 90.10 | 78.00 | 1 | | Jim | 75.00 | 68.90 | 7 | | June | 81.00 | 87.30 | 7 | | Martin | 98.80 | 95.10 | 8 | | Shelia | 75.60 | 72.00 | 9 | | Steve | 22.50 | 72.00 | 23 | +-------------+---------------+---------------+------------+