德哥
2016-03-31
1825浏览量
Unlike regular triggers, which are attached to a single table and capture only DML events, event triggers are global to a particular database and are capable of capturing DDL events.
Command: CREATE EVENT TRIGGER
Description: define a new event trigger
Syntax:
CREATE EVENT TRIGGER name
ON event
[ WHEN filter_variable IN (filter_value [, ... ]) [ AND ... ] ]
EXECUTE PROCEDURE function_name()
The ddl_command_start event occurs just before the execution of a CREATE, ALTER, or DROP command. As an exception, however, this event does not occur for DDL commands targeting shared objects - databases, roles, and tablespaces - or for command targeting event triggers themselves. The event trigger mechanism does not support these object types. ddl_command_start also occurs just before the execution of a SELECT INTO command, since this is equivalent to CREATE TABLE AS.
The ddl_command_end event occurs just after the execution of this same set of commands.
PL/pgSQL can be used to define event triggers. PostgreSQL requires that a procedure that is to be called as an event trigger must be declared as a function with no arguments and a return type of event_trigger.
When a PL/pgSQL function is called as a event trigger, several special variables are created automatically in the top-level block. They are:
TG_EVENT
Data type text; a string representing the event the trigger is fired for.
TG_TAG
Data type text; variable that contains the command tag for which the trigger is fired.
CREATE OR REPLACE FUNCTION etgr1()
RETURNS event_trigger
LANGUAGE plpgsql
AS $$
BEGIN
RAISE NOTICE 'this is etgr1, event:%, command:%', tg_event, tg_tag;
END;
$$;
CREATE OR REPLACE FUNCTION etgr2()
RETURNS event_trigger
LANGUAGE plpgsql
AS $$
BEGIN
RAISE NOTICE 'this is etgr2, event:%, command:%', tg_event, tg_tag;
END;
$$;
CREATE EVENT TRIGGER b ON ddl_command_start EXECUTE PROCEDURE etgr1();
CREATE EVENT TRIGGER a ON ddl_command_start EXECUTE PROCEDURE etgr2();
digoal=# create table digoal(id int);
NOTICE: this is etgr2, event:ddl_command_start, command:CREATE TABLE
NOTICE: this is etgr1, event:ddl_command_start, command:CREATE TABLE
CREATE TABLE
digoal=# select * from pg_event_trigger ;
evtname | evtevent | evtowner | evtfoid | evtenabled | evttags
---------+-------------------+----------+---------+------------+---------
b | ddl_command_start | 10 | 16669 | O |
a | ddl_command_start | 10 | 16671 | O |
(2 rows)
digoal=# select rolname from pg_roles where oid=10;
rolname
----------
postgres
(1 row)
digoal=# select proname from pg_proc where oid=16669;
proname
---------
etgr1
(1 row)
digoal=# select proname from pg_proc where oid=16671;
proname
---------
etgr2
(1 row)
digoal=# create or replace function abort1() returns event_trigger as $$
declare
begin
raise exception 'event:%, command:%. abort.', TG_EVENT, TG_TAG;
end;
$$ language plpgsql;
digoal=# create event trigger tg_abort1 on ddl_command_end execute procedure abort1();
CREATE EVENT TRIGGER
digoal=# create table digoal1(id int);
NOTICE: this is etgr2, event:ddl_command_start, command:CREATE TABLE
NOTICE: this is etgr1, event:ddl_command_start, command:CREATE TABLE
ERROR: event:ddl_command_end, command:CREATE TABLE. abort.
digoal=# \d digoal1
Did not find any relation named "digoal1".
digoal=# create event trigger tg_abort2 on ddl_command_start execute procedure abort1();
CREATE EVENT TRIGGER
digoal=# create table digoal1(id int);
NOTICE: this is etgr2, event:ddl_command_start, command:CREATE TABLE
NOTICE: this is etgr1, event:ddl_command_start, command:CREATE TABLE
ERROR: event:ddl_command_start, command:CREATE TABLE. abort.
digoal=# create event trigger abort2 on ddl_command_start execute procedure abort1();
CREATE EVENT TRIGGER
digoal=# create table digoal1(id int);
NOTICE: this is etgr2, event:ddl_command_start, command:CREATE TABLE
ERROR: event:ddl_command_start, command:CREATE TABLE. abort.
digoal=# \d digoal1
Did not find any relation named "digoal1".
digoal=# select * from pg_event_trigger ;
evtname | evtevent | evtowner | evtfoid | evtenabled | evttags
-----------+-------------------+----------+---------+------------+---------
b | ddl_command_start | 10 | 16669 | O |
a | ddl_command_start | 10 | 16671 | O |
tg_abort1 | ddl_command_end | 10 | 16676 | O |
tg_abort2 | ddl_command_start | 10 | 16676 | O |
abort2 | ddl_command_start | 10 | 16676 | O |
(5 rows)
digoal=# drop event trigger tg_abort1;
DROP EVENT TRIGGER
digoal=# drop event trigger tg_abort2;
DROP EVENT TRIGGER
digoal=# drop event trigger abort2;
DROP EVENT TRIGGER
digoal=# drop event trigger a;
DROP EVENT TRIGGER
digoal=# drop event trigger b;
DROP EVENT TRIGGER
digoal=# select * from pg_event_trigger ;
evtname | evtevent | evtowner | evtfoid | evtenabled | evttags
---------+----------+----------+---------+------------+---------
(0 rows)
CREATE OR REPLACE FUNCTION abort()
RETURNS event_trigger
LANGUAGE plpgsql
AS $$
BEGIN
if current_user = 'postgres' then
RAISE EXCEPTION 'event:%, command:%', tg_event, tg_tag;
end if;
END;
$$;
digoal=# create event trigger a on ddl_command_start when TAG IN ('CREATE TABLE', 'DROP TABLE') execute procedure abort();
CREATE EVENT TRIGGER
digoal=# select * from pg_event_trigger ;
evtname | evtevent | evtowner | evtfoid | evtenabled | evttags
---------+-------------------+----------+---------+------------+-------------------------------
a | ddl_command_start | 10 | 16683 | O | {"CREATE TABLE","DROP TABLE"}
(1 row)
digoal=# \c digoal postgres
You are now connected to database "digoal" as user "postgres".
-- 无法新建表了
digoal=# create table new(id int);
ERROR: event:ddl_command_start, command:CREATE TABLE
digoal=# \d new
Did not find any relation named "new".
digoal=# \dt
List of relations
Schema | Name | Type | Owner
--------+---------+-------+----------
public | digoal | table | postgres
public | digoal1 | table | postgres
public | test | table | postgres
(3 rows)
-- 无法删表了
digoal=# drop table digoal;
ERROR: event:ddl_command_start, command:DROP TABLE
digoal=# \d digoal
Table "public.digoal"
Column | Type | Modifiers
--------+---------+-----------
id | integer |
digoal=# \c digoal digoal
You are now connected to database "digoal" as user "digoal".
digoal=> create table tbl(id int);
CREATE TABLE
digoal=> drop table tbl;
DROP TABLE
-- 未受到影响.
Command: ALTER EVENT TRIGGER
Description: change the definition of an event trigger
Syntax:
ALTER EVENT TRIGGER name DISABLE
ALTER EVENT TRIGGER name ENABLE [ REPLICA | ALWAYS ]
ALTER EVENT TRIGGER name OWNER TO new_owner
ALTER EVENT TRIGGER name RENAME TO new_name
/*
* RunObjectPostCreateHook
*
* It is entrypoint of OAT_POST_CREATE event
*/
void
RunObjectPostCreateHook(Oid classId, Oid objectId, int subId,
bool is_internal)
{
ObjectAccessPostCreate pc_arg;
/* caller should check, but just in case... */
Assert(object_access_hook != NULL);
memset(&pc_arg, 0, sizeof(ObjectAccessPostCreate));
pc_arg.is_internal = is_internal;
(*object_access_hook) (OAT_POST_CREATE,
classId, objectId, subId,
(void *) &pc_arg);
}
/* Core code uses these functions to call the hook (see macros below). */
extern void RunObjectPostCreateHook(Oid classId, Oid objectId, int subId,
bool is_internal);
extern void RunObjectDropHook(Oid classId, Oid objectId, int subId,
int dropflags);
extern void RunObjectPostAlterHook(Oid classId, Oid objectId, int subId,
Oid auxiliaryId, bool is_internal);
extern bool RunNamespaceSearchHook(Oid objectId, bool ereport_on_volation);
extern void RunFunctionExecuteHook(Oid objectId);
。。。。。。
/*
* The following macros are wrappers around the functions above; these should
* normally be used to invoke the hook in lieu of calling the above functions
* directly.
*/
#define InvokeObjectPostCreateHook(classId,objectId,subId) \
InvokeObjectPostCreateHookArg((classId),(objectId),(subId),false)
#define InvokeObjectPostCreateHookArg(classId,objectId,subId,is_internal) \
do { \
if (object_access_hook) \
RunObjectPostCreateHook((classId),(objectId),(subId), \
(is_internal)); \
} while(0)
。。。。。。
postgres=# create or replace function fe() returns event_trigger as $$
declare
begin
if current_user = 'digoal' then
raise exception 'can not execute ddl';
end if;
end;
$$ language plpgsql strict;
CREATE FUNCTION
postgres=# CREATE EVENT TRIGGER a ON ddl_command_start EXECUTE PROCEDURE fe();
CREATE EVENT TRIGGER
postgres=# \c postgres digoal
You are now connected to database "postgres" as user "digoal".
postgres=> create table tbl(id int);
ERROR: can not execute ddl
postgres=> do language plpgsql $$
postgres$> declare
postgres$> begin
postgres$> execute 'create table tbl (id int)';
postgres$> end;
postgres$> $$;
ERROR: can not execute ddl
CONTEXT: SQL statement "create table tbl (id int)"
PL/pgSQL function inline_code_block line 4 at EXECUTE statement
版权声明:本文内容由阿里云实名注册用户自发贡献,版权归原作者所有,阿里云开发者社区不拥有其著作权,亦不承担相应法律责任。具体规则请查看《阿里云开发者社区用户服务协议》和《阿里云开发者社区知识产权保护指引》。如果您发现本社区中有涉嫌抄袭的内容,填写侵权投诉表单进行举报,一经查实,本社区将立刻删除涉嫌侵权内容。
分享数据库前沿,解构实战干货,推动数据库技术变革