Assign to NEW by key in a Postgres trigger
First of all, there is no "trigger body" (unlike Oracle). In Postgres you have a trigger function (also, misleadingly, called "procedure") with a function body and 0-n triggers (without body) calling this function.
The special variable NEW
in plpgsql trigger functions is neither a map nor an array; it's a record holding the new row:
NEW
Data type
RECORD
; variable holding the new database row forINSERT
/UPDATE
operations in row-level triggers. This variable is unassigned in statement-level triggers and forDELETE
operations.
Assigning to a field (or column) of NEW
is simple. The documented assignment operator is :=
. (Since Postgres 9.4 =
is also documented.)
NEW.some_key := 5;
What you seem to be looking for is to parameterize the column name, which isn't quite as simple.
The additional module hstore
provides the #=
operator. (It's included in pretty much all standard distributions.) Install the module once per database with:
CREATE EXTENSION hstore;
Then you can:
NEW := NEW #= '"some_key"=>"5"'::hstore;
Sets the column some_key
to '5' - if the column exists.
- An explicit cast to
hstore
is optional. The operator#=
coerces a string literal to the right data type automatically. hstore
only stores text strings, so a given literal for the value may have to be cast twice - a very minor drawback compared to alternative solutions.- The given string literal has to fit the data type of the column, or an exception is raised.
- If no column with the given name exists, nothing is changed, no exception raised.
Related answer with details and an alternative solution:
- How to set value of composite variable field using dynamic SQL
Code example
CREATE OR REPLACE FUNCTION trg_tbl_ins_bef()
RETURNS trigger AS
$func$
BEGIN
NEW := NEW #= '"some_key"=>"5"';
RETURN NEW;
END
$func$ LANGUAGE plpgsql;
CREATE TRIGGER ins_bef
BEFORE INSERT ON tbl
FOR EACH ROW EXECUTE PROCEDURE trg_tbl_ins_bef();
In Postgres 11 or later I suggest the new syntax:
...
FOR EACH ROW EXECUTE FUNCTION trg_tbl_ins_bef();
I must admit that this is no easy way of solving it, but at least it's a way. I created the below example as a standalone one, to avoid all clutter with trigger creation and such. If you use it in a trigger, you can remove the declaration and initialization of p
and replace the remaining use with NEW
.
DO $$
DECLARE p members_test;
BEGIN
p := (1,2,3);
CREATE TEMP TABLE t ON COMMIT DROP AS SELECT p.*; -- a one row table holding
-- the values of the variable
EXECUTE format($e$UPDATE t SET %s = 43$e$, 'b'); -- this way you can access
-- the columns dynamically
SELECT * INTO p FROM t; -- assign the new values back to the variable
RAISE INFO 'p: %', p;
END;
$$;
INFO: p: (1,43,3)