Thread: Re: What is the postgres version of mysql's "ON DUPLICATE KEY"
Nick wrote: > I have a table with columns > (product_id,related_product_id,related_counter) > > If product A is related to product B then a record should be created, > if the record already exists then the related_counter should be > incremented. > > This is very easy to do with MySQL using INSERT... ON DUPLICATE KEY. > Standard or not, it is very usefull. > > Is there a way to catch the insert error. For example... > > INSERT INTO related_products (product_id,related_product_id) VALUES > (?,?); > IF (???error: duplicate key???) THEN > UPDATE related_products SET related_counter = related_counter + 1; > END IF; > > -Nick With a rule you can do it easily ( never tried ). Regards Gaetano Mendola
UPDATE related_products SET related_counter = related_counter WHERE ..... only updates if the record exists INSERT (x,y,z) SELECT ?,?,1 WHERE NOT EXISTS (SELECT 1 FROM related_products WHERE .....) Inserts if the key does not exist. On Sat, 11 Sep 2004 00:02:26 +0200, Gaetano Mendola <mendola@bigfoot.com> wrote: > Nick wrote: > > > I have a table with columns > > (product_id,related_product_id,related_counter) > > > > If product A is related to product B then a record should be created, > > if the record already exists then the related_counter should be > > incremented. > > > > This is very easy to do with MySQL using INSERT... ON DUPLICATE KEY. > > Standard or not, it is very usefull. > > > > Is there a way to catch the insert error. For example... > > > > INSERT INTO related_products (product_id,related_product_id) VALUES > > (?,?); > > IF (???error: duplicate key???) THEN > > UPDATE related_products SET related_counter = related_counter + 1; > > END IF; > > > > -Nick > > With a rule you can do it easily ( never tried ). > > Regards > Gaetano Mendola > > ---------------------------(end of broadcast)--------------------------- > TIP 4: Don't 'kill -9' the postmaster >
I may have short handed this to much. I will assume the product A has an id of 1 and the related product B has an id of 2. You have a default on related_counter of 1 I am assuming INSERT INTO related_products (product_id,related_product_id) SELECT 1, 2 WHERE NOT EXISTS (SELECT 1 FROM related_products WHERE product_id = 1 AND related_product_id = 2) The insert is plain enough but instead of using values you are getting the data from the select statement. The select statement returns 1 row of constant values just like the doing the values however no row is returned if the where clause is not met. If no row is returned then nothing can be inserted therefore no error is returned. So let's look at the where clause it is a if the subselect returns any value then exists will be true but we invert that with the NOT. The subselect returns 1 if a row already exists with product_id and related_product_id other wise a null row is returned. You can think of this as a INSERT if the key doesn't already exist. If you still need more help just let me know :-) On Sat, 11 Sep 2004 01:17:29 +0100, Ian Linwood <ian@dinwoodie.freeuk.com> wrote: > Hello Kevin, > > Friday, September 10, 2004, 11:19:58 PM, you wrote: > > KB> INSERT (x,y,z) SELECT ?,?,1 WHERE NOT EXISTS (SELECT 1 FROM > KB> related_products WHERE .....) > > could someone walk me through this one? I do not understand it at all. > apologies for my cluelessness ;-) > > -- > Best regards, > Ian > >
> INSERT INTO related_products (product_id,related_product_id) > SELECT 1, 2 WHERE NOT EXISTS (SELECT 1 > FROM > related_products > WHERE > product_id = 1 AND related_product_id = 2) Should not the SELECT be FOR UPDATE ? because if no insert is done, the OP wanted to UPDATE the row, so it should not be deleted by another transaction in-between... Can the above query fail if another transaction inserts a row between the SELECT and the INSERT or postgres guarantee that this won't happen ?
Pierre-Frédéric Caillaud wrote: > > INSERT INTO related_products (product_id,related_product_id) > > SELECT 1, 2 WHERE NOT EXISTS (SELECT 1 > > FROM > > related_products > > WHERE > > product_id = 1 AND related_product_id = 2) > > Should not the SELECT be FOR UPDATE ? > because if no insert is done, the OP wanted to UPDATE the row, so it > should not be deleted by another transaction in-between... > > Can the above query fail if another transaction inserts a row > between the SELECT and the INSERT or postgres guarantee that this > won't happen ? There is no "between" a single statement. -- Peter Eisentraut http://developer.postgresql.org/~petere/
> There is no "between" a single statement. Yes, I know, even if the statement involves mutiple subqueries... I meant : The OP wants to UPDATE if the row already exists, and to INSERT otherwise ; we have the INSERT bit here, but to UPDATE he needs to check if the insert really took place, and if not, issue an UPDATE statement.. so that makes it two statements. By the way, do several consecutive queries inside a plpgsql function count as one statement (the function call) or as several statements (ie. inside a function are transactions like SERIALIZED ?) On Sat, 11 Sep 2004 13:56:26 +0200, Peter Eisentraut <peter_e@gmx.net> wrote: > Pierre-Frédéric Caillaud wrote: >> > INSERT INTO related_products (product_id,related_product_id) >> > SELECT 1, 2 WHERE NOT EXISTS (SELECT 1 >> > FROM >> > related_products >> > WHERE >> > product_id = 1 AND related_product_id = 2) >> >> Should not the SELECT be FOR UPDATE ? >> because if no insert is done, the OP wanted to UPDATE the row, so it >> should not be deleted by another transaction in-between... >> >> Can the above query fail if another transaction inserts a row >> between the SELECT and the INSERT or postgres guarantee that this >> won't happen ? >
Peter Eisentraut <peter_e@gmx.net> writes: > Pierre-Fr�d�ric Caillaud wrote: > INSERT INTO related_products (product_id,related_product_id) > SELECT 1, 2 WHERE NOT EXISTS (SELECT 1 > FROM > related_products > WHERE > product_id = 1 AND related_product_id = 2) >> >> Should not the SELECT be FOR UPDATE ? >> because if no insert is done, the OP wanted to UPDATE the row, so it >> should not be deleted by another transaction in-between... >> >> Can the above query fail if another transaction inserts a row >> between the SELECT and the INSERT or postgres guarantee that this >> won't happen ? > There is no "between" a single statement. Sure there is. In the above example, the EXISTS result will be correct as of the time of the snapshot that was taken at the start of the command (or the start of the whole transaction, if using SERIALIZABLE mode). So it is *entirely* possible for the INSERT to fail on duplicate key if some other transaction commits a conflicting row concurrently. AFAIK, all the bulletproof solutions for this sort of problem involve being prepared to recover from a failed insertion. There are various ways you can do that but they all come down to needing to catch the duplicate key error. In the past you have had to code that in client-side logic. In 8.0 you could write a plpgsql function that catches the exception. Given the need for a test anyway, I think the WHERE NOT EXISTS above is pretty much a waste of time. Just do an INSERT, and if it fails do an UPDATE; or do an UPDATE, and if it fails (hits zero rows) then do an INSERT, being prepared to go back to the UPDATE if the INSERT fails. Which of these is better probably depends on how often you expect each path to be taken. regards, tom lane
On Sat, 11 Sep 2004 11:27:02 -0400, Tom Lane <tgl@sss.pgh.pa.us> wrote: > > > There is no "between" a single statement. > > Sure there is. In the above example, the EXISTS result will be correct > as of the time of the snapshot that was taken at the start of the > command (or the start of the whole transaction, if using SERIALIZABLE > mode). So it is *entirely* possible for the INSERT to fail on duplicate > key if some other transaction commits a conflicting row concurrently. > > AFAIK, all the bulletproof solutions for this sort of problem involve > being prepared to recover from a failed insertion. There are various > ways you can do that but they all come down to needing to catch the > duplicate key error. In the past you have had to code that in > client-side logic. In 8.0 you could write a plpgsql function that > catches the exception. > > Given the need for a test anyway, I think the WHERE NOT EXISTS above > is pretty much a waste of time. Just do an INSERT, and if it fails do > an UPDATE; or do an UPDATE, and if it fails (hits zero rows) then do > an INSERT, being prepared to go back to the UPDATE if the INSERT fails. > Which of these is better probably depends on how often you expect each > path to be taken. It's not meant to be a bulletproof solution. It's meant to be a syntactically equivalent to the MySQL statement. You still have to check for a failure. Do the update followed by the insert in a serial transaction. If the transaction fails you redo the same SQL transaction. This eliminates the need for a this query else this query scenario which is the whole point of the MySQL bastard syntax in the first place. Not the best solution but if you have a good DBA and bad programmers it might be what you actually want.