Configure the cost threshold for parallelism Server Configuration Option
This topic describes how to configure the cost threshold for parallelism server configuration option in SQL Server 2012 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 elapsed time in seconds required to run the serial plan on a specific hardware configuration. The cost threshold for parallelism option can be set to any value from 0 through 32767. The default value is 5.
In This Topic
Before you begin:
Limitations and Restrictions
Recommendations
Security
To configure the cost threshold for parallelism option, using:
SQL Server Management Studio
Transact-SQL
Follow Up: After you configure the cost threshold for parallelism option
Before You Begin
Limitations and Restrictions
The cost refers to an estimated elapsed time in seconds required to run the serial plan on a specific hardware configuration. 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 provides ability to decode and execute instructions. A processor core may 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
Recommendations
This option is an advanced option and should be changed only by an experienced database administrator or certified SQL Server technician.
In certain cases, a parallel plan may 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 before the full optimization is complete.
Security
Permissions
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.
[Top]
Using SQL Server Management Studio
To configure the cost threshold for parallelism option
In Object Explorer, right-click a server and select Properties.
Click the Advanced node.
Under Parallelism, change the CostThresholdForParallelism option to the value you want. Type or select a value from 0 to 32767.
[Top]
Using Transact-SQL
To configure the cost threshold for parallelism option
Connect to the Database Engine.
From the Standard bar, click New Query.
Copy and paste the following example into the query window and click Execute. This example shows how to use sp_configure to set the value of the cost threshold for parallelism option to 10 seconds.
USE AdventureWorks2012 ;
GO
EXEC sp_configure 'show advanced options', 1 ;
GO
RECONFIGURE
GO
EXEC sp_configure 'cost threshold for parallelism', 10 ;
GO
RECONFIGURE
GO
For more information, see Server Configuration Options (SQL Server).
[Top]
Follow Up: After you configure the cost threshold for parallelism option
The setting takes effect immediately without restarting the server.
[Top]
Zobacz także
Odwołanie
ALTER WORKLOAD GROUP (Transact-SQL)
Koncepcje
Configure Parallel Index Operations