SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Committed Transaction, not really committed?


Committed Transaction, not really committed?

Author
Message
thisted
thisted
SSC-Enthusiastic
SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)

Group: General Forum Members
Points: 169 Visits: 343
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?
GilaMonster
GilaMonster
SSC Guru
SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)

Group: General Forum Members
Points: 87253 Visits: 45272
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

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


thisted
thisted
SSC-Enthusiastic
SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)

Group: General Forum Members
Points: 169 Visits: 343
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?
GilaMonster
GilaMonster
SSC Guru
SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)

Group: General Forum Members
Points: 87253 Visits: 45272
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

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


thisted
thisted
SSC-Enthusiastic
SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)

Group: General Forum Members
Points: 169 Visits: 343
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.
thisted
thisted
SSC-Enthusiastic
SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)SSC-Enthusiastic (169 reputation)

Group: General Forum Members
Points: 169 Visits: 343
I get it, it's because this type of error isn't caught by try/catch statements.
GilaMonster
GilaMonster
SSC Guru
SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)SSC Guru (87K reputation)

Group: General Forum Members
Points: 87253 Visits: 45272
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

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


Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search