Firebird 2.5 Language Reference → Firebird 2.5 Language Reference → Data Definition (DDL) Statements → INDEX |
Table of Contents
An index is a database object used for faster data retrieval from a table or for speeding up the sorting of query. Indexes are used also to enforce the refererential integrity constraints PRIMARY KEY, FOREIGN KEY and UNIQUE.
This section describes how to create indexes, activate and deactivate them, delete them and collect statistics (recalculate selectivity) for them.
Table of Contents
Used for: Creating an index for a table
Available in: DSQL, ESQL
Syntax:
CREATE [UNIQUE] [ASC[ENDING] | DESC[ENDING]] INDEX indexname ON tablename {(col [, col …]) | COMPUTED BY (<expression>)};
Table 5.10. CREATE INDEX Statement Parameters
Parameter | Description |
---|---|
indexname | Index name. It may consist of up to 31 characters |
tablename | The name of the table for which the index is to be built |
col | Name of a column in the table. Columns of the types BLOB and ARRAY and computed fields cannot be used in an index |
expression | The expression that will compute the values for a computed index, also known as an “expression index” |
The CREATE INDEX statement creates an index for a table that can be used to speed up searching, sorting and grouping. Indexes are created automatically in the process of defining constraints, such as primary key, foreign key or unique constraints.
An index can be built on the content of columns of any data type except for BLOB and arrays. The name (identifier) of an index must be unique among all index names.
Key Indexes | |
---|---|
When a primary key, foreign key or unique constraint is added to a table or column, an index with the same name is created automatically, without an explicit directive from the designer. For example, the PK_COUNTRY index will be created automatically when you execute and commit the following statement: ALTER TABLE COUNTRY ADD CONSTRAINT PK_COUNTRY PRIMARY KEY (ID);
|
Specifying the keyword UNIQUE in the index creation statement creates an index in which uniqueness will be enforced throughout the table. The index is referred to as a “unique index”. A unique index is not a constraint.
Unique indexes cannot contain duplicate key values (or duplicate key value combinations, in the case of compound, or multi-column, or multi-segment) indexes. Duplicated NULLs are permitted, in accordance with the SQL:99 standard, in both single-segment and multi-segment indexes.
All indexes in Firebird are uni-directional. An index may be constructed from the lowest value to the highest (ascending order) or from the highest value to the lowest (descending order). The keywords ASC[ENDING] and DESC[ENDING] are used to specify the direction of the index. The default index order is ASC[ENDING]. It is quite valid to define both an ascending and a descending index on the same column or key set.
Tip | |
---|---|
A descending index can be useful on a column that will be subjected to searches on the high values (“newest”, maximum, etc.) |
In creating an index, you can use the COMPUTED BY clause to specify an expression instead of one or more columns. Computed indexes are used in queries where the condition in a WHERE, ORDER BY or GROUP BY clause exactly matches the expression in the index definition. The expression in a computed index may involve several columns in the table.
Note | |
---|---|
You can actually create a computed index on a computed field, but the index will never be used. |
Certain limits apply to indexes.
The maximum length of a key in an index is limited to ¼ of the page size.
The number of indexes that can be accommodated for each table is limited. The actual maximum for a specific table depends on the page size and the number of columns in the indexes.
Table 5.11. Maximum Indexes per Table
Page Size | Number of Indexes Depending on Column Count | ||
---|---|---|---|
Single | 2-Column | 3-Column | |
4096 | 203 | 145 | 113 |
8192 | 408 | 291 | 227 |
16384 | 818 | 584 | 454 |
The maximum indexed string length is 9 bytes less than the maximum key length. The maximum indexable string length depends on the page size and the character set.
Table 5.12. Maximum indexable (VAR)CHAR length
Page Size | Maximum Indexable String Length by Charset Type | |||
---|---|---|---|---|
1 byte/char | 2 bytes/char | 3 bytes/char | 4 bytes/char | |
4096 | 1015 | 507 | 338 | 253 |
8192 | 2039 | 1019 | 679 | 509 |
16384 | 4087 | 2043 | 1362 | 1021 |
Only the table owner and administrators have the authority to use CREATE INDEX.
CREATE INDEX IDX_UPDATER ON SALARY_HISTORY (UPDATER_ID);
CREATE DESCENDING INDEX IDX_CHANGE ON SALARY_HISTORY (CHANGE_DATE);
CREATE INDEX IDX_SALESTAT ON SALES (ORDER_STATUS, PAID);
CREATE UNIQUE INDEX UNQ_COUNTRY_NAME ON COUNTRY (NAME);
CREATE INDEX IDX_NAME_UPPER ON PERSONS COMPUTED BY (UPPER (NAME));An index like this can be used for a case-insensitive search:
SELECT * FROM PERSONS WHERE UPPER(NAME) STARTING WITH UPPER('Iv');
See also: ALTER INDEX, DROP INDEX
Table of Contents
Used for: Activating or deactivating an index; rebuilding an index
Available in: DSQL, ESQL
Syntax:
ALTER INDEX indexname {ACTIVE | INACTIVE};
The ALTER INDEX statement activates or deactivates an index. There is no facility on this statement for altering any attributes of the index.
With the INACTIVE option, the index is switched from the active to inactive state. The effect is similar to the DROP INDEX statement except that the index definition remains in the database. Altering a constraint index to the inactive state is not permitted.
An active index can be deactivated if there are no queries using that index; otherwise, an “object in use” error is returned.
Activating an inactive index is also safe. However, if there are active transactions modifying the table, the transaction containing the ALTER INDEX statement will fail if it has the NOWAIT attribute. If the transaction is in WAIT mode, it will wait for completion of concurrent transactions.
On the other side of the coin, if our ALTER INDEX succeeds and starts to rebuild the index at COMMIT, other transactions modifying that table will fail or wait, according to their WAIT/NO WAIT attributes. The situation is exactly the same for CREATE INDEX.
How is it Useful? | |
---|---|
It might be useful to switch an index to the inactive state whilst inserting, updating or deleting a large batch of records in the table that owns the index. |
How is it Useful? | |
---|---|
Even if the index is active when ALTER INDEX ... ACTIVE is executed, the index will be rebuilt. Rebuilding indexes can be a useful piece of houskeeping to do, occasionally, on the indexes of a large table in a database that has frequent inserts, updates or deletes but is infrequently restored. |
Altering the enforcing index of a PRIMARY KEY, FOREIGN KEY or UNIQUE constraint to INACTIVE is not permitted. However, ALTER INDEX ... ACTIVE works just as well with constraint indexes as it does with others, as an index rebuilding tool.
Only the table owner and administrators have the authority to use ALTER INDEX.
ALTER INDEX Examples:
ALTER INDEX IDX_UPDATER INACTIVE;
ALTER INDEX IDX_UPDATER ACTIVE;
See also: CREATE INDEX, DROP INDEX, SET STATISTICS
Used for: Deleting an index
Available in: DSQL, ESQL
Syntax:
DROP INDEX indexname;
The DROP INDEX statement deletes an the named index from the database.
Note | |
---|---|
A constraint index cannot deleted using DROP INDEX. Constraint indexes are dropped during the process of executing the command ALTER TABLE ... DROP CONSTRAINT .... |
Only the table owner and administrators have the authority to use DROP INDEX.
DROP INDEX Example: Deleting the IDX_UPDATER index
DROP INDEX IDX_UPDATER;
See also: CREATE INDEX, ALTER INDEX
Table of Contents
Used for: Recalculating the selectivity of an index
Available in: DSQL, ESQL
Syntax:
SET STATISTICS indexname
The SET STATISTICS statement recalculates the selectivity of the specified index.
The selectivity of an index is the result of evaluating the number of rows that can be selected in a search on every index value. A unique index has the maximum selectivity because it is impossible to select more than one row for each value of an index key if it is used. Keeping the selectivity of an index up to date is important for the optimizer's choices in seeking the most optimal query plan.
Index statistics in Firebird are not automatically recalculated in response to large batches of inserts, updates or deletions. It may be beneficial to recalculate the selectivity of an index after such operations because the selectivity tends to become outdated.
Note | |
---|---|
The statements CREATE INDEX and ALTER INDEX ACTIVE both store index statistics that completely correspond to the contents of the newly-[re]built index. |
The selectivity of an index can be recalculated by the owner of the table or an administrator. It can be performed under concurrent load without risk of corruption. However, be aware that, under concurrent load, the newly calculated statistics could become outdated as soon as SET STATISTICS finishes.
Example Using SET STATISTICS: Recalculating the selectivity of the index IDX_UPDATER
SET STATISTICS INDEX IDX_UPDATER;
See also: CREATE INDEX, ALTER INDEX
Firebird 2.5 Language Reference → Firebird 2.5 Language Reference → Data Definition (DDL) Statements → INDEX |