Megosztás a következőn keresztül:


index_option (Transact-SQL)

Specifies a set of options that can be applied to an index that is part of a constraint definition that is created by using ALTER TABLE.

Topic link iconTransact-SQL Syntax Conventions

Syntax

{ 
    PAD_INDEX = { ON | OFF }
  | FILLFACTOR =fillfactor
  | IGNORE_DUP_KEY = { ON | OFF }
  | STATISTICS_NORECOMPUTE = { ON | OFF }
  | ALLOW_ROW_LOCKS = { ON | OFF }
  | ALLOW_PAGE_LOCKS = { ON | OFF }
  | SORT_IN_TEMPDB = { ON | OFF } 
  | ONLINE = { ON | OFF }
  | MAXDOP =max_degree_of_parallelism
  | DATA_COMPRESSION = { NONE |ROW | PAGE}
      [ ON PARTITIONS ( { <partition_number_expression> | <range> } 
      [ , ...n ] ) ]
}

<range> ::= 
<partition_number_expression> TO <partition_number_expression>

<single_partition_rebuild__option> ::=
{
    SORT_IN_TEMPDB = { ON | OFF }
  | MAXDOP = max_degree_of_parallelism
  | DATA_COMPRESSION = {NONE | ROW | PAGE } }
}

Arguments

  • PAD_INDEX = { ON | OFF }
    Specifies index padding. The default is OFF.

    • ON
      The percentage of free space that is specified by FILLFACTOR is applied to the intermediate-level pages of the index.

    • OFF or fillfactor is not specified
      The intermediate-level pages are filled to near capacity, leaving enough space for at least one row of the maximum size the index can have, given the set of keys on the intermediate pages.

  • FILLFACTOR **=**fillfactor
    Specifies a percentage that indicates how full the Database Engine should make the leaf level of each index page during index creation or alteration. The value specified must be an integer value from 1 to 100. The default is 0.

    Note

    Fill factor values 0 and 100 are identical in all respects.

  • IGNORE_DUP_KEY = { ON | OFF }
    Specifies the error response when an insert operation attempts to insert duplicate key values into a unique index. The IGNORE_DUP_KEY option applies only to insert operations after the index is created or rebuilt. The option has no effect when executing CREATE INDEX, ALTER INDEX, or UPDATE. The default is OFF.

    • ON
      A warning message will occur when duplicate key values are inserted into a unique index. Only the rows violating the uniqueness constraint will fail.

    • OFF
      An error message will occur when duplicate key values are inserted into a unique index. The entire INSERT operation will be rolled back.

    IGNORE_DUP_KEY cannot be set to ON  for indexes created on a view, non-unique indexes, XML indexes, spatial indexes, and filtered indexes.

    To view IGNORE_DUP_KEY, use sys.indexes.

    In backward compatible syntax, WITH IGNORE_DUP_KEY is equivalent to WITH IGNORE_DUP_KEY = ON.

  • STATISTICS_NORECOMPUTE = { ON | OFF }
    Specifies whether statistics are recomputed. The default is OFF.

    • ON
      Out-of-date statistics are not automatically recomputed.

    • OFF
      Automatic statistics updating are enabled.

  • ALLOW_ROW_LOCKS = { ON | OFF }
    Specifies whether row locks are allowed. The default is ON.

    • ON
      Row locks are allowed when accessing the index. The Database Engine determines when row locks are used.

    • OFF
      Row locks are not used.

  • ALLOW_PAGE_LOCKS = { ON | OFF }
    Specifies whether page locks are allowed. The default is ON.

    • ON
      Page locks are allowed when accessing the index. The Database Engine determines when page locks are used.

    • OFF
      Page locks are not used.

  • SORT_IN_TEMPDB = { ON | OFF }
    Specifies whether to store sort results in tempdb. The default is OFF.

    • ON
      The intermediate sort results that are used to build the index are stored in tempdb. This may reduce the time required to create an index if tempdb is on a different set of disks than the user database. However, this increases the amount of disk space that is used during the index build.

    • OFF
      The intermediate sort results are stored in the same database as the index.

  • ONLINE = { ON | OFF }
    Specifies whether underlying tables and associated indexes are available for queries and data modification during the index operation. The default is OFF.

    Note

    Unique nonclustered indexes cannot be created online. This includes indexes that are created due to a UNIQUE or PRIMARY KEY constraint.

    • ON
      Long-term table locks are not held for the duration of the index operation. During the main phase of the index operation, only an Intent Share (IS) lock is held on the source table. This enables queries or updates to the underlying table and indexes to proceed. At the start of the operation, a Shared (S) lock is held on the source object for a very short period of time. At the end of the operation, for a short period of time, an S (Shared) lock is acquired on the source if a nonclustered index is being created; or an SCH-M (Schema Modification) lock is acquired when a clustered index is created or dropped online and when a clustered or nonclustered index is being rebuilt. ONLINE cannot be set to ON when an index is being created on a local temporary table.

    • OFF
      Table locks are applied for the duration of the index operation. An offline index operation that creates, rebuilds, or drops a clustered index, or rebuilds or drops a nonclustered index, acquires a Schema modification (Sch-M) lock on the table. This prevents all user access to the underlying table for the duration of the operation. An offline index operation that creates a nonclustered index acquires a Shared (S) lock on the table. This prevents updates to the underlying table but allows read operations, such as SELECT statements.

    For more information, see How Online Index Operations Work. For more information about locks, see Lock Modes.

    Note

    Online index operations are available only in SQL Server Enterprise, Developer, and Evaluation editions.

  • MAXDOP **=**max_degree_of_parallelism
    Overrides the max degree of parallelism configuration option for the duration of the index operation. For more information, see max degree of parallelism Option. Use MAXDOP to limit the number of processors used in a parallel plan execution. The maximum is 64 processors.

    max_degree_of_parallelism can be:

    • 1
      Suppresses parallel plan generation.

    • >1
      Restricts the maximum number of processors used in a parallel index operation to the specified number.

    • 0 (default)
      Uses the actual number of processors or fewer based on the current system workload.

    For more information, see Configuring Parallel Index Operations.

    Note

    Parallel index operations are available only in SQL Server Enterprise, Developer, and Evaluation editions.

  • DATA_COMPRESSION
    Specifies the data compression option for the specified table, partition number or range of partitions. The options are as follows:

    • NONE
      Table or specified partitions are not compressed.

    • ROW
      Table or specified partitions are compressed by using row compression.

    • PAGE
      Table or specified partitions are compressed by using page compression.

    For more information about compression, see Creating Compressed Tables and Indexes.

  • ON PARTITIONS ( { <partition_number_expression> | <range> } [ ,...n ] )
    Specifies the partitions to which the DATA_COMPRESSION setting applies. If the table is not partitioned, the ON PARTITIONS argument will generate an error. If the ON PARTITIONS clause is not provided, the DATA_COMPRESSION option will apply to all partitions of a partitioned table.

    <partition_number_expression> can be specified in the following ways:

    • Provide the number a partition, for example: ON PARTITIONS (2).

    • Provide the partition numbers for several individual partitions separated by commas, for example: ON PARTITIONS (1, 5).

    • Provide both ranges and individual partitions, for example: ON PARTITIONS (2, 4, 6 TO 8).

    <range> can be specified as partition numbers separated by the word TO, for example: ON PARTITIONS (6 TO 8).

    To set different types of data compression for different partitions, specify the DATA_COMPRESSION option more than once, for example:

    REBUILD WITH 
    (
    DATA_COMPRESSION = NONE ON PARTITIONS (1), 
    DATA_COMPRESSION = ROW ON PARTITIONS (2, 4, 6 TO 8), 
    DATA_COMPRESSION = PAGE ON PARTITIONS (3, 5)
    )
    
  • <single_partition_rebuild__option>
    In most cases, rebuilding an index rebuilds all partitions of a partitioned index. The following options, when applied to a single partition, do not rebuild all partitions.

    • SORT_IN_TEMPDB

    • MAXDOP

    • DATA_COMPRESSION

Remarks

For a complete description of index options, see CREATE INDEX (Transact-SQL).