Thread: bug in delete rule ?

bug in delete rule ?

From
sferriol
Date:
hello
i have a view which joins two tables
CREATE VIEW ALL_CENTERS AS
    SELECT
    t0.center_id,
    t0.institution,
    t0.category,
    t0.street_number,
    t0.street_name,
    t0.postcode,
    t0.district_name,
    t0.city_name,
    t0.province_name,
    t0.country,
    t1.update_date,
    t1.number_of_beds,
    t1.chief,
    t1.phone_center,
    t1.fax_center
    FROM
    center t0,
    center_var t1
    WHERE
    t0.center_id = t1.center_id;

and i create a rule for deleting using the view:
CREATE RULE ALL_CENTERS_DEL AS ON DELETE TO all_centers
DO INSTEAD (
    DELETE FROM center_var WHERE
    center_id = OLD.center_id;
    DELETE FROM center WHERE
    center_id = OLD.center_id;
);

but i this rule delete only line in center_var
and do not remove the line in center table

why ?

sylvain


Attachment

Re: bug in delete rule ?

From
Tom Lane
Date:
sferriol <sylvain.ferriol@imag.fr> writes:
> and i create a rule for deleting using the view:
> CREATE RULE ALL_CENTERS_DEL AS ON DELETE TO all_centers
> DO INSTEAD (
>     DELETE FROM center_var WHERE
>     center_id = OLD.center_id;
>     DELETE FROM center WHERE
>     center_id = OLD.center_id;
> );

> but i this rule delete only line in center_var
> and do not remove the line in center table

Once you delete the center_var row, there is no row in the view that
matches the id, so the comparison against OLD.center_id fails.

You could possibly make the view use an outer join, and be careful to
delete the dependent row first in the rule.  Or maybe one of the tables
can be given a foreign-key dependency on the other, with ON DELETE CASCADE
behavior, and then the view rule need only delete explicitly from the
master table.

            regards, tom lane

Re: bug in delete rule ?

From
günter strubinsky
Date:
Why don't you apply a cascading delete on center?

See bottom of
http://www.postgresql.org/docs/7.4/interactive/ddl-constraints.html :
>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>>
...   shipping_address text,
     ...
 );

 CREATE TABLE order_items (
     product_no integer REFERENCES products ON DELETE RESTRICT,
     order_id integer REFERENCES orders ON DELETE CASCADE,
     quantity integer,
     PRIMARY KEY (product_no, order_id)
 );

Restricting and cascading deletes are the two most common options. RESTRICT
can also be written as NO ACTION and it's also the default if you do not
specify anything. There are two other options for what should happen...
<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<<
with kind regards

 günter strubinsky
 <strubinsky@acm.org>
 Tel: 402.212.0196


-----Original Message-----
From: pgsql-general-owner@postgresql.org
[mailto:pgsql-general-owner@postgresql.org] On Behalf Of sferriol
Sent: Thursday, 25 March, 2004 09:30
To: pgsql-general@postgresql.org
Subject: [GENERAL] bug in delete rule ?

hello
i have a view which joins two tables
CREATE VIEW ALL_CENTERS AS
    SELECT
    t0.center_id,
    t0.institution,
    t0.category,
    t0.street_number,
    t0.street_name,
    t0.postcode,
    t0.district_name,
    t0.city_name,
    t0.province_name,
    t0.country,
    t1.update_date,
    t1.number_of_beds,
    t1.chief,
    t1.phone_center,
    t1.fax_center
    FROM
    center t0,
    center_var t1
    WHERE
    t0.center_id = t1.center_id;

and i create a rule for deleting using the view:
CREATE RULE ALL_CENTERS_DEL AS ON DELETE TO all_centers
DO INSTEAD (
    DELETE FROM center_var WHERE
    center_id = OLD.center_id;
    DELETE FROM center WHERE
    center_id = OLD.center_id;
);

but i this rule delete only line in center_var
and do not remove the line in center table

why ?

sylvain