Server configuration: index create memory
Applies to: SQL Server
This article describes how to configure the index create memory
server configuration option in SQL Server by using SQL Server Management Studio or Transact-SQL. The index create memory
option controls the maximum amount of memory initially allocated for sort operations when creating indexes. 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 uses it. Doing so exceeds the setting of this option. If more memory isn't available, the index creation continues using the memory already allocated.
Limitations
The setting of the min memory per query option has precedence over the index create memory
option. 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 you use partitioned tables and indexes, the minimum memory requirements for index creation might 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 terminates with an error message if the amount set by this option is less than the minimum required to run the query.
The run value for this option doesn't exceed the actual amount of memory that can be used for the operating system and hardware platform on which SQL Server is running.
Recommendations
This option is an advanced option and should be changed only by an experienced database administrator or certified SQL 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 isn't available.
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.
Use SQL Server Management Studio
In Object Explorer, right-click a server and select Properties.
Select the Memory node.
Under Index creation memory, type or select the desired value for the index create memory option.
Use the
index create memory
option to control the amount of memory used by index creation sorts. Theindex 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. Query sorts are controlled through themin memory per query
option.
Use Transact-SQL
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 value of the
index create memory
option to4096
.USE master; GO EXECUTE sp_configure 'show advanced options', 1; GO RECONFIGURE; GO EXECUTE sp_configure 'index create memory', 4096; GO RECONFIGURE; GO EXECUTE sp_configure 'show advanced options', 0; GO RECONFIGURE; GO
For more information, see Server configuration options.
Follow up: After you configure the index create memory option
The setting takes effect immediately without restarting the server.