postgresql/src/pl/plperl/sql/plperl_trigger.sql
Tom Lane 2ec993a7cb Support triggers on views.
This patch adds the SQL-standard concept of an INSTEAD OF trigger, which
is fired instead of performing a physical insert/update/delete.  The
trigger function is passed the entire old and/or new rows of the view,
and must figure out what to do to the underlying tables to implement
the update.  So this feature can be used to implement updatable views
using trigger programming style rather than rule hacking.

In passing, this patch corrects the names of some columns in the
information_schema.triggers view.  It seems the SQL committee renamed
them somewhere between SQL:99 and SQL:2003.

Dean Rasheed, reviewed by Bernd Helmle; some additional hacking by me.
2010-10-10 13:45:07 -04:00

132 lines
3.3 KiB
PL/PgSQL

-- test plperl triggers
CREATE TABLE trigger_test (
i int,
v varchar
);
CREATE OR REPLACE FUNCTION trigger_data() RETURNS trigger LANGUAGE plperl AS $$
# make sure keys are sorted for consistent results - perl no longer
# hashes in repeatable fashion across runs
foreach my $key (sort keys %$_TD)
{
my $val = $_TD->{$key};
# relid is variable, so we can not use it repeatably
$val = "bogus:12345" if $key eq 'relid';
if (! defined $val)
{
elog(NOTICE, "\$_TD->\{$key\} = NULL");
}
elsif (not ref $val)
{
elog(NOTICE, "\$_TD->\{$key\} = '$val'");
}
elsif (ref $val eq 'HASH')
{
my $str = "";
foreach my $rowkey (sort keys %$val)
{
$str .= ", " if $str;
my $rowval = $val->{$rowkey};
$str .= "'$rowkey' => '$rowval'";
}
elog(NOTICE, "\$_TD->\{$key\} = \{$str\}");
}
elsif (ref $val eq 'ARRAY')
{
my $str = "";
foreach my $argval (@$val)
{
$str .= ", " if $str;
$str .= "'$argval'";
}
elog(NOTICE, "\$_TD->\{$key\} = \[$str\]");
}
}
return undef; # allow statement to proceed;
$$;
CREATE TRIGGER show_trigger_data_trig
BEFORE INSERT OR UPDATE OR DELETE ON trigger_test
FOR EACH ROW EXECUTE PROCEDURE trigger_data(23,'skidoo');
insert into trigger_test values(1,'insert');
update trigger_test set v = 'update' where i = 1;
delete from trigger_test;
DROP TRIGGER show_trigger_data_trig on trigger_test;
insert into trigger_test values(1,'insert');
CREATE VIEW trigger_test_view AS SELECT * FROM trigger_test;
CREATE TRIGGER show_trigger_data_trig
INSTEAD OF INSERT OR UPDATE OR DELETE ON trigger_test_view
FOR EACH ROW EXECUTE PROCEDURE trigger_data(24,'skidoo view');
insert into trigger_test_view values(2,'insert');
update trigger_test_view set v = 'update' where i = 1;
delete from trigger_test_view;
DROP VIEW trigger_test_view;
delete from trigger_test;
DROP FUNCTION trigger_data();
CREATE OR REPLACE FUNCTION valid_id() RETURNS trigger AS $$
if (($_TD->{new}{i}>=100) || ($_TD->{new}{i}<=0))
{
return "SKIP"; # Skip INSERT/UPDATE command
}
elsif ($_TD->{new}{v} ne "immortal")
{
$_TD->{new}{v} .= "(modified by trigger)";
return "MODIFY"; # Modify tuple and proceed INSERT/UPDATE command
}
else
{
return; # Proceed INSERT/UPDATE command
}
$$ LANGUAGE plperl;
CREATE TRIGGER "test_valid_id_trig" BEFORE INSERT OR UPDATE ON trigger_test
FOR EACH ROW EXECUTE PROCEDURE "valid_id"();
INSERT INTO trigger_test (i, v) VALUES (1,'first line');
INSERT INTO trigger_test (i, v) VALUES (2,'second line');
INSERT INTO trigger_test (i, v) VALUES (3,'third line');
INSERT INTO trigger_test (i, v) VALUES (4,'immortal');
INSERT INTO trigger_test (i, v) VALUES (101,'bad id');
SELECT * FROM trigger_test;
UPDATE trigger_test SET i = 5 where i=3;
UPDATE trigger_test SET i = 100 where i=1;
SELECT * FROM trigger_test;
CREATE OR REPLACE FUNCTION immortal() RETURNS trigger AS $$
if ($_TD->{old}{v} eq $_TD->{args}[0])
{
return "SKIP"; # Skip DELETE command
}
else
{
return; # Proceed DELETE command
};
$$ LANGUAGE plperl;
CREATE TRIGGER "immortal_trig" BEFORE DELETE ON trigger_test
FOR EACH ROW EXECUTE PROCEDURE immortal('immortal');
DELETE FROM trigger_test;
SELECT * FROM trigger_test;