StDev, StDevP Functions

Description

Return estimates of the standard deviation for a population or a population sample represented as a set of values contained in a specified field on a query.

Syntax

StDev(expr)

StDevP(expr)

The expr placeholder represents a string expression identifying the field that contains the numeric data you want to evaluate or an expression that performs a calculation using the data in that field. Operands in expr can include the name of a table field, a constant, or a function (which can be either intrinsic or user-defined but not one of the other SQL aggregate functions).

Remarks

The StDevP function evaluates a population, and the StDev function evaluates a population sample.

If the underlying query contains fewer than two records (or no records, for the StDevP function), these functions return a Null value (which indicates that a standard deviation can't be calculated).

You can use the StDev and StDevP functions in a query expression. You can also use this expression in the SQL property of a QueryDef object or when creating a Recordset object based on an SQL query.

See Also

Avg function, QueryDef object ("DAO Language Reference"), SELECT statement, SQL property ("DAO Language Reference"), Sum function.

Specifics (Microsoft Access)

In Microsoft Access, you can use the StDev and StDevP functions in the query design grid, in an SQL statement in SQL view of the Query window, or in an SQL statement within Visual Basic code. You can also use the StDev and StDevP functions in a calculated control on a form or report.

The StDev and StDevP functions are most useful in totals queries and crosstab queries. They function the same way whether you create the query in the query design grid or as an SQL statement in SQL view.

In the query design grid, you can create a new totals query by clicking the Totals button on the Query Design toolbar. The Total row is then inserted in the grid. You can set the Total cell beneath a field to the aggregate function to perform on the data in that field.

For example, suppose you have an Orders table that has both a Freight field and a ShipCity field. You can create a query that displays the standard deviation of freight cost for orders sent to each city. Create a new totals query, and drag the ShipCity field to the query design grid. The Total cell beneath the ShipCity field should be set to Group By. Drag the Freight field to the query design grid, and set the Total cell beneath it to StDev. When you run the query, it will display the standard deviation of freight cost for orders sent to each city.

You can view the SQL statement for this query by switching to SQL view. In this example, Microsoft Access creates the following SQL statement:

SELECT ShipCity, StDev(Freight) AS StDevOfFreight 
FROM Orders GROUP BY ShipCity;
You can also use an SQL statement within Visual Basic code. For example, the following code creates a dynaset-type Recordset object from the preceding SQL statement:

Sub StDevFreight()
    Dim dbs As Database, rst As Recordset, strSQL As String

    Set dbs = CurrentDb
    strSQL = "SELECT ShipCity, StDev(Freight) " _
        & "AS StDevOfFreight, ShipCity FROM Orders " _
        & "GROUP BY ShipCity;"
    Set rst = dbs.OpenRecordset(strSQL)
    rst.MoveLast
    Debug.Print rst.RecordCount
    Set dbs = Nothing
End Sub
To use the StDev and StDevP functions in a calculated control, set the control's ControlSource property to an expression containing either of these functions. For example, to display the standard deviation of freight costs for a set of orders in a text box, enter the following expression in the ControlSource property of the text box:

=StDev([Freight])
If you use the StDev or StDevP function in a calculated control, you can restrict the set of records against which the function is performed by setting the form's Filter property.

Example

This example uses the Orders table to estimate the standard deviation of the freight charges for orders shipped to the United Kingdom.

This example calls the EnumFields procedure, which you can find in the SELECT statement example.

Sub StDevX()

    Dim dbs As Database, rst As Recordset

    ' Modify this line to include the path to Northwind
    ' on your computer.
    Set dbs = OpenDatabase("Northwind.mdb")

    ' Calculate the standard deviation of the freight
    ' charges for orders shipped to the United Kingdom.
    Set rst = dbs.OpenRecordset("SELECT " _
        & "StDev(Freight) " _
        & "AS [Freight Deviation] FROM Orders " _
        & "WHERE ShipCountry = 'UK';")

    ' Populate the Recordset.
    rst.MoveLast

    ' Call EnumFields to print the contents of the 
    ' Recordset. Pass the Recordset object and desired
    ' field width.
    EnumFields rst, 15
    
    Debug.Print

    Set rst = dbs.OpenRecordset("SELECT " _
        & "StDevP(Freight) " _
        & "AS [Freight DevP] FROM Orders " _
        & "WHERE ShipCountry = 'UK';")

    ' Populate the Recordset.
    rst.MoveLast

    ' Call EnumFields to print the contents of the 
    ' Recordset. Pass the Recordset object and desired
    ' field width.
    EnumFields rst, 15

    dbs.Close

End Sub
Example (Microsoft Access)

The following example assumes that you have an Orders table that contains fields called Freight and ShipCountry. You can use the StDev and StDevP functions to return the standard deviation of freight charges for orders shipped to the United Kingdom. Enter the following expressions in SQL view in the Query window:

SELECT StDev([Freight]) AS [FreightDev] FROM Orders
WHERE [ShipCountry] = 'UK';

SELECT StDevP([Freight]) AS [FreightDevP] FROM Orders
WHERE [ShipCountry] = 'UK';
The next example creates a calculated control that displays the standard deviation of freight charges for all records in the same Orders table. Open a new form and set its RecordSource property to Orders. Enter the following expression in the ControlSource property of a text box on the form. To apply a condition that limits the search to only some records, such as those for orders shipped to the United Kingdom, set the form's Filter property.

=StDev([Freight])