Updatable view and default sequence values

From: Kouber Saparev <postgres(at)saparev(dot)com>
To: pgsql-admin(at)postgresql(dot)org
Subject: Updatable view and default sequence values
Date: 2006-05-16 13:16:55
Message-ID: e4cjbs$29i$1@sea.gmane.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-admin

Hi All,

I am currently using PostgreSQL 8.1.3 and am trying to create an
updatable view with two (or more) joined tables and I also would like to
have the ability to indicate implicitly the value of the serial primary
key fields.

I have the following two tables:

CREATE TABLE purchase (
purchase_sid SERIAL PRIMARY KEY,
data TEXT
);

CREATE TABLE subscription_purchase (
subscription_purchase_sid SERIAL PRIMARY KEY,
purchase_sid INT NOT NULL UNIQUE REFERENCES purchase ON UPDATE
CASCADE ON DELETE CASCADE,
data TEXT
);

I have also created the following view:

CREATE VIEW
s_purchase AS
SELECT
p.purchase_sid,
p.data AS pdata,
sp.subscription_purchase_sid,
sp.data AS sdata
FROM
purchase p INNER JOIN subscription_purchase sp
ON
sp.purchase_sid = p.purchase_sid;

Now, in order to make the view updatable I added this rule:

CREATE RULE s_purchase_update AS
ON UPDATE TO s_purchase DO INSTEAD (
UPDATE
purchase
SET
purchase_sid = NEW.purchase_sid,
data = NEW.pdata
WHERE
purchase_sid = OLD.purchase_sid;

UPDATE
subscription_purchase
SET
subscription_purchase_sid = NEW.subscription_purchase_sid,
purchase_sid = NEW.purchase_sid,
data = NEW.sdata
WHERE
subscription_purchase_sid = OLD.subscription_purchase_sid;
);

The tricky part comes when I try to make my view insertable. Normally
I'd insert without specifying the sequence values, but in some cases I'd
want also to have full control of what's going into the underlying
tables. The thing is that when I try to do it the simple way by
specifying default values in the view itself:

ALTER TABLE s_purchase ALTER COLUMN purchase_sid SET DEFAULT
NEXTVAL('purchase_purchase_sid_seq');
ALTER TABLE s_purchase ALTER COLUMN subscription_purchase_sid SET
DEFAULT NEXTVAL('subscription_purchase_subscription_purchase_sid_seq');

CREATE RULE s_purchase_insert AS
ON INSERT TO s_purchase DO INSTEAD (
INSERT INTO purchase
(purchase_sid, data)
VALUES
(NEW.purchase_sid, NEW.pdata);

INSERT INTO subscription_purchase
(subscription_purchase_sid, purchase_sid, data)
VALUES
(NEW.subscription_purchase_sid, NEW.purchase_sid, NEW.sdata);
);

I get foreign key constraint violation. That's happening because default
values are executed *before* the rule, so NEXTVAL for the sequence
'purchase_purchase_sid_seq' is executed twice - once for each table.

The work around is to remove the default value for this sequence and to
call it in the rule itself with coalesce:

ALTER TABLE s_purchase ALTER COLUMN purchase_sid DROP DEFAULT;

CREATE RULE s_purchase_insert AS
ON INSERT TO s_purchase DO INSTEAD (
INSERT INTO purchase
(purchase_sid, data)
VALUES
(COALESCE(NEW.purchase_sid,
NEXTVAL('purchase_purchase_sid_seq')), NEW.pdata);

INSERT INTO subscription_purchase
(subscription_purchase_sid, purchase_sid, data)
VALUES
(NEW.subscription_purchase_sid, COALESCE(NEW.purchase_sid,
CURRVAL('purchase_purchase_sid_seq')), NEW.sdata);
);

The thing is that in the real case I have multiple tables that have to
be joined so I really want to get rid of all this COALESCE stuff and to
put everything in the view definition.

Any ideas how to suppress multiple invocations of nextval() or how to do
it anyway? :)

--
Kouber Saparev
http://kouber.saparev.com

Responses

Browse pgsql-admin by date

  From Date Subject
Next Message Andy Shellam 2006-05-16 13:28:11 Re: reg:Query
Previous Message sandhya 2006-05-16 13:12:21 Re: reg:Query