Ideas about Error 266 "Transaction count after EXECUTE indicates that a COMMIT or ROLLBACK TRANSACTION statement is missing. Previous count = 1, current count = 0."

  • I had to deal with this whilst writing a unit test framework for my TSQL

    Create simple procedure that performs rollback:

    create proc dbo.spTest

    as

    begin

    begin tran

    rollback tran

    end

    Execute the procedure:

    begin tran

    exec dbo.spTest

    if (xact_state() <> 0) rollback tran

    Enjoy the error:

    Msg 266, Level 16, State 2, Procedure spTest, Line 0

    Transaction count after EXECUTE indicates that a COMMIT or ROLLBACK TRANSACTION statement is missing. Previous count = 1, current count = 0.

    This feature can be very useful as a single nested rollback can abort not only the transaction but any logic (that would be rolled back anyway)

    But it has some serious consequences - if you have a procedure that performs a rollback and returns a value ...

    create proc dbo.spTest

    as

    begin

    begin tran

    rollback tran

    return 666

    end

    and execute this:

    declare @return int

    begin try

    begin tran

    exec @return = dbo.spTest

    if (xact_state() <> 0) rollback tran

    end try

    begin catch

    if (xact_state() <> 0) rollback tran

    select @return

    end catch

    It will *always* return 0

    In my stored procedures I use:

    return 0 -- System Error

    return 1 -- Success

    return 2 -- Logic Error

    there is a huge difference between a system and logic error!

    logic errors are caused by the user's actions and they should sort themselves out (and not call me)

    system errors are NOT the user's fault (they SHOULD call me)

    The problem with the 266 error is that it CONVERTS logic errors into system errors ...

    But what about OUTPUT parameters?

    create proc dbo.spTest @Value int output

    as

    begin

    begin tran

    rollback tran

    set @Value = 666

    end

    declare @Value int

    begin try

    begin tran

    exec dbo.spTest @Value output

    if (xact_state() <> 0) rollback tran

    end try

    begin catch

    if (xact_state() <> 0) rollback tran

    select @Value

    end catch

    Aha! This works now ...

    Also you can filter out the 266 errors:

    declare @Return int

    begin try

    exec spWhatever @Return output

    end try

    begin catch

    if (error_number() <> 266) --throw the error

    end catch

    if (@Return = 1) begin

    print 'success'

    end else if (@Return = 2) begin

    print 'logic error'

    end else begin

    print 'system error'

    end--if

    Well those are my thoughts about the 266 error

  • Another option is to not nest transactions. Have a single point of control.

    i.e. only the level that starts the transaction commits or rolls back.


    Cursors never.
    DTS - only when needed and never to control.

  • something like

    if (xact_state() = 0) begin

    begin tran

    set @towner = 1

    end--if

    if (xact_state() <> 0 and @towner = 1) begin

    rollback tran

    end--if

  • Another solution to my original problem (unit testing t-sql - continuing after expected error)

    I am surprised this works really - a more reliable check for sql server to make would be "bindtoken after == bindtoken before"

    Because this can lead to total chaos:

    go

    create proc PreserveTrancount as

    begin

    declare @trancount int

    set @trancount = @@trancount

    --

    if (xact_state() <> 0) rollback tran

    --

    while (@@trancount < @trancount) begin tran

    end

    go

    select @@trancount

    exec PreserveTrancount

    select @@trancount

    go

    begin tran

    select @@trancount

    exec PreserveTrancount

    select @@trancount

    rollback tran

    go

  • We recently had the same issue in SQL2005 that did not go away after SP4... Once we upgraded to Cumulative update 3 for SP4 the error went away... So there is some fix in one of the cumulative updates after SP4 that fixes this error... For us the same proc that was throwing thousands of these errors is no longer throwing and we did not have to change the logic... The error was being thrown in queries updating/inserting into temp tables and we were about to open a case with Microsoft.

    Otherwise we found another workaround that creating an outer transaction for most of the body of the proc where temp-tables were being created so that the statements modifying temp tables were in an outer transation also caused SQL not to throw the errors at the expense of having a large outer transaction.

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

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