Re: [HACKERS] Update on Insert

Lists: pgsql-generalpgsql-hackers
From: SebiF <sfeher(at)gmail(dot)com>
To: pgsql-hackers(at)postgresql(dot)org
Subject: Update on Insert
Date: 2009-11-16 18:31:05
Message-ID: 48624cbf-bdee-43f8-bc56-bd670c19570d@j4g2000yqe.googlegroups.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

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


From: Robert Haas <robertmhaas(at)gmail(dot)com>
To: SebiF <sfeher(at)gmail(dot)com>
Cc: pgsql-hackers(at)postgresql(dot)org
Subject: Re: Update on Insert
Date: 2009-11-16 19:10:10
Message-ID: 603c8f070911161110i58c12459jeced1b1c10e3af7a@mail.gmail.com
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

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


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
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


From: Andreas Kretschmer <akretschmer(at)spamfence(dot)net>
To: pgsql-hackers(at)postgresql(dot)org
Subject: Re: Update on Insert
Date: 2009-11-16 20:53:42
Message-ID: mnq8t6-4be.ln1@news.a-kretschmer.de
Views: Raw Message | Whole Thread | Download mbox | Resend email
Lists: pgsql-general pgsql-hackers

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.

21:53 < akretschmer> ??upsert
21:53 < rtfm_please> For information about upsert
21:53 < rtfm_please> see http://www.postgresql.org/docs/current/static/plpgsql-control-structures.html#PLPGSQL-UPSERT-EXAMPLE

Read that.

Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect. (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly." (unknown)
Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889°