SYSCAT.INDEXES catalog view
Each row represents an index. Indexes on typed tables are represented by two rows: one for the "logical index" on the typed table, and one for the "H-index" on the hierarchy table.
Column Name | Data Type | Nullable | Description |
---|---|---|---|
INDSCHEMA | VARCHAR (128) | Schema name of the index. | |
INDNAME | VARCHAR (128) | Unqualified name of the index. | |
OWNER | VARCHAR (128) | Authorization ID of the owner of the index. | |
OWNERTYPE | CHAR (1) |
|
|
TABSCHEMA | VARCHAR (128) | Schema name of the table or nickname on which the index is defined. | |
TABNAME | VARCHAR (128) | Unqualified name of the table or nickname on which the index is defined. | |
COLNAMES | VARCHAR (640) | This column is no longer used and will be removed in the next release. Use SYSCAT.INDEXCOLUSE for this information. | |
UNIQUERULE | CHAR (1) | Unique rule.
|
|
MADE_UNIQUE | CHAR (1) |
|
|
COLCOUNT | SMALLINT | Number of columns in the key, plus the number of include columns, if any. | |
UNIQUE_COLCOUNT | SMALLINT | Number of columns required for a unique key. It is always <= COLCOUNT, and < COLCOUNT only if there are include columns; -1 if the index has no unique key (that is, it permits duplicates). | |
INDEXTYPE5 | CHAR (4) | Type of index.
|
|
ENTRYTYPE | CHAR (1) |
|
|
PCTFREE | SMALLINT | Percentage of each index page to be reserved during the initial building of the index. This space is available for data insertions after the index has been built. | |
IID | SMALLINT | Identifier for the index. | |
NLEAF | BIGINT | Number of leaf pages; -1 if statistics are not collected. | |
NLEVELS | SMALLINT | Number of index levels; -1 if statistics are not collected. | |
FIRSTKEYCARD | BIGINT | Number of distinct first-key values; -1 if statistics are not collected. | |
FIRST2KEYCARD | BIGINT | Number of distinct keys using the first two columns of the index; -1 if statistics are not collected, or if not applicable. | |
FIRST3KEYCARD | BIGINT | Number of distinct keys using the first three columns of the index; -1 if statistics are not collected, or if not applicable. | |
FIRST4KEYCARD | BIGINT | Number of distinct keys using the first four columns of the index; -1 if statistics are not collected, or if not applicable. | |
FULLKEYCARD | BIGINT | Number of distinct full-key values; -1 if statistics are not collected. | |
DBPARTITION_FIRSTKEYCARD | BIGINT | Reserved for future use. | |
DBPARTITION_FIRST2KEYCARD | BIGINT | Reserved for future use. | |
DBPARTITION_FIRST3KEYCARD | BIGINT | Reserved for future use. | |
DBPARTITION_FIRST4KEYCARD | BIGINT | Reserved for future use. | |
DBPARTITION_FULLKEYCARD | BIGINT | Reserved for future use. | |
CLUSTERRATIO3 | SMALLINT | Degree of data clustering with the index; -1 if statistics are not collected or if detailed index statistics are collected (in which case, CLUSTERFACTOR will be used instead). | |
CLUSTERFACTOR3 | DOUBLE | Finer measurement of the degree of clustering; -1 if statistics are not collected or if the index is defined on a nickname. | |
SEQUENTIAL_PAGES | BIGINT | Number of leaf pages located on disk in index key order with few or no large gaps between them; -1 if statistics are not collected. | |
DENSITY | INTEGER | Ratio of SEQUENTIAL_PAGES to number of pages in the range of pages occupied by the index, expressed as a percent (integer between 0 and 100); -1 if statistics are not collected. | |
USER_DEFINED | SMALLINT | 1 if this index was defined by a user and has not been dropped; 0 otherwise. | |
SYSTEM_REQUIRED | SMALLINT |
|
|
CREATE_TIME | TIMESTAMP | Time when the index was created. | |
STATS_TIME | TIMESTAMP | Y | Last time that any change was made to the recorded statistics for this index. The null value if no statistics are available. |
PAGE_FETCH_PAIRS3 | VARCHAR (520) | A list of pairs of integers, represented in character form. Each pair represents the number of pages in a hypothetical buffer, and the number of page fetches required to scan the table with this index using that hypothetical buffer. Zero-length string if no data is available. | |
MINPCTUSED | SMALLINT | A non-zero integer value indicates that the index is enabled for online defragmentation, and represents the minimum percentage of used space on a page before a page merge can be attempted. A zero value indicates that no page merge is attempted. | |
REVERSE_SCANS | CHAR (1) |
|
|
INTERNAL_FORMAT | SMALLINT | Possible values are:
|
|
COMPRESSION | CHAR (1) | Specifies whether index compression is activated
|
|
IESCHEMA | VARCHAR (128) | Y | Schema name of the index extension. The null value for ordinary indexes. |
IENAME | VARCHAR (128) | Y | Unqualified name of the index extension. The null value for ordinary indexes. |
IEARGUMENTS | CLOB (64K) | Y | External information of the parameter specified when the index is created. The null value for ordinary indexes. |
INDEX_OBJECTID | INTEGER | Identifier for the index object. | |
NUMRIDS | BIGINT | Total number of row identifiers (RIDs) or block identifiers (BIDs) in the index; -1 if not known. | |
NUMRIDS_DELETED | BIGINT | Total number of row identifiers (or block identifiers) in the index that are marked deleted, excluding those identifiers on leaf pages on which all the identifiers are marked deleted. | |
NUM_EMPTY_LEAFS | BIGINT | Total number of index leaf pages that have all of their row identifiers (or block identifiers) marked deleted. | |
AVERAGE_RANDOM_FETCH_ PAGES1,2 | DOUBLE | Average number of random table pages between sequential page accesses when fetching using the index; -1 if not known. | |
AVERAGE_RANDOM_PAGES2 | DOUBLE | Average number of random table pages between sequential page accesses; -1 if not known. | |
AVERAGE_SEQUENCE_GAP2 | DOUBLE | Gap between index page sequences. Detected through a scan of index leaf pages, each gap represents the average number of index pages that must be randomly fetched between sequences of index pages; -1 if not known. | |
AVERAGE_SEQUENCE_FETCH_ GAP1,2 | DOUBLE | Gap between table page sequences when fetching using the index. Detected through a scan of index leaf pages, each gap represents the average number of table pages that must be randomly fetched between sequences of table pages; -1 if not known. | |
AVERAGE_SEQUENCE_PAGES2 | DOUBLE | Average number of index pages that are accessible in sequence (that is, the number of index pages that the prefetchers would detect as being in sequence); -1 if not known. | |
AVERAGE_SEQUENCE_FETCH_ PAGES1,2 | DOUBLE | Average number of table pages that are accessible in sequence (that is, the number of table pages that the prefetchers would detect as being in sequence) when fetching using the index; -1 if not known. | |
TBSPACEID | INTEGER | Identifier for the index table space. | |
LEVEL2PCTFREE | SMALLINT | Percentage of each index level 2 page to be reserved during initial building of the index. This space is available for future inserts after the index has been built. | |
PAGESPLIT | CHAR (1) | Index page split behavior.
|
|
AVGPARTITION_ CLUSTERRATIO3 | SMALLINT | Degree of data clustering within a single data partition. -1 if the table is not partitioned, if statistics are not collected, or if detailed statistics are collected (in which case AVGPARTITION_ CLUSTERFACTOR will be used instead). | |
AVGPARTITION_ CLUSTERFACTOR3 | DOUBLE | Finer measurement of the degree of clustering within a single data partition. -1 if the table is not partitioned, if statistics are not collected, or if the index is defined on a nickname. | |
AVGPARTITION_PAGE_FETCH_ PAIRS3 | VARCHAR (520) | A list of paired integers in character form. Each pair represents a potential buffer pool size and the corresponding page fetches required to access a single data partition from the table. Zero-length string if no data is available, or if the table is not partitioned. | |
PCTPAGESSAVED | SMALLINT | Approximate percentage of pages saved in the index as a result of index compression. -1 if statistics are not collected. | |
DATAPARTITION_CLUSTERFACTOR | DOUBLE | A statistic measuring the "clustering" of the index keys with regard to data partitions. It is a number between 0 and 1, with 1 representing perfect clustering and 0 representing no clustering. | |
INDCARD | BIGINT | Cardinality of the index. This might be different from the cardinality of the table for indexes that do not have a one-to-one relationship between the table rows and the index entries. | |
AVGLEAFKEYSIZE | INTEGER | Average index key size for keys on leaf pages in the index. | |
AVGNLEAFKEYSIZE | INTEGER | Average index key size for keys on non-leaf pages in the index. | |
OS_PTR_SIZE | INTEGER | Platform word size with which the index was created.
|
|
COLLECTSTATISTCS | CHAR (1) | Specifies how statistics were collected at index creation
time.
|
|
DEFINER4 | VARCHAR (128) | Authorization ID of the owner of the index. | |
LASTUSED | DATE | Date when the index was last used by any DML statement to perform a scan, or used to enforce referential integrity constraints. This column is not updated when the index is used on an HADR standby database, nor is it updated when rows are inserted into the table on which the index is defined. The default value is '0001-01-01'. This value is updated asynchronously not more than once within a 24 hour period and might not reflect usage within the last 15 minutes. | |
PERIODNAME | VARCHAR(128) | Y | Name of the period used to define this index. |
PERIODPOLICY | CHAR (1) | If a period name was specified, the index uses this period
policy.
|
|
MADE_WITHOUTOVERLAPS | CHAR (1) |
|
|
NULLKEYS | CHAR (1) |
|
|
FUNC_PATH | CLOB (2K) | Y | SQL path in effect when the index was defined with an expression in the key. The null value if the key does not include any expressions. |
VIEWSCHEMA | VARCHAR(128) | Y | Schema name of the statistical view associated with the index key, if the key includes at least one expression. The null value if there are no expressions in the key. |
VIEWNAME | VARCHAR(128) | Y | Unqualified name of the statistical view associated with the index key, if the key includes at least one expression. The null value if there are no expressions in the key. |
ENVSTRINGUNITS | VARCHAR (11) | Default string units when the object was created. | |
REMARKS | VARCHAR (254) | Y | User-provided comments, or the null value. |
Note:
Statistics for the partitioned index represent a single partition, except for FIRSTKEYCARD, FIRST2KEYCARD, FIRST3KEYCARD, FIRST4KEYCARD, and FULLKEYCARD statistics. Because these statistics are used in cardinality estimates, they are for the entire index and not for an index partition. |