By using this site, you agree to our updated Privacy Policy and our Terms of Use. Manage your Cookies Settings.
443,934 Members | 1,527 Online
Bytes IT Community
+ Ask a Question
Need help? Post your question and get tips & solutions from a community of 443,934 IT Pros & Developers. It's quick & easy.

Transaction isolation levels

P: n/a
I am redesigning an application that distributes heldesk tickets to our
50 engineers automatically. When the engineer logs into their window a
stored procedure executes that searches through all open tickets and
assigns a predetermined amount of the open tickets to that engineer.The
problem I am running into is that if 2 or more engineers log in at the
same time the stored procedure will distribute the same set of tickets
multiple times.

Originally this was fixed by "reworking" the way SQL Server handles
transactions. The original developer wrote his code like this:

-----
DECLARE @RET_STAT INT
SELECT 'X' INTO #TEMP
BEGIN TRAN
UPDATE #TEMP SET 'X' = 'Y'
SELECT TOP 1 @TICKET_# =TICKET_NUMBER FROM TICKETS WHERE STATUS = 'O'
EXEC @RET_STAT = USP_MOVE2QUEUE @TICKET_#, @USERID
IF @RET_STAT <> 0
ROLLBACK TRAN
RETURN @RET_STAT
END
COMMIT TRAN
-----

The UPDATE of the #TEMP table forces the transaction to kick off and
locks the row in table TICKETS until the entire transaction has
completed.

I would like to get rid of the #TEMP table and start using isolation
levels, but I am unsure which isolation level would continue to lock
the selected data and not allow anyone else access. Do I need a
combination of isolation level and "WITH (ROWLOCK)"?

Additionally, the TICKETS table is used throughout the application and
I cannot exclusively lock the entire table just for the distribution
process. It is VERY high I/O!

Thanks for the help.

Feb 15 '06 #1
Share this Question
Share on Google+
3 Replies


P: n/a
Josh,

This thread talks about a very similar problem...

http://groups.google.com/group/comp....d494bcaf9ce1c7

And has a good solution.

Feb 15 '06 #2

P: n/a
On 15 Feb 2006 13:55:09 -0800, joshsackett wrote:

(snip)
Originally this was fixed by "reworking" the way SQL Server handles
transactions. The original developer wrote his code like this:

-----
DECLARE @RET_STAT INT
SELECT 'X' INTO #TEMP
BEGIN TRAN
UPDATE #TEMP SET 'X' = 'Y'
SELECT TOP 1 @TICKET_# =TICKET_NUMBER FROM TICKETS WHERE STATUS = 'O'
EXEC @RET_STAT = USP_MOVE2QUEUE @TICKET_#, @USERID
IF @RET_STAT <> 0
ROLLBACK TRAN
RETURN @RET_STAT
END
COMMIT TRAN
-----

The UPDATE of the #TEMP table forces the transaction to kick off and
locks the row in table TICKETS until the entire transaction has
completed.
Hi Josh,

I see several things wrong with this code.

First: the update of #TEMP will lock the updated row, but it still won't
lock the rows in the TICKETS table. They are just read, so they get a
shared lock during the SELECT, which is released immediately after the
SELECT statement finishes.

Second: the ROLLBACK and RETURN statements after the test of @RET_STAT
are not enclosed in a BEGIN END block. Therefor, only the ROLLBACK is
executed conditionally; the RETURN will always be executed and the
execution will never arrive at the COMMIT statement.

I would like to get rid of the #TEMP table and start using isolation
levels, but I am unsure which isolation level would continue to lock
the selected data and not allow anyone else access. Do I need a
combination of isolation level and "WITH (ROWLOCK)"?
Since the #TEMP table does nothing (the original developer clearly
didn't understand how transactions and locking work!), you can just
remove that. It won't change anything (except performance).

Since you're not updating the TICKET table but still want the row to be
locked, you'll have to force an exclusive lock. There's no isolation
level that does that - you'll have to use a locking hint.

The ROWLOCK locking hint is superfluous, since row-level locking are
chosen by default in SQL Server 2000.

Here's my code suggestion:

DECLARE @RetStat int
BEGIN TRANSACTION
SELECT TOP 1
@Ticket = TicketNumber
FROM Tickets WITH (XLOCK)
WHERE Status = 'O'
EXECUTE @RetStat = USP_Move2Queue @Ticket, @UserID
IF @RetStat <> 0
ROLLBACK TRANSACTION
ELSE
COMMIT TRANSACTION
RETURN @RetStat

Additionally, the TICKETS table is used throughout the application and
I cannot exclusively lock the entire table just for the distribution
process. It is VERY high I/O!


The code above will block other transactions until the stored procedure
USP_Muve2Queue has finished executing. You should ensure that this
procedure is as fast as possible. If you can move code from this stored
proc to a procedure that execut4es after committing the transaction,
you'll gain concurrency.

It's also possible to add an extra locking hint - change "WITH (XLOCK)"
to "WITH (XLOCK, READPAST)". This tells SQL Server: if you encounter a
locked row, don't wait for the lock to be released; just skip it and
read the next row. That would increase concurrency in this scenario. But
it also introduces the risk of incorrect information - if there's only
one row with status 'O' in the table, it is locked, but the transaction
that has locked it is in the process of a rollback, a simulteneous
execution of this code would skip it and report no more rows waiting to
be processed - while in fact, there still is one!

--
Hugo Kornelis, SQL Server MVP
Feb 15 '06 #3

P: n/a
joshsackett (jo*********@gmail.com) writes:
Originally this was fixed by "reworking" the way SQL Server handles
transactions. The original developer wrote his code like this:

-----
DECLARE @RET_STAT INT
SELECT 'X' INTO #TEMP
BEGIN TRAN
UPDATE #TEMP SET 'X' = 'Y'
SELECT TOP 1 @TICKET_# =TICKET_NUMBER FROM TICKETS WHERE STATUS = 'O'
EXEC @RET_STAT = USP_MOVE2QUEUE @TICKET_#, @USERID
IF @RET_STAT <> 0
ROLLBACK TRAN
RETURN @RET_STAT
END
COMMIT TRAN
-----

The UPDATE of the #TEMP table forces the transaction to kick off and
locks the row in table TICKETS until the entire transaction has
completed.
No, that's a misunderstanding. The UPDATE of #TEMP is entirely
meaningless. The lock taken out on TICKETS will be a shared lock
that under the default isolation level will be released.
I would like to get rid of the #TEMP table and start using isolation
levels, but I am unsure which isolation level would continue to lock
the selected data and not allow anyone else access. Do I need a
combination of isolation level and "WITH (ROWLOCK)"?


You need a non-clustered index on (STATUS, TICKET_NUMBER), and you
need to add the locking hint WITH (UPDLOCK, HOLDLOCK). Finally, you
should add a ORDER BY TICKET_NUMBER to the query.

HOLDLOCK gives you serializable isolation level that prevents the result
of the query to be changed while the query is running. UPDLOCK is a
read-lock, which only can be held by one process. Thus, if a second
process arrive here, it will be held up until the first commits.
--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server 2005 at
http://www.microsoft.com/technet/pro...ads/books.mspx
Books Online for SQL Server 2000 at
http://www.microsoft.com/sql/prodinf...ons/books.mspx
Feb 15 '06 #4

This discussion thread is closed

Replies have been disabled for this discussion.