Re: [HACKERS] Update on Insert

From: Thom Brown <thombrown(at)gmail(dot)com>
To: Robert Haas <robertmhaas(at)gmail(dot)com>
Cc: SebiF <sfeher(at)gmail(dot)com>, PGSQL Mailing List <pgsql-general(at)postgresql(dot)org>
Subject: Re: [HACKERS] Update on Insert
Date: 2009-11-16 19:46:29
Message-ID: bddc86150911161146j106ddd74sb1a5fb1eddd1f5b1@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Thread:
Lists: pgsql-general pgsql-hackers

2009/11/16 Robert Haas <robertmhaas(at)gmail(dot)com>:
> On Mon, Nov 16, 2009 at 1:31 PM, SebiF <sfeher(at)gmail(dot)com> wrote:
>> Hi Everyone,
>>
>> Given a table "Items" with a PK "item1" and "Qty" - a numeric column
>> I'd like to define a way in Postgres to insert when item11 doesn't
>> exist already in "Items" and update the Qty by adding the new quantity
>> to the existent when the item11 exists. What is a good approach and
>> where should I be looking for details. Thanks.
>>
>> Sebastian
>
> This is not a -hackers question; please use pgsql-general instead.
>
> Also see example 38-2 here:
> http://www.postgresql.org/docs/current/static/plpgsql-control-structures.html
>
> ...Robert
>

You could try something like the following:

CREATE FUNCTION update_items(item_value TEXT, qty_value INTEGER)
RETURNS BOOL AS $$
DECLARE item_rec RECORD;
BEGIN
SELECT INTO item_rec * FROM items WHERE item = item_value;

IF item_rec.item IS NULL THEN
INSERT INTO items (item, qty) VALUES (item_value, qty_value);
RAISE NOTICE 'added';
RETURN true;
ELSE
UPDATE items SET qty = qty + qty_value WHERE item = item_value;
RAISE NOTICE 'updated';
RETURN true;
END IF;
END;
$$ LANGUAGE plpgsql

Then use:

SELECT update_items('monkey',9);

You could probably also create an updateable view with a rule applied
or something.

Thom

In response to

Browse pgsql-general by date

  From Date Subject
Next Message Tom Lane 2009-11-16 19:52:00 Re: Need full search text on a shared hosting web site using 8.1.x
Previous Message John R Pierce 2009-11-16 19:15:50 Re: Need full search text on a shared hosting web site using 8.1.x

Browse pgsql-hackers by date

  From Date Subject
Next Message Peter Eisentraut 2009-11-16 20:37:07 Re: UTF8 with BOM support in psql
Previous Message Andres Freund 2009-11-16 19:17:25 Re: Unpredictable shark slowdown after migrating to 8.4