Home Explore Blog CI



postgresql

57th chunk of `doc/src/sgml/plpgsql.sgml`
226dbaac304e856f88af840a8d5d942042f62dba5e088d7e0000000100000fa8
   integer
);

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,
        -- 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(), current_user, OLD.*;
        ELSIF (TG_OP = 'UPDATE') THEN
            INSERT INTO emp_audit SELECT 'U', now(), current_user, NEW.*;
        ELSIF (TG_OP = 'INSERT') THEN
            INSERT INTO emp_audit SELECT 'I', now(), current_user, NEW.*;
        END IF;
        RETURN NULL; -- result is ignored since this is an AFTER trigger
    END;
$emp_audit$ LANGUAGE plpgsql;

CREATE TRIGGER emp_audit
AFTER INSERT OR UPDATE OR DELETE ON emp
    FOR EACH ROW EXECUTE FUNCTION process_emp_audit();
</programlisting>
   </example>

   <para>
    A variation of the previous example uses a view joining the main table
    to the audit table, to show when each entry was last modified. This
    approach still records the full audit trail of changes to the table,
    but also presents a simplified view of the audit trail, showing just
    the last modified timestamp derived from the audit trail for each entry.
    <xref linkend="plpgsql-view-trigger-audit-example"/> shows an example
    of an audit trigger on a view in <application>PL/pgSQL</application>.
   </para>

   <example id="plpgsql-view-trigger-audit-example">
    <title>A <application>PL/pgSQL</application> View Trigger Function for Auditing</title>

    <para>
     This example uses a trigger on the view to make it updatable, and
     ensure that any insert, update or delete of a row in the view is
     recorded (i.e., audited) in the <literal>emp_audit</literal> table. The current time
     and user name are recorded, together with the type of operation
     performed, and the view displays the last modified time of each row.
    </para>

<programlisting>
CREATE TABLE emp (
    empname           text PRIMARY KEY,
    salary            integer
);

CREATE TABLE emp_audit(
    operation         char(1)   NOT NULL,
    userid            text      NOT NULL,
    empname           text      NOT NULL,
    salary            integer,
    stamp             timestamp NOT NULL
);

CREATE VIEW emp_view AS
    SELECT e.empname,
           e.salary,
           max(ea.stamp) AS last_updated
      FROM emp e
      LEFT JOIN emp_audit ea ON ea.empname = e.empname
     GROUP BY 1, 2;

CREATE OR REPLACE FUNCTION update_emp_view() RETURNS TRIGGER AS $$
    BEGIN
        --
        -- Perform the required operation on emp, and create a row in emp_audit
        -- to reflect the change made to emp.
        --
        IF (TG_OP = 'DELETE') THEN
            DELETE FROM emp WHERE empname = OLD.empname;
            IF NOT FOUND THEN RETURN NULL; END IF;

            OLD.last_updated = now();
            INSERT INTO emp_audit VALUES('D', current_user, OLD.*);
            RETURN OLD;
        ELSIF (TG_OP = 'UPDATE') THEN
            UPDATE emp SET salary = NEW.salary WHERE empname = OLD.empname;
            IF NOT FOUND THEN RETURN NULL; END IF;

            NEW.last_updated = now();
            INSERT INTO emp_audit VALUES('U', current_user, NEW.*);
            RETURN NEW;
        ELSIF (TG_OP = 'INSERT') THEN
            INSERT INTO emp VALUES(NEW.empname, NEW.salary);

            NEW.last_updated = now();
            INSERT INTO emp_audit VALUES('I', current_user, NEW.*);
            RETURN NEW;
        END IF;
    END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER emp_audit
INSTEAD OF INSERT OR UPDATE OR DELETE ON emp_view
    FOR EACH ROW EXECUTE FUNCTION update_emp_view();
</programlisting>
   </example>

   <para>
    One use of triggers is to maintain a summary table
    of another table. The resulting summary can be used in place of the
    original table for certain queries &mdash; often with vastly reduced run
    times.
    This technique is commonly

Title: PL/pgSQL Trigger Example: Auditing with a View
Summary
This section presents another PL/pgSQL trigger example focusing on auditing with a view. It builds upon the previous auditing example by introducing a view that joins the main table with the audit table, displaying the last modified timestamp for each entry. The example shows how to create a trigger on the view to make it updatable, ensuring that any insert, update, or delete operations performed on the view are recorded in the audit table and reflected in the view's last modified timestamp.