Thread: plpgsql merge func question
hi, i tried to write a merge function in plpgsql, which is derived from the example in the docs (Example 38-2 in http://www.postgresql.org/docs/8.4/static/plpgsql-control-structures.html). Code is below. This works fine as long as entries in count_table have todays date in "datum". when i have older entries the function "locks up" (doesn't return, server has 100% cpu). i'm a plpgsql novice. can someone explain why this happens? related question: i didn't find a way to log queries that happen inside functions. is this possible? postgres version is 8.4.17 thx matthias CREATE or replace FUNCTION merge_func(id INT, foobarvar text) RETURNS integer AS $$ DECLARE countervar integer; BEGIN LOOP UPDATE count_table ct SET counter = counter+1 WHERE ct.user_id = id and foobar = foobarvar and datum = current_date returning counter into countervar; IF found THEN RETURN countervar; END IF; BEGIN insert into count_table (user_id, foobar, datum, counter) values (id, foobarvar, current_date, 1) returning counter into countervar; RETURN countervar; EXCEPTION WHEN unique_violation THEN END; END LOOP; END; $$ LANGUAGE plpgsql; \d count_table Table "count_table" Column | Type | Modifiers ---------+-----------------------+-------------------- user_id | integer | not null foobar | character varying(30) | not null datum | date | not null counter | integer | not null default 0
Matthias Leopold <matthias@aic.at> wrote: > hi, > > i tried to write a merge function in plpgsql, which is derived from the > example in the docs (Example 38-2 in > http://www.postgresql.org/docs/8.4/static/plpgsql-control-structures.html). > Code is below. This works fine as long as entries in count_table have > todays date in "datum". when i have older entries the function "locks > up" (doesn't return, server has 100% cpu). i'm a plpgsql novice. can > someone explain why this happens? related question: i didn't find a way Can't reproduce, works for me. > to log queries that happen inside functions. is this possible? > > postgres version is 8.4.17 You should update, i'm using 9.3, it's possible with http://www.postgresql.org/docs/9.3/interactive/auto-explain.html and set auto_explain.log_nested_statements = on; I don't know if 8.3 contains auto-explain. 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°
On Fri, Dec 20, 2013 at 6:42 AM, Andreas Kretschmer <akretschmer@spamfence.net> wrote: > Matthias Leopold <matthias@aic.at> wrote: > >> hi, >> >> i tried to write a merge function in plpgsql, which is derived from the >> example in the docs (Example 38-2 in >> http://www.postgresql.org/docs/8.4/static/plpgsql-control-structures.html). >> Code is below. This works fine as long as entries in count_table have >> todays date in "datum". when i have older entries the function "locks >> up" (doesn't return, server has 100% cpu). i'm a plpgsql novice. can >> someone explain why this happens? related question: i didn't find a way > > Can't reproduce, works for me. Almost certainly a non-'unique_violation' exception is being thrown (perhaps from a dependent trigger). In a loop like that there should always be a handler of last resort. I bitterly griped about this example a few years back (search the archives). TBH, many times I've wished that caught-but-unhandled exceptions were re-thrown by default. Unless high concurrency is needed, for merge functionality it makes a lot more sense to just lock the table before the insert instead of rigging a loop. merlin
On Friday, December 20, 2013, Merlin Moncure wrote:
On Fri, Dec 20, 2013 at 6:42 AM, Andreas Kretschmer
<akretschmer@spamfence.net> wrote:
> Matthias Leopold <matthias@aic.at> wrote:
>
>> hi,
>>
>> i tried to write a merge function in plpgsql, which is derived from the
>> example in the docs (Example 38-2 in
>> http://www.postgresql.org/docs/8.4/static/plpgsql-control-structures.html).
>> Code is below. This works fine as long as entries in count_table have
>> todays date in "datum". when i have older entries the function "locks
>> up" (doesn't return, server has 100% cpu). i'm a plpgsql novice. can
>> someone explain why this happens? related question: i didn't find a way
>
> Can't reproduce, works for me.
Almost certainly a non-'unique_violation' exception is being thrown
(perhaps from a dependent trigger). In a loop like that there should
always be a handler of last resort. I bitterly griped about this
example a few years back (search the archives). TBH, many times I've
wished that caught-but-unhandled exceptions were re-thrown by default.
Unless high concurrency is needed, for merge functionality it makes a
lot more sense to just lock the table before the insert instead of
rigging a loop.
Anctually, I had it messed up in my head...uncaught exceptions are not supressed. What might be happening is an unguarded trigger...as with http://www.spinics.net/lists/pgsql/msg112560.html. heh
merlin
Am 2013-12-20 21:03, schrieb Merlin Moncure: > On Fri, Dec 20, 2013 at 6:42 AM, Andreas Kretschmer > <akretschmer@spamfence.net> wrote: >> Matthias Leopold <matthias@aic.at> wrote: >> >>> hi, >>> >>> i tried to write a merge function in plpgsql, which is derived from the >>> example in the docs (Example 38-2 in >>> http://www.postgresql.org/docs/8.4/static/plpgsql-control-structures.html). >>> Code is below. This works fine as long as entries in count_table have >>> todays date in "datum". when i have older entries the function "locks >>> up" (doesn't return, server has 100% cpu). i'm a plpgsql novice. can >>> someone explain why this happens? related question: i didn't find a way >> >> Can't reproduce, works for me. > > Almost certainly a non-'unique_violation' exception is being thrown > (perhaps from a dependent trigger). In a loop like that there should > always be a handler of last resort. I bitterly griped about this > example a few years back (search the archives). TBH, many times I've > wished that caught-but-unhandled exceptions were re-thrown by default. > > Unless high concurrency is needed, for merge functionality it makes a > lot more sense to just lock the table before the insert instead of > rigging a loop. > > merlin > > thank you very much, it was indeed a non-'unique_violation'... matthias