Duplicate Reference Numbers using MAX()+1

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

    Duplicate Reference Numbers using MAX()+1

    Hi

    Within a stored procedure I'm getting the next value of a reference
    number using (simplified):

    BEGIN TRANSACTION
    @next_ref=selec t max(ref) from table
    insert into table (ref) values (@next_ref+1)

    create related records in other tables.

    COMMIT TRANSACTION

    I'm getting duplicate values in a multi-user network, presumably
    because the new record is not commited until the transaction is
    complete and another user starts another transaction and reads the same
    max value.

    Can anyone suggest a way of ensuring unique values? Perhaps by locking
    the table for the duration.
    There is already a separate identity column that increments ok.

  • David Portas

    #2
    Re: Duplicate Reference Numbers using MAX()+1

    If you have an IDENTITY column, why do you want an incrementing "ref"
    as well? Sure, you can lock the table each time but then you'll block
    other inserts and turn your multi user system into a single user
    system. The IDENTITY feature exists precisely to solve that problem.

    --
    David Portas
    SQL Server MVP
    --

    Comment

    • Erland Sommarskog

      #3
      Re: Duplicate Reference Numbers using MAX()+1

      JohnSouth (jsouth@cix.co. uk) writes:[color=blue]
      > Within a stored procedure I'm getting the next value of a reference
      > number using (simplified):
      >
      > BEGIN TRANSACTION
      > @next_ref=selec t max(ref) from table
      > insert into table (ref) values (@next_ref+1)
      >
      > create related records in other tables.
      >
      > COMMIT TRANSACTION
      >
      > I'm getting duplicate values in a multi-user network, presumably
      > because the new record is not commited until the transaction is
      > complete and another user starts another transaction and reads the same
      > max value.
      >[/color]

      Add "WITH (UPDLOCK)" after the table name in the first query.

      If you have a requirement that these values should be unique, you should
      also add a UNIQUE constraint on this column.


      --
      Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

      Books Online for SQL Server SP3 at
      Accelerate your AI application's time to market by harnessing the power of your own data and the built-in AI capabilities of SQL Server 2025, the enterprise database with best-in-class security, performance and availability.

      Comment

      • JohnSouth

        #4
        Re: Duplicate Reference Numbers using MAX()+1


        Erland Sommarskog wrote:[color=blue]
        > JohnSouth (jsouth@cix.co. uk) writes:[color=green]
        > > Within a stored procedure I'm getting the next value of a reference
        > > number using (simplified):
        > >
        > > BEGIN TRANSACTION
        > > @next_ref=selec t max(ref) from table
        > > insert into table (ref) values (@next_ref+1)
        > >
        > > create related records in other tables.
        > >
        > > COMMIT TRANSACTION
        > >
        > > I'm getting duplicate values in a multi-user network, presumably
        > > because the new record is not commited until the transaction is
        > > complete and another user starts another transaction and reads the[/color][/color]
        same[color=blue][color=green]
        > > max value.
        > >[/color]
        >
        > Add "WITH (UPDLOCK)" after the table name in the first query.
        >
        > If you have a requirement that these values should be unique, you[/color]
        should[color=blue]
        > also add a UNIQUE constraint on this column.
        >
        >
        > --
        > Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se
        >
        > Books Online for SQL Server SP3 at
        > http://www.microsoft.com/sql/techinf...2000/books.asp[/color]

        Thanks Erland
        As I understand it, the UPDLOCK hint will still allow other users to
        read the table but will stop another transaction from doing the same
        select max()until the first transaction has done the update and is
        complete.
        Hopefully it won't have too much impact on performance.

        Comment

        • Erland Sommarskog

          #5
          Re: Duplicate Reference Numbers using MAX()+1

          JohnSouth (jsouth@cix.co. uk) writes:[color=blue]
          > As I understand it, the UPDLOCK hint will still allow other users to
          > read the table but will stop another transaction from doing the same
          > select max()until the first transaction has done the update and is
          > complete.[/color]

          Correct. UPDLOCK is a shared lock, other processe can still read the
          value. But if they use UPDLOCK they get stuck.

          What you really do is to upgrade the transaction isolation level to
          Serializable instead of the default READ COMMITTED. UPDLOCK is a
          special tweak to prevent deadlocks. Regular serializable would have meant
          that two processes could have read the max value, and then they
          would have deadlocked on the INSERT statements. Thanks to the UPDLOCK
          this does not happen.

          --
          Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

          Books Online for SQL Server SP3 at
          Accelerate your AI application's time to market by harnessing the power of your own data and the built-in AI capabilities of SQL Server 2025, the enterprise database with best-in-class security, performance and availability.

          Comment

          Working...