Explanation of "Ambiguous Outer Joins" Error MessageID: Q124937
|
This article discusses the error message:
This error message occurs when you try to run a query that contains certain combinations of joins. (The three types of joins in Microsoft Access are left outer joins, right outer joins, and equi-joins.) For example, running the following query results in the error message:The SQL statement couldn't be executed because it contains ambiguous outer joins.
Consultants ---> Active Consultants ---- Projects
The SQL statement for this query reads:
Consultants LEFT JOIN [Active Consultants] EQUI-JOIN Projects
The Microsoft Access Help topic for the error message states:
The sample query above (Consultants LEFT JOIN [Active Consultants] EQUI- JOIN Projects) can be processed in two ways. The result of the left outer join between the Consultants and Active Consultants tables can be equi-joined to the Projects table:You tried to execute an SQL statement that contains multiple joins; the results of the query can differ depending on the order in which the joins are performed.
(Consultants ---> Active Consultants) ---- Projects
Or, the Consultants table can be left outer joined to the result of the
equi-join between the Active Consultants and Projects tables:
Consultants ---> (Active Consultants ---- Projects)
You must specify which method should be used by changing one of the joins
or by separating the query into two queries.
Table: Consultants
---------------------
Field Name: ConsID
Data Type: AutoNumber
Field Name: FName
Data Type: Text
Primary Key: ConsID
Table: Active Consultants
--------------------------
Field Name: ConsID
Data Type: Number
FieldSize: Long Integer
Field Name: ProjID
Data Type: Text
Field Name: StartDate
Data Type: Date/Time
Primary Key: none
Table: Projects
------------------
Field Name: ProjID
Data Type: Text
Field Name: Desc
Data Type: Text
Primary Key: ProjID
Consultants:
ConsID FName
-----------------
1 Taylor
2 Brad
3 Sharlene
4 Marla
Active Consultants:
ConsID ProjID StartDate
---------------------------
1 A1 7/8/95
2 D4 9/1/95
3 8/15/95
Projects:
ProjID Desc
-----------------------------
A1 ACME Payroll Upgrade
D4 Efficiency Study
Query: AllConsInfo
---------------------------------------------------------------
Type: Select Query
Join: [Consultants].[ConsID] ---> [Active Consultants].[ConsID]
Field: FName
Table: Consultants
Field: StartDate
Table: Active Consultants
Field: ProjID
Table: Active Consultants
NOTE: Make sure that the following property is selected for the join
(double-click the join line to check the join property):
Include ALL records from 'Consultants' and only those records from
'Active Consultants' where the joined fields are equal.
FName StartDate ProjID
-----------------------------
Taylor 7/8/95 A1
Brad 9/1/95 D4
Sharlene 8/15/95
Marla
Note the following items about the query's result:
- All the consultants are returned.
- If a consultant is active, his or her start date is returned.
- If a consultant is assigned to a project, the project ID is
returned.
Query: AllConsInfoAndProjects
------------------------------------------------------
Type: Select Query
Join: [AllConsInfo].[ProjID] <---> [Projects].[ProjID]
Field: FName
Table: AllConsInfo
Field: StartDate
Table: AllConsInfo
Field: Desc
Table: Projects
NOTE: Make sure that the join property is type 1.
FName StartDate Desc
-----------------------------------------
Taylor 7/8/95 ACME Payroll Upgrade
Brad 9/1/95 Efficiency Study
Query: ProjInfo
-------------------------------------------------------------
Type: Select Query
Join: [Active Consultants].[ProjID] <---> [Projects].[ProjID]
Field: ConsID
Table: Active Consultants
Field: StartDate
Table: Active Consultants
Field: Desc
Table: Projects
ConsID StartDate Desc
-----------------------------------------
1 7/8/95 ACME Payroll Upgrade
2 9/1/95 Efficiency Study
Query: ProjInfoAndConsultants
-----------------------------------------------------
Type: Select Query
Join: [ProjInfo].[ConsID] <--- [Consultants].[ConsID]
Field: FName
Table: Consultants
Field: StartDate
Table: ProjInfo
Field: Desc
Table: ProjInfo
NOTE: Make sure that the following property is selected for the join:
Include ALL records from 'Consultants' and only those records from
'ProjectInfo' where the joined fields are equal.
FName StartDate Desc
-------------------------------------------
Taylor 7/8/95 ACME Payroll Upgrade
Brad 9/1/95 Efficiency Study
Sharlene
Marla
Consultants ---> Active Consultants ---- Projects
Microsoft Access produces an error message because the query can be
processed in multiple ways.
OK : Consultants ---- Active Consultants ---- Projects
OK : Consultants ---- Active Consultants ---> Projects
ERR: Consultants ---- Active Consultants <--- Projects
ERR: Consultants ---> Active Consultants ---- Projects
OK : Consultants ---> Active Consultants ---> Projects
ERR: Consultants ---> Active Consultants <--- Projects
OK : Consultants <--- Active Consultants ---- Projects
OK : Consultants <--- Active Consultants ---> Projects
OK : Consultants <--- Active Consultants <--- Projects
There are three rules that can be derived from this table:
Additional query words: inf
Keywords : kberrmsg kbusage kbdta QryJoin
Version : WINDOWS:2.0,7.0,97
Platform : WINDOWS
Issue type : kbhowto
Last Reviewed: July 8, 1999