From: | Tom Lane <tgl(at)sss(dot)pgh(dot)pa(dot)us> |
---|---|
To: | Mark Gibson <gibsonm(at)cromwell(dot)co(dot)uk> |
Cc: | pgsql-sql(at)postgresql(dot)org |
Subject: | Re: Implementation of a bag pattern using rules |
Date: | 2004-02-09 16:09:34 |
Message-ID: | 20111.1076342974@sss.pgh.pa.us |
Views: | Raw Message | Whole Thread | Download mbox | Resend email |
Thread: | |
Lists: | pgsql-sql |
Mark Gibson <gibsonm(at)cromwell(dot)co(dot)uk> writes:
> Alternatively, for the relative option (increase 'apple' by 12), replace
> the 'bag_abs' rule with:
> CREATE RULE bag_rel AS ON INSERT TO bag_test
> WHERE
> EXISTS (SELECT 1 FROM bag_test WHERE item = NEW.item)
> DO INSTEAD
> UPDATE bag_test SET qty = qty + NEW.qty WHERE item = NEW.item;
This can't work because an ON INSERT rule fires after the INSERT itself
is executed. You have the equivalent of
INSERT INTO ... WHERE NOT EXISTS(SELECT ...);
UPDATE ... WHERE item = NEW.item AND EXISTS(SELECT ...);
The INSERT will execute because there's no row matching the EXISTS(),
and then the UPDATE will execute too because now there is a matching
row. In some contexts this is a feature. However, you want a single
test to control both actions.
I think you need to use a BEFORE INSERT trigger instead. It could
do something like
-- see if there is an existing row, if so update it
UPDATE bag_test SET qty = qty + NEW.qty WHERE item = NEW.item;
-- if there was one, suppress the INSERT
IF found THEN
RETURN NULL;
END IF;
-- else allow the INSERT
RETURN NEW;
You could also extend the trigger to handle the
delete-upon-reaching-zero logic.
regards, tom lane
From | Date | Subject | |
---|---|---|---|
Next Message | Christopher Browne | 2004-02-09 16:18:55 | Re: timestamptz - problems |
Previous Message | Christoph Haller | 2004-02-09 16:02:40 | Re: Index not used - now me |