BUG: "SET TRANSACTION ISOLATION LEVEL" Ignored in Stored ProcLast reviewed: July 16, 1997Article ID: Q171322 |
The information in this article applies to:
SYMPTOMSIf you code "SET TRANSACTION ISOLATION LEVEL <option>" within a stored procedure, the statement is ignored during the execution of that stored procedure. The isolation level in effect for the connection that first executes the stored procedure will be used during all subsequent executions of that procedure plan, even if a subsequent connection is using a different isolation level when it calls the relevant stored procedure. Also, the connection that issues the CREATE PROCEDURE statement will have its transaction isolation level set to whatever <option> is coded for the "SET TRANSACTION ISOLATION LEVEL <option>" statement within the procedure.
CAUSEThe SET TRANSACTION ISOLATION LEVEL <option> that is contained in the CREATE PROCEDURE statement is executed as if it were coded outside of the procedure. However, the CREATE PROCEDURE statement executes without indicating any problem, (unless the SET statement is the only statement in the procedure, in which case you get error 124: "CREATE PROCEDURE contains no statement"). Furthermore, the transaction isolation level associated with the connection that first executes the relevant stored procedure is set during all subsequent executions of that procedures execution plan.
WORKAROUNDTo work around this problem, do one of the following:
STATUSMicrosoft has confirmed this to be a problem in Microsoft SQL Server version 6.5. We are researching this problem and will post new information here in the Microsoft Knowledge Base as it becomes available.
MORE INFORMATIONAs a result of this issue, users will experience unpredictable locking behavior when using stored procedures, unless the SET TRANSACTION ISOLATION LEVEL statement is never used on connections that call stored procedures. Calling the same stored procedure twice in a row may result in different locking behavior if you pick up different plans from the procedure cache. To demonstrate this issue, execute the following code within ISQL/w:
use pubs go CREATE TABLE testing (f1 int NOT NULL , f2 varchar (24) NOT NULL ) GO create procedure testproc as set transaction isolation level serializable select * from testing go BEGIN TRANSACTION insert into testing values (123456, '123456') goOn a separate connection, execute the following statements:
use pubs go set transaction isolation level read uncommitted go exec testproc goNote that the stored procedure returns uncommitted rows, despite the fact that the isolation level was set to serializable within the stored procedure code. To tidy up after this demonstration, issue the following code from the first connection:
use pubs go rollback tran go drop table testing go drop proc testproc go |
Additional query words: Transact-SQL trans-sql t-sql sp proc
© 1998 Microsoft Corporation. All rights reserved. Terms of Use. |