Question About Transactions

  • When working with a stored procedure that executes several INSERT, UPDATE , DELETE queries, do I structure the sp so that all of them are contained within a single transaction or do I have to struction the sp so that each query statement is contained within its own transaction? The queries are related to an import that I'm doing where existing data is wiped from the target tables and the replaced with data from the import.

    Example1:

    BEGIN TRANSACTION 1

    DELETE...

    UPDATE...

    INSERT....

    COMIIT TRANSACTION 1

    Example 2:

    BEGIN TRANSACTION 1

    DELETE...

    BEGIN TRANSACTION 2

    UPDATE...

    BEGIN TRANSACTION 3

    INSERT

    COMIT TRANSACTION 3

    COMIT TRANSACTION 2

    COMIT TRANSACTION 1

  • david.holley (8/30/2012)


    Example 2:

    BEGIN TRANSACTION 1

    DELETE...

    BEGIN TRANSACTION 2

    UPDATE...

    BEGIN TRANSACTION 3

    INSERT

    COMIT TRANSACTION 3

    COMIT TRANSACTION 2

    COMIT TRANSACTION 1

    Nested transactions don't actually exists, just syntatical sugar that makes you think they do. That's the same as Example 1.

    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
  • To add to what Gail is saying not only do they not really exist the appearance of nested transactions can seem to work when everything goes smoothly but will cause you nothing but grief when stuff doesn't go correctly. If a rollback is issued against as "inner" transaction, the "outer" transaction no longer exists and all your logic is going to break all over the place.

    Nested transactions in sql server are like leprechauns and unicorns...they might be cool if they actually existed but they don't so stop looking for them. 😀

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • So basically a single transaction and then check @@Error after each statement as in...

    BEGIN TRAN

    UPDATE

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    DELETE

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    DESTROY WORLD

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    INSERT

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    COMMIT TRAN

    RETURN 0

    ERR_HANDLER:

    KILL KENNY

    ROLLBACK

    RETURN 1

  • david.holley (8/30/2012)


    So basically a single transaction and then check @@Error after each statement as in...

    BEGIN TRAN

    UPDATE

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    DELETE

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    DESTROY WORLD

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    INSERT

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    COMMIT TRAN

    RETURN 0

    ERR_HANDLER:

    KILL KENNY

    ROLLBACK

    RETURN 1

    That is not the best way to handle this. You should use try/catch instead the older style of constantly checking @@error.

    BEGIN TRAN

    begin try

    UPDATE

    DELETE

    DESTROY WORLD

    INSERT

    COMMIT TRAN

    RETURN 0

    end try

    begin catch

    KILL KENNY

    ROLLBACK

    RETURN 1

    end catch

    _______________________________________________________________

    Need help? Help us help you.

    Read the article at http://www.sqlservercentral.com/articles/Best+Practices/61537/ for best practices on asking questions.

    Need to split a string? Try Jeff Modens splitter http://www.sqlservercentral.com/articles/Tally+Table/72993/.

    Cross Tabs and Pivots, Part 1 – Converting Rows to Columns - http://www.sqlservercentral.com/articles/T-SQL/63681/
    Cross Tabs and Pivots, Part 2 - Dynamic Cross Tabs - http://www.sqlservercentral.com/articles/Crosstab/65048/
    Understanding and Using APPLY (Part 1) - http://www.sqlservercentral.com/articles/APPLY/69953/
    Understanding and Using APPLY (Part 2) - http://www.sqlservercentral.com/articles/APPLY/69954/

  • Sean Lange (8/30/2012)


    david.holley (8/30/2012)


    So basically a single transaction and then check @@Error after each statement as in...

    BEGIN TRAN

    UPDATE

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    DELETE

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    DESTROY WORLD

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    INSERT

    IF @@ERROR <> 0 GOTO ERR_HANDLER

    COMMIT TRAN

    RETURN 0

    ERR_HANDLER:

    KILL KENNY

    ROLLBACK

    RETURN 1

    That is not the best way to handle this. You should use try/catch instead the older style of constantly checking @@error.

    BEGIN TRAN

    begin try

    UPDATE

    DELETE

    DESTROY WORLD

    INSERT

    COMMIT TRAN

    RETURN 0

    end try

    begin catch

    KILL KENNY

    ROLLBACK

    RETURN 1

    end catch

    Thanks. I also found this article which helped to explain why the sp's that I've created never threw an error back to the ASP.NET frontend when I tested raising an error.

    http://www.4guysfromrolla.com/webtech/041906-1.shtml

  • Based on your original statement - I would recommend not even using an explicit transaction. Since this is an import process and you are wiping the data (truncating) and then reloading from the source - using a transaction around the inserts/updates is not very useful.

    Now, if you have to return the system to the state it was in before your process started (on an error, of course) - then you would put the truncate statements inside the transaction also, that way when the statement is rolled back the truncate also gets rolled back.

    Be aware that this type of process can (and probably will) expand your transaction log to a much larger size. It will require the log to be that size to handle all of the transactions - which cannot be marked as reusable space in the transaction log until all of them complete or are rolled back.

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

Viewing 7 posts - 1 through 6 (of 6 total)

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