Creates an index on one or more columns in a table, computed or non-computed. Creates partitioned indexes.
Allows computed columns, like ordinary columns, to be index keys, and creates function-based indexes. A function-based index has one or more expressions as its index key.
The existing create index syntax can create indexes on computed columns, but some new syntax is needed to create function-based indexes.
create [unique] [clustered | nonclustered] index index_name on [[database.]owner.]table_name (column_expression [asc | desc] [, column_expression [asc | desc]]...) [with {fillfactor = pct, max_rows_per_page = num_rows, reservepagegap = num_pages, consumers = x, ignore_dup_key, sorted_data, [ignore_dup_row | allow_dup_row], statistics using num_steps values}] [on segment_name] [index_partition_clause]
Syntax to create index partitions
index_partition_clause::= [local index [partition_name [on segment_name] [, partition_name [on segment_name]...]]]
Syntax for function-based indexes
create [unique | nonclustered] index index_name on [[database.] owner.] table_name (column_expression [asc | desc] [, column_expression [asc | desc]]...
prohibits duplicate index values (also called “key values”). The system checks for duplicate key values when the index is created (if data already exists), and each time data is added with an insert or update. If there is a duplicate key value or if more than one row contains a null value, the command fails, and Adaptive Server prints an error message giving the duplicate entry.
WARNING! Adaptive Server does not detect duplicate rows if a table contains any non-null text, unitext, or image columns.
update and insert commands, which generate duplicate key values, can succeed if you create your index using the allow_dup_row option.
Composite indexes (indexes in which the key value is composed of more than one column) can also be unique.
The default is nonunique. To create a nonunique clustered index on a table that contains duplicate rows, specify allow_dup_row or ignore_dup_row. See “Duplicate rows”.
When you create a unique local index on range-, list-, and hash-partitioned tables, the index key list is a superset of the partition-key list.
means that the physical order of rows on the current database device is the same as the indexed order of the rows. The bottom, or leaf level, of the clustered index contains the actual data pages. A clustered index almost always retrieves data faster than a nonclustered index. Only one clustered index per table is permitted. See “Creating clustered indexes”.
If clustered is not specified, nonclustered is assumed.
means that the physical order of the rows is not the same as their indexed order. The leaf level of a nonclustered index contains pointers to rows on data pages. You can have as many as 249 nonclustered indexes per table.
is the name of the index. Index names must be unique within a table, but need not be unique within a database.
is the name of the table in which the indexed column or columns are located. Specify the database name if the table is in another database, and specify the owner’s name if more than one table of that name exists in the database. The default value for owner is the current user, and the default value for database is the current database.
is a valid Transact-SQL expression that references at least one base column, and does not contain columns from other tables, local and global variables, aggregate functions, or subqueries.
column_expressions replaces the column_name variable used in Adaptive Server before version 15.0.
specifies whether the index is to be created in ascending or descending order for the column specified. The default is ascending order.
specifies how full Adaptive Server makes each page when it creates a new index on existing data. The fillfactor percentage is relevant only when the index is created. As the data changes, the pages are not maintained at any particular level of fullness.
The value you specify is not saved in sysindexes for display by sp_helpindex or for later use by the reorg command. Use sp_chgattribute to create stored fillfactor values.
The default for fillfactor is 0; this is used when you do not include with fillfactor in the create index statement (unless the value has been changed with sp_configure). When specifying a fillfactor, use a value between 1 and 100.
A fillfactor of 0 creates clustered indexes with completely full pages and nonclustered indexes with completely full leaf pages. It leaves a comfortable amount of space within the index B-tree in both the clustered and nonclustered indexes. There is seldom a reason to change the fillfactor.
If the fillfactor is set to 100, Adaptive Server creates both clustered and nonclustered indexes with each page 100 percent full. A fillfactor of 100 makes sense only for read-only tables—tables to which no data is ever added.
fillfactor values smaller than 100 (except 0, which is a special case) cause Adaptive Server to create new indexes with pages that are not completely full. A fillfactor of 10 might be a reasonable choice if you are creating an index on a table that will eventually hold a great deal more data, but small fillfactor values cause each index (or index and data) to occupy more storage space.
WARNING! Creating a clustered index with a fillfactor affects the amount of storage space your data occupies, since Adaptive Server redistributes the data as it creates the clustered index.
limits the number of rows on data pages and the leaf-level pages of indexes. Unlike fillfactor, the max_rows_per_page value is maintained until it is changed with sp_chgattribute.
If you do not specify a value for max_rows_per_page, Adaptive Server uses a value of 0 when creating the table. Values for tables and clustered indexes range from 0 to 183K on a 2K page, to 0 to 1486 on a 16K page.
The maximum number of rows per page for nonclustered indexes depends on the size of the index key. Adaptive Server returns an error message if the specified value is too high.
A max_rows_per_page value of 0 creates clustered indexes with full pages and nonclustered indexes with full leaf pages. It leaves a comfortable amount of space within the index B-tree in both clustered and nonclustered indexes.
If max_rows_per_page is set to 1, Adaptive Server creates both clustered and nonclustered indexes with one row per page at the leaf level. Use low values to reduce lock contention on frequently accessed data. However, low max_rows_per_page values cause Adaptive Server to create new indexes with pages that are not completely full, uses more storage space, and may cause more page splits.
If Component Integration Services is enabled, you cannot use max_rows_per_page for remote servers.
WARNING! Creating a clustered index with max_rows_per_page can affect the amount of storage space your data occupies, since Adaptive Server redistributes the data as it creates the clustered index.
specifies a ratio of filled pages to empty pages to be left during extent I/O allocation operations. For each specified num_pages, an empty page is left for future expansion of the index. Valid values are 0 – 255. The default is 0.
specifies the number of consumer processes that should perform the sort operation for creating the index. The actual number of consumer processes used to sort the index may be different than the specified number depending on the number of worker processes available and the number of data partitions.
cancels attempts of duplicate key entry into a table that has a unique index (clustered or nonclustered). Adaptive Server cancels the attempted insert or update of a duplicate key with an informational message. After the cancellation, the transaction containing the duplicate key proceeds to completion.
You cannot create a unique index on a column that includes duplicate values or more than one null value, whether or not ignore_dup_key is set. If you attempt to do so, Adaptive Server prints an error message that displays the first of the duplicate values. You must eliminate duplicates before Adaptive Server can create a unique index on the column.
allows you to create a new, nonunique clustered index on a table that includes duplicate rows. ignore_dup_row deletes the duplicate rows from the table, and cancels any insert or update that would create a duplicate row, but does not roll back the entire transaction. See “Duplicate rows” for more information.
allows you to create a nonunique clustered index on a table that includes duplicate rows, and allows you to duplicate rows with update and insert statements. See “Duplicate rows” for an explanation of how to use these options.
speeds creation of clustered indexes or unique nonclustered indexes when the data in the table is already in sorted order (for example, when you have used bcp to copy data that has already been sorted into an empty table). See “Using the sorted_data option to speed sorts” for more information.
specifies the number of steps to generate for the histogram used to optimize queries. If you omit this clause:
The default value is 20, if no histogram is currently stored for the leading index column.
The current number of steps is used, if a histogram for the leading column of the index column already exists.
If you specify 0 for num_steps, the index is re-created, but the statistics for the index are not overwritten in the system tables.
The actual number of steps may differ from the one you specify; if the histogram steps specified with num_steps is M, and the histogram tuning factor parameter is N, then the actual steps are between M and M*N, depending on the number of frequency cells that exist in the distribution.
creates the index on the named segment. Before using the on segment_name option, initialize the device with disk init, and add the segment to the database using sp_addsegment. See your System Administrator, or use sp_helpsegment for a list of the segment names available in your database. There are two locations where you can use on segment_name:
Immediately before the index_partition_clause – defines a global default which will be used for all partitions where the segment is not explicitly defined in the index_partition_clause
Within that clause itself – allows you to specify a segment for each individual partition
See the examples section for an example that uses on segment_name in both locations.
specifies, for semantically partitioned tables, an index that is always equipartitioned with its base table; that is, the table and index share the same partitioning key and partitioning criteria. For round-robin partitioned tables, a local index means that index keys in each of its index partitions refer to data rows in one and only one table partition.
For both semantically partitioned tables and round-robin partitioned tables, each table partition has only one corresponding index partition.
specifies the name of a new partition on which indexes are to stored. Partition names must be unique within the set of partitions on a table or index. Partition names can be delimited identifiers if set quoted_identifier is on. Otherwise, they must be valid identifiers.
If partition_name is omitted, Adaptive Server creates a name in the form table_name_partition_id. Adaptive Server truncates partition names that exceed the allowed maximum length.
Creates an index named au_id_ind on the au_id column of the authors table:
create index au_id_ind on authors (au_id)
Creates a unique clustered index named au_id_ind on the au_id column of the authors table:
create unique clustered index au_id_ind on authors (au_id)
Creates an index named ind1 on the au_id and title_id columns of the titleauthor table:
create index ind1 on titleauthor (au_id, title_id)
Creates a nonclustered index named zip_ind on the zip column of the authors table, filling each index page one-quarter full and limiting the sort to 4 consumer processes:
create nonclustered index zip_ind on authors (postalcode) with fillfactor = 25, consumers = 4
Creates an index with ascending ordering on pub_id and descending order on pubdate:
create index pub_dates_ix on titles (pub_id asc, pubdate desc)
Creates an index on title_id, using 50 histogram steps for optimizer statistics and leaving 1 empty page out of every 40 pages in the index:
create index title_id_ix on titles (title_id) with reservepagegap = 40, statistics using 50 values
Creates a local, clustered index on a partitioned salesdetail table. The clust_idx index inherits the partition strategy, partition key, and partition bounds of salesdetail.
create clustered index clust_idx on salesdetail (ord_num) local index
Creates a nonpartitioned, nonclustered global index on a partitioned sales table, which is partitioned by range on the date column.
create nonclustered index global_idx on sales (order_num)
First, creates a table, pback_sales, with three data partitions:
create table pback_sales (c1 int, c2 int, c3 varchar (20)) partition range (c1) (p1 c1 values <= (10), p2 c1 values <= (20), p3 c1 values <= (MAX))
Then, creates a local, function-based index on partition p1:
create index fc_idx on pback_sales (c1*c2) local index p1
Creates a function-based index:
create index sum_sales on mytitles (price * total_sales)
Specifies the on segment_name clause both before and after the partition name:
use tempdb go if not exists(select 1 from tempdb..syssegments where name = 'seg1') exec sp_addsegment seg1,tempdb,master go if not exists(select 1 from tempdb..syssegments where name = 'seg2') exec sp_addsegment seg2,tempdb,master go if not exists(select 1 from tempdb..syssegments where name = 'seg3') exec sp_addsegment seg3,tempdb,master go if not exists(select 1 from tempdb..syssegments where name = 'seg4') exec sp_addsegment seg4,tempdb,master go if exists(select 1 from sysobjects where name = 't1') drop table t1 go create table t1 (a int, b varchar(30)) partition by roundrobin (p1 on seg1, p2 on seg2) go create index t1_i1 on t1 (a) local index go create index t1_i2 on t1 (a) on seg3 local index ip1 on seg4 go sp_help t1 go
Provides the following output:
Name Owner Object_type Create_date ---- ----- ----------- ------------------- t1 dbo user table Aug 7 2008 11:14AM (1 row affected) Column_name Type Length Prec Scale Nulls Default_name Rule_name Access_Rule_name Computed_Column_object Identity ----------- ------- ------ ---- ----- ----- ------------ --------- ---------------- ---------------------- ---------- a int 4 NULL NULL 0 NULL NULL NULL NULL 0 b varchar 30 NULL NULL 0 NULL NULL NULL NULL 0 Object has the following indexes index_name index_keys index_description index_max_rows_per_page index_fillfactor index_reservepagegap index_created index_local ---------- ---------- ----------------- ----------------------- ---------------- -------------------- ------------------- ----------- t1_i1 a nonclustered 0 0 0 Aug 7 2008 11:14AM Local Index t1_i2 a nonclustered 0 0 0 Aug 7 2008 11:14AM Local Index (2 rows affected) index_ptn_name index_ptn_seg ---------------- ------------- t1_i1_952063116 default t1_i1_968063173 default ip1 seg4 t1_i2_1000063287 seg3 (4 rows affected) No defined keys for this object. name type partition_type partitions partition_keys ---- ---------- -------------- ---------- -------------- t1 base table roundrobin 2 NULL (1 row affected) partition_name partition_id pages row_count segment create_date -------------- ------------ ----- --------- ------- ------------------- p1 920063002 1 0 seg1 Aug 7 2008 11:14AM p2 936063059 1 0 seg2 Aug 7 2008 11:14AM Partition_Conditions -------------------- NULL Avg_pages Max_pages Min_pages Ratio(Max/Avg) Ratio(Min/Avg) ----------- ----------- ----------- -------------- ---------------- 1 1 1 1.000000 1.000000 Lock scheme Allpages The attribute 'exp_row_size' is not applicable to tables with allpages lock scheme. The attribute 'concurrency_opt_threshold' is not applicable to tables with allpages lock scheme. exp_row_size reservepagegap fillfactor max_rows_per_page identity_gap ascinserts ------------ -------------- ---------- ----------------- ------------ ----------- 0 0 0 0 0 0 (1 row affected) concurrency_opt_threshold optimistic_index_lock dealloc_first_txtpg ------------------------- --------------------- ------------------- 0 0 0 (1 row affected) (return status = 0)
Run update statistics periodically if you add data to the table that changes the distribution of keys in the index. The query optimizer uses the information created by update statistics to select the best plan for running queries on the table.
If the table contains data when you create a nonclustered index, Adaptive Server runs update statistics on the new index. If the table contains data when you create a clustered index, Adaptive Server runs update statistics on all the table’s indexes.
Index all columns that are regularly used in joins.
When Component Integration Services is enabled, the create index command is reconstructed and passed directly to the Adaptive Server associated with the table.
Adaptive Server automatically recompiles stored procedures after executing create index statements. Although adhoc queries that you start before executing create index still continue to work, they do not take advantage of the new index.In Adaptive Server versions 12.5 and earlier, create index was ignored by cached stored procedures.
Indexes speed data retrieval, but can slow data updates. For better performance, create a table on one segment and create its nonclustered indexes on another segment, when the segments are on separate physical devices.
Adaptive Server can create indexes in parallel if a table is partitioned and the server is configured for parallelism. It can also use sort buffers to reduce the amount of I/O required during sorting. For more information, see Chapter 9, “Parallel Sorting,” in the Performance and Tuning Guide: Optimizer and Abstract Plans.
Create a clustered index before creating any nonclustered indexes, since nonclustered indexes are automatically rebuilt when a clustered index is created.
When using parallel sort for data-only-locked tables, the number of worker processes must be configured to equal or exceed the number of partitions, even for empty tables. The database option select into/bulkcopy/pllsort must also be enabled.
A table “follows” its clustered index. When you create a table, use the on segment_name extension to create clustered index, the table migrates to the segment where the index is created.
If you create a table on a specific segment, then create a clustered index without specifying a segment, Adaptive Server moves the table to the default segment when it creates the clustered index there.
Because text, unitext, and image data is stored in a separate page chain, creating a clustered index with on segment_name does not move text and image columns.
To create a clustered index, Adaptive Server duplicates the existing data; the server deletes the original data when the index is complete. Before creating a clustered index, use sp_spaceused to make sure that the database has at least 120 percent of the size of the table available as free space.
The clustered index is often created on the table’s primary key (the column or columns that uniquely identify the row). You can record the primary key in the database (for use by front-end programs and sp_depends) using sp_primarykey.
To allow duplicate rows in a clustered index, specify allow_dup_row.
You can create an index on an encrypted column if you specify the encryption key without any initialization vector or random padding. Adpative Server issues an error if you execute create index on an encrypted column with an initialization vector or random padding. Indexes on encrypted columns are useful for equality and non-equality matches, but are not useful for matching case-insensitive data, or for range searches of any data.
You cannot use an encrypted column in an expression for a functional index
Use the asc and desc keywords after index column names to specify the sorting order for the index keys. Creating indexes so that columns are in the same order specified in the order by clause of queries eliminates the sorting step during query processing. For more information, see Chapter 6, “Indexing for Performance,” in the Performance and Tuning Guide: Locking.
Space is allocated to tables and indexes in increments of one extent, or eight pages, at a time. Each time an extent is filled, another extent is allocated. Use sp_spaceused to display the amount of space allocated and used by an index.
In some cases, using the sorted_data option allows Adaptive Server to skip copying the data rows as described in Table 1-8. In these cases, you need only enough additional space for the index structure itself. Depending on key size, this is usually about 20 percent of the size of the table.
The ignore_dup_row and allow_dup_row options are not relevant when you are creating a nonunique, nonclustered index. Adaptive Server attaches a unique row identification number internally in each nonclustered index; duplicate rows are not a problem even for identical data values.
ignore_dup_row and allow_dup_row are mutually exclusive.
In all-pages-locked tables, nonunique clustered index allows duplicate keys, but does not allow duplicate rows unless you specify allow_dup_row. This behavior differs for data-only-locked tables, and is described in detail on Table 1-6.
allow_dup_row allows you to create a nonunique, clustered index on a table that includes duplicate rows. If a table has a nonunique, clustered index that was created without the allow_dup_row option, you cannot create new duplicate rows using the insert or update command.
If any index in the table is unique, the requirement for uniqueness takes precedence over the allow_dup_row option. You cannot create an index with allow_dup_row if a unique index exists on any column in the table.
The ignore_dup_row option is also used with a nonunique, clustered index. The ignore_dup_row option eliminates duplicates from a batch of data. ignore_dup_row cancels any insert or update that would create a duplicate row, but does not roll back the entire transaction.
Table 1-6 illustrates how allow_dup_row and ignore_dup_row affect attempts to create a nonunique, clustered index on a table that includes duplicate rows and attempts to enter duplicate rows into a table.
Option setting |
Create an index on a table that has duplicate rows |
Insert duplicate rows into a table with an index |
---|---|---|
Neither option set |
create index fails. |
insert fails. |
allow_dup_row set |
create index completes. |
insert completes. |
ignore_dup_row set |
Index is created but duplicate rows are deleted; error message. |
All rows are inserted except duplicates; error message. |
Table 1-7 shows which index options you can use with the different types of indexes:
Index type |
Options |
---|---|
Clustered |
ignore_dup_row | allow_dup_row |
Unique, clustered |
ignore_dup_key |
Nonclustered |
None |
Unique, nonclustered |
ignore_dup_key |
As an alternative to create index, you can implicitly create unique indexes by specifying a unique constraint with the create table or alter table statement. The unique constraint creates a clustered or nonclustered unique index on the columns of a table. These implicit indexes are named after the constraint, and they follow the same rules for indexes created with create index.
You cannot drop indexes supporting unique constraints using the drop index statement. They are dropped when the constraints are dropped through an alter table statement or when the table is dropped. See create table for more information about unique constraints.
The sorted_data option can reduce the time needed to create an index by skipping the sort step and by eliminating the need to copy the data rows to new pages in certain cases. The speed increase becomes significant on large tables and increases to several times faster in tables larger than 1GB.
If sorted_data is specified, but data is not in sorted order, Adaptive Server displays an error message, and the command fails.
Creating a nonunique, nonclustered index succeeds, unless there are rows with duplicate keys. If there are rows with duplicate keys, Adaptive Server displays an error message, and the command fails.
The effects of sorted_data for creating a clustered index depend on whether the table is partitioned and whether certain other options are used in the create index command. Some options require data copying, if used at all, for nonpartitioned tables and sorts plus data copying for partitioned tables, while others require data copying only if you use:
The ignore_dup_row option
The fillfactor option
The on segmentname clause to specify a segment that is different from the segment where the table data is located
The max_rows_per_page clause to specify a value that is different from the value associated with the table
Table 1-8 shows when the sort is required and when the table is copied for partitioned and nonpartitioned tables.
Options |
Partitioned table |
Unpartitioned table |
---|---|---|
No options specified |
Parallel sort necessary only for creating a clustered index on a round-robin partitioned table; copies data, distributing evenly on partitions; creates index tree. |
Either parallel or nonparallel sort; copies data, creates index tree. |
with sorted_data only or with sorted_data on same_segment |
Creates index tree only. Does not perform the sort or copy data. Does not run in parallel. |
Creates index tree only. Does not perform the sort or copy data. Does not run in parallel. |
with sorted_data and ignore_dup_row or fillfactor or on other_segment or max_rows_per_page |
Parallel sort; copies data, distributing evenly on partitions; creates index tree. |
Copies data and creates the index tree. Does not perform the sort. Does not run in parallel. |
Use the with statistics clause to specify the number of steps for a histogram for the leading column of an index. Histograms are used during query optimization to determine the number of rows that match search arguments for a column.
To re-create an index without updating the values in sysstatistics for a column, use 0 for the number of steps. This avoids overwriting statistics that have been changed with optdiag.
If you specify the histogram tuning factor parameter with a value, then create index uses anywhere between 20 and M*20 steps, depending on the number of frequency cells that have been isolated. The default is 20, but you can specify a different number with the using step values option.
fillfactor, max_rows_per_page, and reservepagegap help manage space on index pages in different ways:
fillfactor applies to indexes for all locking schemes. For clustered indexes on allpages-locked tables, it affects the data pages of the table. On all other indexes, it affects the leaf level of the index.
max_rows_per_page applies only to index pages of allpages-locked tables.
reservepagegap applies to tables and indexes for all locking schemes.
reservepagegap affects space usage in indexes when:
The index is created.
reorg commands on indexes are executed.
Nonclustered indexes are rebuilt after creating a clustered index.
When a reservepagegap value is specified in a create clustered index command, it applies to:
The data and index pages of allpages-locked tables
Only the index pages of data-only-locked tables
The num_pages value specifies a ratio of filled pages to empty pages on the leaf level of the index so that indexes can allocate space close to existing pages, as new space is required. For example, a reservepagegap of 10 leaves 1 empty page for each 9 used pages.
reservepagegap specified along with create clustered index on an allpages-locked table overwrites any value previously specified with create table or alter table.
You can change the space management properties for an index with sp_chgattribute. Changing properties with sp_chgattribute does not immediately affect storage for indexes on the table. Future large scale allocations, such as reorg rebuild, use the sp_chgattribute value.
The fillfactor value set by sp_chgattribute is stored in the fill_factor column in sysindexes. The fillfactor is applied when an index is re-created as a result of an alter table...lock command or a reorg rebuild command.
Table 1-9 shows the index options supported for allpages-locked and data-only-locked tables. On data-only-locked tables, the ignore_dup_row and allow_dup_row options are enforced during create index, but are not enforced during insert and update operations. Data-only-locked tables always allow the insertion of duplicate rows.
Index type |
Allpages-locked table |
Data-only-locked table |
|
---|---|---|---|
During index creation |
During inserts |
||
Clustered |
allow_dup_row, ignore_dup_row |
allow_dup_row, ignore_dup_row |
allow_dup_row |
Unique clustered |
ignore_dup_key |
ignore_dup_key |
ignore_dup_key |
Nonclustered |
None |
None |
None |
Unique nonclustered |
ignore_dup_key |
ignore_dup_key |
ignore_dup_key |
Table 1-10 shows the behavior of commands that attempt to insert duplicate rows into tables with clustered indexes, and when the clustered indexes are dropped and re-created.
Options |
Allpages-locked table |
Data-only-locked table |
---|---|---|
No options specified |
Insert fails with error message 2615. Re-creating the index succeeds. |
Insert succeeds. Re-creating the index fails with error message 1508. |
allow_dup_row |
Insert and re-creating the index succeed. |
Insert and re-creating the index succeed. |
ignore_dup_row |
Insert fails with “Duplicate row was ignored” message. Re-creating the index succeeds. |
Insert succeeds. Re-creating the index deletes duplicate rows. |
You can use the sorted_data option to create index only immediately following a bulk copy operation into an empty table. Once data modifications to that table cause additional page allocations, you cannot use the sorted_data option.
Specifying different values for space management properties may override the sort suppression functionality of the sorted_data.
Each index—including composite indexes—is represented by one row in sysindexes.
For information about the order of the data retrieved through indexes and the effects of an Adaptive Server installed sort order, see the order by clause.
For information about a table’s indexes, execute sp_helpindex. For information about index partitions, you can also execute sp_helpartitions.
Each index partition and data partition is represented by one row in syspartitions.
You can use materialized computed columns as index keys, as though they were regular columns.
To convert a virtual column to a materialized column and index it, use alter table modify with the materialized option before executing create index.
A computed column need not be deterministic to be used as an index key; however, you must be careful about the possible impact of a nondeterministic column on the queries that reference it.
A local index inherits the partition strategies, partition columns, and partition bounds (for range and list partitions) of the base table.
Adaptive Server maintains local indexes, rebuilding the local index if the base table is repartitioned with a different partition key.
Adaptive Server supports:
Index type |
Table type |
---|---|
Local clustered and nonclustered partitioned indexes |
Partitioned tables |
Global, clustered, unpartitioned indexes |
Round-robin partitioned tables |
Global, nonclustered, unpartitioned indexes |
All partitioned tables |
For range-, hash-, and list-partitioned tables, clustered indexes are always local. Adaptive Server creates a local clustered index whether or not “local index” is included in the syntax.
You can create indexes directly on expressions.
The expression must be deterministic.
Because Adaptive Server does not verify the deterministic property of the expression index key, the user is responsible for maintaining the property. A change in this property can cause unexpected results.
As a function-based index key must be deterministic, its result is preevaluated, and reused without reevaluation. Adaptive Server assumes all function-based index keys to be deterministic and uses their preevaluated values when they are referenced in a query; they are reevaluated only when the values of their base columns are changed.
An index can have multiple function-based index keys or a combination of function-based index keys and regular columns.
Expressions used as index keys must be deterministic. An expression key is different from a computed column index key, which needs to be evaluated only once, and does not require the deterministic property. An expression, however, must be reevaluated upon each occurrence of the expression in a specified query, and must always return the same result.
If a user-defined function that is referenced by a function-based index is dropped or becomes invalid, any operations that call that function fail.
Adaptive Server does not support clustered function-based indexes.
You cannot create a function-based index with the sorted_data option.
Once you create an index key on an expression, subsequent queries recognize the expression as an index key only if the expression is exactly the same as the expression used to create the index key.
All insert, delete, and update operations on base columns cause Adaptive Server to update the value of function-based index keys automatically.
ANSI SQL – Compliance level: Transact-SQL extension.
create index permission defaults to the table owner and is not transferable.
Values in event and extrainfo columns of sysaudits are:
Event |
Audit option |
Command or access audited |
Information in extrainfo |
---|---|---|---|
104 |
create |
create index |
|
Commands alter table, create table, drop index, insert, order by clause, set, update
System procedures sp_addsegment, sp_chgattribute, sp_helpcomputedcolumn, sp_helpindex, sp_helpsegment, sp_spaceused