Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayThis browser is no longer supported.
Upgrade to Microsoft Edge to take advantage of the latest features, security updates, and technical support.
Applies to:
SQL Server
This article describes how to configure the cursor threshold
server configuration option in SQL Server by using SQL Server Management Studio or Transact-SQL. The cursor threshold
option specifies the number of rows in the cursor set at which cursor keysets are generated asynchronously. When cursors generate a keyset for a result set, the query optimizer estimates the number of rows that are returned for that result set. If the query optimizer estimates that the number of returned rows is greater than this threshold, the cursor is generated asynchronously, allowing the user to fetch rows from the cursor while the cursor continues to be populated. Otherwise, the cursor is generated synchronously, and the query waits until all rows are returned.
SQL Server doesn't support generating keyset-driven or static Transact-SQL cursors asynchronously. Transact-SQL cursor operations such as OPEN
or FETCH
are batched, so there's no need for the asynchronous generation of Transact-SQL cursors. SQL Server continues to support asynchronous keyset-driven or static application programming interface (API) server cursors where low latency OPEN
is a concern, due to client round trips for each cursor operation.
The accuracy of the query optimizer to determine an estimate for the number of rows in a keyset depends on the currency of the statistics for each of the tables in the cursor.
This option is an advanced option and should be changed only by an experienced database administrator or certified SQL Server professional.
If you set cursor threshold
to -1
, all keysets are generated synchronously, which benefits small cursor sets. If you set cursor threshold
to 0
, all cursor keysets are generated asynchronously. With other values, the query optimizer compares the number of expected rows in the cursor set and builds the keyset asynchronously if it exceeds the number set in cursor threshold
. Don't set cursor threshold
too low, because small result sets are better built synchronously.
Execute permissions on sp_configure
with no parameters or with only the first parameter are granted to all users by default. To execute sp_configure
with both parameters to change a configuration option or to run the RECONFIGURE
statement, a user must be granted the ALTER SETTINGS
server-level permission. The ALTER SETTINGS
permission is implicitly held by the sysadmin and serveradmin fixed server roles.
In Object Explorer, right-click a server and select Properties.
Select the Advanced node.
Under Miscellaneous, change the cursor threshold
option to the value you want.
Connect to the Database Engine.
From the Standard bar, select New Query.
Copy and paste the following example into the query window and select Execute. This example shows how to use sp_configure to set the cursor threshold
option to 0
so that cursor keysets are generated asynchronously.
USE master;
GO
EXECUTE sp_configure 'show advanced options', 1;
GO
RECONFIGURE;
GO
EXECUTE sp_configure 'cursor threshold', 0;
GO
RECONFIGURE;
GO
EXECUTE sp_configure 'show advanced options', 0;
GO
RECONFIGURE;
GO
For more information, see Server configuration options.
The setting takes effect immediately without restarting the server.
Events
Mar 31, 11 PM - Apr 2, 11 PM
The biggest SQL, Fabric and Power BI learning event. March 31 – April 2. Use code FABINSIDER to save $400.
Register todayTraining
Module
Configure SQL Server resources for optimal performance - Training
Configure SQL Server resources for optimal performance
Certification
Microsoft Certified: Azure Database Administrator Associate - Certifications
Administer an SQL Server database infrastructure for cloud, on-premises and hybrid relational databases using the Microsoft PaaS relational database offerings.
Documentation
DB_NAME (Transact-SQL) - SQL Server
DB_NAME (Transact-SQL)
Memory optimization for faster temp table and table variables - SQL Server
Learn about converting temporary tables, table variables, or table-valued parameters to memory-optimized tables and table variables to improve performance.
OBJECT_NAME (Transact-SQL) - SQL Server
OBJECT_NAME (Transact-SQL)