When you run a query based on two tables (in this example, table A
and table B) with an outer join to include all the records from table A,
and you apply a WHERE clause to table B, you expect to see all the records from table A and those records from table B that satisfy the WHERE clause. Instead, only those records from table B that satisfy the WHERE clause and have a matching value in table A are returned.
↑ Back to the top
When you run the query, the outer join is performed first, creating all the
records from table A. Then, the WHERE clause from table B is applied to all
the records, eliminating records from the query. The result set does not
contain all the records from table A, but contains only those for which the
condition is met for table B.
Unlike Microsoft Access, SQL Server currently processes the WHERE before
the join. This is because this feature was implemented before the ANSI
SQL-92 standard. Before then, there was no outer join spec at all.
Therefore, the same query can return different results against SQL
Server, depending on whether you use a Select query or a SQL pass-through
query (in which case SQL Server handles the query and simply returns
the results.)
↑ Back to the top
If you want to return all the records in table A, you can use two queries.
The first query should apply the WHERE clause to table B, and the second
query should combine table A with the first query to perform the outer
join.
↑ Back to the top
This type of query processing complies with the ANSI SQL 92 specification.
↑ Back to the top
Steps to Return the Expected Recordset
- Start Microsoft Access and open the sample database Northwind.mdb.
- Create a new query based on the Products table.
- Drag the CategoryID and ProductName fields from the Products field list to the query grid.
- In the Criteria row for the ProductName field, type Like A*.
- Save the query as Query1, and then close it.
- Create a new query based on the Categories table and the Query1 query.
- Drag the CategoryName field from the Categories field list to the query grid.
- Drag the ProductName field from the Query1 field list to the query grid.
- Double-click the join line. In the Join Properties box, click the Include ALL records from 'Categories'..." option button, and then click OK.
- Run the query.
Note that all the records from the Categories table are returned, with the ProductName field filled in for records and with a matching record in the Products table.
Steps to Reproduce Behavior
CAUTION: If you follow the steps in this example, you modify the sample database Northwind.mdb. You may want to back up the Northwind.mdb file and follow these steps on a copy of the database.
- Start Microsoft Access and open the sample database Northwind.mdb.
- Create a new query based on the Categories and the Products tables. The two tables should be joined on the CategoryID field.
- Double-click the join line between the two table field lists. In the Join Properties box, select the Include ALL records from 'Categories'... option button, and then click OK.
- Drag the CategoryName field from the Categories field list to the first column of the query grid.
- Drag the ProductName field from the Products field list to the second column of the query grid.
- In the Criteria row of the ProductName column, type Like A*.
- Run the query.
Note that not all the records from the Categories table are returned. Instead, only those records with a product name starting with the letter "A" are returned.
↑ Back to the top
For more information about relationships, click Microsoft Access Help on the
Help menu, type work with relationships in the Office Assistant or
the Answer Wizard, and then click Search to view the topics
returned.
↑ Back to the top