diff options
author | Tom Lane <tgl@sss.pgh.pa.us> | 2017-09-16 15:31:26 -0400 |
---|---|---|
committer | Tom Lane <tgl@sss.pgh.pa.us> | 2017-09-16 15:31:26 -0400 |
commit | 936df5ba80a46fb40bfc93da49a709cbc0aafe5e (patch) | |
tree | 2d6c0c2af0abe2f558bae6f796a5bf83abb6dc3a | |
parent | 0f79440fb0b4c5a9baa9a95570c01828a9093802 (diff) | |
download | postgresql-936df5ba80a46fb40bfc93da49a709cbc0aafe5e.tar.gz postgresql-936df5ba80a46fb40bfc93da49a709cbc0aafe5e.zip |
Doc: add example of transition table use in a trigger.
I noticed that there were exactly no complete examples of use of
a transition table in a trigger function, and no clear description
of just how you'd do it either. Improve that.
-rw-r--r-- | doc/src/sgml/plpgsql.sgml | 78 | ||||
-rw-r--r-- | doc/src/sgml/trigger.sgml | 6 |
2 files changed, 81 insertions, 3 deletions
diff --git a/doc/src/sgml/plpgsql.sgml b/doc/src/sgml/plpgsql.sgml index 6dc438a1525..d18b48c40cc 100644 --- a/doc/src/sgml/plpgsql.sgml +++ b/doc/src/sgml/plpgsql.sgml @@ -4013,7 +4013,7 @@ CREATE OR REPLACE FUNCTION process_emp_audit() RETURNS TRIGGER AS $emp_audit$ BEGIN -- -- Create a row in emp_audit to reflect the operation performed on emp, - -- make use of the special variable TG_OP to work out the operation. + -- making use of the special variable TG_OP to work out the operation. -- IF (TG_OP = 'DELETE') THEN INSERT INTO emp_audit SELECT 'D', now(), user, OLD.*; @@ -4265,6 +4265,82 @@ UPDATE sales_fact SET units_sold = units_sold * 2; SELECT * FROM sales_summary_bytime; </programlisting> </example> + + <para> + <literal>AFTER</> triggers can also make use of <firstterm>transition + tables</> to inspect the entire set of rows changed by the triggering + statement. The <command>CREATE TRIGGER</> command assigns names to one + or both transition tables, and then the function can refer to those names + as though they were read-only temporary tables. + <xref linkend="plpgsql-trigger-audit-transition-example"> shows an example. + </para> + + <example id="plpgsql-trigger-audit-transition-example"> + <title>Auditing with Transition Tables</title> + + <para> + This example produces the same results as + <xref linkend="plpgsql-trigger-audit-example">, but instead of using a + trigger that fires for every row, it uses a trigger that fires once + per statement, after collecting the relevant information in a transition + table. This can be significantly faster than the row-trigger approach + when the invoking statement has modified many rows. Notice that we must + make a separate trigger declaration for each kind of event, since the + <literal>REFERENCING</> clauses must be different for each case. But + this does not stop us from using a single trigger function if we choose. + (In practice, it might be better to use three separate functions and + avoid the run-time tests on <varname>TG_OP</>.) + </para> + +<programlisting> +CREATE TABLE emp ( + empname text NOT NULL, + salary integer +); + +CREATE TABLE emp_audit( + operation char(1) NOT NULL, + stamp timestamp NOT NULL, + userid text NOT NULL, + empname text NOT NULL, + salary integer +); + +CREATE OR REPLACE FUNCTION process_emp_audit() RETURNS TRIGGER AS $emp_audit$ + BEGIN + -- + -- Create rows in emp_audit to reflect the operations performed on emp, + -- making use of the special variable TG_OP to work out the operation. + -- + IF (TG_OP = 'DELETE') THEN + INSERT INTO emp_audit + SELECT 'D', now(), user, o.* FROM old_table o; + ELSIF (TG_OP = 'UPDATE') THEN + INSERT INTO emp_audit + SELECT 'U', now(), user, n.* FROM new_table n; + ELSIF (TG_OP = 'INSERT') THEN + INSERT INTO emp_audit + SELECT 'I', now(), user, n.* FROM new_table n; + END IF; + RETURN NULL; -- result is ignored since this is an AFTER trigger + END; +$emp_audit$ LANGUAGE plpgsql; + +CREATE TRIGGER emp_audit_ins + AFTER INSERT ON emp + REFERENCING NEW TABLE AS new_table + FOR EACH STATEMENT EXECUTE PROCEDURE process_emp_audit(); +CREATE TRIGGER emp_audit_upd + AFTER UPDATE ON emp + REFERENCING OLD TABLE AS old_table NEW TABLE AS new_table + FOR EACH STATEMENT EXECUTE PROCEDURE process_emp_audit(); +CREATE TRIGGER emp_audit_del + AFTER DELETE ON emp + REFERENCING OLD TABLE AS old_table + FOR EACH STATEMENT EXECUTE PROCEDURE process_emp_audit(); +</programlisting> + </example> + </sect2> <sect2 id="plpgsql-event-trigger"> diff --git a/doc/src/sgml/trigger.sgml b/doc/src/sgml/trigger.sgml index a16256056f0..f5f74af5a17 100644 --- a/doc/src/sgml/trigger.sgml +++ b/doc/src/sgml/trigger.sgml @@ -317,9 +317,11 @@ be created to make the sets of affected rows available to the trigger. <literal>AFTER ROW</> triggers can also request transition tables, so that they can see the total changes in the table as well as the change in - the individual row they are currently being fired for. The syntax for + the individual row they are currently being fired for. The method for examining the transition tables again depends on the programming language - that is being used. + that is being used, but the typical approach is to make the transition + tables act like read-only temporary tables that can be accessed by SQL + commands issued within the trigger function. </para> </sect1> |