SET ROWCOUNT (Transact-SQL)
Applies to: SQL Server Azure SQL Database Azure SQL Managed Instance Azure Synapse Analytics Analytics Platform System (PDW)
Causes SQL Server to stop processing the query after the specified number of rows are returned.
Transact-SQL syntax conventions
SET ROWCOUNT { number | @number_var }
number | @number_var
Is the number, an integer, of rows to be processed before stopping the specific query.
Important
Using SET ROWCOUNT will not affect DELETE, INSERT, and UPDATE statements in a future release of SQL Server. Avoid using SET ROWCOUNT with DELETE, INSERT, and UPDATE statements in new development work, and plan to modify applications that currently use it. For a similar behavior, use the TOP syntax. For more information, see TOP (Transact-SQL).
To set this option off so that all rows are returned, specify SET ROWCOUNT 0.
Setting the SET ROWCOUNT option causes most Transact-SQL statements to stop processing when they have been affected by the specified number of rows. This includes triggers. The ROWCOUNT option does not affect dynamic cursors, but it does limit the rowset of keyset and insensitive cursors. This option should be used with caution.
SET ROWCOUNT overrides the SELECT statement TOP keyword if the rowcount is the smaller value.
The setting of SET ROWCOUNT is set at execute or run time and not at parse time.
Requires membership in the public role.
SET ROWCOUNT stops processing after the specified number of rows. In the following example, note that over 500 rows meet the criteria of Quantity
less than 300
. However, after applying SET ROWCOUNT, you can see that not all rows were returned.
USE AdventureWorks2022;
GO
SELECT count(*) AS Count
FROM Production.ProductInventory
WHERE Quantity < 300;
GO
Here's the result set.
Count
-----------
537
(1 row(s) affected)
Now, set ROWCOUNT
to 4
and return all rows to demonstrate that only 4 rows are returned.
SET ROWCOUNT 4;
SELECT *
FROM Production.ProductInventory
WHERE Quantity < 300;
GO
-- (4 row(s) affected)
SET ROWCOUNT stops processing after the specified number of rows. In the following example, note that more than 20 rows meet the criteria of AccountType = 'Assets'
. However, after applying SET ROWCOUNT, you can see that not all rows were returned.
-- Uses AdventureWorks
SET ROWCOUNT 5;
SELECT * FROM [dbo].[DimAccount]
WHERE AccountType = 'Assets';
To return all rows, set ROWCOUNT to 0.
-- Uses AdventureWorks
SET ROWCOUNT 0;
SELECT * FROM [dbo].[DimAccount]
WHERE AccountType = 'Assets';