Blocking and Transactions OK?

Collapse
This topic is closed.
X
X
 
  • Time
  • Show
Clear All
new posts
  • laurenq uantrell

    Blocking and Transactions OK?

    I'm wondering if I'm doing this right. Wondering about the transactions
    and error handling. (Do I even need to put BEGIN TRANSACTION AND
    COMMIT TRANSACTION in there?)

    I think that this sproc is causing occasional blocking:

    Alter Procedure sprocINSERTSTUF F
    @Col1Data int = Null,
    @Col2Data nvarchar(255) = Null,
    @Col3Data ntext = Null,
    @UniqueID int OUTPUT

    AS

    set nocount on
    set xact_abort on

    DECLARE @err int
    DECLARE @ServerDate DateTime
    SELECT @ServerDate = GETUTCDATE()

    BEGIN TRANSACTION


    INSERT INTO
    tblStuff (Col1, Col2, Col3, DateCreated, etc.)
    VALUES
    (@Col1Data, @Col2Data, @Col3Data, @ServerDate, etc.)

    SELECT @err = @@error IF @err <> 0 BEGIN ROLLBACK TRANSACTION RETURN
    @err END

    SELECT @UniqueID = SCOPE_IDENTITY( )

    COMMIT TRANSACTION

    BEGIN TRANSACTION

    INSERT INTO
    tblMoreStuff (UniqueID, DateCreated, Col1, Col2, Col3)
    Values
    (@UniqueID, @ServerDate, @Col1Data, @Col2Data, 'Text Label: ' +
    isnull(Cast(@Co l3Data AS nvarchar(4000)) ,'<none>')

    SELECT @err = @@error IF @err <> 0 BEGIN ROLLBACK TRANSACTION RETURN
    @err END

    COMMIT TRANSACTION
    SELECT @err = @@error IF @err <> 0 RETURN @err

  • Erland Sommarskog

    #2
    Re: Blocking and Transactions OK?

    laurenq uantrell (laurenquantrel l@hotmail.com) writes:[color=blue]
    > I'm wondering if I'm doing this right. Wondering about the transactions
    > and error handling. (Do I even need to put BEGIN TRANSACTION AND
    > COMMIT TRANSACTION in there?)[/color]

    Depends on your business requirements. If it's OK that a row gets
    inserter into tblStuff, but not any row in tblMoreStuff, you can take
    it out entirely. If you want both rows or none of the rows inserted,
    you should take out the COMMIT and the BEGIN in the middle, to make
    it one single transaction.
    [color=blue]
    > I think that this sproc is causing occasional blocking:[/color]

    Since it's only two plain insert statements, that's a bit surprising.
    But if there is a long-running trigger on one of the tables you could
    get blocking.
    [color=blue]
    > @Col3Data ntext = Null,
    >...
    > 'Text Label: ' +
    > isnull(Cast(@Co l3Data AS nvarchar(4000)) ,'<none>')
    >...[/color]

    What's the point with accepting an ntext parameter, if you truncate it
    anyway?


    --
    Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

    Books Online for SQL Server SP3 at
    Get the flexibility you need to use integrated solutions, apps, and innovations in technology with your data, wherever it lives—in the cloud, on-premises, or at the edge.


    Comment

    • laurenq uantrell

      #3
      Re: Blocking and Transactions OK?

      Erland,
      Thanks for your reply.
      [color=blue]
      > @Col3Data ntext = Null,
      >...
      > 'Text Label: ' +
      > isnull(Cast(@Co l3Data AS nvarchar(4000)) ,'<none>')
      >...[/color]
      [color=blue]
      >What's the point with accepting an ntext parameter, if you truncate it anyway?[/color]

      The second table is used to hold a history of changes to the first
      table tblStuff and in this particular case it's not necessary (or
      desirable) to have the unlimited text in any ntext column stored, so
      it's truncated.

      Comment

      • laurenq uantrell

        #4
        Re: Blocking and Transactions OK?

        I forgot to mention in my front end application (MS Access 2K) I use
        the following:

        On Error GoTo myErr:
        ' Execute the sproc that runs the Insert above
        myErr:
        CurrentProject. Connection.Exec ute "IF @@trancount > 0 ROLLBACK
        TRANSACTION", , adExecuteNoReco rds

        I am wondering if this should be sufficient to not leave an open
        transaction in the event of an error.

        Comment

        • Erland Sommarskog

          #5
          Re: Blocking and Transactions OK?

          laurenq uantrell (laurenquantrel l@hotmail.com) writes:[color=blue]
          > I forgot to mention in my front end application (MS Access 2K) I use
          > the following:
          >
          > On Error GoTo myErr:
          > ' Execute the sproc that runs the Insert above
          > myErr:
          > CurrentProject. Connection.Exec ute "IF @@trancount > 0 ROLLBACK
          > TRANSACTION", , adExecuteNoReco rds
          >
          > I am wondering if this should be sufficient to not leave an open
          > transaction in the event of an error.[/color]

          In theory maybe. But good software practice is that every module
          cleans up after itself, and does not rely on somebody else to do it.
          Least of all one should trust an application that uses ADO.

          Look at it this way: you have this handling in many stored procedures.
          Maybe you happen to forget to insert it in some place. And you have
          this handling in many places in your client code. Maybe you acceidently
          leave it in some place. So keep a double safeguard.

          --
          Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

          Books Online for SQL Server SP3 at
          Get the flexibility you need to use integrated solutions, apps, and innovations in technology with your data, wherever it lives—in the cloud, on-premises, or at the edge.


          Comment

          • laurenq uantrell

            #6
            Re: Blocking and Transactions OK?

            >Look at it this way: you have this handling in many stored procedures.[color=blue]
            >Maybe you happen to forget to insert it in some place. And you have
            >this handling in many places in your client code. Maybe you acceidently
            >leave it in some place. So keep a double safeguard.[/color]

            I'm not sure what you'rer suggesting...

            I thought that this would clear up any error in the sproc:

            SELECT @err = @@error IF @err <> 0 BEGIN ROLLBACK TRANSACTION RETURN
            @err END


            COMMIT TRANSACTION
            SELECT @err = @@error IF @err <> 0 RETURN @err


            Are you suggesting I put:

            IF @@trancount > 0 ROLLBACK TRANSACTION

            inthe sproc as well and not check for that in the front-end
            application?

            Comment

            • laurenq uantrell

              #7
              Re: Blocking and Transactions OK?

              >Look at it this way: you have this handling in many stored procedures.[color=blue]
              >Maybe you happen to forget to insert it in some place. And you have
              >this handling in many places in your client code. Maybe you acceidently
              >leave it in some place. So keep a double safeguard.[/color]

              I'm not sure what you'rer suggesting...

              I thought that this would clear up any error in the sproc:

              SELECT @err = @@error IF @err <> 0 BEGIN ROLLBACK TRANSACTION RETURN
              @err END


              COMMIT TRANSACTION
              SELECT @err = @@error IF @err <> 0 RETURN @err


              Are you suggesting I put:

              IF @@trancount > 0 ROLLBACK TRANSACTION

              inthe sproc as well and not check for that in the front-end
              application?

              Comment

              • Erland Sommarskog

                #8
                Re: Blocking and Transactions OK?

                laurenq uantrell (laurenquantrel l@hotmail.com) writes:[color=blue][color=green]
                >>Look at it this way: you have this handling in many stored procedures.
                >>Maybe you happen to forget to insert it in some place. And you have
                >>this handling in many places in your client code. Maybe you acceidently
                >>leave it in some place. So keep a double safeguard.[/color]
                >
                > I'm not sure what you'rer suggesting...
                >
                > I thought that this would clear up any error in the sproc:
                >
                > SELECT @err = @@error IF @err <> 0 BEGIN ROLLBACK TRANSACTION RETURN
                > @err END
                >
                >
                > COMMIT TRANSACTION
                > SELECT @err = @@error IF @err <> 0 RETURN @err
                >
                >
                > Are you suggesting I put:
                >
                > IF @@trancount > 0 ROLLBACK TRANSACTION
                >
                > inthe sproc as well and not check for that in the front-end
                > application?[/color]

                So I'm suggesting that you should keep things as they are. (But make
                sure that your transaction scope is the right one. The procedure
                you posted seemed funny to me with a COMMIT in the middle.)


                --
                Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

                Books Online for SQL Server SP3 at
                Get the flexibility you need to use integrated solutions, apps, and innovations in technology with your data, wherever it lives—in the cloud, on-premises, or at the edge.


                Comment

                • laurenq uantrell

                  #9
                  Re: Blocking and Transactions OK?

                  Erland. Thanks for the help and the good avice. The COMMIT in the
                  middle in this situation is because the first insert puts a new row of
                  data into a table, the second insert records the row/column info into a
                  row in a history table. In this situation, I want to be sure that the
                  new record is recorded in the primary data table even if the history is
                  not. If there is a failure on the second insert, I don't want to
                  rollback the first insert, even though the records might not end up in
                  sync (original and history) this would be corrected hopefully the next
                  time the record is updated.
                  I have considered and rejected using triggers for this purpose even
                  though that has been suggested.
                  Thanks again for your help in m understanding of how these things work!
                  lq

                  Comment

                  • Erland Sommarskog

                    #10
                    Re: Blocking and Transactions OK?

                    laurenq uantrell (laurenquantrel l@hotmail.com) writes:[color=blue]
                    > Erland. Thanks for the help and the good avice. The COMMIT in the
                    > middle in this situation is because the first insert puts a new row of
                    > data into a table, the second insert records the row/column info into a
                    > row in a history table. In this situation, I want to be sure that the
                    > new record is recorded in the primary data table even if the history is
                    > not. If there is a failure on the second insert, I don't want to
                    > rollback the first insert, even though the records might not end up in
                    > sync (original and history) this would be corrected hopefully the next
                    > time the record is updated.[/color]

                    Good. I just wanted to make sure that it's on purpose.

                    (I remember a system I worked with looooong ago. There was a stored
                    proecdure that filled up a table, and it was one long transaction.
                    Unfortunately, it tended to fill up the transaction log. (This was
                    Sybase 4.x, no autogrow.) My colleagues found the fix - they inserted
                    some COMMIT/BEGIN. Oh well.)
                    [color=blue]
                    > I have considered and rejected using triggers for this purpose even
                    > though that has been suggested.[/color]

                    Well, that would buy you a transaction for the current and history table.



                    --
                    Erland Sommarskog, SQL Server MVP, esquel@sommarsk og.se

                    Books Online for SQL Server SP3 at
                    Get the flexibility you need to use integrated solutions, apps, and innovations in technology with your data, wherever it lives—in the cloud, on-premises, or at the edge.


                    Comment

                    Working...