For the last part of the series on transactions, I’m going to look at a problem that I ran across entirely by chance while doing some performance tuning. A procedure had a transaction in it, and it was named. Something like this:
CREATE PROCEDURE RemoveUser (@UserID INT) AS BEGIN TRY BEGIN TRANSACTION Important DELETE FROM Users WHERE UserID = @UserID COMMIT TRANSACTION Important END TRY BEGIN CATCH ROLLBACK TRANSACTION Important END CATCH GO
The error’s squelched, not handled, but let’s ignore that, it’s not the point of this post. The example as written doesn’t need a transaction, but the real procedure was a tad more complex. The transaction is named, and the name is specified in the COMMIT and ROLLBACK as well.
Before I go into the problem with this code, I’m going to quote from three Books Online entries.
transaction_name
Is the name assigned to the transaction. transaction_name must conform to the rules for identifiers, but identifiers longer than 32 characters are not allowed. Use transaction names only on the outermost pair of nested BEGIN…COMMIT or BEGIN…ROLLBACK statements. transaction_name is always case sensitive, even when the instance of SQL Server is not case sensitive.
transaction_name
Is ignored by the SQL Server Database Engine. transaction_name specifies a transaction name assigned by a previous BEGIN TRANSACTION. transaction_name must conform to the rules for identifiers, but cannot exceed 32 characters. transaction_name can be used as a readability aid by indicating to programmers which nested BEGIN TRANSACTION the COMMIT TRANSACTION is associated with.
transaction_name
Is the name assigned to the transaction on BEGIN TRANSACTION. transaction_name must conform to the rules for identifiers, but only the first 32 characters of the transaction name are used. When nesting transactions, transaction_name must be the name from the outermost BEGIN TRANSACTION statement. transaction_name is always case sensitive, even when the instance of SQL Server is not case sensitive.
I do love how Books Online refers to nested transactions as though they were real things…
Now that we’re perused the documentation, let’s go back to the code. As-is it runs fine, however let’s try that procedure called from within another transaction.
BEGIN TRANSACTION EXEC dbo.RemovePosts @UserID = 152; EXEC dbo.RemoveThreads @UserID = 152; EXEC dbo.RemoveUser @UserID = 152; COMMIT
Some sort of ‘remove all my details’ functionality, except that I’ve ‘forgotten’ to check one foreign key relationship and so the delete inside the inner transaction is going to throw an error. Execution is going to be transferred to the CATCH block and the ROLLBACK TRANSACTION is going to run.
Msg 6401, Level 16, State 1, Procedure RemoveUser, Line 10
Cannot roll back Important. No transaction or savepoint of that name was found.
Whoops.
The documentation for ROLLBACK TRANSACTION states ‘When nesting transactions, transaction_name must be the name from the outermost BEGIN TRANSACTION statement.’. In this case a second transaction has been wrapped around the first, the outer transaction had no name and hence an error occurred.
No big deal though, right? It’s just a different error being thrown, right? It’s not as if we were handling and logging the error properly in the first place.
Not quite.
The error was thrown by the ROLLBACK statement. As such, the transaction is still open, the locks are held and the transaction log space can’t be reused. Unless the application that called this was checking for open transactions, that transaction could potentially be left open for quite some amount of time, causing blocking and/or the transaction log to grow.
It’s not just that someone in the future might call the code from another stored proc within a transaction, it’s also that it might be that the code is called from an application which started a transaction. Or called from SSIS which started a transaction. It’s very hard to ensure that code is never called from within an existing transaction
In conclusion, if you want to put a name on a BEGIN TRANSACTION, for documentation purposes or to help with debugging, go ahead. If you want to put a name on a COMMIT, that’s fine too, although it has no effect at all on how the code runs. Don’t put names on the ROLLBACK ever, as it leaves the code with a potential hidden bug.
This concludes the short series on transactions. The full list is:
- A Mess of Nested Transactions
- Savepoints and conditional transactions
- Why would you want to name a transaction?
- When naming transactions causes an error (this post)
It’s a bit annoying that naming/referring to a named transaction is execution-ally irrelevant except in when using ROLLBACK. This is good to know.
Also, I think “blog” in “Execution is going to be transferred to the CATCH blog and the ROLLBACK TRANSACTION is going to run” should be “block”.
Thank you for this short series, and in particular, this last post.
Whoops. Fixed
Hello Gail. We have begun to implement a pattern given by Sebastian Meine (of tSQLt fame) given here:
http://sqlity.net/en/585/how-to-rollback-in-procedures/
As you can see, transactions are named and the ROLLBACK is also named. Do you have any thoughts on this?
Thanks, Ash
The only place there’s a name on a rollback in that is when it’s a savepoint name, and there’s nowhere that there’s a name on a BEGIN TRANSACTION in that code.
I covered savepoints in the second part of this series.