Begin transaction and commit transaction

  • 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

  • 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

    --
    :hehe:

  • 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, 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
  • 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

  • Thanks to one and all.

    -LK

Viewing 5 posts - 1 through 4 (of 4 total)

You must be logged in to reply to this topic. Login to reply