客户的数据库从10.2.0.1升级到10.2.0.5后,出现了ORA-918错误,不过导致错误出现的原因并不是升级碰到了BUG,而是升级解决了BUG。
在Oracle 10.2.0.5中,解决了一个Bug 5368296 ANSI join SQL may not report ORA-918 for ambiguous column,结果原本客户受这个bug影响而没有报错的SQL语句,在升级之后开始大面积报错。
而解决办法除了修改SQL语句外,只有回退一个办法,Oracle显然不会为了重现一个bug而提供什么解决方案。当然这个问题的避免应该通过前期的测试来避免,不过这里还是关注一下这个bug。
在如果使用标准查询写法,当关联表的个数超过2个,且表都包含相同的列名,那么在查询的时候如果不指定这个列名的属主,是不会报错的。
SQL*Plus: Release 10.2.0.3.0 - Production ON Tue Nov 8 15:51:41 2011 Copyright (c) 1982, 2006, Oracle. ALL Rights Reserved. Connected TO: Oracle DATABASE 10g Enterprise Edition Release 10.2.0.3.0 - Production WITH the Partitioning, OLAP AND DATA Mining options SQL> CREATE USER u1 IDENTIFIED BY u1 DEFAULT tablespace users; USER created. SQL> GRANT CONNECT, resource TO u1; GRANT succeeded. SQL> conn u1/u1 Connected. SQL> CREATE TABLE t1 (id NUMBER); TABLE created. SQL> CREATE TABLE t2 (id NUMBER); TABLE created. SQL> CREATE TABLE t3 (id NUMBER); TABLE created. SQL> SELECT id FROM t1, t2, t3 WHERE t1.id = t2.id AND t1.id = t3.id; SELECT id FROM t1, t2, t3 WHERE t1.id = t2.id AND t1.id = t3.id * ERROR at line 1: ORA-00918: COLUMN ambiguously defined SQL> SELECT id FROM t1 JOIN t2 ON t1.id = t2.id JOIN t3 ON t1.id = t3.id; no ROWS selected SQL> SELECT id FROM t1 JOIN t2 ON t1.id = t2.id; SELECT id FROM t1 JOIN t2 ON t1.id = t2.id * ERROR at line 1: ORA-00918: COLUMN ambiguously defined |
可以看到,Oracle的写法不存在这个问题,而如果使用标准SQL写法,在表连接数超过2张的时候,就会引发bug,Oracle会忽略列重名问题。
SQL> ALTER TABLE t3 ADD (id1 NUMBER); TABLE altered. SQL> SELECT id FROM t1 JOIN t2 ON t1.id = t2.id JOIN t3 ON t1.id = t3.id1; no ROWS selected SQL> ALTER TABLE t3 DROP (id); TABLE altered. SQL> SELECT id FROM t1 JOIN t2 ON t1.id = t2.id JOIN t3 ON t1.id = t3.id1; SELECT id FROM t1 JOIN t2 ON t1.id = t2.id JOIN t3 ON t1.id = t3.id1 * ERROR at line 1: ORA-00918: COLUMN ambiguously defined |
测试还发现,导致问题的原因只和表中是否存在列有关,而与是否是连接列没有关系,因此必须三张或以上的表拥有相同的列名,才会引发这个bug。