在Oracle数据库中,如何快速获取某个用户下的所有表、索引、约束及触发器的创建SQL语句呢?本文给出一个简单的示例脚本,经过测试,除位于回收站下的对象及只读视图的约束语句不能获取,其它对象基本均可获取CREATE语句。
脚本内容如下:
[oracle@oracledg ~]$ cat get_ddl.sql -- Be sure the variable 'S' means the Schema name,it should be UPPERCASE. -- And this script COULDNOT get the constraints CREATE DDL,which CONSTRAINT_TYPE is 'O',cause it's READ ONLY on a view. -- Author Info:Asher Huang -- http://OracleOnlinux.cn -- Mail:3dian14@gmail.com def S='&Schema' set serveroutput on set long 20000 set lines 2000 pages 0 ver off echo off head off feed off set newpage none set trimspool on set long 5000000 spool &S..sql DECLARE CURSOR C1 IS SELECT '&S' AS u_name, table_name AS tab_name FROM user_tables; CURSOR C2 IS SELECT '&S' AS u_name, index_name AS idx_name FROM user_indexes; CURSOR C3 IS SELECT '&S' AS u_name, constraint_name AS cons_name FROM user_constraints where constraint_type not in('R','O'); CURSOR C4 IS SELECT '&S' AS u_name, table_name AS tab_name FROM user_constraints where constraint_type in('R'); CURSOR C5 IS SELECT '&S' AS u_name, trigger_name AS trig_name FROM user_triggers; V_MSG CLOB; BEGIN DBMS_OUTPUT.put_line('The CREATE DDL for schema &S''s Tables are:'); FOR x IN C1 LOOP select dbms_metadata.get_ddl('TABLE', x.tab_name, x.u_name) INTO V_MSG from dual; DBMS_OUTPUT.put_line(V_MSG); END LOOP; DBMS_OUTPUT.put_line('The CREATE DDL for schema &S''s Indexes are:'); FOR x IN C2 LOOP select dbms_metadata.get_ddl('INDEX', x.idx_name, x.u_name) INTO V_MSG from dual; DBMS_OUTPUT.put_line(V_MSG); END LOOP; DBMS_OUTPUT.put_line('The CREATE DDL for schema &S''s Constraints are:'); FOR x IN C3 LOOP select dbms_metadata.get_ddl('CONSTRAINT', x.cons_name, x.u_name) INTO V_MSG from dual; DBMS_OUTPUT.put_line(V_MSG); END LOOP; DBMS_OUTPUT.put_line('The CREATE DDL for schema &S''s Reference Constraints are:'); FOR x IN C4 LOOP select dbms_metadata.get_dependent_ddl('REF_CONSTRAINT', x.tab_name, x.u_name) INTO V_MSG from dual; DBMS_OUTPUT.put_line(V_MSG); END LOOP; DBMS_OUTPUT.put_line('The CREATE DDL for schema &S''s Triggers are:'); FOR x IN C5 LOOP select dbms_metadata.get_ddl('TRIGGER', x.trig_name, x.u_name) INTO V_MSG from dual; DBMS_OUTPUT.put_line(V_MSG); END LOOP; END; / spool off; [oracle@oracledg ~]$
测试获取SCOTT用户的所有表、索引、约束、触发器创建脚本如下:
[oracle@oracledg ~]$ cat SCOTT.sql The CREATE DDL for schema SCOTT's Tables are: CREATE TABLE "SCOTT"."DEPT" ( "DEPTNO" NUMBER(2,0), "DNAME" VARCHAR2(14), "LOC" VARCHAR2(13), CONSTRAINT "PK_DEPT" PRIMARY KEY ("DEPTNO") USING INDEX PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" ENABLE ) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 NOCOMPRESS LOGGING STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" CREATE TABLE "SCOTT"."EMP" ( "EMPNO" NUMBER(4,0), "ENAME" VARCHAR2(10), "JOB" VARCHAR2(9), "MGR" NUMBER(4,0), "HIREDATE" DATE, "SAL" NUMBER(7,2), "COMM" NUMBER(7,2), "DEPTNO" NUMBER(2,0), CONSTRAINT "PK_EMP" PRIMARY KEY ("EMPNO") USING INDEX PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" ENABLE, CONSTRAINT "FK_DEPTNO" FOREIGN KEY ("DEPTNO") REFERENCES "SCOTT"."DEPT" ("DEPTNO") ENABLE ) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 NOCOMPRESS LOGGING STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" CREATE TABLE "SCOTT"."BONUS" ( "ENAME" VARCHAR2(10), "JOB" VARCHAR2(9), "SAL" NUMBER, "COMM" NUMBER ) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 NOCOMPRESS LOGGING STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" CREATE TABLE "SCOTT"."SALGRADE" ( "GRADE" NUMBER, "LOSAL" NUMBER, "HISAL" NUMBER ) PCTFREE 10 PCTUSED 40 INITRANS 1 MAXTRANS 255 NOCOMPRESS LOGGING STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" The CREATE DDL for schema SCOTT's Indexes are: CREATE UNIQUE INDEX "SCOTT"."PK_EMP" ON "SCOTT"."EMP" ("EMPNO") PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" CREATE UNIQUE INDEX "SCOTT"."PK_DEPT" ON "SCOTT"."DEPT" ("DEPTNO") PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" The CREATE DDL for schema SCOTT's Constraints are: ALTER TABLE "SCOTT"."EMP" ADD CONSTRAINT "PK_EMP" PRIMARY KEY ("EMPNO") USING INDEX PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" ENABLE ALTER TABLE "SCOTT"."DEPT" ADD CONSTRAINT "PK_DEPT" PRIMARY KEY ("DEPTNO") USING INDEX PCTFREE 10 INITRANS 2 MAXTRANS 255 COMPUTE STATISTICS STORAGE(INITIAL 65536 NEXT 1048576 MINEXTENTS 1 MAXEXTENTS 2147483645 PCTINCREASE 0 FREELISTS 1 FREELIST GROUPS 1 BUFFER_POOL DEFAULT) TABLESPACE "USERS" ENABLE The CREATE DDL for schema SCOTT's Reference Constraints are: ALTER TABLE "SCOTT"."EMP" ADD CONSTRAINT "FK_DEPTNO" FOREIGN KEY ("DEPTNO") REFERENCES "SCOTT"."DEPT" ("DEPTNO") ENABLE The CREATE DDL for schema SCOTT's Triggers are: [oracle@oracledg ~]$