STDDEV_SAMP and STDDEV_POP window functions - Amazon Redshift

STDDEV_SAMP and STDDEV_POP window functions

The STDDEV_SAMP and STDDEV_POP window functions return the sample and population standard deviation of a set of numeric values (integer, decimal, or floating-point). See also STDDEV_SAMP and STDDEV_POP functions.

STDDEV_SAMP and STDDEV are synonyms for the same function.

Syntax

STDDEV_SAMP | STDDEV | STDDEV_POP ( [ ALL ] expression ) OVER ( [ PARTITION BY expr_list ] [ ORDER BY order_list frame_clause ] )

Arguments

expression

The target column or expression that the function operates on.

ALL

With the argument ALL, the function retains all duplicate values from the expression. ALL is the default. DISTINCT is not supported.

OVER

Specifies the window clauses for the aggregation functions. The OVER clause distinguishes window aggregation functions from normal set aggregation functions.

PARTITION BY expr_list

Defines the window for the function in terms of one or more expressions.

ORDER BY order_list

Sorts the rows within each partition. If no PARTITION BY is specified, ORDER BY uses the entire table.

frame_clause

If an ORDER BY clause is used for an aggregate function, an explicit frame clause is required. The frame clause refines the set of rows in a function's window, including or excluding sets of rows within the ordered result. The frame clause consists of the ROWS keyword and associated specifiers. See Window function syntax summary.

Data types

The argument types supported by the STDDEV functions are SMALLINT, INTEGER, BIGINT, NUMERIC, DECIMAL, REAL, and DOUBLE PRECISION.

Regardless of the data type of the expression, the return type of a STDDEV function is a double precision number.

Examples

The following example shows how to use STDDEV_POP and VAR_POP functions as window functions. The query computes the population variance and population standard deviation for PRICEPAID values in the SALES table.

select salesid, dateid, pricepaid, round(stddev_pop(pricepaid) over (order by dateid, salesid rows unbounded preceding)) as stddevpop, round(var_pop(pricepaid) over (order by dateid, salesid rows unbounded preceding)) as varpop from sales order by 2,1; salesid | dateid | pricepaid | stddevpop | varpop --------+--------+-----------+-----------+--------- 33095 | 1827 | 234.00 | 0 | 0 65082 | 1827 | 472.00 | 119 | 14161 88268 | 1827 | 836.00 | 248 | 61283 97197 | 1827 | 708.00 | 230 | 53019 110328 | 1827 | 347.00 | 223 | 49845 110917 | 1827 | 337.00 | 215 | 46159 150314 | 1827 | 688.00 | 211 | 44414 157751 | 1827 | 1730.00 | 447 | 199679 165890 | 1827 | 4192.00 | 1185 | 1403323 ...

The sample standard deviation and variance functions can be used in the same way.