>
Var, VarP Functions
Description
Return estimates of the variance for a population or a population sample represented as a set of values contained in a specified field on a query.
Syntax
Var(expr)
VarP(expr)
The VarP function evaluates a population, and the Var function evaluates a population sample.
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 or domain aggregate functions).
Remarks
If the underlying query contains fewer than two records, the Var and VarP functions return a Null (which indicates that a variance can't be calculated).
You can use the Var and VarP functions in a query expression or in an SQL statement.
Specifics (Microsoft Access)
In Microsoft Access, you can use the Var and VarP 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 Var and VarP functions in a calculated control on a form or report.
The Var and VarP 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 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 variance 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 Var. When you run the query, it will display the variance 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 DISTINCTROW Var(Orders.Freight) AS VarOfFreight, Orders.ShipCity
FROM Orders
GROUP BY Orders.ShipCity;
You can also use an SQL statement such as this one within Visual Basic code. For example, using the following code you can create a Recordset object based on the query defined by this SQL statement.
Dim dbs As DatabAse, rst As Recordset, strSQL As String
Set dbs = CurrentDb
strSQL = "SELECT DISTINCTROW Var(Orders.Freight) AS VarOfFreight, "_
& "Orders.ShipCity FROM Orders GROUP BY Orders.ShipCity;"
Set rst = dbs.OpenRecordset(strSQL)
To use the Var and VarP functions in a calculated control, set the control's ControlSource property to an expression containing either of these functions. For example, to display the variance across freight costs in a text box, enter the following expression in the ControlSource property of the text box.
= Var([Freight])
If you use the Var or VarP 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 variance of freight costs for orders shipped to the United Kingdom.
SELECT Var(Freight) AS [UK Freight Variance] FROM Orders
WHERE ShipCountry = 'UK';
SELECT VarP(Freight) AS [UK Freight VarianceP] FROM Orders
WHERE ShipCountry = 'UK';
Example (Microsoft Access)
The following example assumes that you have an Orders table that contains a field called Freight. You can use the Var and VarP functions to estimate the variance of freight costs for orders shipped to the United Kingdom. Enter the following expressions in SQL view in the Query window:
SELECT Var([Freight]) AS [UKFreightVariance] FROM Orders
WHERE [ShipCountry] = 'UK';
SELECT VarP([Freight]) AS [UKFreightVarianceP] FROM Orders
WHERE [ShipCountry] = 'UK';
The next example creates a calculated control that displays the estimated variance for freight costs for 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.
= Var([Freight])