mirror of
https://github.com/postgres/postgres.git
synced 2025-06-11 20:28:21 +03:00
Offer triggers on foreign tables.
This covers all the SQL-standard trigger types supported for regular tables; it does not cover constraint triggers. The approach for acquiring the old row mirrors that for view INSTEAD OF triggers. For AFTER ROW triggers, we spool the foreign tuples to a tuplestore. This changes the FDW API contract; when deciding which columns to populate in the slot returned from data modification callbacks, writable FDWs will need to check for AFTER ROW triggers in addition to checking for a RETURNING clause. In support of the feature addition, refactor the TriggerFlags bits and the assembly of old tuples in ModifyTable. Ronan Dunklau, reviewed by KaiGai Kohei; some additional hacking by me.
This commit is contained in:
@ -390,3 +390,219 @@ insert into loc1(f2) values('bye');
|
||||
insert into rem1(f2) values('bye remote');
|
||||
select * from loc1;
|
||||
select * from rem1;
|
||||
|
||||
-- ===================================================================
|
||||
-- test local triggers
|
||||
-- ===================================================================
|
||||
|
||||
-- Trigger functions "borrowed" from triggers regress test.
|
||||
CREATE FUNCTION trigger_func() RETURNS trigger LANGUAGE plpgsql AS $$
|
||||
BEGIN
|
||||
RAISE NOTICE 'trigger_func(%) called: action = %, when = %, level = %',
|
||||
TG_ARGV[0], TG_OP, TG_WHEN, TG_LEVEL;
|
||||
RETURN NULL;
|
||||
END;$$;
|
||||
|
||||
CREATE TRIGGER trig_stmt_before BEFORE DELETE OR INSERT OR UPDATE ON rem1
|
||||
FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
|
||||
CREATE TRIGGER trig_stmt_after AFTER DELETE OR INSERT OR UPDATE ON rem1
|
||||
FOR EACH STATEMENT EXECUTE PROCEDURE trigger_func();
|
||||
|
||||
CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger
|
||||
LANGUAGE plpgsql AS $$
|
||||
|
||||
declare
|
||||
oldnew text[];
|
||||
relid text;
|
||||
argstr text;
|
||||
begin
|
||||
|
||||
relid := TG_relid::regclass;
|
||||
argstr := '';
|
||||
for i in 0 .. TG_nargs - 1 loop
|
||||
if i > 0 then
|
||||
argstr := argstr || ', ';
|
||||
end if;
|
||||
argstr := argstr || TG_argv[i];
|
||||
end loop;
|
||||
|
||||
RAISE NOTICE '%(%) % % % ON %',
|
||||
tg_name, argstr, TG_when, TG_level, TG_OP, relid;
|
||||
oldnew := '{}'::text[];
|
||||
if TG_OP != 'INSERT' then
|
||||
oldnew := array_append(oldnew, format('OLD: %s', OLD));
|
||||
end if;
|
||||
|
||||
if TG_OP != 'DELETE' then
|
||||
oldnew := array_append(oldnew, format('NEW: %s', NEW));
|
||||
end if;
|
||||
|
||||
RAISE NOTICE '%', array_to_string(oldnew, ',');
|
||||
|
||||
if TG_OP = 'DELETE' then
|
||||
return OLD;
|
||||
else
|
||||
return NEW;
|
||||
end if;
|
||||
end;
|
||||
$$;
|
||||
|
||||
-- Test basic functionality
|
||||
CREATE TRIGGER trig_row_before
|
||||
BEFORE INSERT OR UPDATE OR DELETE ON rem1
|
||||
FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
|
||||
|
||||
CREATE TRIGGER trig_row_after
|
||||
AFTER INSERT OR UPDATE OR DELETE ON rem1
|
||||
FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
|
||||
|
||||
delete from rem1;
|
||||
insert into rem1 values(1,'insert');
|
||||
update rem1 set f2 = 'update' where f1 = 1;
|
||||
update rem1 set f2 = f2 || f2;
|
||||
|
||||
|
||||
-- cleanup
|
||||
DROP TRIGGER trig_row_before ON rem1;
|
||||
DROP TRIGGER trig_row_after ON rem1;
|
||||
DROP TRIGGER trig_stmt_before ON rem1;
|
||||
DROP TRIGGER trig_stmt_after ON rem1;
|
||||
|
||||
DELETE from rem1;
|
||||
|
||||
|
||||
-- Test WHEN conditions
|
||||
|
||||
CREATE TRIGGER trig_row_before_insupd
|
||||
BEFORE INSERT OR UPDATE ON rem1
|
||||
FOR EACH ROW
|
||||
WHEN (NEW.f2 like '%update%')
|
||||
EXECUTE PROCEDURE trigger_data(23,'skidoo');
|
||||
|
||||
CREATE TRIGGER trig_row_after_insupd
|
||||
AFTER INSERT OR UPDATE ON rem1
|
||||
FOR EACH ROW
|
||||
WHEN (NEW.f2 like '%update%')
|
||||
EXECUTE PROCEDURE trigger_data(23,'skidoo');
|
||||
|
||||
-- Insert or update not matching: nothing happens
|
||||
INSERT INTO rem1 values(1, 'insert');
|
||||
UPDATE rem1 set f2 = 'test';
|
||||
|
||||
-- Insert or update matching: triggers are fired
|
||||
INSERT INTO rem1 values(2, 'update');
|
||||
UPDATE rem1 set f2 = 'update update' where f1 = '2';
|
||||
|
||||
CREATE TRIGGER trig_row_before_delete
|
||||
BEFORE DELETE ON rem1
|
||||
FOR EACH ROW
|
||||
WHEN (OLD.f2 like '%update%')
|
||||
EXECUTE PROCEDURE trigger_data(23,'skidoo');
|
||||
|
||||
CREATE TRIGGER trig_row_after_delete
|
||||
AFTER DELETE ON rem1
|
||||
FOR EACH ROW
|
||||
WHEN (OLD.f2 like '%update%')
|
||||
EXECUTE PROCEDURE trigger_data(23,'skidoo');
|
||||
|
||||
-- Trigger is fired for f1=2, not for f1=1
|
||||
DELETE FROM rem1;
|
||||
|
||||
-- cleanup
|
||||
DROP TRIGGER trig_row_before_insupd ON rem1;
|
||||
DROP TRIGGER trig_row_after_insupd ON rem1;
|
||||
DROP TRIGGER trig_row_before_delete ON rem1;
|
||||
DROP TRIGGER trig_row_after_delete ON rem1;
|
||||
|
||||
|
||||
-- Test various RETURN statements in BEFORE triggers.
|
||||
|
||||
CREATE FUNCTION trig_row_before_insupdate() RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
NEW.f2 := NEW.f2 || ' triggered !';
|
||||
RETURN NEW;
|
||||
END
|
||||
$$ language plpgsql;
|
||||
|
||||
CREATE TRIGGER trig_row_before_insupd
|
||||
BEFORE INSERT OR UPDATE ON rem1
|
||||
FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
|
||||
|
||||
-- The new values should have 'triggered' appended
|
||||
INSERT INTO rem1 values(1, 'insert');
|
||||
SELECT * from loc1;
|
||||
INSERT INTO rem1 values(2, 'insert') RETURNING f2;
|
||||
SELECT * from loc1;
|
||||
UPDATE rem1 set f2 = '';
|
||||
SELECT * from loc1;
|
||||
UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
|
||||
SELECT * from loc1;
|
||||
|
||||
DELETE FROM rem1;
|
||||
|
||||
-- Add a second trigger, to check that the changes are propagated correctly
|
||||
-- from trigger to trigger
|
||||
CREATE TRIGGER trig_row_before_insupd2
|
||||
BEFORE INSERT OR UPDATE ON rem1
|
||||
FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
|
||||
|
||||
INSERT INTO rem1 values(1, 'insert');
|
||||
SELECT * from loc1;
|
||||
INSERT INTO rem1 values(2, 'insert') RETURNING f2;
|
||||
SELECT * from loc1;
|
||||
UPDATE rem1 set f2 = '';
|
||||
SELECT * from loc1;
|
||||
UPDATE rem1 set f2 = 'skidoo' RETURNING f2;
|
||||
SELECT * from loc1;
|
||||
|
||||
DROP TRIGGER trig_row_before_insupd ON rem1;
|
||||
DROP TRIGGER trig_row_before_insupd2 ON rem1;
|
||||
|
||||
DELETE from rem1;
|
||||
|
||||
INSERT INTO rem1 VALUES (1, 'test');
|
||||
|
||||
-- Test with a trigger returning NULL
|
||||
CREATE FUNCTION trig_null() RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
RETURN NULL;
|
||||
END
|
||||
$$ language plpgsql;
|
||||
|
||||
CREATE TRIGGER trig_null
|
||||
BEFORE INSERT OR UPDATE OR DELETE ON rem1
|
||||
FOR EACH ROW EXECUTE PROCEDURE trig_null();
|
||||
|
||||
-- Nothing should have changed.
|
||||
INSERT INTO rem1 VALUES (2, 'test2');
|
||||
|
||||
SELECT * from loc1;
|
||||
|
||||
UPDATE rem1 SET f2 = 'test2';
|
||||
|
||||
SELECT * from loc1;
|
||||
|
||||
DELETE from rem1;
|
||||
|
||||
SELECT * from loc1;
|
||||
|
||||
DROP TRIGGER trig_null ON rem1;
|
||||
DELETE from rem1;
|
||||
|
||||
-- Test a combination of local and remote triggers
|
||||
CREATE TRIGGER trig_row_before
|
||||
BEFORE INSERT OR UPDATE OR DELETE ON rem1
|
||||
FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
|
||||
|
||||
CREATE TRIGGER trig_row_after
|
||||
AFTER INSERT OR UPDATE OR DELETE ON rem1
|
||||
FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
|
||||
|
||||
CREATE TRIGGER trig_local_before BEFORE INSERT OR UPDATE ON loc1
|
||||
FOR EACH ROW EXECUTE PROCEDURE trig_row_before_insupdate();
|
||||
|
||||
INSERT INTO rem1(f2) VALUES ('test');
|
||||
UPDATE rem1 SET f2 = 'testo';
|
||||
|
||||
-- Test returning system attributes
|
||||
INSERT INTO rem1(f2) VALUES ('test') RETURNING ctid, xmin, xmax;
|
||||
|
Reference in New Issue
Block a user