Blog Post

Using @@ROWCOUNT can be a bit tricky

,

@@ROWCOUNT is a very useful system variable that returns the number of rows read/affected by the previous statement. It’s frequently used in loops and in error handling.

TL;DR Store @@ROWCOUNT into a variable immediately after the command you are interested in to persist the value for later use.

So why is it tricky to use? Remember that it returns the number of rows affected by the previous statement. Every statement. Look at this piece of code:

BEGIN TRY
SELECT TOP 10 * FROM sys.objects
END TRY
BEGIN CATCH
SELECT TOP 5 * FROM sys.objects
END CATCH
SELECT @@ROWCOUNT

You might think that the result of @@ROWCOUNT would be 10 since that’s the previous command that was run. You might also think it would be 5 since that’s the last command in the code, right? However you would be wrong on both counts. The TRY/CATCH block is actually the last command, so the result of @@ROWCOUNT is 0. If you plan on using @@ROWCOUNT you need to do this:

DECLARE @RowCount int
BEGIN TRY
SELECT TOP 10 * FROM sys.objects
SET @RowCount = @@ROWCOUNT
SELECT @@ROWCOUNT
END TRY
BEGIN CATCH
SELECT TOP 5 * FROM sys.objects
SET @RowCount = @@ROWCOUNT
END CATCH
SELECT @RowCount

The result of this code shows that even the act of storing @@ROWCOUNT into a variable changes it. If you are a fan of physics you can think of this as the observer effect of SQL Server. Even the act of looking at @@ROWCOUNT changes it. On the other hand we do now have that value stored into a user variable so we can actually use it without losing it.

This is the trick to using this system variable. Store it into a user variable as the very next command.

Filed under: Microsoft SQL Server, SQLServerPedia Syndication, T-SQL Tagged: code language, language sql, microsoft sql server, sql statements, T-SQL

Rate

You rated this post out of 5. Change rating

Share

Share

Rate

You rated this post out of 5. Change rating