INF: Stored Procedures, Transactions, and Error 266ID: Q158325
|
If a stored procedure exits with the @@trancount value that is not the same
as when the stored procedure was entered, the following error will occur:
Error: 266, Severity: 16, State: 1
Transaction count after EXECUTE indicates that a COMMIT or ROLLBACK TRAN
is missing. Previous count = %ld, Current count = %ld.
The following is a short code example that demonstrates the problem:
CREATE PROCEDURE test AS
SELECT @@trancount
ROLLBACK TRANSACTION
SELECT @@trancount
GO
BEGIN TRANSACTION
EXEC test
GO
-- Example 1.a
CREATE PROCEDURE test1a AS
SELECT @@trancount
GO
BEGIN TRANSACTION
EXEC test1a
ROLLBACK TRANSACTION
GO
-- Example 1.b
CREATE PROCEDURE test1c AS
SELECT @@trancount
GO
CREATE PROCEDURE test1b AS
BEGIN TRANSACTION
EXEC test1c
COMMIT TRANSACTION
GO
EXEC test1b
GO
-- Example 2
CREATE PROCEDURE test2b AS
SELECT @@trancount
BEGIN TRANSACTION
SELECT @@trancount
COMMIT TRANSACTION
SELECT @@trancount
GO
CREATE PROCEDURE test2a AS
BEGIN TRANSACTION
EXEC test2b
COMMIT TRANSACTION
GO
EXEC test2a
GO
-- Example 3
USE master
EXEC sp_addmessage 50001, 16, 'Rollback of transaction in test3'
GO
CREATE PROCEDURE test3 AS
RAISERROR (50001,16,1)
GO
BEGIN TRANSACTION
EXEC test3
IF @@error <> 50001
BEGIN
PRINT 'Commit'
COMMIT TRANSACTION
END
ELSE
BEGIN
PRINT 'Rollback'
ROLLBACK TRANSACTION
END
GO
-- Example 4
CREATE TABLE x (col1 int)
GO
CREATE TRIGGER xins ON x FOR INSERT AS
ROLLBACK TRANSACTION
GO
CREATE PROCEDURE sp_xinsert AS
SELECT @@trancount
INSERT x (col1) VALUES (1)
SELECT @@trancount
GO
BEGIN TRANSACTION
EXEC sp_xinsert
IF @@error <> 0
BEGIN
PRINT 'Commit'
COMMIT TRANSACTION
END
ELSE
BEGIN
PRINT 'Rollback'
ROLLBACK TRANSACTION
END
GO
SELECT * FROM x
Additional query words: commit rollback trigger
Keywords : kbprg SSrvProg SSrvStProc SSrvTran_SQL
Version : 4.2x 6.0 6.5
Platform : WINDOWS
Issue type :
Last Reviewed: April 2, 1999