Mark Gibson <gibsonm@cromwell.co.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 itUPDATE bag_test SET qty = qty + NEW.qty WHERE item = NEW.item;-- if
therewas one, suppress the INSERTIF found THEN RETURN NULL;END IF;-- else allow the INSERTRETURN NEW;
You could also extend the trigger to handle the
delete-upon-reaching-zero logic.
regards, tom lane