Thread: BUG #3945: unexpected ON INSERT rule behaviour

BUG #3945: unexpected ON INSERT rule behaviour

From
"Holger Klawitter"
Date:
The following bug has been logged online:

Bug reference:      3945
Logged by:          Holger Klawitter
Email address:      info@klawitter.de
PostgreSQL version: 8.2.6
Operating system:   Linux/i386
Description:        unexpected ON INSERT rule behaviour
Details:

Well,
this is probably not really a bug, more a feature
deeply buried in the query-tree-concept worth placed as a pitfall warning in
the documentation :-)

The following code:
CREATE TABLE a (a int);
CREATE TABLE b (b int);

CREATE OR REPLACE RULE a_to_b
AS ON INSERT TO a
DO ALSO INSERT INTO b VALUES (NEW.a);

INSERT INTO a VALUES ( 1 );
INSERT INTO a VALUES ((SELECT max(a)+1 from a));

SELECT * from b;

Produces the following output:
 b
---
 1
 3         <---- 2 expected here
(2 rows)

One would expect 1 and 2 to be stored in b.

The problem is that NEW.a is not the *value* being inserted. Instead, NEW
reproduces the unevaluated
selected statement.

Regards
  Holger

Re: BUG #3945: unexpected ON INSERT rule behaviour

From
"Gurjeet Singh"
Date:
On Feb 8, 2008 2:20 PM, Holger Klawitter <info@klawitter.de> wrote:

>
> The following bug has been logged online:
>
> Bug reference:      3945
> Logged by:          Holger Klawitter
> Email address:      info@klawitter.de
> PostgreSQL version: 8.2.6
> Operating system:   Linux/i386
> Description:        unexpected ON INSERT rule behaviour
> Details:
>
> Well,
> this is probably not really a bug, more a feature
> deeply buried in the query-tree-concept worth placed as a pitfall warning
> in
> the documentation :-)
>

You are correct, it's not a bug, but a feature request that won't be
entertained.

postgres=3D# explain INSERT INTO a VALUES ( 1 );
                QUERY PLAN
------------------------------------------
 Result  (cost=3D0.00..0.01 rows=3D1 width=3D0)

 Result  (cost=3D0.00..0.01 rows=3D1 width=3D0)
(3 rows)

postgres=3D# explain INSERT INTO a VALUES ((SELECT max(a)+1 from a));
                            QUERY PLAN
-------------------------------------------------------------------
 Result  (cost=3D40.01..40.02 rows=3D1 width=3D0)
   InitPlan
     ->  Aggregate  (cost=3D40.00..40.01 rows=3D1 width=3D4)
           ->  Seq Scan on a  (cost=3D0.00..34.00 rows=3D2400 width=3D4)

 Result  (cost=3D40.01..40.02 rows=3D1 width=3D0)
   InitPlan
     ->  Aggregate  (cost=3D40.00..40.01 rows=3D1 width=3D4)
           ->  Seq Scan on a  (cost=3D0.00..34.00 rows=3D2400 width=3D4)
(9 rows)

The docs are pretty clear on this; Rules are applied at parse time (' The
rule system is located between the parser and the planner'), and hence can
only work with hard-coded values in the VALUES clause.

Personally, although much slower, I prefer using triggers if the logic
depends on NEW/OLD values. Rules are perfect fit only if
1) Your operations do not depend on NEW/OLD pseudo relations. For eg., plain
unconditional INSERT/UPDATE/DELETE on another relation.
2) You are *absolutely* sure that no app will use prepared statements, and
will always provide values in the statements, and not something like you did
above.

Best regards,
--=20
gurjeet[.singh]@EnterpriseDB.com
singh.gurjeet@{ gmail | hotmail | indiatimes | yahoo }.com

EnterpriseDB      http://www.enterprisedb.com

17=B0 29' 34.37"N,   78=B0 30' 59.76"E - Hyderabad
18=B0 32' 57.25"N,   73=B0 56' 25.42"E - Pune
37=B0 47' 19.72"N, 122=B0 24' 1.69" W - San Francisco *

http://gurjeet.frihost.net

Mail sent from my BlackLaptop device