Special Guidelines for Partitioned Indexes
Although partitioned indexes can be implemented independently from their base tables, it generally makes sense to design a partitioned table and then create an index on the table. When you do this, SQL Server automatically partitions the index by using the same partition scheme and partitioning column as the table. As a result, the index is partitioned in essentially the same manner as the table. This makes the index aligned with the table.
SQL Server does not align the index with the table if you specify a different partition scheme or a separate filegroup on which to put the index at creation time.
Aligning an index with a partitioned table is particularly important if you anticipate that it will expand by taking on additional partitions, or that it will be involved in frequent partition switches. For more information, see Designing Partitions to Manage Subsets of Data. When a table and its indexes are in alignment, SQL Server can switch partitions quickly and efficiently while maintaining the partition structure of both the table and its indexes.
Note
An index does not have to participate in the same named partition function to be aligned with its base table. However, the partition function of the index and the base table must be essentially the same, in that 1) the arguments of the partition functions have the same data type, 2) they define the same number of partitions, and 3) they define the same boundary values for partitions.
The Tuning Options tab of the Database Engine Tuning Advisor provides an Aligned partitioning setting to specify that new recommended indexes be aligned with their base tables. The Keep aligned partitioning setting can be used for the same purpose and can also be used to drop existing nonaligned indexes. For more information, see Database Engine Tuning Advisor (Tuning Options Tab). Generally, the Database Engine Tuning Advisor can be used to recommend indexes for performance, and this can be a mix of aligned and nonaligned indexes. For more information, see Database Engine Tuning Advisor Overview.
Designing a partitioned index independently (unaligned) of the base table can be useful in the following cases:
The base table has not been partitioned.
The index key is unique and it does not contain the partitioning column of the table.
You want the base table to participate in collocated joins with more tables using different join columns.
Note
To enable partition switching, all indexes on the table must be aligned.
Consider the information in the following sections when you create a partitioned index.
Partitioning Unique Indexes
When partitioning a unique index (clustered or nonclustered), the partitioning column must be chosen from among those used in the unique index key.
Note
This restriction enables SQL Server to investigate only a single partition to make sure no duplicate of a new key value already exists in the table.
If it is not possible for the partitioning column to be included in the unique key, you must use a DML trigger instead to enforce uniqueness.
Partitioning Clustered Indexes
When partitioning a clustered index, the clustering key must contain the partitioning column. When partitioning a nonunique clustered index, and the partitioning column is not explicitly specified in the clustering key, SQL Server adds the partitioning column by default to the list of clustered index keys. If the clustered index is unique, you must explicitly specify that the clustered index key contain the partitioning column.
Partitioning NonClustered Indexes
When partitioning a unique nonclustered index, the index key must contain the partitioning column. When partitioning a nonunique, nonclustered index, SQL Server adds the partitioning column by default as a nonkey (included) column of the index to make sure the index is aligned with the base table. SQL Server does not add the partitioning column to the index if it is already present in the index.
Memory Limitations and Partitioned Indexes
Memory limitations can affect the performance or ability of SQL Server to build a partitioned index. This is especially the case when the index is not aligned with its base table or is not aligned with its clustered index, if the table already has a clustered index applied to it.
When SQL Server performs sorting to build partitioned indexes, it first builds one sort table for each partition. It then builds the sort tables either in the respective filegroup of each partition or in tempdb, if the SORT_IN_TEMPDB index option is specified.
Each sort table requires a minimum amount of memory to build. When you are building a partitioned index that is aligned with its base table, sort tables are built one at a time, using less memory. However, when you are building a nonaligned partitioned index, the sort tables are built at the same time.
As a result, there must be sufficient memory to handle these concurrent sorts. The larger the number of partitions, the more memory required. The minimum size for each sort table, for each partition, is 40 pages, with 8 kilobytes per page. For example, a nonaligned partitioned index with 100 partitions requires sufficient memory to serially sort 4,000 (40 * 100) pages at the same time. If this memory is available, the build operation will succeed, but performance may suffer. If this memory is not available, the build operation will fail. Alternatively, an aligned partitioned index with 100 partitions requires only sufficient memory to sort 40 pages, because the sorts are not performed at the same time.
For both aligned and nonaligned indexes, the memory requirement can be greater if SQL Server is applying degrees of parallelism to the build operation on a multiprocessor computer. This is because the greater the degrees of parallelism, the greater the memory requirement. For example, if SQL Server sets degrees of parallelism to 4, a nonaligned partitioned index with 100 partitions requires sufficient memory for four processors to sort 4,000 pages at the same time, or 16,000 pages. If the partitioned index is aligned, the memory requirement is reduced to four processors sorting 40 pages, or 160 (4 * 40) pages. You can use the MAXDOP index option to manually reduce the degrees of parallelism. For more information, see Configuring Parallel Index Operations.
For more information about how SQL Server performs sorting operations when you are building indexes, see tempdb and Index Creation.