Rules with sequence columns

Lists: pgsql-sql
From: Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us>
To: Ray Madigan <ray(at)madigans(dot)org>
Cc: Pgsql-Sql <pgsql-sql(at)postgresql(dot)org>
Subject: Re: Rules with sequence columns
Date: 2007-03-28 16:17:05
Message-ID: 26419.1175098625@sss.pgh.pa.us
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

Ray Madigan <ray(at)madigans(dot)org> writes:
> Does anyone have any suggestion?

Use a trigger to propagate the data to the other table. You can't make
this work reliably with a rule, because rules are macros and hence
inherently subject to double-evaluation problems when dealing with
volatile functions.

regards, tom lane


From: Ray Madigan <ray(at)madigans(dot)org>
To: Pgsql-Sql <pgsql-sql(at)postgresql(dot)org>
Subject: Rules with sequence columns
Date: 2007-03-28 16:25:17
Message-ID: 460A96ED.9000001@madigans.org
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-sql

I have the following situation that I would appreciate your input on:

I have a table with a column that I use to uniquely identify its rows.
The table also has a rule on insert that stores the row identifier into
another table for reference at some other point.

The table is defined as

CREATE SEQUENCE foo_seq;

CREATE TABLE foo ( fooK INTEGER DEFAULT NEXTVAL ( 'foo_seq' ),
fooN VARCHAR(32) NOT NULL UNIQUE,
link INTEGER NOT NULL
DEFAULT 0 );

The rule does an insert into another table and I have implemented the
rule in two ways.

CREATE RULE insertCD AS ON INSERT TO foo
DO INSERT INTO cdFoo ( contextK, componentK )
SELECT currval ( 'foo_seq' ), componentK
FROM Component
WHERE componentN = 'Division';

or

CREATE RULE insertCD AS ON INSERT TO foo
DO INSERT INTO cdFoo ( contextK, componentK )
SELECT new.fooK, componentK
FROM Component
WHERE componentN = 'Division';

The situation is that every time the rule fires, the foo sequence is
incremented
for each row in the foo table. and the reference value is not the same
in the table.

I have tried to take the default nextval ( 'foo_seq' ) from the row
initialization and move it to the insert

insert into foo ( fook, fooN ) values ( nextval ( 'foo_seq' ), 'Name' );
with the same result.

The only way I have been able to make it work is ugly.

int fooK = select nextval ( 'foo_seq' );
insert into foo ( fooK, fooN ) values ( fooK, 'Name' );

Does anyone have any suggestion?