In my previous post I mentioned the fact that the ROLLBACK command rolls back the entire transaction all the way to the top level. If that is the case then can we roll back an inner transaction and still maintain and commit the rest of the transaction? Yes as it happens we can, by using the SAVE TRANSACTION command. The SAVE TRANSACTION command acts very much like the BEGIN TRANSACTION command in that it begins a new transaction, adds one to @@TRANCOUNT, and can be committed using the COMMIT command. However in this case it also creates a save point that can be rolled back to by using the ROLLBACK TRANSACTION command. As always it’s easier with an example.
-- Create a table to use during the tests CREATE TABLE tb_TransactionTest (value int) GO
-- Test using 2 transactions with a save point to allow -- us to roll back only the inner of the transaction. BEGIN TRANSACTION -- outer transaction PRINT @@TRANCOUNT INSERT INTO tb_TransactionTest VALUES (1) SAVE TRANSACTION TestTrans-- inner transaction with save point PRINT @@TRANCOUNT INSERT INTO tb_TransactionTest VALUES (2) ROLLBACK TRANSACTION TestTrans --roll back to the save point PRINT @@TRANCOUNT INSERT INTO tb_TransactionTest VALUES (3) IF @@TRANCOUNT > 0 COMMIT -- commit the outer transaction PRINT @@TRANCOUNT SELECT * FROM tb_TransactionTest GO
-- Clean up table to use during the tests DROP TABLE tb_TransactionTest GO
Unlike in the previous tests where the ROLLBACK either rolled back all the way to the beginning of the top level transaction this time it rolled back just to the save point giving a result of 1, 3. Also even though I kept in the code that checked the @@TRANCOUNT before the commit the transaction level is in fact still 1 so the COMMIT statement wouldn’t have errored out either way.
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.
- Transactions: Rolling back a nested transaction.
- Transactions: Rolling back a transaction inside a stored procedure.
- Transactions: What are they?
- Transactions: Who, What and Where
- Transactions: Creating a single restore point across multiple databases.
- Transactions: What commands aren’t allowed.
Filed under: Microsoft SQL Server, SQLServerPedia Syndication, T-SQL, Transactions Tagged: code language, language sql, microsoft sql server, T-SQL, transactions