>
LEFT JOIN, RIGHT JOIN Operations
Description
Combines source-table records when used in any FROM
clause.
Syntax
FROM table1 [ LEFT | RIGHT ] JOIN table2
ON table1.field1 compopr table2.field2
The LEFT JOIN and RIGHT JOIN operations have these
parts.
Part |
Description |
|
table1, table2 |
The names of the tables from which
records are combined. |
field1, field2 |
The names of the fields that are joined.
The fields must be of the same data type and contain the
same kind of data, but they don't need to have the same
name. |
compopr |
Any relational comparison operator: =,
<, >, <=, >=, or <>. |
Remarks
Use a LEFT JOIN operation to create a left outer
join. Left outer joins include all of the records from the first
(left) of two tables, even if there are no matching values for
records in the second (right) table.
Use a RIGHT JOIN operation to create a right outer
join. Right outer joins include all of the records from the
second (right) of two tables, even if there are no matching
values for records in the first (left) table.
For example, you could use LEFT JOIN with the
Departments (left) and Employees (right) tables to select all
departments, including those that have no employees assigned to
them. To select all employees, including those who aren't
assigned to a department, you would use RIGHT JOIN.
The following example shows how you could join the
Categories and Products tables on the Category ID field. The
query produces a list of all categories, including those that
contain no products:
SELECT CategoryName, ProductName
FROM Categories LEFT JOIN Products
ON Categories.CategoryID = Products.CategoryID;
In this example, Category ID is the joined field,
but it isn't included in the query results because it isn't
included in the SELECT statement. To include the joined field,
enter the field name in the SELECT statement in this case,
Categories.CategoryID.
- Notes
- To create a query that includes only records in which the
data in the joined fields is the same, use an INNER JOIN
operation.
- A LEFT JOIN or a RIGHT JOIN can be nested inside an INNER
JOIN, but an INNER JOIN cannot be nested inside a LEFT
JOIN or a RIGHT JOIN. See the discussion of nesting in
the INNER JOIN topic to see how to nest joins within
other joins.
- You can link multiple ON clauses. See the discussion of
clause linking in the INNER JOIN topic to see how this is
done.
- If you try to join fields containing Memo or OLE Object
data, an error occurs.
See Also
INNER JOIN Operation, UNION Operation.
Example
These examples assume the existence of hypothetical
Department Name and Department ID fields in an Employees table.
This example selects all departments, including
those without employees.
SELECT [Department Name], FirstName & " " & LastName AS Name
FROM Departments LEFT JOIN Employees
ON Departments.[Department ID] = Employees.[Department ID]
ORDER BY [Department Name];
This example selects all employees, including those
not assigned to a department.
SELECT LastName & ", " & FirstName AS Name, [Department Name]
FROM Departments RIGHT JOIN Employees
ON Departments.[Department ID] = Employees.[Department ID]
ORDER BY LastName & ", " & FirstName;