473,750 Members | 2,253 Online
Bytes | Software Development & Data Engineering Community
+ Post

Home Posts Topics Members FAQ

Transaction isolation levels

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
3 4613
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
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
joshsackett (jo*********@gm ail.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 misunderstandin g. 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****@sommarsk og.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 thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

0
1092
by: Sara | last post by:
I am getting an error that states: DB_E_ERRORSINCOMMAND when I try to establish a transaction in an Oracle 7.2 database. The code is: Try If AuthHelper.App_conn.State = ConnectionState.Closed Then AuthHelper.App_conn.Open() End If Dim myTrans As System.Data.OleDb.OleDbTransaction=AuthHelper.App_conn.BeginTransaction()
3
3293
by: Florian G. Pflug | last post by:
Hi I'd like to know if there is a way to specify different transaction isolation levels for different tables in the db. The reason i'm asking this (rather bizarre sounding, i know ;-) ) question is the following: I'm importing about 2 million records into my application each day (the data is more or less fully replaced each day). My importer updates only a few tables (about 5 - 10), but reads a lot of other tables (10 or so) while...
2
8137
by: kanda | last post by:
Hello. I am developing the application (VBA&ODBC, to be exact) which periodically calls the stored procedures in the IBM DB2. A few of the procedures require executing with isolation level RR ( ANSI "SERIALIZABLE" ), not the default; default is CS (ANSI "Read Committed")). The procedure language is SQL. According to the documentation, I can adjust procedure *run*-time isolation level by setting *compile*-time dataserver-wide option
2
1977
by: cj | last post by:
Hi. I need a better understanding of transaction isolation levels. I can't seem to visualize a scenario for each level. The serializable level is the only one I really understand. I do not seem to grasp what a RepeatableRead is or what a phantom row is. I think I need a more non-technical definition. Does anyone know of any resource that would provide this? I have many books and MSDN libraries but still am unclear. Thanks,
2
3791
by: Christian Stooker | last post by:
Part one: ====== Hi ! I want to use SQLite database like the FireBird database: with big isolation level. What's that meaning ? I have an application that periodically check some input directory,
1
2190
by: Mark | last post by:
Hello, I'm using the following code implementing transactions: Using trans1 As New Transactions.TransactionScope 'Data manipulations here! End using How do I change the transaction isolation level?
3
7218
by: D. | last post by:
I have a question about the "readCommitted" transaction isolation level. I have a client that is updating a record on a table. I suspend the execution after the UPDATE but before the commit statement. Than another client is trying to read the same record. As transaction isolation is set to "readCommited" I expected that the second client will read the old version of the record (before the update). Instead, the second client hangs and...
5
2435
by: dhek | last post by:
Hi, I have 1 SQL statement selecting data from various tables and updating other tables. The question then is how do I prevent other applications from modifying the tables that I'm working on (that is while my transaction is being executed)? I know that the isolation level should be either REPEATABLE READ or
3
1303
by: ms | last post by:
Hi, I used SqlTransaction to insert datas to table A in my program ,but I find that before I commit the transaction ,I even can not use query analyzer to query data in table A, could anybody tell me why and is it normal or not? Thanks -ja
0
9575
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers, it seems that the internal comparison operator "<=>" tries to promote arguments from unsigned to signed. This is as boiled down as I can make it. Here is my compilation command: g++-12 -std=c++20 -Wnarrowing bit_field.cpp Here is the code in...
0
9394
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven tapestry of website design and digital marketing. It's not merely about having a website; it's about crafting an immersive digital experience that captivates audiences and drives business growth. The Art of Business Website Design Your website is...
1
9338
by: Hystou | last post by:
Overview: Windows 11 and 10 have less user interface control over operating system update behaviour than previous versions of Windows. In Windows 11 and 10, there is no way to turn off the Windows Update option using the Control Panel or Settings app; it automatically checks for updates and installs any it finds, whether you like it or not. For most users, this new feature is actually very convenient. If you want to control the update process,...
0
9256
tracyyun
by: tracyyun | last post by:
Dear forum friends, With the development of smart home technology, a variety of wireless communication protocols have appeared on the market, such as Zigbee, Z-Wave, Wi-Fi, Bluetooth, etc. Each protocol has its own unique characteristics and advantages, but as a user who is planning to build a smart home system, I am a bit confused by the choice of these technologies. I'm particularly interested in Zigbee because I've heard it does some...
1
6803
isladogs
by: isladogs | last post by:
The next Access Europe User Group meeting will be on Wednesday 1 May 2024 starting at 18:00 UK time (6PM UTC+1) and finishing by 19:30 (7.30PM). In this session, we are pleased to welcome a new presenter, Adolph Dupré who will be discussing some powerful techniques for using class modules. He will explain when you may want to use classes instead of User Defined Types (UDT). For example, to manage the data in unbound forms. Adolph will...
0
4712
by: TSSRALBI | last post by:
Hello I'm a network technician in training and I need your help. I am currently learning how to create and manage the different types of VPNs and I have a question about LAN-to-LAN VPNs. The last exercise I practiced was to create a LAN-to-LAN VPN between two Pfsense firewalls, by using IPSEC protocols. I succeeded, with both firewalls in the same network. But I'm wondering if it's possible to do the same thing, with 2 Pfsense firewalls...
0
4885
by: adsilva | last post by:
A Windows Forms form does not have the event Unload, like VB6. What one acts like?
1
3322
by: 6302768590 | last post by:
Hai team i want code for transfer the data from one system to another through IP address by using C# our system has to for every 5mins then we have to update the data what the data is updated we have to send another system
3
2223
bsmnconsultancy
by: bsmnconsultancy | last post by:
In today's digital era, a well-designed website is crucial for businesses looking to succeed. Whether you're a small business owner or a large corporation in Toronto, having a strong online presence can significantly impact your brand's success. BSMN Consultancy, a leader in Website Development in Toronto offers valuable insights into creating effective websites that not only look great but also perform exceptionally well. In this comprehensive...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.