TechNet
Export (0) Print
Expand All

STDEV (Transact-SQL)

 

THIS TOPIC APPLIES TO: yesSQL Server (starting with 2008) yesAzure SQL Database yesAzure SQL Data Warehouse yesParallel Data Warehouse

Returns the statistical standard deviation of all values in the specified expression.

Topic link icon Transact-SQL Syntax Conventions


STDEV ( [ ALL | DISTINCT ] expression ) 
   OVER ( [ partition_by_clause ] order_by_clause )  
-- Azure SQL Data Warehouse and Parallel Data Warehouse
      -- Aggregate Function Syntax 
STDEV ( [ ALL | DISTINCT ] expression )
-- Azure SQL Data Warehouse and Parallel Data Warehouse
      -- Analytic Function Syntax 
STDEV (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 STDEV is used on all items in a SELECT statement, each value in the result set is included in the calculation. STDEV can be used with numeric columns only. Null values are ignored.

STDEV 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 all bonus values in the SalesPerson table in the AdventureWorks2012 database.

SELECT STDEV(Bonus)
FROM Sales.SalesPerson;
GO

The following example returns the standard deviation of the sales quota values in the table dbo.FactSalesQuota. The first column contains the standard deviation of all distinct values and the second column contains the standard deviation of all values including any duplicates values.

-- Uses AdventureWorks

SELECT STDEV(DISTINCT SalesAmountQuota)AS Distinct_Values, STDEV(SalesAmountQuota) AS All_Values
FROM dbo.FactSalesQuota;

Here is the result set.

Distinct_Values   All_Values

----------------  ----------------

398974.27         398450.57

The following example returns the standard deviation of the sales quota values for each quarter in a calendar year. Notice that the ORDER BY in the OVER clause orders the STDEV and the ORDER BY of the SELECT statement orders the result set.

-- Uses AdventureWorks

SELECT CalendarYear AS Year, CalendarQuarter AS Quarter, SalesAmountQuota AS SalesQuota,
       STDEV(SalesAmountQuota) OVER (ORDER BY CalendarYear, CalendarQuarter) AS StdDeviation
FROM dbo.FactSalesQuota
WHERE EmployeeKey = 272 AND CalendarYear = 2002
ORDER BY CalendarQuarter;

Here is the result set.

Year  Quarter  SalesQuota              StdDeviation

----  -------  ----------------------  -------------------

2002  1         91000.0000             null

2002  2        140000.0000             34648.23

2002  3         70000.0000             35921.21

2002  4        154000.0000             39752.36

Community Additions

ADD
Show:
© 2016 Microsoft