业务表:数据库DDL语句记录
create table SYS.DB_DDL_RECORD(
OPERATETIME timestamp(6)
,IP_ADDRESS varchar2(30 byte)
,HOSTNAME varchar2(30 byte)
,MODULE varchar2(30 byte)
,OPERATION varchar2(30 byte)
,OBJECT_TYPE varchar2(30 byte)
,OBJECT_NAME varchar2(61 byte)
,SQL_STMT clob
,DB_SCHEMA varchar2(30 byte)
,UUID varchar2(32 byte)default SYS_GUID() not null enable
,constraint DB_DDL_RECORD_PK primary key(UUID) using index
);
comment on column SYS.DB_DDL_RECORD.OPERATETIME is '操作时间';
comment on column SYS.DB_DDL_RECORD.IP_ADDRESS is 'ip地址';
comment on column SYS.DB_DDL_RECORD.HOSTNAME is '连接电脑机器名';
comment on column SYS.DB_DDL_RECORD.MODULE is '连接使用Application';
comment on column SYS.DB_DDL_RECORD.OPERATION is '操作类型';
comment on column SYS.DB_DDL_RECORD.OBJECT_TYPE is '数据库对象类型';
comment on column SYS.DB_DDL_RECORD.OBJECT_NAME is '数据库对象名称';
comment on column SYS.DB_DDL_RECORD.SQL_STMT is 'sql语句体';
comment on column SYS.DB_DDL_RECORD.DB_SCHEMA is '连接的schema';
comment on table SYS.DB_DDL_RECORD is '数据库DDL语句记录,有问题请联系Kindey.S,微信kindey123;
通过触发器实现记录
create or replace trigger DDL_RECORD
after ddl on database
/*
authro:Kindey.S
date:2018-07-23
version:1.0.0.0
describe:create
date:2018-07-23
version:1.0.1.0
describe:修复hostname取值错误问题
remark:recording for DDL operating.
*/
declare
pragma AUTONOMOUS_TRANSACTION;--开启自治事务
PART number;--长语句分段数量
STMT clob := null;--转换后的语句
SQL_TEXT ORA_NAME_LIST_T;--原始语句
begin
--长语句转换
PART := ORA_SQL_TXT(SQL_TEXT);
for i in 1 .. PART loop
STMT := STMT || SQL_TEXT(i);
end loop;
--插入记录
insert into DB_DDL_RECORD
(OPERATETIME, IP_ADDRESS, HOSTNAME, MODULE, OPERATION, OBJECT_TYPE, OBJECT_NAME, SQL_STMT,DB_SCHEMA)
values
(SYSTIMESTAMP,
SYS_CONTEXT('USERENV', 'IP_ADDRESS'),
SYS_CONTEXT('USERENV', 'HOST'),
SYS_CONTEXT('USERENV', 'MODULE'),
ORA_SYSEVENT,
ORA_DICT_OBJ_TYPE,
ORA_DICT_OBJ_NAME,
replace(STMT,CHR(0),''),
user
);
commit;
end;
/