Sign in with Microsoft
Sign in or create an account.
Hello,
Select a different account.
You have multiple accounts
Choose the account you want to sign in with.

You can use the DStDev and DStDevP functions to estimate the standard deviation across a set of values in a specified set of records (a domain). Use the DStDev and DStDevP functions in a Visual Basic for Applications (VBA) module, a macro, a query expression, or a calculated control on a form or report.

Use the DStDevP function to evaluate a population and the DStDev function to evaluate a population sample.

For example, you could use the DStDev function in a module to calculate the standard deviation across a set of students' test scores.

Syntax

DStDev ( expr , domain [, criteria] )

DStDevP ( expr , domain [, criteria] )

The DStDev and DStDevP functions have these arguments:

Argument

Description

expr

Required. An expression that identifies the numeric field on which you want to find the standard deviation. It can be a string expression identifying a field from a table or query, or it can be an expression that performs a calculation on data in that field. In expr, you can include the name of a field in a table, a control on a form, a constant, or a function. If expr includes a function, it can be either built-in or user-defined, but not another domain aggregate or SQL aggregate function.

domain

Required. A string expression identifying the set of records that constitutes the domain. It can be a table name or a query name for a query that does not require a parameter.

criteria

Optional. A string expression used to restrict the range of data on which the DStDev or DStDevP function is performed. For example, criteria is often equivalent to the WHERE clause in an SQL expression, without the word WHERE. If criteria is omitted, the DStDev and DStDevP functions evaluate expr against the entire domain. Any field that is included in criteria must also be a field in domain; otherwise, the DStDev and DStDevP functions will return a Null.

Remarks

If domain refers to fewer than two records or if fewer than two records satisfy criteria, the DStDev and DStDevP functions return a Null, indicating that a standard deviation can't be calculated.

Whether you use the DStDev or DStDevP function in a macro, module, query expression, or calculated control, you must construct the criteria argument carefully to ensure that it will be evaluated correctly.

You can use the DStDev and DStDevP functions to specify criteria in the Criteria row of a select query. For example, you could create a query on an Orders table and a Products table to display all products for which the freight cost fell above the mean plus the standard deviation for freight cost. The Criteria row beneath the Freight field would contain the following expression:

>(DStDev("[Freight]", "Orders") + DAvg("[Freight]", "Orders"))

You can use the DStDev and DStDevP functions in a calculated field expression of a query, or in the Update To row of an update query.

Note: You can use the DStDev and DStDevP functions or the StDev and StDevP functions in a calculated field expression of a totals query. If you use the DStDev or DStDevP function, values are calculated before data is grouped. If you use the StDev or StDevP function, the data is grouped before values in the field expression are evaluated.

Use the DStDev and DStDevP function in a calculated control when you need to specify criteria to restrict the range of data on which the function is performed. For example, to display standard deviation for orders to be shipped to California, set the ControlSource property of a text box to the following expression:

=DStDev("[Freight]", "Orders", "[ShipRegion] = 'CA'")

If you simply want to find the standard deviation across all records in domain, use the StDev or StDevP function.

Tip    If the data type of the field from which expr is derived is a number, the DStDev and DStDevP functions return a Double data type. If you use the DStDev or DStDevP function in a calculated control, include a data type conversion function in the expression to improve performance.

Note: Unsaved changes to records in domain are not included when you use these functions. If you want the DStDev or DStDevP function to be based on the changed values, you must first save the changes by clicking Save Record under Records on the Data tab, moving the focus to another record, or by using the Update method.

Query examples

Expression

Results

SELECT DStDev("unitprice","productSales","unitprice>140") AS Expr1, DStDevP("unitprice","productSales","unitprice<140") AS Expr2 FROM productSales GROUP BY DStDev("unitprice","productSales","unitprice>140"), DStDevP("unitprice","productSales","unitprice<140");

Calculates the Standard Deviation of "UnitPrice" (considering te given data as sample) from the table "ProductSales" where "unitprice" is greater than 140 and displays the result in Expr1. Also calculates the Standard Deviation of "UnitPrice" (considering the given data as entire population) where "unitprice" is less than 140 and displays the results in Expr2.

SELECT DStDev("unitprice","productSales","unitprice>140") AS DstDev, DStDevP("unitprice","productSales","unitprice<140") AS DstDevP FROM productSales GROUP BY DStDev("unitprice","productSales","unitprice>140"), DStDevP("unitprice","productSales","unitprice<140");

Calculates the Standard Deviation of "UnitPrice" (considering te given data as sample) from the table "ProductSales" where "unitprice" is greater than 140 and displays the result in DstDev. Also calculates the Standard Deviation of "UnitPrice" (considering the given data as entire population) where "unitprice" is less than 140 and displays the results in DstDevP.

VBA example

Note: Examples that follow demonstrate the use of this function in a Visual Basic for Applications (VBA) module. For more information about working with VBA, select Developer Reference in the drop-down list next to Search and enter one or more terms in the search box.

The following example returns estimates of the standard deviation for a population and a population sample for orders shipped to the United Kingdom. The domain is an Orders table. The criteria argument restricts the resulting set of records to those for which the ShipCountryRegion value is UK.

Dim dblX As Double
Dim dblY As Double
' Sample estimate.
dblX = DStDev("[Freight]", "Orders", _
"[ShipCountryRegion] = 'UK'")
' Population estimate.
dblY = DStDevP("[Freight]", "Orders", _
"[ShipCountryRegion] = 'UK'")

The next example calculates the same estimates by using a variable, strCountryRegion, in the criteria argument. Note that single quotation marks (') are included in the string expression, so that when the strings are concatenated, the string literal UK will be enclosed in single quotation marks.

Dim strCountryRegion As String
Dim dblX As Double
Dim dblY As Double
strCountryRegion = "UK"
dblX = DStDev("[Freight]", "Orders", _
"[ShipCountryRegion] = '" & strCountryRegion & "'")
dblY = DStDevP("[Freight]", "Orders", _
"[ShipCountryRegion] = '" & strCountryRegion & "'")

Need more help?

Want more options?

Explore subscription benefits, browse training courses, learn how to secure your device, and more.

Communities help you ask and answer questions, give feedback, and hear from experts with rich knowledge.

Was this information helpful?

What affected your experience?
By pressing submit, your feedback will be used to improve Microsoft products and services. Your IT admin will be able to collect this data. Privacy Statement.

Thank you for your feedback!

×