WHERE Clause

Description

Specifies which records from the tables listed in the FROM clause are affected by a SELECT, UPDATE, or DELETE statement.

Syntax

SELECT fieldlist
FROM tableexpression
WHERE criteria

A SELECT statement containing a WHERE clause has these parts:

Part

Description

fieldlist

The name of the field or fields to be retrieved along with any field name aliases, selection predicates (ALL, DISTINCT, DISTINCTROW, or TOP), or other SELECT statement options.

tableexpression

The name of the table or tables from which data is retrieved.

criteria

An expression that records must satisfy to be included in the query results.


Remarks

The Microsoft Jet database engine selects the records that meet the conditions listed in the WHERE clause. If you don't specify a WHERE clause, your query returns all rows from the table. If you specify more than one table in your query and you haven't included a WHERE clause or a JOIN clause, your query generates a Cartesian product of the tables.

WHERE is optional, but when included, follows FROM. For example, you can select all employees in the sales department (WHERE Dept = 'Sales') or all customers between the ages of 18 and 30 (WHERE Age Between 18 And 30).

If you don't use a JOIN clause to perform SQL join operations on multiple tables, the resulting Recordset object won't be updatable.

WHERE is similar to HAVING. WHERE determines which records are selected. Similarly, once records are grouped with GROUP BY, HAVING determines which records are displayed.

Use the WHERE clause to eliminate records you don't want grouped by a GROUP BY clause.

Use various expressions to determine which records the SQL statement returns. For example, the following SQL statement selects all employees whose salaries are more than $21,000:

SELECT LastName, Salary
FROM Employees
WHERE Salary > 21000;
A WHERE clause can contain up to 40 expressions linked by logical operators, such as And and Or.

When you enter a field name that contains a space or punctuation, surround the name with brackets ([ ]). For example, a customer information table might include information about specific customers :

SELECT [Customer's Favorite Restaurant]
When you specify the criteria argument, date literals must be in U.S. format, even if you're not using the U.S. version of the Microsoft Jet database engine. For example, May 10, 1996, is written 10/5/96 in the United Kingdom and 5/10/96 in the United States. Be sure to enclose your date literals with the number sign (#) as shown in the following examples.

To find records dated May 10, 1996 in a United Kingdom database, you must use the following SQL statement:

SELECT *
FROM Orders
WHERE ShippedDate = #5/10/96#;
You can also use the DateValue function which is aware of the international settings established by Microsoft Windows. For example, use this code for the United States:

SELECT *
FROM Orders
WHERE ShippedDate = DateValue('5/10/96');
And use this code for the United Kingdom:

SELECT *
FROM Orders
WHERE ShippedDate = DateValue('10/5/96');
Note If the column referenced in the criteria string is of type GUID, the criteria expression uses a slightly different syntax:

WHERE ReplicaID = {GUID {12345678-90AB-CDEF-1234-567890ABCDEF}}

Be sure to include the nested braces and hyphens as shown.

See Also

ALL, DISTINCT, DISTINCTROW, TOP predicates, DELETE statement, FROM clause, GROUP BY clause, HAVING clause, IN clause, INNER JOIN operation, LEFT JOIN, RIGHT JOIN operations, ORDER BY clause, SELECT statement, SELECT...INTO statement, UPDATE statement.

Specifics (Microsoft Access)

In Microsoft Access, the conditions that you establish in a WHERE clause in SQL view are the same as those you might enter in the Criteria cell in the query design grid. If you enter criteria in the query design grid, you can change to SQL view to see the WHERE clause.

Conversely, if you enter a WHERE clause in an SQL statement in SQL view, you can change to Design view to see the criteria in the query design grid, unless you are creating a union query. Union queries can only be viewed in SQL view.

Example

The following example assumes the existence of a hypothetical Salary field in an Employees table. Note that this field does not actually exist in the Northwind database Employees table.

This example selects the LastName and FirstName fields of each record in which the last name is King.

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

Sub WhereX()

    Dim dbs As Database, rst As Recordset

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

    ' Select records from the Employees table where the
    ' last name is King.
    Set rst = dbs.OpenRecordset("SELECT LastName, " _
        & "FirstName FROM Employees " _
        & "WHERE LastName = 'King';")
    ' Populate the Recordset.
    rst.MoveLast

    ' Call EnumFields to print the contents of the
    ' Recordset.
    EnumFields rst, 12

    dbs.Close

End Sub
Example (Microsoft Access)

To try the following examples in Microsoft Access, first create a new query in the Northwind sample database. Close the Show Table dialog box without specifying a table or query. Switch to SQL view, paste an individual example into the SQL window, and run the query.

The following example selects the LastName and FirstName fields of each record in which the last name is King:

SELECT LastName, FirstName FROM Employees
WHERE LastName = 'King';
The next example selects the LastName and FirstName fields for employees whose last names begin with the letter S:

SELECT LastName, FirstName FROM Employees
WHERE LastName Like 'S*';
The following example selects products whose unit prices are between $20 and $50, inclusive:

SELECT ProductName, UnitPrice FROM Products
WHERE (UnitPrice >=20.00 And UnitPrice <= 50.00);
The next example selects all products whose names fall in alphabetic order between "Cha" and "Out", inclusive. It doesn't retrieve "Outback Lager" because "Outback Lager" follows "Out" and therefore is outside the specified range.

SELECT ProductName, UnitPrice FROM Products
WHERE ProductName Between 'Cha' And 'Out';
The following example selects orders placed during the first half of 1995:

SELECT OrderID, OrderDate FROM Orders
WHERE OrderDate Between #1-1-95# And #6-30-95#;
The next example selects orders shipped to Idaho, Oregon, or Washington:

SELECT OrderID, ShipRegion FROM Orders
WHERE ShipRegion In ('ID', 'OR', 'WA');