Oracle使用DBMS_METADATA.GET_DDL获取对象的DDL语句

教程发布:风哥 教程分类:ITPUX技术网 更新日期:2022-02-12 浏览学习:632

Oracle使用DBMS_METADATA.GET_DDL获取对象的DDL语句

1、下面的语句用于查看单个表、索引、视图的ddl定义
--查看表table的ddl定义[color=purple]:[mw_shl_code=sql,true]set pagesize 0
set long 90000
set feedback off
set echo off
spool ddl.sql
select dbms_metadata.get_ddl('TABLE','TAB_NAME','SCOTT') from dual;
spool off;
[/mw_shl_code]

--查看索引index的ddl定义[color=purple]:[mw_shl_code=sql,true]set pagesize 0
set long 90000
set feedback off
set echo off
spool ddl.sql
select dbms_metadata.get_ddl('INDEX','IDX_NAME','SCOTT') from dual;
spool off;
[/mw_shl_code]

--查看视图view的ddl定义[color=purple]:[mw_shl_code=sql,true]set pagesize 0
set long 90000
set feedback off
set echo off
spool ddl.sql
select dbms_metadata.get_ddl('VIEW','VIEW_NAME','SCOTT') from dual;
spool off;[/mw_shl_code]

--查看存储过程procedure的dll定义:
[color=purple][mw_shl_code=sql,true]set pagesize 0
set long 90000
set feedback off
set echo off
spool ddl.sql
SELECT DBMS_METADATA.GET_DDL('PROCEDURE', U.object_name) FROM User_objects U WHERE object_type='PROCEDURE';
spool off;
[/mw_shl_code]

2. 获取一个SCHEMA下的所有建表、视图和建索引的语法
[color=purple][mw_shl_code=sql,true]set pagesize 0
set long 90000
set feedback off
set echo off
spool schema.sql
connect scott/tiger;
SELECT DBMS_METADATA.GET_DDL('TABLE',u.table_name) FROM USER_TABLES u;
SELECT DBMS_METADATA.GET_DDL('VIEW',u.VIEW_name) FROM USER_VIEWS u;
SELECT DBMS_METADATA.GET_DDL('INDEX',u.index_name) FROM USER_INDEXES u;
spool off;
[/mw_shl_code]

3. 获取某个SCHEMA的建全部存储过程的语法
[color=purple][mw_shl_code=sql,true]set pagesize 0
set long 90000
set feedback off
set echo off
spool procedures.sql
select DBMS_METADATA.GET_DDL('PROCEDURE',u.object_name) from user_objects u where object_type = 'PROCEDURE';
spool off;[/mw_shl_code]

4. 获取某个SCHEMA的建全部函数的语法
[color=purple][mw_shl_code=sql,true]set pagesize 0
set long 90000
set feedback off
set echo off
spool function.sql
select DBMS_METADATA.GET_DDL('FUNCTION',u.object_name) from user_objects u where object_type = 'FUNCTION';
spool off;[/mw_shl_code]

5、dbms_metadata.get_ddl使用说明
使用说明:dbms_metadata.get_ddl('VIEW','VIEW_NAME','SCOTT') 这三个参数的介绍:
第一个指定导出DDL定义的对象类型(此例中为表类型)
第二个是对象名(此例中即表名)
第三个是对象所在的用户名

6、掌见问题及解决方法
1)常见问题1
SQL> select dbms_metadata.get_ddl('TABLE','PC','SCOTT') from dual;
ERROR:
ORA-19206: Invalid value for query or REF CURSOR parameter
ORA-06512: at "SYS.DBMS_XMLGEN", line 83
ORA-06512: at "SYS.DBMS_METADATA", line 345
ORA-06512: at "SYS.DBMS_METADATA", line 410
ORA-06512: at "SYS.DBMS_METADATA", line 449
ORA-06512: at "SYS.DBMS_METADATA", line 615
ORA-06512: at "SYS.DBMS_METADATA", line 1221
ORA-06512: at line 1

no rows selected

SQL>
解决办法:运行$ORACLE_HOME/rdbms/admin/catmeta.sql

2)常见错误2
今天在一个数据库上执行DBMS_METADATA包的时候,出现了ORA-19206的错误。
具体错误信息如下:

SQL> SELECT DBMS_METADATA.GET_DDL('MATERIALIZED_VIEW', 'CAT_AUTH_GMP', 'NDMAIN') FROM DUAL;
ERROR:
ORA-19206: Invalid value for query or REF CURSOR parameter
ORA-06512: at "SYS.DBMS_XMLGEN", line 83
ORA-06512: at "SYS.DBMS_METADATA", line 345
ORA-06512: at "SYS.DBMS_METADATA", line 410
ORA-06512: at "SYS.DBMS_METADATA", line 449
ORA-06512: at "SYS.DBMS_METADATA", line 615
ORA-06512: at "SYS.DBMS_METADATA", line 1221
ORA-06512: at line 1
no rows selected

仔细检查了一下,发现所有和物化视图相关的表在执行DBMS_METADATA.GET_DDL时都会出现上面的错误,而其他的对象并没有受到影响。
由于这个数据库的数据是通过EXP/IMP迁移得到的,虽然在IMP过程中没有什么明显的错误信息,但是仍然怀疑是EXP/IMP造成的数据字典出现了错误。
查询了一下METALINK信息,发现了很多类似的错误,而Oracle给出的解决方法是重装XDB。

于是尝试重装XML方案:

首先以SYSDBA身份登陆,关闭并重启数据库,为卸载XML对象做准备:

SQL> CONN / AS SYSDBA
Connected.
SQL> SHUTDOWN IMMEDIATE
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> STARTUP
ORACLE instance started.

Total System Global Area 5876197568 bytes
Fixed Size 739520 bytes
Variable Size 503316480 bytes
Database Buffers 5368709120 bytes
Redo Buffers 3432448 bytes
Database mounted.
Database opened.
SQL> SET ECHO ON
SQL> SPO XDB_REMOVAL.LOG
SQL> @?/rdbms/admin/catnoqm.sql
SQL> Rem
SQL> Rem $Header: catnoqm.sql 03-jan-2002.17:32:31 spannala Exp $
SQL> Rem
SQL> Rem catnoqm.sql
SQL> Rem
SQL> Rem Copyright (c) 2001, 2002, Oracle Corporation. All rights reserved.
SQL> Rem
SQL> Rem NAME
SQL> Rem catnoqm.sql - CATalog script for removing (NO) XDB
SQL> Rem
SQL> Rem DESCRIPTION
SQL> Rem this script drops the metadata created for SQL XML management
SQL> Rem This scirpt must be invoked as sys. It is to be invoked as
SQL> Rem
SQL> Rem @@catnoqm
SQL> Rem NOTES
SQL> Rem
SQL> Rem MODIFIED (MM/DD/YY)
SQL> Rem spannala 01/03/02 - tables are not handled by xdb
SQL> Rem spannala 01/02/02 - registry
SQL> Rem spannala 12/20/01 - passing in the resource tablespace name
SQL> Rem tsingh 11/17/01 - remove connection string
SQL> Rem tsingh 06/30/01 - XDB: XML Database merge
SQL> Rem amanikut 02/13/01 - Creation
SQL> Rem
SQL> Rem
SQL>
SQL> execute dbms_registry.removing('XDB');
BEGIN dbms_registry.removing('XDB'); END;
*
ERROR at line 1:
ORA-01403: no data found
ORA-06512: at "SYS.DBMS_REGISTRY", line 420
ORA-06512: at line 1

SQL> drop user xdb cascade;
User dropped.

SQL> SPO OFF
从上面脚本调用的结果可以确定,XML对象在执行导入时没有注册成功,可能这就是导致错误产生的原因。

保证JAVA池和共享池都大于150M,且XDB表空间可扩展,或者大于150M。则可以重启系统。

SQL> SHUTDOWN IMMEDIATE
Database closed.
Database dismounted.
ORACLE instance shut down.
SQL> STARTUP
ORACLE instance started.

Total System Global Area 5876197568 bytes
Fixed Size 739520 bytes
Variable Size 503316480 bytes
Database Buffers 5368709120 bytes
Redo Buffers 3432448 bytes
Database mounted.
Database opened.

下面重新安装XML方案:

SQL> SET ECHO ON
SQL> SPO XDB_INSTALL.LOG
SQL> @?/rdbms/admin/catqm.sql XDBPASSWD XDB TEMP

调用catqm.sql时,后面的三个参数依次时XDB用户的密码、默认表空间和临时镖客。

SQL> @?/rdbms/admin/catxdbj.sql

然后继续执行上面的SQL:

然后检查XDB用户是否存在错误对象,以及XDB是否注册到数据库中:

SQL> SELECT COUNT(*) FROM DBA_OBJECTS WHERE OWNER = 'XDB' AND STATUS = 'INVALID';

COUNT(*)
----------
0

SQL> SELECT COMP_NAME, STATUS, VERSION FROM DBA_REGISTRY WHERE COMP_NAME = 'Oracle XML Database';

COMP_NAME STATUS VERSION
---------------------------------------- ----------- --------------------
Oracle XML Database VALID 9.2.0.4.0

下面重启数据库和监听,XDB重装完毕。
重建XDB之后,对DBMS_METADATA的访问恢复正常:

SQL> SELECT DBMS_METADATA.GET_DDL('MATERIALIZED_VIEW', 'CAT_AUTH_GMP', 'NDMAIN') FROM DUAL;

DBMS_METADATA.GET_DDL('MATERIALIZED_VIEW','CAT_AUTH_GMP','NDMAIN')
------------------------------------------------------------------

CREATE MATERIALIZED VIEW "NDMAIN"."CAT_AUTH_GMP"
ORGANIZATION HEAP PCTFREE

本文标签:
网站声明:本文由风哥整理发布,转载请保留此段声明,本站所有内容将不对其使用后果做任何承诺,请读者谨慎使用!
【上一篇】
【下一篇】