Обсуждение: Rules on a view overwrite default values. Any way to reinstate them?

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

Rules on a view overwrite default values. Any way to reinstate them?

От
Bradley Kieser
Дата:
Hi,

I use views extensively to implement security on tables. This requires
each table to have a view. All updates, inserts and deletes take place
through the view. The view has rules for each of these operations
defining security for that table. Under other conditions, the view also
removes complex views of the underlying data from the application layer
by supplying a view where the rules for update, insert and delete
implement business logic.

The problem is that rules on a view mean that the default values for NOT
NULL columns (used extensively) no longer trigger!

E.g.

Table A had column "updated_time" which is not null default now().
Inserting into the view on table A where "updated_time" has not been
supplied will not fill in "now()". It will attempt to put in a null
value and hence the insert will fail in the insert rule on that view.

Is there any way to tell PG to implement the triggers on the underlying
table? It will make it extremely difficult to implement this schema if I
have to try to put in null field handling... and it really should be PG
doing this not me! No doubt if this is a bug, it will be fixed in 8.x!

Thanks,

Brad

Re: Rules on a view overwrite default values. Any way to

От
Scott Marlowe
Дата:
On Mon, 2005-01-03 at 11:02, Bradley Kieser wrote:
> Hi,
>
> I use views extensively to implement security on tables. This requires
> each table to have a view. All updates, inserts and deletes take place
> through the view. The view has rules for each of these operations
> defining security for that table. Under other conditions, the view also
> removes complex views of the underlying data from the application layer
> by supplying a view where the rules for update, insert and delete
> implement business logic.
>
> The problem is that rules on a view mean that the default values for NOT
> NULL columns (used extensively) no longer trigger!
>
> E.g.
>
> Table A had column "updated_time" which is not null default now().
> Inserting into the view on table A where "updated_time" has not been
> supplied will not fill in "now()". It will attempt to put in a null
> value and hence the insert will fail in the insert rule on that view.
>
> Is there any way to tell PG to implement the triggers on the underlying
> table? It will make it extremely difficult to implement this schema if I
> have to try to put in null field handling... and it really should be PG
> doing this not me! No doubt if this is a bug, it will be fixed in 8.x!

Try changing the udpate triggers you're creating to pass in DEFAULT
(similar to NULL in the way it's NOT quoted, etc...) in the update /
insert query to the lower level and see if that fixes things.

Re: Rules on a view overwrite default values. Any way to

От
Bradley Kieser
Дата:
Hey Scott, that's ingenious, only thing is that I use NOT NULL for many
data columns too, where the value may or may not be passed in. Will try
with a COALESCE and will post back here.

Thx again!

Brad

Scott Marlowe wrote:

>On Mon, 2005-01-03 at 11:02, Bradley Kieser wrote:
>
>
>>Hi,
>>
>>I use views extensively to implement security on tables. This requires
>>each table to have a view. All updates, inserts and deletes take place
>>through the view. The view has rules for each of these operations
>>defining security for that table. Under other conditions, the view also
>>removes complex views of the underlying data from the application layer
>>by supplying a view where the rules for update, insert and delete
>>implement business logic.
>>
>>The problem is that rules on a view mean that the default values for NOT
>>NULL columns (used extensively) no longer trigger!
>>
>>E.g.
>>
>>Table A had column "updated_time" which is not null default now().
>>Inserting into the view on table A where "updated_time" has not been
>>supplied will not fill in "now()". It will attempt to put in a null
>>value and hence the insert will fail in the insert rule on that view.
>>
>>Is there any way to tell PG to implement the triggers on the underlying
>>table? It will make it extremely difficult to implement this schema if I
>>have to try to put in null field handling... and it really should be PG
>>doing this not me! No doubt if this is a bug, it will be fixed in 8.x!
>>
>>
>
>Try changing the udpate triggers you're creating to pass in DEFAULT
>(similar to NULL in the way it's NOT quoted, etc...) in the update /
>insert query to the lower level and see if that fixes things.
>
>
>

Re: Rules on a view overwrite default values. Any way to

От
Bradley Kieser
Дата:
Hmm... I have tested this and it works a treat for cols that I ONLY want
to put the default values into, but sadly the coalesce function doesn't
accept default as one of its parameters, so I can't use this for columns
that I want to default only if null.

:-(


Scott Marlowe wrote:

>On Mon, 2005-01-03 at 11:02, Bradley Kieser wrote:
>
>
>>Hi,
>>
>>I use views extensively to implement security on tables. This requires
>>each table to have a view. All updates, inserts and deletes take place
>>through the view. The view has rules for each of these operations
>>defining security for that table. Under other conditions, the view also
>>removes complex views of the underlying data from the application layer
>>by supplying a view where the rules for update, insert and delete
>>implement business logic.
>>
>>The problem is that rules on a view mean that the default values for NOT
>>NULL columns (used extensively) no longer trigger!
>>
>>E.g.
>>
>>Table A had column "updated_time" which is not null default now().
>>Inserting into the view on table A where "updated_time" has not been
>>supplied will not fill in "now()". It will attempt to put in a null
>>value and hence the insert will fail in the insert rule on that view.
>>
>>Is there any way to tell PG to implement the triggers on the underlying
>>table? It will make it extremely difficult to implement this schema if I
>>have to try to put in null field handling... and it really should be PG
>>doing this not me! No doubt if this is a bug, it will be fixed in 8.x!
>>
>>
>
>Try changing the udpate triggers you're creating to pass in DEFAULT
>(similar to NULL in the way it's NOT quoted, etc...) in the update /
>insert query to the lower level and see if that fixes things.
>
>---------------------------(end of broadcast)---------------------------
>TIP 2: you can get off all lists at once with the unregister command
>    (send "unregister YourEmailAddressHere" to majordomo@postgresql.org)
>
>
>

Re: Rules on a view overwrite default values. Any way to

От
Stephan Szabo
Дата:
On Mon, 3 Jan 2005, Bradley Kieser wrote:

> Hi,
>
> I use views extensively to implement security on tables. This requires
> each table to have a view. All updates, inserts and deletes take place
> through the view. The view has rules for each of these operations
> defining security for that table. Under other conditions, the view also
> removes complex views of the underlying data from the application layer
> by supplying a view where the rules for update, insert and delete
> implement business logic.
>
> The problem is that rules on a view mean that the default values for NOT
> NULL columns (used extensively) no longer trigger!
>
> E.g.
>
> Table A had column "updated_time" which is not null default now().
> Inserting into the view on table A where "updated_time" has not been
> supplied will not fill in "now()". It will attempt to put in a null
> value and hence the insert will fail in the insert rule on that view.

I believe the easiest way is to attach a default to the view column
using ALTER TABLE viewname ALTER COLUMN viewcolumn SET DEFAULT
defaultexpr.

Re: Rules on a view overwrite default values. Any way to reinstate them?

От
Tom Lane
Дата:
Bradley Kieser <brad@kieser.net> writes:
> The problem is that rules on a view mean that the default values for NOT
> NULL columns (used extensively) no longer trigger!

The way you're supposed to fix this is to attach default values to the
view itself.

ALTER TABLE myview ALTER COLUMN updated_time SET DEFAULT now();

Now an INSERT on myview will include the correct expression before view
expansion happens.

I'm not sure how long we've had this, but it's definitely in 7.4.

            regards, tom lane

Re: Rules on a view overwrite default values. Any way to

От
Bradley Kieser
Дата:
Thanks Tom and Stephan!

This works perfectly!

Brad


Tom Lane wrote:

>Bradley Kieser <brad@kieser.net> writes:
>
>
>>The problem is that rules on a view mean that the default values for NOT
>>NULL columns (used extensively) no longer trigger!
>>
>>
>
>The way you're supposed to fix this is to attach default values to the
>view itself.
>
>ALTER TABLE myview ALTER COLUMN updated_time SET DEFAULT now();
>
>Now an INSERT on myview will include the correct expression before view
>expansion happens.
>
>I'm not sure how long we've had this, but it's definitely in 7.4.
>
>            regards, tom lane
>
>
>