February 22, 2013 at 7:34 am
I recently executed a script in SSMS. The script contained the logic below
Begin Try
Begin Tran
DO WORK
Commit Tran
End Try
Begin CATCH
SEND ERROR
END CATCH
The Script completed sub-second. I got the green little checkmark that said "Query executed Successfully" at the bottom of my query window.
10 minutes later I got a call that performance on the database was "SLOW"
I ran SP_WHOISACTIVE and found that my session was still active, even though SSMS made it look like everything completed successfully. I started seeing this (3 times for me personally, a few times for developers as well) since I upgraded to SSMS 2012. Has anyone else seen this. Is it a client issue? Is it a server issue? Is this the result of normal locking from other processes?
February 22, 2013 at 7:45 am
Possibility 1: Nested Transactions.
Something like this:
Begin transaction
-- do some stuff
Begin transaction
-- do some more stuff
Commit transaction
That transaction is still open. The commit did nothing other than decrement the open transaction count, because there was more than one Begin Tran
Possibility 2: Do Work threw an error. You don't have a rollback in your catch block, so the commit never occurred and hence the transaction was left open.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
February 22, 2013 at 7:50 am
I missed the Rollback in my psudocode. It does exist in the actual code within the Begin/End Catch statement.
I think you're right about the nested transactions though...
I originally ran the script against master :ermm:
Got an error that the tables it was attempting to update didn't exist
Then switched the database to the correct database, and ran it again.
Does that make sense for what I'm seeing?
February 22, 2013 at 8:08 am
Yup. You began the transaction twice and committed it once, thereby leaving the transaction open and all locks still held.
If you'd checked @@TranCount it would have shown 1, and DBCC OpenTran would have shown your change (assuming that it was the oldest open transaction).
p.s. Ad-hoc, unchecked changes to a production database? That's just asking for this kind of problem and worse.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
February 22, 2013 at 8:24 am
If the Rollback transaction is within the Catch Statement, why doesn't the transaction end?
Here's an example script I used for testing this out just now. The table I'm trying to update exists in a different database, so it fails
USE [MASTER]
BEGIN TRY
BEGIN TRANSACTION
Update DBAEmails Set Email = 'thisted@gmail.com' where ID = 2
COMMIT TRANSACTION
END TRY
BEGIN Catch
print 'Failure to Update Email'
RollBack Transaction
End Catch
I get the error message
Msg 208, Level 16, State 1, Line 4
Invalid object name 'DBAEmails'.
But the Rollback doesn't happen?
What you mention in your PS is true. We need to work out a better solution.
February 22, 2013 at 8:38 am
I get it, it's because this type of error isn't caught by try/catch statements.
February 22, 2013 at 9:16 am
Invalid object is not a run-time error, it's thrown in the parse/bind/optimise phase. Try catch catches run-time errors.
Gail Shaw
Microsoft Certified Master: SQL Server, MVP, M.Sc (Comp Sci)
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply