Archive

Archive for May 25, 2015

SQL error – Msg 6401, Level 16, State 1 – Cannot roll back Transaction. No transaction or savepoint of that name was found

May 25, 2015 1 comment

Yesterday in a SQL forum I saw a question regarding this error, and the person who had asked this question was finding it difficult to fix it.

He had a scenario where the Outer Transaction has an Inner Transaction, as shown below. And he was trying to ROLLBACK the inner Transaction and was getting an error for this similar SQL batch that I’ve tried to simulated here:

–> I’ve created a sample table let’s executed the whole below:

USE [tempdb]
GO

CREATE TABLE dbo.TranTest (ID INT)
GO

-- Outer Transaction - BEGIN
SELECT @@TRANCOUNT AS 'outerTran Begin', count(*) from dbo.TranTest -- 0, 0
BEGIN TRANSACTION outerTran

INSERT INTO dbo.TranTest values(1)
SELECT @@TRANCOUNT AS 'outerTran Begin', count(*) from dbo.TranTest -- 1, 1

	-- Inner Transaction
	BEGIN TRANSACTION innerTran

	INSERT INTO dbo.TranTest values(2)
	SELECT @@TRANCOUNT AS 'innerTran Begin', count(*) from dbo.TranTest -- 2, 2

	ROLLBACK TRANSACTION innerTran
	SELECT @@TRANCOUNT AS 'innerTran Rollback', count(*) from dbo.TranTest -- 2, 2

-- Outer Transaction - COMMIT
COMMIT TRANSACTION outerTran
SELECT @@TRANCOUNT AS 'outerTran Commit', count(*) from dbo.TranTest -- 1, 2
GO

SELECT * FROM dbo.TranTest -- 2
GO

– You can see the count of rows inserted in the comments with every SELECT statement.
– But the ROLLBACK TRANSACTION innerTran statement at Line 20 fails with following error:
Msg 6401, Level 16, State 1, Line 20
Cannot roll back innerTran1. No transaction or savepoint of that name was found.

– And thus the last SELECT statement still gives Transaction count = 2, as this Transaction is not Rollbacked and neither committed.

–> NOTE: With the ROLLBACK TRANSACTION statement as per MS BoL you can only specify the name of the outermost BEGIN TRANSACTION statement. So, how can we make this code fail-proof?
 

There are 2 ways to solve this:
1. Just use ROLLBACK TRANSACTION without the name of any transaction.
2. Use SAVE TRANSACTION instead of BEGIN TRANSACTION for inner Transactions.
 

Option #1: Using just ROLLBACK TRANSACTION statement:

-- Outer Transaction - BEGIN
SELECT @@TRANCOUNT AS 'outerTran Begin', count(*) from dbo.TranTest -- 0, 0
BEGIN TRANSACTION outerTran

INSERT INTO dbo.TranTest values(1)
SELECT @@TRANCOUNT AS 'outerTran Begin', count(*) from dbo.TranTest -- 1, 1

	-- Inner Transaction
	BEGIN TRANSACTION innerTran

	INSERT INTO dbo.TranTest values(2)
	SELECT @@TRANCOUNT AS 'innerTran Begin', count(*) from dbo.TranTest -- 2, 2

	ROLLBACK TRANSACTION -- here, removed inner Transaction name
	SELECT @@TRANCOUNT AS 'innerTran Rollback', count(*) from dbo.TranTest -- 0, 0

-- Outer Transaction - COMMIT
COMMIT TRANSACTION outerTran
SELECT @@TRANCOUNT AS 'outerTran Commit', count(*) from dbo.TranTest -- 1, 3
GO

SELECT * FROM dbo.TranTest -- 0
GO

– This ROLLBACK statement rollbacks the whole Transaction resulting no rows in dbo.TransTest table.
– But the COMMIT TRANSACTION outerTran statement at Line 20 fails with following error:
Msg 3902, Level 16, State 1, Line 24
The COMMIT TRANSACTION request has no corresponding BEGIN TRANSACTION.

 

Option #2: Using SAVE TRANSACTION instead of BEGIN TRANSACTION

-- Outer Transaction - BEGIN
SELECT @@TRANCOUNT AS 'outerTran Begin', count(*) from dbo.TranTest -- 0, 0
BEGIN TRANSACTION outerTran

INSERT INTO dbo.TranTest values(1)
SELECT @@TRANCOUNT AS 'outerTran Begin', count(*) from dbo.TranTest -- 1, 1

	-- Inner Transaction
	SAVE TRANSACTION innerTran -- here, created a SavePoint

	INSERT INTO dbo.TranTest values(2)
	SELECT @@TRANCOUNT AS 'innerTran Begin', count(*) from dbo.TranTest -- 1, 2

	ROLLBACK TRANSACTION innerTran -- Rolling back a SavePoint
	SELECT @@TRANCOUNT AS 'innerTran Rollback', count(*) from dbo.TranTest -- 1, 1

-- Outer Transaction - COMMIT
COMMIT TRANSACTION outerTran
SELECT @@TRANCOUNT AS 'outerTran Commit', count(*) from dbo.TranTest -- 0, 1
GO

SELECT * FROM dbo.TranTest -- 1
GO

As you can see that we have converted the Inner Transaction to a Save Point, as as per the error we’ve taken care of this with option #2.

In this case a SavePoint was created and you can Rollback a SavePoint inside the outer Transaction. Thus the outer transaction was finally committed with table having value “1” and inner SavePoint was Rollbacked with row having value “2”.

COMMIT vs ROLLBACK


Advertisement