create sequence ddl_seq;
create table ddl_log (
id bigint not null primary key,
moment timestamp not null,
user_name varchar(63) not null,
event_type varchar(25) not null,
object_type varchar(25) not null,
ddl_event varchar(25) not null,
object_name varchar(63) not null,
sql_text blob sub_type text not null,
ok char(1) not null
);
set term !;
create trigger trig_ddl_log_before before any ddl statement
as
declare id type of column ddl_log.id;
begin
-- We do the changes in an AUTONOMOUS TRANSACTION, so if an exception happens
-- and the command didn't run, the log will survive.
in autonomous transaction do
begin
insert into ddl_log (id, moment, user_name, event_type, object_type,
ddl_event, object_name, sql_text, ok)
values (next value for ddl_seq, current_timestamp, current_user,
rdb$get_context('DDL_TRIGGER', 'EVENT_TYPE'),
rdb$get_context('DDL_TRIGGER', 'OBJECT_TYPE'),
rdb$get_context('DDL_TRIGGER', 'DDL_EVENT'),
rdb$get_context('DDL_TRIGGER', 'OBJECT_NAME'),
rdb$get_context('DDL_TRIGGER', 'SQL_TEXT'),
'N')
returning id into id;
rdb$set_context('USER_SESSION', 'trig_ddl_log_id', id);
end
end!