Thread: Setting NEW in AFTER trigger

Setting NEW in AFTER trigger

From
Robert Fitzpatrick
Date:
Is it not possible to set the value of a field by reference of NEW.field
in an AFTER trigger? I have a trigger where I set NEW.field :=
myfunction and NEW.field shows the resulting value in my RAISE NOTICE as
shown here...

CREATE OR REPLACE FUNCTION "public"."registrants_tr_test_func" () RETURNS trigger AS
$body$
BEGIN
NEW.egw_id := egw_add_account(NEW.id);
RAISE NOTICE 'TEST: %', NEW.egw_id;
RETURN NEW;
END;
$body$
LANGUAGE 'plpgsql'
VOLATILE
CALLED ON NULL INPUT
SECURITY INVOKER
COST 100;
CREATE TRIGGER "registrants_tr_test" AFTER UPDATE
ON "public"."registrants" FOR EACH ROW
EXECUTE PROCEDURE "public"."registrants_tr_test_func"();

update registrants set registrant_email = 'lists@webtent.net' where id = 14135;
NOTICE:  Groupware user already exists: 3058
CONTEXT:  PL/pgSQL function "registrants_tr_test_func" line 2 at assignment
NOTICE:  TEST: 3058

maxegen=> SELECT  public.registrants.egw_id FROM   public.registrants WHERE   public.registrants.id = 14135;
 egw_id
--------

(1 row)

The Groupware NOTICE is output from the function if a lookup is found
and returns the existing id in place of an INSERT with the new id
returned if not found. I get no errors, but NEW.field remains NULL after
updating the record as shown above. Hopefully I'm doing something wrong?

--
Robert


Re: Setting NEW in AFTER trigger

From
Tom Lane
Date:
Robert Fitzpatrick <lists@webtent.net> writes:
> Is it not possible to set the value of a field by reference of NEW.field
> in an AFTER trigger?

An AFTER trigger can't retroactively affect the update that already
happened, if that's what you're imagining this would do.  Use a BEFORE
trigger if you want to affect what gets stored.

            regards, tom lane