Thread: Trigger Procedure Error: NEW used in query that is not in a rule

Trigger Procedure Error: NEW used in query that is not in a rule

From
"Javier Fonseca V."
Date:

Hello.

I'm doing a Trigger Procedure in pl/pgSQL.  It makes some kind of auditing.

I think that it's working alright except for the next line:

EXECUTE 'INSERT INTO ' || quote_ident(somedynamictablename) || ' SELECT new.*';

PostgreSQL keeps telling me: "ERROR: NEW used in query that is not in a rule".  I think that this NEW problem is because of the scope of the EXECUTE statement (outside the scope of the trigger), so it doesn't recognize the NEW record.

Maybe I could fix it concatenating column names and the 'new' values but I want to do my trigger as flexible as possible (I have several tables to audit).

Somebody has any suggestion?

Thanks a lot,

Javier

Re: Trigger Procedure Error: NEW used in query that is not in a rule

From
Decibel!
Date:
On Sat, Aug 11, 2007 at 02:43:30AM -0500, Javier Fonseca V. wrote:
> Hello.
>
> I'm doing a Trigger Procedure in pl/pgSQL.  It makes some kind of auditing.
>
> I think that it's working alright except for the next line:
>
> EXECUTE 'INSERT INTO ' || quote_ident(somedynamictablename) || ' SELECT
> new.*';
>
> PostgreSQL keeps telling me: "ERROR: NEW used in query that is not in a
> rule".  I think that this NEW problem is because of the scope of the EXECUTE
> statement (outside the scope of the trigger), so it doesn't recognize the
> NEW record.

Sort-of... the issue is that EXECUTE hands the string off to the
backend, which has no clue what "NEW" is; only the trigger procedure
understands NEW.

> Maybe I could fix it concatenating column names and the 'new' values but I
> want to do my trigger as flexible as possible (I have several tables to
> audit).
>
> Somebody has any suggestion?

You could theoretically make the trigger entirely dynamic by having it
pull the needed info out of the system catalogs... but I wouldn't want
to see the performance of that... If you care about performance *at
all*, I'd suggest writing some code that will generate the triggers for
a given table for you. I don't expect it'd be much harder than writing a
completely dynamic trigger.
--
Decibel!, aka Jim Nasby                        decibel@decibel.org
EnterpriseDB      http://enterprisedb.com      512.569.9461 (cell)

Attachment

Re: Trigger Procedure Error: NEW used in query that is not in a rule

From
"Javier Fonseca V."
Date:
The first time that I read it, the work-around sounded a little odd (extreme!) to me... but actually it would really work!.
 
Thanks for the tip :)
 
Javier

 
On 8/15/07, Decibel! <decibel@decibel.org> wrote:
On Sat, Aug 11, 2007 at 02:43:30AM -0500, Javier Fonseca V. wrote:
> Hello.
>
> I'm doing a Trigger Procedure in pl/pgSQL.  It makes some kind of auditing.
>
> I think that it's working alright except for the next line:
>
> EXECUTE 'INSERT INTO ' || quote_ident(somedynamictablename) || ' SELECT
> new.*';
>
> PostgreSQL keeps telling me: "ERROR: NEW used in query that is not in a
> rule".  I think that this NEW problem is because of the scope of the EXECUTE
> statement (outside the scope of the trigger), so it doesn't recognize the
> NEW record.

Sort-of... the issue is that EXECUTE hands the string off to the
backend, which has no clue what "NEW" is; only the trigger procedure
understands NEW.

> Maybe I could fix it concatenating column names and the 'new' values but I
> want to do my trigger as flexible as possible (I have several tables to
> audit).
>
> Somebody has any suggestion?

You could theoretically make the trigger entirely dynamic by having it
pull the needed info out of the system catalogs... but I wouldn't want
to see the performance of that... If you care about performance *at
all*, I'd suggest writing some code that will generate the triggers for
a given table for you. I don't expect it'd be much harder than writing a
completely dynamic trigger.
--
Decibel!, aka Jim Nasby                        decibel@decibel.org
EnterpriseDB      http://enterprisedb.com       512.569.9461 (cell)


Javier Fonseca V. wrote:
> Hello.
>
> I'm doing a Trigger Procedure in pl/pgSQL.  It makes some kind of auditing.
>
> I think that it's working alright except for the next line:
>
> EXECUTE 'INSERT INTO ' || quote_ident(somedynamictablename) || ' SELECT
> new.*';
>
> PostgreSQL keeps telling me: "ERROR: NEW used in query that is not in a
> rule".  I think that this NEW problem is because of the scope of the
> EXECUTE statement (outside the scope of the trigger), so it doesn't
> recognize the NEW record.
>
> Maybe I could fix it concatenating column names and the 'new' values but
> I want to do my trigger as flexible as possible (I have several tables
> to audit).
>
> Somebody has any suggestion?

You got some suggestions in response to your multipost of this question in
pgsql.sql.

--
Lew

Re: Trigger Procedure Error: NEW used in query that is not in a rule

From
jablonov
Date:
Here is other option using functionality of ROW and EXECUTE USING.

  IF EXISTS(SELECT relname FROM pg_class WHERE relname = tablename)
  THEN sql := 'INSERT INTO ' || tablename || ' VALUES (($1).*)';
  ELSE sql := 'INSERT INTO ' || tablexception || ' VALUES (($1).*)';
  END IF;

  tablerow := ROW(NEW.*)::public.measurement;

  EXECUTE sql USING tablerow;

  RETURN new;

--
View this message in context:
http://postgresql.1045698.n5.nabble.com/Trigger-Procedure-Error-NEW-used-in-query-that-is-not-in-a-rule-tp1886197p4826781.html
Sent from the PostgreSQL - general mailing list archive at Nabble.com.