@@Rowcount is not reliable?

  • I have used @@RowCount next to one update statement in a stored procedure.

    It was working fine in one of our production database, but recently we observed sometimes it will not work properly.

    is @@RowCount is not reliable?

    please advice.

  • It never failed on my memory.

    Unexpected results it returned only in cases when it was used incorrectly.

    Can you show your code?

    But don't modify anything, every detail may be very important.

    _____________
    Code for TallyGenerator

  • Hi Sergiy,

    my stored procedure is as follows..

    basically this procedure should return @NewStatus only once if it is called multiple times for a given @ID

    UPDATE Table SET Status=@NewStatus WHERE ID=@ID AND Status=@CurrentStatus

    IF @@ROWCOUNT=1

    RETURN @NewStatus

    ELSE

    RETURN @CurrentStatus

  • Try to run this:

    SELECT ID, Status, COUNT(*)

    FROM Table

    GROUP BY ID, Status

    HAVING COUNT(*) > 1

    _____________
    Code for TallyGenerator

  • You have to be careful when using @@ROWCOUNT. Your example should work as you expect, but the example below will not...

    UPDATE .....

    SELECT @MyErr = @@ERROR

    IF @@ROWCOUNT > 1 ...

    In this situation @@ROWCOUNT will always be 1 because of the SELECT running after the update that saves the error code.

    If you need to save both the @@ERROR and @@ROWCOUNT values, use something similar to the code below. You can then refer to @MyErr and @MyCount whenever you want and always get the values from the UPDATE statement.

    UPDATE...

    SELECT @MyErr = @@ERROR, @MyCount = @@ROWCOUNT

    Original author: https://github.com/SQL-FineBuild/Common/wiki/ 1-click install and best practice configuration of SQL Server 2019, 2017 2016, 2014, 2012, 2008 R2, 2008 and 2005.

    When I give food to the poor they call me a saint. When I ask why they are poor they call me a communist - Archbishop Hélder Câmara

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

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