LEFT JOIN, RIGHT JOIN Operations (Microsoft Access SQL)
Last modified: March 09, 2015
Applies to: Access 2013 | Office 2013
In this article
Syntax
Remarks
Example
Combines source-table records when used in any FROM clause.
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 do not need to have the same name. |
|
compopr |
Any relational comparison operator: "=," "<," ">," "<=," ">=," or "<>." |
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 are not assigned to a department, you would use RIGHT JOIN.
The following example shows how you could join the Categories and Products tables on the CategoryID 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, CategoryID is the joined field, but it is not included in the query results because it is not included in the SELECT statement. To include the joined field, enter the field name in the SELECT statement — in this case, Categories.CategoryID.
Note |
|---|
|
This example assumes the existence of hypothetical Department Name and Department ID fields in an Employees table. Note that these fields do not actually exist in the Northwind database Employees table.
This example selects all departments, including those without employees.
This example calls the EnumFields procedure, which you can find in the SELECT statement example.
Sub LeftRightJoinX()
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 all departments, including those
' without employees.
Set rst = dbs.OpenRecordset _
("SELECT [Department Name], " _
& "FirstName & Chr(32) & LastName AS Name " _
& "FROM Departments LEFT JOIN Employees " _
& "ON Departments.[Department ID] = " _
& "Employees.[Department ID] " _
& "ORDER BY [Department Name];")
' Populate the Recordset.
rst.MoveLast
' Call EnumFields to print the contents of the
' Recordset. Pass the Recordset object and desired
' field width.
EnumFields rst, 20
dbs.Close
End Sub
Note