Oracle中Left Outer Join和外关联(+)的区别

数据库技术    2009-03-24 01:26  

外关联是Oracle数据库的专有语句

Left Outer Join则是SQL-92的标准语句

通常认为这两个SQL是可以等效的,但还是有些细微的差别。

一般说来,外关联的等值条件等效于Left Outer Join中的on语句;两个where中其他语句是一样的。

但是Left Outer Join中的其他条件(非表连接)出现在On关键词后面还是出现在Where关键词后面是不一样的,这样的语句很难用外关联进行同义转义。

 

下面我们先看一个测试数据,和一个测试案例

创建一个部门表和员工表

CREATE TABLE departments

(

depID  NUMBER(38,0),

depName VARCHAR2(20),

delFlag NUMBER(1,0)

);

 

CREATE TABLE employees

(

empID  NUMBER(38,0),

empName VARCHAR2(20),

depID  NUMBER(38,0),

delFlag NUMBER(1,0)

);

 

INSERT INTO departments VALUES(1,'Finacle',0);

INSERT INTO departments VALUES(2,'Marketing',0);

INSERT INTO departments VALUES(3,'HR',1);

INSERT INTO departments VALUES(4,'IT',0);

 

INSERT INTO employees VALUES(1,'wbq',1,0);

INSERT INTO employees VALUES(2,'czh',2,0);

INSERT INTO employees VALUES(3,'chh',1,0);

INSERT INTO employees VALUES(4,'wal',2,0);

INSERT INTO employees VALUES(5,'ddd',3,0);

 

COMMIT;

 

以下为测试例子

--列出部门ID3的部门和员工信息,不管该部门是否有员工

SELECT d.depID,d.depName,e.empName

FROM departments d

LEFT OUTER JOIN employees e

   ON d.depID = e.depID

WHERE d.depID =3

ORDER BY d.depID;

 

--和上面等效

SELECT d.depID,d.depName,e.empName

FROM departments d, employees e

WHERE d.depID = e.depID(+)

  AND d.depID =3

ORDER BY d.depID;

 

 

 

 

 

--当join on 后有过滤条件时,是先执行该过滤,然后将过滤后的结果再外连接

SELECT d.depID,d.depName,e.empName d.delflag

FROM departments d

LEFT OUTER JOIN employees e

   ON d.depID = e.depID AND e.depID=3

ORDER BY d.depID;

 

--等效的oracle SQL:

SELECT d.depID,d.depName,e.empName
FROM departments d, (select * from employees where depID =3 )e
WHERE d.depID = e.depID(+)
ORDER BY d.depID;

 

 

--where后的条件是在连接之后才进行的

SELECT d.depID,d.depName,e.empName,d.delflag

FROM departments d, employees e

WHERE d.depID = e.depID(+)

  AND (e.depID=3 or e.depID is NULL)

ORDER BY d.depID;

在线留言

我要留言