設定 cost threshold for parallelism 伺服器組態選項Configure the cost threshold for parallelism Server Configuration Option

適用於: 是SQL Server 否Azure SQL Database 否Azure SQL 資料倉儲 否平行處理資料倉儲 APPLIES TO: yesSQL Server noAzure SQL Database noAzure SQL Data Warehouse noParallel Data Warehouse

此主題描述如何使用 ,在 SQL Server 2017SQL Server 2017 中設定 SQL Server Management StudioSQL Server Management Studio cost threshold for parallelism Transact-SQLTransact-SQL伺服器組態選項。This topic describes how to configure the cost threshold for parallelism server configuration option in SQL Server 2017SQL Server 2017 by using SQL Server Management StudioSQL Server Management Studio or Transact-SQLTransact-SQL. 平行處理原則的成本臨界值 選項指定 SQL ServerSQL Server 為查詢建立及執行平行計劃的臨界值。The cost threshold for parallelism option specifies the threshold at which SQL ServerSQL Server creates and runs parallel plans for queries. SQL ServerSQL 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 is not a unit of time. cost threshold for parallelism 選項可設成從 0 到 32767 的任何值。The cost threshold for parallelism option can be set to any value from 0 through 32767. 預設值為 5。The default value is 5.

本主題內容In This Topic

開始之前Before You Begin

限制事項Limitations and Restrictions

  • 成本是指成本的抽象單位,而非預估時間單位。The cost refers to an abstracted unit of cost and not a unit of estimated time. 只有在對稱式多重處理器上才應該設定 cost threshold for parallelismOnly set cost threshold for parallelism on symmetric multiprocessors.

  • SQL ServerSQL Server 會忽略 值:ignores the cost threshold for parallelism value under the following conditions:

    • 您的電腦只有一個邏輯處理器。Your computer has only one logical processor.

    • 因為 SQL ServerSQL Server affinity mask 組態選項的關係,只有一個邏輯處理器可供 使用。Only a single logical processor is available to SQL ServerSQL Server because of the affinity mask configuration option.

    • max degree of parallelism 選項設為 1。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. 下列 Transact-SQLTransact-SQL 查詢可用於取得系統的 CPU 資訊。The following Transact-SQLTransact-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

  • 此選項是進階選項,只有具經驗的資料庫管理員或通過認證的 SQL ServerSQL Server 專業人員才可變更。This option is an advanced option and should be changed only by an experienced database administrator or certified SQL ServerSQL Server professional.

  • 在某些狀況下,即使查詢的成本計畫小於目前的 cost threshold for parallelism 值,還是會選擇平行計畫。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 earlier in the optimization process. 如需詳細資訊,請參閱查詢處理架構指南For more information, refer to the Query Processing Architecture Guide.

  • 雖然預設值 5 對於大部分系統就已足夠,但是可能適用不同的值。While the default value of 5 is adequate for most systems, a different value may be appropriate. 若需要將應用程式效能最佳化,請以較高和較低值來執行應用程式測試。Perform application testing with higher and lower values if needed to optimize application performance.

安全性Security

權限Permissions

不含參數或只含第一個參數之 sp_configure 上的執行權限預設會授與所有使用者。Execute permissions on sp_configure with no parameters or with only the first parameter are granted to all users by default. 以同時設定兩個參數的 sp_configure 來變更組態選項或執行 RECONFIGURE 陳述式時,使用者必須取得 ALTER SETTINGS 伺服器層級權限。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. 系統管理員 (sysadmin)serveradmin 固定伺服器角色會隱含 ALTER SETTINGS 權限。The ALTER SETTINGS permission is implicitly held by the sysadmin and serveradmin fixed server roles.

使用 SQL Server Management StudioUsing SQL Server Management Studio

設定 cost threshold for parallelism 選項To configure the cost threshold for parallelism option

  1. 在 [物件總管] 中,以滑鼠右鍵按一下伺服器,然後選取 [屬性]In Object Explorer, right-click a server and select Properties.

  2. 按一下 [進階] 節點。Click the Advanced node.

  3. 在 [平行處理原則] 下,將 [平行處理原則的成本閾值] 選項變更為所需的值。Under Parallelism, change the Cost Threshold for Parallelism option to the value you want. 輸入或選取 0 到 32767 之間的值。Type or select a value from 0 to 32767.

使用 Transact-SQLUsing Transact-SQL

設定 cost threshold for parallelism 選項To configure the cost threshold for parallelism option

  1. 連接到 Database EngineDatabase EngineConnect to the Database EngineDatabase Engine.

  2. 在標準列中,按一下 [新增查詢]From the Standard bar, click New Query.

  3. 複製下列範例並將其貼到查詢視窗中,然後按一下 [執行]Copy and paste the following example into the query window and click Execute. 此範例示範如何使用 sp_configurecost threshold for parallelism 選項的值設定為 10This example shows how to use sp_configure to set the value of the cost threshold for parallelism option to 10.

USE AdventureWorks2012 ;  
GO  
EXEC sp_configure 'show advanced options', 1 ;  
GO  
RECONFIGURE  
GO  
EXEC sp_configure 'cost threshold for parallelism', 10 ;  
GO  
RECONFIGURE  
GO  

如需詳細資訊,請參閱 伺服器設定選項 (SQL Server)伺服器組態選項。For more information, see Server Configuration Options (SQL Server).

後續操作:設定平行處理原則的成本閾值選項之後Follow Up: After you configure the cost threshold for parallelism option

設定會立即生效,不需要重新啟動伺服器。The setting takes effect immediately without restarting the server.

另請參閱See Also

設定平行索引作業 Configure Parallel Index Operations
查詢提示 (Transact-SQL) Query Hints (Transact-SQL)
ALTER WORKLOAD GROUP (Transact-SQL) ALTER WORKLOAD GROUP (Transact-SQL)
affinity mask 伺服器組態選項 affinity mask Server Configuration Option
RECONFIGURE (Transact-SQL) RECONFIGURE (Transact-SQL)
伺服器組態選項 (SQL Server) Server Configuration Options (SQL Server)
sp_configure (Transact-SQL)sp_configure (Transact-SQL)