Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Committed Transaction, not really committed? Expand / Collapse
Author
Message
Posted Friday, February 22, 2013 7:34 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, September 16, 2014 7:46 AM
Points: 47, Visits: 264
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?

Post #1423058
Posted Friday, February 22, 2013 7:45 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 1:14 PM
Points: 39,977, Visits: 36,340
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 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1423067
Posted Friday, February 22, 2013 7:50 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, September 16, 2014 7:46 AM
Points: 47, Visits: 264
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
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?
Post #1423070
Posted Friday, February 22, 2013 8:08 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 1:14 PM
Points: 39,977, Visits: 36,340
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 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1423081
Posted Friday, February 22, 2013 8:24 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, September 16, 2014 7:46 AM
Points: 47, Visits: 264
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.
Post #1423094
Posted Friday, February 22, 2013 8:38 AM
SSC Rookie

SSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC RookieSSC Rookie

Group: General Forum Members
Last Login: Tuesday, September 16, 2014 7:46 AM
Points: 47, Visits: 264
I get it, it's because this type of error isn't caught by try/catch statements.
Post #1423104
Posted Friday, February 22, 2013 9:16 AM


SSC-Dedicated

SSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-DedicatedSSC-Dedicated

Group: General Forum Members
Last Login: Today @ 1:14 PM
Points: 39,977, Visits: 36,340
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 2008, MVP
SQL In The Wild: Discussions on DB performance with occasional diversions into recoverability

We walk in the dark places no others will enter
We stand on the bridge and no one may pass

Post #1423122
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse