設定 index create memory 伺服器組態選項Configure the index create memory 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 index create memory Transact-SQLTransact-SQL伺服器組態選項。This topic describes how to configure the index create memory server configuration option in SQL Server 2017SQL Server 2017 by using SQL Server Management StudioSQL Server Management Studio or Transact-SQLTransact-SQL. [索引建立記憶體] 選項會控制在建立索引時,一開始為排序作業所配置的記憶體數量上限。The index create memory option controls the maximum amount of memory initially allocated for sort operations when creating indexes. 這個選項的預設值是 0 (自我設定)。The default value for this option is 0 (self-configuring). 若稍後在建立索引時需要更多記憶體,且有足夠的記憶體可用,則伺服器會使用該記憶體,因而超過此選項的設定。If more memory is later needed for index creation and the memory is available, the server will use it; thereby, exceeding the setting of this option. 若沒有更多可用的記憶體,則會使用預先配置的記憶體繼續進行索引建立作業。If additional memory is not available, the index creation will continue using the memory already allocated.

本主題內容In This Topic

開始之前Before You Begin

限制事項Limitations and Restrictions

  • [每個查詢的最小記憶體] 選項之設定,優先順序高於 [索引建立記憶體] 選項。The setting of the min memory per query option has precedence over the index create memory option. 若您同時變更了兩個選項,且 index create memory 小於 min memory per query,您會看到警告訊息,但仍會設定該值。If you change both options and the index create memory is less than min memory per query, you receive a warning message, but the value is set. 執行查詢時,您會看到同樣的警告。During query execution, you receive a similar warning.

  • 使用資料分割資料表與索引時,如果有非對齊之資料分割索引與高度平行處理,建立索引時所需的最低記憶體需求會大幅增加。When using partitioned tables and indexes, the minimum memory requirements for index creation may increase significantly if there are non-aligned partitioned indexes and a high degree of parallelism. 此選項會控制在單一索引建立作業中,為所有索引資料分割配置的初始記憶體數量總計。This option controls the total initial amount of memory allocated for all index partitions in a single index creation operation. 若此選項設定的記憶體數量小於執行查詢所需的最低記憶體需求,則查詢會終止,且會顯示錯誤訊息。The query will terminate with an error message if the amount set by this option is less than the minimum required to run the query.

  • 此選項的執行值將不會超過執行 SQL ServerSQL Server 之作業系統與硬體平台可用的實際記憶體數量。The run value for this option will not exceed the actual amount of memory that can be used for the operating system and hardware platform on which SQL ServerSQL Server is running.

建議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.

  • [索引建立記憶體] 選項為自我設定,並且通常不需要調整便可使用。The index create memory option is self-configuring and usually works without requiring adjustment. 然而,如果無法建立索引,請考慮增加這個選項的執行值。However, if you experience difficulties creating indexes, consider increasing the value of this option from its run value.

  • 對生產系統建立索引通常是難得執行的工作,多半排程為工作在離峰時間執行。Creating an index on a production system is usually an infrequently performed task, often scheduled as a job to execute during off-peak time. 因此,一旦有機會在離峰時間或是在建立索引不頻繁時,加大 [索引建立記憶體] 可能有助於改善建立索引的效能。Therefore, when creating indexes infrequently and during off-peak time, increasing the index create memory can improve the performance of index creation. 但仍請儘量將 [每個查詢的最小記憶體] 設定選項維持在較小的值,讓索引建立作業即使無法取得要求的記憶體,還是能夠啟動。Keep the min memory per query configuration option at a lower number, however, so the index creation job still starts even if all the requested memory is not available.

安全性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

若要設定 index create memory 選項To configure the index create memory option

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

  2. 按一下 [記憶體] 節點。Click the Memory node.

  3. [索引建立記憶體] 之下,輸入或選取所要的索引建立記憶體選項值。Under Index creation memory, type or select the desired value for the index create memory option.

    index create memory 選項可用來控制索引建立排序所使用的記憶體大小。Use the index create memory option to control the amount of memory used by index creation sorts. [索引建立記憶體] 屬於自我設定的選項,而且不需調整即可適用於大部份情況。The index create memory option is self-configuring and should work in most cases without requiring adjustment. 然而,如果無法建立索引,請考慮增加這個選項的執行值。However, if you experience difficulties creating indexes, consider increasing the value of this option from its run value. 查詢排序是透過 min memory per query 選項來控制。Query sorts are controlled through the min memory per query option.

使用 Transact-SQLUsing Transact-SQL

若要設定 index create memory 選項To configure the index create memory 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_configureindex create memory 選項的值設定為 4096This example shows how to use sp_configure to set the value of the index create memory option to 4096.

USE AdventureWorks2012 ;  
EXEC sp_configure 'show advanced options', 1;  
GO  
RECONFIGURE;  
GO  
EXEC sp_configure 'index create memory', 4096  
GO  
RECONFIGURE;  
GO  

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

後續操作:設定索引建立記憶體選項之後Follow Up: After you configure the index create memory option

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

另請參閱See Also

sys.configurations (Transact-SQL) sys.configurations (Transact-SQL)
RECONFIGURE (Transact-SQL) RECONFIGURE (Transact-SQL)
伺服器記憶體伺服器組態選項 Server Memory Server Configuration Options
伺服器組態選項 (SQL Server) Server Configuration Options (SQL Server)
sp_configure (Transact-SQL)sp_configure (Transact-SQL)