Home Explore Blog CI



postgresql

59th chunk of `doc/src/sgml/plpgsql.sgml`
c32828175c58111083d7c7e0fa40a14660790df1f8d0434e0000000100000fc3
 column(s) on UPDATE, INSERT, DELETE.
--
CREATE OR REPLACE FUNCTION maint_sales_summary_bytime() RETURNS TRIGGER
AS $maint_sales_summary_bytime$
    DECLARE
        delta_time_key          integer;
        delta_amount_sold       numeric(15,2);
        delta_units_sold        numeric(12);
        delta_amount_cost       numeric(15,2);
    BEGIN

        -- Work out the increment/decrement amount(s).
        IF (TG_OP = 'DELETE') THEN

            delta_time_key = OLD.time_key;
            delta_amount_sold = -1 * OLD.amount_sold;
            delta_units_sold = -1 * OLD.units_sold;
            delta_amount_cost = -1 * OLD.amount_cost;

        ELSIF (TG_OP = 'UPDATE') THEN

            -- forbid updates that change the time_key -
            -- (probably not too onerous, as DELETE + INSERT is how most
            -- changes will be made).
            IF ( OLD.time_key != NEW.time_key) THEN
                RAISE EXCEPTION 'Update of time_key : % -> % not allowed',
                                                      OLD.time_key, NEW.time_key;
            END IF;

            delta_time_key = OLD.time_key;
            delta_amount_sold = NEW.amount_sold - OLD.amount_sold;
            delta_units_sold = NEW.units_sold - OLD.units_sold;
            delta_amount_cost = NEW.amount_cost - OLD.amount_cost;

        ELSIF (TG_OP = 'INSERT') THEN

            delta_time_key = NEW.time_key;
            delta_amount_sold = NEW.amount_sold;
            delta_units_sold = NEW.units_sold;
            delta_amount_cost = NEW.amount_cost;

        END IF;


        -- Insert or update the summary row with the new values.
        <<insert_update>>
        LOOP
            UPDATE sales_summary_bytime
                SET amount_sold = amount_sold + delta_amount_sold,
                    units_sold = units_sold + delta_units_sold,
                    amount_cost = amount_cost + delta_amount_cost
                WHERE time_key = delta_time_key;

            EXIT insert_update WHEN found;

            BEGIN
                INSERT INTO sales_summary_bytime (
                            time_key,
                            amount_sold,
                            units_sold,
                            amount_cost)
                    VALUES (
                            delta_time_key,
                            delta_amount_sold,
                            delta_units_sold,
                            delta_amount_cost
                           );

                EXIT insert_update;

            EXCEPTION
                WHEN UNIQUE_VIOLATION THEN
                    -- do nothing
            END;
        END LOOP insert_update;

        RETURN NULL;

    END;
$maint_sales_summary_bytime$ LANGUAGE plpgsql;

CREATE TRIGGER maint_sales_summary_bytime
AFTER INSERT OR UPDATE OR DELETE ON sales_fact
    FOR EACH ROW EXECUTE FUNCTION maint_sales_summary_bytime();

INSERT INTO sales_fact VALUES(1,1,1,10,3,15);
INSERT INTO sales_fact VALUES(1,2,1,20,5,35);
INSERT INTO sales_fact VALUES(2,2,1,40,15,135);
INSERT INTO sales_fact VALUES(2,3,1,10,1,13);
SELECT * FROM sales_summary_bytime;
DELETE FROM sales_fact WHERE product_key = 1;
SELECT * FROM sales_summary_bytime;
UPDATE sales_fact SET units_sold = units_sold * 2;
SELECT * FROM sales_summary_bytime;
</programlisting>
   </example>

   <para>
    <literal>AFTER</literal> triggers can also make use of <firstterm>transition
    tables</firstterm> to inspect the entire set of rows changed by the triggering
    statement.  The <command>CREATE TRIGGER</command> 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"/>,

Title: PL/pgSQL Trigger Function: Updating Summary Table and Transition Tables for Auditing
Summary
This section provides a detailed example of a PL/pgSQL trigger function (`maint_sales_summary_bytime`) designed to maintain a summary table (`sales_summary_bytime`) in response to changes in a fact table (`sales_fact`). The function calculates incremental changes in sales data (amount sold, units sold, amount cost) based on the operation (INSERT, UPDATE, or DELETE) performed on the fact table. It then updates or inserts rows in the summary table to reflect these changes. Additionally, the section introduces the concept of 'transition tables' in AFTER triggers, allowing the function to inspect all rows modified by the triggering statement, and references another example on auditing with transition tables.