11gr2增强CREATE OR REPLACE TYPE功能

11.2对于CREATE OR REPLACE TYPE语句进行了增加,增加了FORCE选项。
在11.2之前,只要有其他的表或TYPE依赖了当前对象,这个对象就无法进行REPLACE了:

SQL> CREATE TYPE t_num_tab IS TABLE OF NUMBER;
2 /
TYPE created.
SQL> CREATE TYPE t_record IS object (id NUMBER, n_tab t_num_tab);
2 /
TYPE created.
SQL> CREATE OR REPLACE TYPE t_num_tab IS TABLE OF NUMBER(5);
2 /
CREATE OR REPLACE TYPE t_num_tab IS TABLE OF NUMBER(5);
*
ERROR at line 1:
ORA-02303: cannot DROP OR REPLACE a TYPE WITH TYPE OR TABLE dependents

这是11.2之前的情况,尝试执行CREATE OR REPLACE将会导致ORA-2303错误,在11.2中Oracle增加了FORCE功能,使得一个仅被TYPE所依赖的对象仍然可以执行REPLACE的操作:

SQL> CREATE OR REPLACE TYPE t_num_tab force IS TABLE OF NUMBER(5);
2 /
TYPE created.
SQL> SELECT * FROM v$version;
BANNER
--------------------------------------------------------------------------------
Oracle DATABASE 11g Enterprise Edition Release 11.2.0.3.0 - 64bit Production
PL/SQL Release 11.2.0.3.0 - Production
CORE 11.2.0.3.0 Production
TNS FOR Solaris: Version 11.2.0.3.0 - Production
NLSRTL Version 11.2.0.3.0 - Production

有意思的是,FORCE语句的位置不对则不会生效,这时同样会报ORA-2303的错误,而并不会导致语句错误:

SQL> CREATE OR REPLACE force TYPE t_num_tab IS TABLE OF NUMBER(5);
CREATE OR REPLACE force TYPE t_num_tab IS TABLE OF NUMBER(5)
*
ERROR at line 1:
ORA-02303: cannot DROP OR REPLACE a TYPE WITH TYPE OR TABLE dependents
 
SQL> CREATE OR REPLACE TYPE t_num_tab IS TABLE OF NUMBER(5) force;
2 /
CREATE OR REPLACE TYPE t_num_tab IS TABLE OF NUMBER(5) force;
*
ERROR at line 1:
ORA-02303: cannot DROP OR REPLACE a TYPE WITH TYPE OR TABLE dependents

最后这个功能只对被TYPE所依赖的对象有效,一旦对象被表所依赖,则FORCE功能也不起作用:

SQL> CREATE TABLE t_type_tab (id NUMBER, c_tab t_num_tab)
2 nested TABLE c_tab store AS c_tab_tab;
TABLE created.
SQL> CREATE OR REPLACE TYPE t_num_tab force IS TABLE OF NUMBER(6);
2 /
CREATE OR REPLACE TYPE t_num_tab force IS TABLE OF NUMBER(6);
*
ERROR at line 1:
ORA-22866: cannot REPLACE a TYPE WITH TABLE dependents

Oracle的错误信息也变成了ORA-22866。其实这时可以预料的,因为一旦创建了表,就相当于进行了实体化的工作,如果依赖的类型发生了变化,将会影响表中已有的数据的读写。不过其实Oracle可以做到更进一步,就是如果表段没有创建或者表中没有插入数据的情况下,允许对依赖的对象进行修改。

This entry was posted in ORACLE and tagged , , , , . Bookmark the permalink.

Leave a Reply

Your email address will not be published. Required fields are marked *