Thread: tables referenced from insert...returning

tables referenced from insert...returning

From
"Michael Shulman"
Date:
Hi,

What are the rules about what tables/views can be referenced from the
RETURNING clause of an INSERT?

I am particularly puzzled by the following.  Given these definitions:

CREATE TABLE test (id serial primary key, name varchar);
CREATE VIEW tv AS SELECT * FROM test;

This works:

CREATE RULE _update AS ON UPDATE TO tv DO INSTEAD
  UPDATE test SET name = NEW.name WHERE id = OLD.id RETURNING NEW.*;

But this does not:

CREATE RULE _insert AS ON INSERT TO tv DO INSTEAD
  INSERT INTO test (name) VALUES (NEW.name) RETURNING NEW.*;

It gives

ERROR:  invalid reference to FROM-clause entry for table "*NEW*"
LINE 2:   INSERT INTO test (name) VALUES (NEW.name) RETURNING NEW.*;
                                                              ^
HINT:  There is an entry for table "*NEW*", but it cannot be
referenced from this part of the query.

Why is there a difference?

Thanks!
Mike

Re: tables referenced from insert...returning

From
Tom Lane
Date:
"Michael Shulman" <shulman@mathcamp.org> writes:
> CREATE RULE _insert AS ON INSERT TO tv DO INSTEAD
>   INSERT INTO test (name) VALUES (NEW.name) RETURNING NEW.*;
> ERROR:  invalid reference to FROM-clause entry for table "*NEW*"
> LINE 2:   INSERT INTO test (name) VALUES (NEW.name) RETURNING NEW.*;
>                                                               ^
> HINT:  There is an entry for table "*NEW*", but it cannot be
> referenced from this part of the query.

Hmm ... that might be a bug, but in any case, wouldn't it be wiser to do

CREATE RULE _insert AS ON INSERT TO tv DO INSTEAD
  INSERT INTO test (name) VALUES (NEW.name) RETURNING test.*;

Multiple evaluations of NEW in the text of a rule are a great way
to cause yourself trouble --- consider what happens if there's
a volatile function such as nextval() involved.  It's almost always
safest to base RETURNING expressions on the already-stored data.
In the example at hand, your approach would lie about the stored
value of "id" anyway, since whatever NEW.id might be, it's not
likely to match the sequence-assigned id.

            regards, tom lane

Re: tables referenced from insert...returning

From
"Michael Shulman"
Date:
On Mon, Jun 23, 2008 at 8:46 PM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
> Hmm ... that might be a bug, but in any case, wouldn't it be wiser to do
>
> CREATE RULE _insert AS ON INSERT TO tv DO INSTEAD
>  INSERT INTO test (name) VALUES (NEW.name) RETURNING test.*;

Well, what I'm really trying to do is write a rule for inserting into
a multi-table view which has a meaningful RETURNING clause.  Looking
back at the documentation for NEW, I see you are right that even if it
worked, this wouldn't do what I want.  Guess I'll have to try to
figure out something else.

> Multiple evaluations of NEW in the text of a rule are a great way
> to cause yourself trouble --- consider what happens if there's
> a volatile function such as nextval() involved.

Ouch!  I didn't realize that multiple references to NEW were actually
translated by the rule system into multiple *evaluations* of the
supplied arguments.  Are there reasons one might desire that behavior?

I can think of simple situations in which one would *not* want such
multiple evaluation.  For example, a rule on table1 which logs all
modifications of table1 to table1_log would be naturally written as

CREATE RULE log AS ON INSERT TO table1 DO ALSO
  INSERT INTO table1_log (new_value,...) VALUES (NEW.value,...);

(This is very close to the example of an ON UPDATE rule given in the
manual.)  But apparently if I then say

INSERT INTO table1 SET value = volatile_function();

the volatile function will be evaluated twice, and the value logged
may not be the same as the value actually inserted.  This seems
counterintuitive to me; I would expect the supplied arguments to be
evaluated once and the resulting values substituted wherever NEW
appears.

Mike

Re: tables referenced from insert...returning

From
Tom Lane
Date:
"Michael Shulman" <shulman@mathcamp.org> writes:
> On Mon, Jun 23, 2008 at 8:46 PM, Tom Lane <tgl@sss.pgh.pa.us> wrote:
>> Multiple evaluations of NEW in the text of a rule are a great way
>> to cause yourself trouble --- consider what happens if there's
>> a volatile function such as nextval() involved.

> Ouch!  I didn't realize that multiple references to NEW were actually
> translated by the rule system into multiple *evaluations* of the
> supplied arguments.  Are there reasons one might desire that behavior?

Well, the rule system is fundamentally a macro-expansion mechanism,
and multiple-evaluation risks come with that territory.  There are
things you can do with macro expansion that can't be done any other
way, so I don't think that that decision was wrong on its face, but
certainly we've seen plenty of traps for the unwary in it.

I've occasionally wondered what a "rule system mark II" might look
like, but frankly I have no idea how to design one that has useful
functionality and fewer traps.

> I can think of simple situations in which one would *not* want such
> multiple evaluation.  For example, a rule on table1 which logs all
> modifications of table1 to table1_log would be naturally written as

> CREATE RULE log AS ON INSERT TO table1 DO ALSO
>   INSERT INTO table1_log (new_value,...) VALUES (NEW.value,...);

Except that NEW.* doesn't necessarily have any relationship at all to
what was actually put into table1 --- it'll just be the values that were
provided to the original "INSERT INTO view" command.  Your own example
showed the difference.  This sort of logging application is *far* better
served by triggers.

Perhaps the grail we're looking for is a rule-like syntax for defining
what are really triggers.  Not sure though...

            regards, tom lane