Re: Creating a RULE for UPDATing a VIEW

From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: "Dean Gibson (DB Administrator)" <postgresql(at)ultimeth(dot)com>
Cc: pgsql-sql(at)postgresql(dot)org
Subject: Re: Creating a RULE for UPDATing a VIEW
Date: 2009-05-03 17:36:42
Message-ID: 27650.1241372202@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-sql

"Dean Gibson (DB Administrator)" <postgresql(at)ultimeth(dot)com> writes:
> So, I tried:

> CREATE RULE _update AS ON UPDATE TO public.yyy DO INSTEAD
> (DELETE FROM private.zzz WHERE key_field = OLD.key_field;
> INSERT INTO private.zzz VALUES( NEW.*) );

Nope, won't work, standard gotcha for rules newbies. As soon as you
delete in the first command, the row no longer exists in the view,
and "new.*" is just a macro for a view reference.

AFAIK there really isn't any way to do it except

ON UPDATE DO INSTEAD
UPDATE private.zzz SET f1 = new.f1, f2 = new.f2, ...
WHERE key_field = old.key_field;

BTW, you should also consider adding RETURNING clauses to these
rules so that UPDATE RETURNING &etc will work on the views.
Here at least you can use "RETURNING *" ...

regards, tom lane

In response to

Browse pgsql-sql by date

  From Date Subject
Next Message johnf 2009-05-03 22:26:58 Re: using a list to query
Previous Message Dean Gibson (DB Administrator) 2009-05-03 16:50:41 Creating a RULE for UPDATing a VIEW