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

Begin transaction and commit transaction Expand / Collapse
Author
Message
Posted Tuesday, August 25, 2009 7:16 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Today @ 4:30 PM
Points: 310, Visits: 651
1. begin tran tran1
go

2. update Person.Contact
set LastName = 'tran1'
where FirstName = 'Gustavo'
and Title = 'Mr.'

3. begin tran tran2
go

4. update Person.Contact
set LastName = 'tran2'
where FirstName = 'Gustavo'
and Title = 'Sr.'

--Now I commit tran2
commit tran tran2

and now I rollback. According to theory at least the transaction tran2 should have been committed. But both the transactions are rolled back. No changes are made. Both the values are also rolled back when I try to commit tran1 transaction instead of tran2 transaction.

-LK
Post #776648
Posted Tuesday, August 25, 2009 7:31 AM


SSC-Addicted

SSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-AddictedSSC-Addicted

Group: General Forum Members
Last Login: Monday, October 31, 2011 1:10 PM
Points: 480, Visits: 1,163
Try using this:


BEGIN TRY
BEGIN TRANSACTION

TSQL Logic here

COMMIT
END TRY
--Catch any errors above
BEGIN CATCH
IF @@TRANCOUNT > 0
ROLLBACK
DECLARE @ErrMsg nvarchar(4000), @ErrSeverity int
SELECT @ErrMsg = ERROR_MESSAGE(), @ErrSeverity = ERROR_SEVERITY()
RAISERROR(@ErrMsg, @ErrSeverity, 1)
END CATCH




--
Post #776664
Posted Tuesday, August 25, 2009 7:37 AM


SSC-Forever

SSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-ForeverSSC-Forever

Group: General Forum Members
Last Login: Today @ 1:53 PM
Points: 42,771, Visits: 35,870
http://msdn.microsoft.com/en-us/library/ms188929.aspx

BEGIN TRANSACTION
Arguments
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.


http://msdn.microsoft.com/en-us/library/ms190295.aspx

COMMIT TRANSACTION: Marks the end of a successful implicit or explicit transaction. If @@TRANCOUNT is 1, COMMIT TRANSACTION makes all data modifications performed since the start of the transaction a permanent part of the database, frees the resources held by the transaction, and decrements @@TRANCOUNT to 0. If @@TRANCOUNT is greater than 1, COMMIT TRANSACTION decrements @@TRANCOUNT only by 1 and the transaction stays active.


Arguments
transaction_name
Is ignored by the SQL Server Database Engine.


http://msdn.microsoft.com/en-us/library/ms181299.aspx
ROLLBACK TRANSACTION
Rolls back an explicit or implicit transaction to the beginning of the transaction, or to a savepoint inside the transaction.


Arguments
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.



So the commit just decrements the transaction count by 1, leaving it at a value of 1. When the rollback fires,the entire transaction, back to the first begin tran is rolled back.

Transaction names are more for descriptive or documentation than anything else.



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 #776670
Posted Thursday, August 27, 2009 2:24 PM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Monday, September 21, 2009 4:48 PM
Points: 4, Visits: 10
I am wondering why you are putting a transaction inside a transaction. Although this is not unheard of and certainly useful at times, if you attempt to rollback the outside transaction (tran1) then everything inside that transaction will get rolled back, including the second transaction. If this is not your intention, split the logic into two separate transactions. If you do indeed want to roll back everything, I would recommend something a little more straight forward such as:

DECLARE @Err INT
SET @Err = 0
BEGIN TRANSACTION

/***Some logic here***/

--Check for any errors
SET @Err = @Err + @@ERROR

/***More logic***/

--Check for any errors
SET @Err = @Err + @@ERROR

IF @Err > 0
ROLLBACK
ELSE
COMMIT

Post #778687
Posted Friday, August 28, 2009 2:40 AM
Old Hand

Old HandOld HandOld HandOld HandOld HandOld HandOld HandOld Hand

Group: General Forum Members
Last Login: Today @ 4:30 PM
Points: 310, Visits: 651
Thanks to one and all.

-LK
Post #778940
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse