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 cost threshold for parallelism
server configuration option in SQL Server by using SQL Server Management Studio or Transact-SQL. The cost threshold for parallelism
option specifies the threshold at which SQL Server creates and runs parallel plans for queries. SQL Server creates and runs a parallel plan for a query only when the estimated cost to run a serial plan for the same query is higher than the value set in cost threshold for parallelism
. The cost refers to an estimated cost required to run the serial plan on a specific hardware configuration, and isn't a unit of time. The cost threshold for parallelism
option can be set to any value from 0 through 32767.
The cost refers to an abstracted unit of cost and not a unit of estimated time. Only set cost threshold for parallelism
on symmetric multiprocessors.
SQL Server ignores the cost threshold for parallelism
value under the following conditions:
Your computer has only one logical processor.
Only a single logical processor is available to SQL Server because of the affinity mask
configuration option.
The max degree of parallelism
option is set to 1
.
A logical processor is the basic unit of processor hardware that allows the operating system to dispatch a task or execute a thread context. Each logical processor can execute only one thread context at a time. The processor core is the circuitry that decodes and executes instructions. A processor core might contain one or more logical processors. The following Transact-SQL query can be used for obtaining CPU information for the system.
SELECT (cpu_count / hyperthread_ratio) AS PhysicalCPUs,
cpu_count AS logicalCPUs
FROM sys.dm_os_sys_info;
This option is an advanced option and should be changed only by an experienced database administrator or certified SQL Server professional.
In certain cases, a parallel plan might be chosen even though the query's cost plan is less than the current cost threshold for parallelism
value. This can happen because the decision to use a parallel or serial plan is based on a cost estimate provided earlier in the optimization process. For more information, see the Query Processing Architecture Guide.
While the default value of 5
is adequate for most systems, a different value might be appropriate. Perform application testing with higher and lower values if needed to optimize application performance.
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 Parallelism, change the cost threshold for parallelism
option to the value you want. Type or select a value from 0 to 32767.
This example shows how to use sp_configure to set the value of the cost threshold for parallelism
option to 10
.
USE master;
GO
EXECUTE sp_configure 'show advanced options', 1;
GO
RECONFIGURE;
GO
EXECUTE sp_configure 'cost threshold for parallelism', 10;
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
Documentation
Server configuration: max degree of parallelism - SQL Server
Learn about the max degree of parallelism (MAXDOP) option. See how to use it to limit the number of processors that SQL Server uses in parallel plan execution.
optimize for ad hoc workloads (server configuration option) - SQL Server
Learn about the 'optimize for ad hoc workloads' option. Use it to improve SQL Server plan cache efficiency when workloads contain many single-use ad hoc batches.
Soft-NUMA (SQL Server) - SQL Server
Learn about soft-NUMA in SQL Server 2014 SP2 and newer versions. See how to use automatic soft-NUMA and how to manually configure SQL Server to use soft-NUMA.