Configure the index create memory Server Configuration Option

This topic describes how to configure the index create memory server configuration option in SQL Server 2012 by using SQL Server Management Studio or Transact-SQL. The index create memory option controls the maximum amount of memory initially allocated for 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 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

    Recommendations

    Security

  • To configure the index create memory option, using:

    SQL Server Management Studio

    Transact-SQL

  • Follow Up:  After you configure the index create memory option

Before You Begin

Limitations and Restrictions

  • 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 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.

  • 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 Server is running. On 32-bit operating systems, the run value will be less than 3 gigabytes (GB).

Recommendations

  • This option is an advanced option and should be changed only by an experienced database administrator or certified SQL Server technician.

  • 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.

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.

Arrow icon used with Back to Top link [Top]

Using SQL Server Management Studio

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.

    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. Query sorts are controlled through the min memory per query option.

Arrow icon used with Back to Top link [Top]

Using Transact-SQL

To configure the index create memory option

  1. Connect to the Database Engine.

  2. From the Standard bar, click New Query.

  3. 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 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

For more information, see Server Configuration Options.

Arrow icon used with Back to Top link [Top]

Follow Up: After you configure the index create memory option

The setting takes effect immediately without restarting the server.

Arrow icon used with Back to Top link [Top]

See Also

Reference

sys.configurations (Transact-SQL)

RECONFIGURE (Transact-SQL)

sp_configure (Transact-SQL)

Concepts

Server Memory Server Configuration Options

Server Configuration Options