The best answer: RTFM!
I found this example in the docs, although it should really exit the
Loop after 10 failed attempts instead of going indefinitely:
CREATE FUNCTION merge_db(key INT, data TEXT) RETURNS VOID AS
$$
BEGIN
LOOP
UPDATE db SET b = data WHERE a = key;
IF found THEN
RETURN;
END IF;
BEGIN
INSERT INTO db(a,b) VALUES (key, data);
RETURN;
EXCEPTION WHEN unique_violation THEN
-- do nothing
END;
END LOOP;
END;
$$
LANGUAGE plpgsql;
On 3/4/07, Berend Tober <btober@ct.metrocast.net> wrote:
> Postgres User wrote:
> > I'm using this code to increment a counter table:
> >
> > IF Exists (SELECT keyfld FROM counter_tbl WHERE key_fld = 'key_val') THEN
> > UPDATE counter_tbl SET counter_fld = counter_fld + 1
> > WHERE key_fld = 'key_val';
> > ELSE
> > INSERT INTO counter_tbl(key_fld, counter_fld) VALUES('key_val', 1);
> > END IF;
> >
> > Now, I assume that it's possible for another session to INSERT a row
> > in the microseconds that exist between the Select and Insert
> > statements above.
> >
> > I also assume that I can wrap the above code in a transaction, and if
> > the transaction fails (because another session's Insert causes my
> > Insert to fail), then I simply need to re-execute it once. (Updates
> > should never fail.)
> >
> > Does anyone have a simple example of the best way to code this type of
> > transaction- and the best way to re-execute the same code on failure?
> > I could use a loop but I'm not sure if that's the best solution.
>
> I think I would try the INSERT first. If it fails, then trap the
> exception and do the UPDATE
>
>