STDDEV_ SAMP
On this page
Calculates the sample standard deviation value from a set of numbers.
STDDEV_
returns NULL if there are not matching rows.
May be used as a window function and with the frame clause.
Syntax
Aggregate Function
STDDEV_SAMP ( expression )
Window Function & Window Frame Clause
STDDEV_SAMP ( [DISTINCT ] (col | expr ) OVER ( [PARTITION BY (col | expr )] [ORDER BY (col | expr ) [ <window_frame> ] ] )
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 STDDEV_SAMP(yearly_total) FROM player_scores;
+---------------------------+
| STDDEV_SAMP(yearly_total) |
+---------------------------+
| 61.656858 |
+---------------------------+
Window Function
SELECT player_name, yearly_total,ROUND(STDDEV_SAMP(yearly_total) OVER (ORDER BY player_name, yearly_total)) AS STDDEV_SAMPFROM player_scoresORDER BY player_name;
+-------------+--------------+-------------+
| player_name | yearly_total | STDDEV_SAMP |
+-------------+--------------+-------------+
| Eve | 369.10 | NULL |
| Jack | 348.50 | 15 |
| Jim | 271.60 | 51 |
| June | 327.30 | 42 |
| Martin | 378.30 | 42 |
| Shelia | 307.10 | 40 |
| Steve | 202.50 | 62 |
+-------------+--------------+-------------+
Window Frame Clause
SELECT player_name, 1st_qtr_score, 2nd_qtr_score,ROUND(STDDEV_SAMP(1st_qtr_score) OVER (ORDER BY player_name, 1st_qtr_score, 2nd_qtr_score ROWS UNBOUNDED PRECEDING)) AS STDDEV_SAMPFROM player_scoresORDER BY player_name;
+-------------+---------------+---------------+-------------+
| player_name | 1st_qtr_score | 2nd_qtr_score | STDDEV_SAMP |
+-------------+---------------+---------------+-------------+
| Eve | 91.50 | 88.10 | NULL |
| Jack | 90.10 | 78.00 | 1 |
| Jim | 75.00 | 68.90 | 9 |
| June | 81.00 | 87.30 | 8 |
| Martin | 98.80 | 95.10 | 9 |
| Shelia | 75.60 | 72.00 | 10 |
| Steve | 22.50 | 72.00 | 25 |
+-------------+---------------+---------------+-------------+
Last modified: February 23, 2023