FIX: LOCK_TIMEOUT causes transaction to roll back and @@error does not capture error 1222

Article translations Article translations
Article ID: 286286 - View products that this article applies to.
This article was previously published under Q286286
BUG #: 351234 (SHILOH)
BUG #: 352640 (SHILOH)
Expand all | Collapse all

On This Page

SYMPTOMS

In SQL Server 7.0, the LOCK_TIMEOUT setting aborts a single statement in a batch when a lock timeout occurs. You can then code to check for @@error = 1222 and implement an error handler.

In the original release of SQL Server 2000, design changes to the software changed the behavior of the LOCK_TIMEOUT setting. A system server process ID (spid) that incurs a lock timeout is treated like a deadlock victim; the entire batch is rolled back and aborted, and you are unable to check for @@error = 1222.

Starting with the release listed in the "Resolution" section, the software has been changed to revert to the SQL Server 7.0 behavior of only aborting a single statement.

NOTE: The Customizing the Lock Time-out section in SQL Server 2000 Books Online correctly describes the SQL Server 7.0 behavior and the SQL Server 2000 behavior of the version provided in this fix and later.

RESOLUTION

A supported hotfix is available from Microsoft. However, this hotfix is intended to correct only the problem that is described in this article. Apply this hotfix only to systems that are experiencing this specific problem.

If the hotfix is available for download, there is a "Hotfix download available" section at the top of this Knowledge Base article. If this section does not appear, submit a request to Microsoft Customer Service and Support to obtain the hotfix.

Note If additional issues occur or if any troubleshooting is required, you might have to create a separate service request. The usual support costs will apply to additional support questions and issues that do not qualify for this specific hotfix. For a complete list of Microsoft Customer Service and Support telephone numbers or to create a separate service request, visit the following Microsoft Web site:
http://support.microsoft.com/contactus/?ws=support
Note The "Hotfix download available" form displays the languages for which the hotfix is available. If you do not see your language, it is because a hotfix is not available for that language. The English version of this fix should have the following file attributes or later:
   Version    File name     Platform
   ---------------------------------

   8.00.277   s80277i.exe   Intel
				
NOTE: Due to file dependencies, the most recent hotfix or feature that contains the above files may also contain additional files.

WORKAROUND

Common alternatives to using the LOCK_TIMEOUT setting are:
  • Use the READPAST locking hint. (Note, however, that you cannot use READPAST with an INSERT, UPDATE, or DELETE statement.)
  • Use query timeouts instead of lock timeouts.

STATUS

Microsoft has confirmed this to be a problem in SQL Server 2000.

MORE INFORMATION

Steps to Reproduce Behavior

  1. In SQL Server Query Analyzer, open a connection window and connect to SQL Server 2000. Create a table by using this code:
    CREATE TABLE timeout_test (fname varchar(20), lname varchar(20))
    					
  2. Begin a transaction and insert the following into the table created in step 1:
    BEGIN TRAN
    INSERT INTO timeout_test VALUES ('John', 'Smith')
    					
  3. Open a new connection window in Query Analyzer and connect to the SQL Server 2000 server. Begin a new transaction and set the lock timeout value to 1 as follows:
    BEGIN TRAN
    SET LOCK_TIMEOUT 1
    DELETE FROM timeout_test WHERE lname = 'Smith'
    IF @@error = 1222
    PRINT '-> Error 1222 was trapped.'
    ELSE
    PRINT '-> Error 1222 was NOT trapped.'
    					

Results

  • On the original release of SQL Server 2000:
    Server: Msg 1222, Level 16, State 50, Line 1
    Lock request time out period exceeded.
  • On SQL Server 7.0 and SQL Server 2000 versions containing the fix:
    Server: Msg 1222, Level 16, State 50, Line 1
    Lock request time out period exceeded.
    The statement has been terminated.
    -> Error 1222 was trapped.

Properties

Article ID: 286286 - Last Review: October 7, 2005 - Revision: 3.7
APPLIES TO
  • Microsoft SQL Server 2000 Standard Edition
Keywords: 
kbautohotfix kbhotfixserver kbbug kbfix kbqfe kbsqlserv2000sp1fix KB286286

Give Feedback

 

Contact us for more help

Contact us for more help
Connect with Answer Desk for expert help.
Get more support from smallbusiness.support.microsoft.com