Обсуждение: Creating a RULE for UPDATing a VIEW

Поиск
Список
Период
Сортировка

Creating a RULE for UPDATing a VIEW

От
"Dean Gibson (DB Administrator)"
Дата:
Using PostgreSQL version 8.3.0:

For various reasons, I have a number of VIEWs that are (except for the 
schema/table/view names) automatically generated as identity mappings of 
corresponding TABLEs;  eg:

CREATE VIEW public.yyy AS SELECT * FROM private.zzz;

Since we don't have updatable VIEWS yet, I tried:

CREATE RULE _update AS ON UPDATE TO public.yyy DO INSTEAD UPDATE private.zzz SET (*) = NEW.* WHERE key_field =
OLD.key_field;

In order to make the automatic generation easy, I'm trying to make the 
syntax as general as possible, in particular, so that I don't have to 
list all of the column names (that appears to work).  However, the above 
(and other ingenious, but also incorrect, syntaxes) produces an error 
message.  So, I tried:

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

This is syntactically accepted, but when I attempt to UPDATE a row, the 
old row is deleted but the new row is not inserted.  Manually listing 
the NEW.columns in place of "NEW.*" doesn't help.

-- Dean

-- 
Mail to my list address MUST be sent via the mailing list.
All other mail to my list address will bounce.



Re: Creating a RULE for UPDATing a VIEW

От
Tom Lane
Дата:
"Dean Gibson (DB Administrator)" <postgresql@ultimeth.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 INSTEADUPDATE 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