Transactions: Rolling back a nested transaction

5

December 17, 2013 by Kenneth Fisher

Transactions are great and wonderful things. They make sure that our work stays atomic, consistent, isolated and durable (yes ACID). And if we use an explicit transaction (created by BEGIN TRANSACTION) and we make a mistake we can always roll the transaction back. Unfortunately rolling back a transaction and committing a transaction aren’t quite the same.

Transactions can be nested. We can tell how many layers of transactions deep we are by looking at @@TRANCOUNT. When we create an explicit transaction it increases @@TRANCOUNT by 1. When we commit a transaction it decreases @@TRANCOUNT by 1. However when we roll back a transaction it decreases @@TRANCOUNT to 0. This means no matter how deep in nested transactions we are one ROLLBACK will undo the whole thing all the way back to the top. Easy to say but in order to help it sink in how about an example or two?

-- Create a table to use during the tests
CREATE TABLE tb_TransactionTest (value int)
GO
-- Test using 2 transactions and a rollback on the 
-- outer transaction
BEGIN TRANSACTION -- outer transaction
	PRINT @@TRANCOUNT
	INSERT INTO tb_TransactionTest VALUES (1)
	BEGIN TRANSACTION -- inner transaction
		PRINT @@TRANCOUNT
		INSERT INTO tb_TransactionTest VALUES (2)
	COMMIT -- commit the inner transaction
	PRINT @@TRANCOUNT
	INSERT INTO tb_TransactionTest VALUES (3)
ROLLBACK -- roll back the outer transaction
PRINT @@TRANCOUNT
SELECT * FROM tb_TransactionTest
GO

This demonstrates committing an “inner” transaction then rolling back the “outer”. Even though the “inner” transaction is committed when the “outer” one is rolled back the whole thing gets rolled back and no rows are in the table.

Next let’s go the other way around.

-- Test using 2 transactions and a rollback on the 
-- inner transaction
BEGIN TRANSACTION -- outer transaction
	PRINT @@TRANCOUNT
	INSERT INTO tb_TransactionTest VALUES (1)
	BEGIN TRANSACTION -- inner transaction
		PRINT @@TRANCOUNT
		INSERT INTO tb_TransactionTest VALUES (2)
	ROLLBACK -- roll back the inner transaction
	PRINT @@TRANCOUNT
	INSERT INTO tb_TransactionTest VALUES (3)
-- We get an error here because there is no transaction
-- to commit.
COMMIT -- commit the outer transaction
PRINT @@TRANCOUNT
SELECT * FROM tb_TransactionTest
GO

After rolling back the inner transaction we actually get an error when trying to commit the outer transaction. Logically it might seem like you could roll back the inner transaction and commit the remainder of the transaction however it doesn’t work that way. Once the ROLLBACK command is executed the whole transaction is rolled back all the way to the beginning. The last insert statement (value 3) is in an implicit transaction and will commit even though the COMMIT statement returns an error. So we end up with one row with a 3 in it.

One way to avoid the error is to take advantage of the @@TRANCOUNT system variable.

-- Test using @@TRANCOUNT to avoid an error when we
-- used a ROLLBACK. 
-- Clean up from last time
TRUNCATE TABLE tb_TransactionTest
BEGIN TRANSACTION -- outer transaction
	PRINT @@TRANCOUNT
	INSERT INTO tb_TransactionTest VALUES (1)
	BEGIN TRANSACTION -- inner transaction
		PRINT @@TRANCOUNT
		INSERT INTO tb_TransactionTest VALUES (2)
	ROLLBACK --roll back the inner transaction
	PRINT @@TRANCOUNT
	INSERT INTO tb_TransactionTest VALUES (3)
	IF @@TRANCOUNT > 0
		-- No error this time
		COMMIT -- commit the outer transaction
PRINT @@TRANCOUNT
SELECT * FROM tb_TransactionTest
GO

Transactions are a big subject which I’m going to explore over several posts. I am by no means going to cover the subject exhaustively but if you have any subjects you would like me to cover or think I’ve missed something feel free to comment or email me.

5 thoughts on “Transactions: Rolling back a nested transaction

  1. Taraka says:

    Hi Kenneth, the information was so useful. But I had a doubt while practicing the Nested Transactions.

    I tried to execute the following code, though outer transaction is rollbacked, the value @a after rollback is not reverted.

    Begin Transaction

    declare @a char;
    select @a=’a’;

    Begin Transaction
    if (@a = ‘a’)
    begin
    select @a = ‘b’
    Commit Transaction
    end
    else
    Rollback Transaction
    –select @a;

    if @@TRANCOUNT > 0
    begin
    Rollback Transaction
    select @a;
    end

    • Variables (even table variables) are not covered under transactions. If you need to be able to revert to the old value you will either need to store it in a “backup” variable (say @a_old) or store it in a temp table (#variables) or something along those lines.

  2. venkat says:

    hi thanks ,its good article and usefull

  3. reader says:

    I’m going through whole series of your transaction posts, great work!

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out /  Change )

Facebook photo

You are commenting using your Facebook account. Log Out /  Change )

Connecting to %s

This site uses Akismet to reduce spam. Learn how your comment data is processed.

Enter your email address to follow this blog and receive notifications of new posts by email.

Join 3,755 other subscribers

Follow me on Twitter

ToadWorld Pro of the Month November 2013
%d bloggers like this: