From: | Anthony Chavez <acc(at)anthonychavez(dot)org> |
---|---|
To: | pgsql-general(at)postgresql(dot)org |
Subject: | ON INSERT view rule |
Date: | 2006-07-12 16:26:45 |
Message-ID: | m24pxmwzzu.fsf@pegasos.aegaeum.anthonychavez.org |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-general |
Hello, pgsql-general!
I originally posted this to pgsql-sql, but after not seing any
response for roughly a day and after re-reading the charters, I felt
that pgsql-general might be more appropriate.
What I've got here are a couple of ON INSERT rules for a view. The
second rule is what I'm concerned about. I wrote it with PostgreSQL's
ACID compliance in mind, but can I trust it?
From what I gather, if I were to simply use NEW.address_line_id rather
than address_lines_id_seq.last_value, it would be replaced by
nextval(address_line_id_seq), so I'm trying to work around that.
If there is there a better way to do this, I'm all ears. Would
lastval() work for me in this case? Thanks!
There is probably a better way of accomplishing what I'm after, but
this is the design that we've come up with, and the one that we're
more-or-less stuck with for the time being. There are 2 additional
things that we implemented that aren't shown in the code below.
1. The addresses_address_lines view assumes that a row already exists
in the addresses relation because that relation has some NOT NULL
attributes that lack defaults. Hence, there is no insert_addresses
rule. I suppose I should create one, but choosing a default value
for some of the foreign keys in that relation (which are allowed to
be NULL) would be difficult.
2. I have an AFTER INSERT trigger function on the addresses relation
that inserts a default display_orderings tuple (with ordering = 0)
and sets up the association in the junctions table. Hence the use
of UPDATE in the insert_display_orderings rule.
--
Anthony Chavez http://anthonychavez.org/
mailto:acc(at)anthonychavez(dot)org jabber:acc(at)jabber(dot)anthonychavez(dot)org
CREATE OR REPLACE VIEW addresses_address_lines
AS
SELECT a.id AS address_id,
al.id AS address_line_id,
line,
ordering
FROM addresses a
INNER JOIN
address_lines al
ON al.address_id = a.id
LEFT OUTER JOIN
junctions
ON parent_table = 'address_lines'
AND parent_id = al.id
AND child_table = 'display_orderings'
LEFT OUTER JOIN
display_orderings o
ON o.id = child_id;
CREATE OR REPLACE RULE insert_address_lines
AS ON INSERT
TO addresses_address_lines
DO INSTEAD
INSERT INTO address_lines (address_id, line)
VALUES (NEW.address_id, NEW.line);
CREATE OR REPLACE RULE insert_display_orderings
AS ON INSERT
TO addresses_address_lines
DO
UPDATE display_orderings
SET ordering = NEW.ordering
FROM address_lines_id_seq
INNER JOIN
junctions
ON parent_table = 'address_lines'
AND parent_id = last_value
AND child_table = 'display_orderings'
WHERE ordering <> NEW.ordering
AND display_orderings.id = child_id;
--
Anthony Chavez http://anthonychavez.org/
mailto:acc(at)anthonychavez(dot)org jabber:acc(at)jabber(dot)anthonychavez(dot)org
From | Date | Subject | |
---|---|---|---|
Next Message | Michael Fuhr | 2006-07-12 16:29:51 | Re: getting function argument names from psql? |
Previous Message | Tim Hart | 2006-07-12 16:18:23 | Re: Long term database archival |