触发器概述
触发时机 | 触发事件 | 行级触发器 | 语句级触发器 |
---|---|---|---|
BEFORE | INSERT、UPDATE、DELETE | 表和外部表 | 表、视图和外部表 |
BEFORE | TRUNCATE | -- | 表 |
AFTER | INSERT、UPDATE、DELETE | 表和外部表 | 表、视图和外部表 |
AFTER | TRUNCATE | -- | 表 |
INSTEAD OF | INSERT、UPDATE、DELETE | 视图 | -- |
INSTEAD OF | TRUNCATE | -- | -- |
创建触发器
使用 CREATE FUNCTION 语句创建一个触发器函数;
使用 CREATE TRIGGER 语句将该函数与表进行关联。
CREATE [ OR REPLACE ] FUNCTION trigger_function ()
RETURNS trigger
AS $$
DECLARE
declarations
BEGIN
statements;
...
END; $$
LANGUAGE plpgsql;
NEW ,类型为 RECORD,代表了行级触发器 INSERT、UPDATE 操作之后的新数据行。对于 DELETE 操作或者语句级触发器而言,该变量为 null;
OLD,类型为 RECORD,代表了行级触发器 UPDATE、DELETE 操作之前的旧数据行。对于 INSERT 操作或者语句级触发器而言,该变量为 null;
TG_NAME,触发器的名称;
TG_WHEN,触发的时机,例如 BEFORE、AFTER 或者 INSTEAD OF;
TG_LEVEL,触发器的级别,ROW 或者 STATEMENT;
TG_OP,触发的操作,INSERT、UPDATE、DELETE 或者 TRUNCATE;
TG_RELID,触发器所在表的 oid;
TG_TABLE_NAME,触发器所在表的名称;
TG_TABLE_SCHEMA,触发器所在表的模式;
TG_NARGS,创建触发器时传递给触发器函数的参数个数;
TG_ARGV[],创建触发器时传递给触发器函数的具体参数,下标从 0 开始。非法的下标(小于 0 或者大于等于 tg_nargs)将会返回空值。
CREATE TRIGGER trigger_name
{BEFORE | AFTER | INSTEAD OF} {event [OR ...]}
ON table_name
[FOR [EACH] {ROW | STATEMENT}]
[WHEN ( condition ) ]
EXECUTE FUNCTION trigger_function;
create table employees_history (
id serial primary key,
employee_id int null,
first_name varchar(20) null,
last_name varchar(25) null,
email varchar(25) null,
phone_number varchar(20) null,
hire_date date null,
job_id varchar(10) null,
salary numeric(8,2) null,
commission_pct numeric(2,2) null,
manager_id int null,
department_id int null,
action_type varchar(10) not null,
change_dt timestamp not null
);
create or replace function track_employees_change()
returns trigger as
$$
begin
if tg_op = 'INSERT' then
insert into employees_history(employee_id, first_name, last_name, email, phone_number,
hire_date, job_id, salary, commission_pct, manager_id,
department_id, action_type, change_dt)
values(new.employee_id, new.first_name, new.last_name, new.email, new.phone_number,
new.hire_date, new.job_id, new.salary, new.commission_pct, new.manager_id,
new.department_id, 'INSERT', current_timestamp);
elsif tg_op = 'UPDATE' then
insert into employees_history(employee_id, first_name, last_name, email, phone_number,
hire_date, job_id, salary, commission_pct, manager_id,
department_id, action_type, change_dt)
values(old.employee_id, old.first_name, old.last_name, old.email, old.phone_number,
old.hire_date, old.job_id, old.salary, old.commission_pct, old.manager_id,
old.department_id, 'UPDATE', current_timestamp);
elsif tg_op = 'DELETE' then
insert into employees_history(employee_id, first_name, last_name, email, phone_number,
hire_date, job_id, salary, commission_pct, manager_id,
department_id, action_type, change_dt)
values(old.employee_id, old.first_name, old.last_name, old.email, old.phone_number,
old.hire_date, old.job_id, old.salary, old.commission_pct, old.manager_id,
old.department_id, 'DELETE', current_timestamp);
end if;
return new;
end; $$
language plpgsql;
create trigger trg_employees_change
before insert or update or delete
on employees
for each row
execute function track_employees_change();
insert into employees(employee_id, first_name, last_name, email, phone_number, hire_date, job_id, salary, commission_pct, manager_id, department_id)
values(207, 'Tony', 'Dong', 'TonyDong', '01066665678', '2020-05-25', 'IT_PROG', 6000, null, 103, 60);
select * from employees_history;
id|employee_id|first_name|last_name|email |phone_number|hire_date |job_id |salary |commission_pct|manager_id|department_id|action_type|change_dt |
--|-----------|----------|---------|--------|------------|----------|-------|-------|--------------|----------|-------------|-----------|-------------------|
1| 207|Tony |Dong |TonyDong|01066665678 |2020-05-25|IT_PROG|6000.00| | 103| 60|INSERT |2020-05-25 15:45:17|
管理触发器
ALTER TRIGGER name ON table_name RENAME TO new_name;
ALTER TABLE table_name
{ENABLE | DISABLE} TRIGGER {trigger_name | ALL | USER};
删除触发器
DROP TRIGGER [IF EXISTS] trigger_name
ON table_name [RESTRICT | CASCADE];
drop trigger trg_employees_change on employees;
事件触发器
TG_EVENT,触发事件;
TG_TAG,触发语句。
create or replace function abort_any_command()
returns event_trigger
as $$
begin
if (user != 'postgres') then
raise exception 'command % is disabled', tg_tag;
end if;
end; $$
language plpgsql;
create event trigger abort_ddl on ddl_command_start
execute function abort_any_command();
hrdb=# select user;
user
------
tony
(1 row)
hrdb=# create table t(id int);
ERROR: command CREATE TABLE is disabled
CONTEXT: PL/pgSQL function abort_any_command() line 4 at RAISE
ALTER EVENT TRIGGER name DISABLE;
ALTER EVENT TRIGGER name ENABLE;
ALTER EVENT TRIGGER name RENAME TO new_name;
DROP EVENT TRIGGER [ IF EXISTS ] name [ CASCADE | RESTRICT ];
DROP EVENT TRIGGER abort_ddl;