What is the postgres version of mysql's "ON DUPLICATE KEY"

Collapse
This topic is closed.
X
X
 
  • Time
  • Show
Clear All
new posts
  • Nick

    What is the postgres version of mysql's "ON DUPLICATE KEY"

    I have a table with columns
    (product_id,rel ated_product_id ,related_counte r)

    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_product s (product_id,rel ated_product_id ) VALUES
    (?,?);
    IF (???error: duplicate key???) THEN
    UPDATE related_product s SET related_counter = related_counter + 1;
    END IF;

    -Nick
  • Gaetano Mendola

    #2
    Re: What is the postgres version of mysql's "ON DUPLICATE KEY"

    Nick wrote:
    [color=blue]
    > I have a table with columns
    > (product_id,rel ated_product_id ,related_counte r)
    >
    > 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_product s (product_id,rel ated_product_id ) VALUES
    > (?,?);
    > IF (???error: duplicate key???) THEN
    > UPDATE related_product s SET related_counter = related_counter + 1;
    > END IF;
    >
    > -Nick[/color]

    With a rule you can do it easily ( never tried ).


    Regards
    Gaetano Mendola





    Comment

    • Kevin Barnard

      #3
      Re: What is the postgres version of mysql's "ON DUPLICATE KEY"

      UPDATE related_product s 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_product s WHERE .....)

      Inserts if the key does not exist.

      On Sat, 11 Sep 2004 00:02:26 +0200, Gaetano Mendola <mendola@bigfoo t.com> wrote:[color=blue]
      > Nick wrote:
      >[color=green]
      > > I have a table with columns
      > > (product_id,rel ated_product_id ,related_counte r)
      > >
      > > 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_product s (product_id,rel ated_product_id ) VALUES
      > > (?,?);
      > > IF (???error: duplicate key???) THEN
      > > UPDATE related_product s SET related_counter = related_counter + 1;
      > > END IF;
      > >
      > > -Nick[/color]
      >
      > With a rule you can do it easily ( never tried ).
      >
      > Regards
      > Gaetano Mendola
      >
      > ---------------------------(end of broadcast)---------------------------
      > TIP 4: Don't 'kill -9' the postmaster
      >[/color]

      ---------------------------(end of broadcast)---------------------------
      TIP 5: Have you checked our extensive FAQ?



      Comment

      • Kevin Barnard

        #4
        Re: What is the postgres version of mysql's &quot;ON DUPLICATE KEY&quot;

        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_product s (product_id,rel ated_product_id )
        SELECT 1, 2 WHERE NOT EXISTS (SELECT 1
        FROM related_product s
        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:[color=blue]
        > 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_product s WHERE .....)
        >
        > could someone walk me through this one? I do not understand it at all.
        > apologies for my cluelessness ;-)
        >
        > --
        > Best regards,
        > Ian
        >
        >[/color]

        ---------------------------(end of broadcast)---------------------------
        TIP 1: subscribe and unsubscribe commands go to majordomo@postg resql.org

        Comment

        • Pierre-Frédéric Caillaud

          #5
          Re: What is the postgres version of mysql's &quot;ON DUPLICATE KEY&quot;

          [color=blue]
          > INSERT INTO related_product s (product_id,rel ated_product_id )
          > SELECT 1, 2 WHERE NOT EXISTS (SELECT 1
          > FROM
          > related_product s
          > WHERE
          > product_id = 1 AND related_product _id = 2)[/color]

          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 ?

          ---------------------------(end of broadcast)---------------------------
          TIP 6: Have you searched our list archives?



          Comment

          • Peter Eisentraut

            #6
            Re: What is the postgres version of mysql's &quot;ON DUPLICATE KEY&quot;

            Pierre-Frédéric Caillaud wrote:[color=blue][color=green]
            > > INSERT INTO related_product s (product_id,rel ated_product_id )
            > > SELECT 1, 2 WHERE NOT EXISTS (SELECT 1
            > > FROM
            > > related_product s
            > > WHERE
            > > product_id = 1 AND related_product _id = 2)[/color]
            >
            > 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 ?[/color]

            There is no "between" a single statement.

            --
            Peter Eisentraut



            ---------------------------(end of broadcast)---------------------------
            TIP 1: subscribe and unsubscribe commands go to majordomo@postg resql.org

            Comment

            • Pierre-Frédéric Caillaud

              #7
              Re: What is the postgres version of mysql's &quot;ON DUPLICATE KEY&quot;

              [color=blue]
              > There is no "between" a single statement.[/color]

              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.ne t>
              wrote:
              [color=blue]
              > Pierre-Frédéric Caillaud wrote:[color=green][color=darkred]
              >> > INSERT INTO related_product s (product_id,rel ated_product_id )
              >> > SELECT 1, 2 WHERE NOT EXISTS (SELECT 1
              >> > FROM
              >> > related_product s
              >> > WHERE
              >> > product_id = 1 AND related_product _id = 2)[/color]
              >>
              >> 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 ?[/color]
              >[/color]


              ---------------------------(end of broadcast)---------------------------
              TIP 5: Have you checked our extensive FAQ?



              Comment

              • Tom Lane

                #8
                Re: What is the postgres version of mysql's &quot;ON DUPLICATE KEY&quot;

                Peter Eisentraut <peter_e@gmx.ne t> writes:[color=blue]
                > Pierre-Frédéric Caillaud wrote:
                > INSERT INTO related_product s (product_id,rel ated_product_id )
                > SELECT 1, 2 WHERE NOT EXISTS (SELECT 1
                > FROM
                > related_product s
                > WHERE
                > product_id = 1 AND related_product _id = 2)[color=green]
                >>
                >> 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 ?[/color][/color]
                [color=blue]
                > There is no "between" a single statement.[/color]

                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

                ---------------------------(end of broadcast)---------------------------
                TIP 6: Have you searched our list archives?



                Comment

                • Kevin Barnard

                  #9
                  Re: What is the postgres version of mysql's &quot;ON DUPLICATE KEY&quot;

                  On Sat, 11 Sep 2004 11:27:02 -0400, Tom Lane <tgl@sss.pgh.pa .us> wrote:[color=blue]
                  >[color=green]
                  > > There is no "between" a single statement.[/color]
                  >
                  > 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.[/color]

                  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.

                  ---------------------------(end of broadcast)---------------------------
                  TIP 7: don't forget to increase your free space map settings

                  Comment

                  Working...