Export (0) Print
Expand All

STDEVP (Transact-SQL)

Returns the statistical standard deviation for the population for all values in the specified expression.

Applies to: SQL Server (SQL Server 2008 through current version), Azure SQL Database.

Topic link icon Transact-SQL Syntax Conventions

STDEVP ( [ ALL | DISTINCT ] expression ) 
   OVER ( [ partition_by_clause ] order_by_clause )  

ALL

Applies the function to all values. ALL is the default.

DISTINCT

Specifies that each unique value is considered.

expression

Is a numeric expression. Aggregate functions and subqueries are not permitted. expression is an expression of the exact numeric or approximate numeric data type category, except for the bit data type.

OVER ( [ partition_by_clause ] order_by_clause)

partition_by_clause divides the result set produced by the FROM clause into partitions to which the function is applied. If not specified, the function treats all rows of the query result set as a single group. order_by_clause determines the logical order in which the operation is performed. order_by_clause is required. For more information, see OVER Clause (Transact-SQL).

If STDEVP is used on all items in a SELECT statement, each value in the result set is included in the calculation. STDEVP can be used with numeric columns only. Null values are ignored.

STDEVP is a deterministic function when used without the OVER and ORDER BY clauses. It is nondeterministic when specified with the OVER and ORDER BY clauses. For more information, see Deterministic and Nondeterministic Functions.

The following example returns the standard deviation for the population for all bonus values in the SalesPerson table in the AdventureWorks2012 database.

SELECT STDEVP(Bonus)
FROM Sales.SalesPerson;
GO
Was this page helpful?
(1500 characters remaining)
Thank you for your feedback

Community Additions

ADD
Show:
© 2014 Microsoft