Oracle8i SQL Reference Release 2 (8.1.6) A76989-01 |
|
SQL Statements (continued), 9 of 20
global_partition_clause::=
on_range_partitioned_table_clause::=
segment_attributes_clause::=
on_hash_partitioned_table_clause::=
on_composite_partitioned_table_clause::=
storage_clause: See "storage_clause".
To create an index on
To create a domain index, which is an instance of an application-specific index of type indextype.
An index is a schema object that contains an entry for each value that appears in the indexed column(s) of the table or cluster and provides direct, fast access to rows. A partitioned index consists of partitions containing an entry for each value that appears in the indexed column(s) of the table. A function-based index is an index on expressions. It enables you to construct queries that evaluate the value returned by an expression, which in turn may include functions (built-in or user-defined).
For a discussion of indexes, see Oracle8i Concepts. For information on modifying an index, see "ALTER INDEX".
To create an index in your own schema, one of the following conditions must be true:
INDEX
privilege on the table to be indexed.
CREATE
ANY
INDEX
system privilege.
To create an index in another schema, you must have CREATE
ANY
INDEX
system privilege. Also, the owner of the schema to contain the index must have either space quota on the tablespaces to contain the index or index partitions, or UNLIMITED
TABLESPACE
system privilege.
To create a domain index in your own schema, you must also have EXECUTE
privilege on the indextype. If you are creating a domain index in another user's schema, the index owner also must have EXECUTE
privilege on the indextype and its underlying implementation type. Before creating a domain index, you should first define the indextype. See "CREATE INDEXTYPE".
To create a function-based index in your own schema on your own table, you must have the QUERY REWRITE
system privilege. To create the index in another schema or on another schema's table, you must have the GLOBAL
QUERY
REWRITE
privilege. The table owner must also have the EXECUTE
object privilege on the function(s) used in the function-based index.
|
specifies that the value of the column (or columns) upon which the index is based must be unique. If the index is local nonprefixed (see local_index_clause below), then the index key must contain the partitioning key. |
|
|
Oracle recommends that you do not explicitly define See Also: The "constraint_clause". |
|
|
Restrictions: |
|
|
specifies that index is to be created as a bitmap, rather than as a B-tree. Bitmap indexes store the rowids associated with a key value as a bitmap. Each bit in the bitmap corresponds to a possible rowid, and if the bit is set, it means that the row with the corresponding rowid contains the key value. The internal representation of bitmaps is best suited for applications with low levels of concurrent transactions, such as data warehousing. See Oracle8i Concepts and Oracle8i Designing and Tuning for Performance for more information about using bitmap indexes. Restrictions: |
|
schema |
is the schema to contain the index. If you omit schema, Oracle creates the index in your own schema. |
|
index |
is the name of the index to be created. An index can contain several partitions. |
|
cluster_index_clause |
specifies the cluster for which a cluster index is to be created. If you do not qualify cluster with schema, Oracle assumes the cluster is in your current schema. You cannot create a cluster index for a hash cluster. See Also: "CREATE CLUSTER". |
|
table_index_clause |
specifies table (and its attributes) on which you are defining the index. If you do not qualify table with schema, Oracle assumes the table is contained in your own schema. |
|
|
You create an index on a nested table column by creating the index on the nested table storage table. Include the |
|
|
Restrictions: |
|
|
See Also: "CREATE TABLE" and Oracle8i Concepts for more information on temporary tables. |
|
t_alias |
specifies a correlation name (alias) for the table upon which you are building the index. |
|
|
Note: This alias is required if the index_expression_list references any object type attributes or object type methods. See "Function-based Index on Type Method Example". |
|
index_expr_list |
lets you specify the column or column expression upon which the index is based. |
|
column |
is the name of a column in the table. A bitmap index can have a maximum of 30 columns. Other indexes can have as many as 32 columns.
Restriction: You cannot create an index on columns or attributes whose type is user-defined, |
|
|
You can create an index on a scalar object attribute column or on the system-defined |
|
|
is an expression built from columns of table, constants, SQL functions, and user-defined functions. When you specify column_expression, you create a function-based index.
Name resolution of the function is based on the schema of the index creator. User-defined functions used in column_expression are fully name resolved during the |
|
|
After creating a function-based index, collect statistics on both the index and its base table using the |
|
|
Notes on function-based indexes:
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
Restrictions on function-based indexes:
See Also: "CREATE FUNCTION" and PL/SQL User's Guide and Reference. |
|
|
specifies whether the index should be created in ascending or descending order. Indexes on character data are created in ascending or descending order of the character values in the database character set.
Oracle treats descending indexes as if they were function-based indexes. You do not need the
Restriction: You cannot specify either of these clauses for a domain index. You cannot specify |
|
index_attributes |
||
physical_attributes_clause |
establishes values for physical and storage characteristics for the index. See "CREATE TABLE".
Restriction: You cannot specify the |
|
|
|
is the percentage of space to leave free for updates and insertions within each of the index's data blocks. |
|
storage_clause |
establishes the storage characteristics for the index. See the "storage_clause". |
|
is the name of the tablespace to hold the index, index partition, or index subpartition. If you omit this clause, Oracle creates the index in the default tablespace of the owner of the schema containing the index. |
|
|
For a local index, you can specify the keyword |
|
|
enables key compression, which eliminates repeated occurrence of key column values and may substantially reduce storage. Use integer to specify the prefix length (number of prefix columns to compress).
|
|
|
Oracle compresses only nonpartitioned indexes that are nonunique or unique indexes of at least two columns.
Restriction: You cannot specify |
|
|
disables key compression. This is the default. |
|
|
indicates to Oracle that the rows are stored in the database in ascending order, so that Oracle does not have to sort the rows when creating the index. If the rows of the indexed column or columns are not stored in ascending order, Oracle returns an error. For greatest savings of sort time and space, use this clause immediately after the initial load of rows into a table. Restrictions: |
|
|
stores the bytes of the index block in reverse order, excluding the rowid. You cannot specify |
|
|
You cannot reverse a bitmap index or an index-organized table. |
|
|
specifies that the creation of the index will be logged ( |
|
|
If index is nonpartitioned, this is the logging attribute of the index. |
|
|
If index is partitioned, the logging attribute specified is
|
|
|
In |
|
|
If the database is run in |
|
|
The logging attribute of the index is independent of that of its base table. |
|
|
If you omit this clause, the logging attribute is that of the tablespace in which it resides. |
|
|
See Also: Oracle8i Concepts and Oracle8i Parallel Server Concepts for more information about logging and parallel DML. |
|
|
specifies that DML operations on the table will be allowed during creation of the index. For a description of online index building and rebuilding, see Oracle8i Concepts.
Restriction: Parallel DML is not supported during online index building. If you specify |
|
|
enables you to collect statistics at relatively little cost during the creation of an index. These statistics are stored in the data dictionary for ongoing use by the optimizer in choosing a plan of execution for SQL statements. The types of statistics collected depend on the type of index you are creating. |
|
|
Note: If you create an index using another index (instead of a table), the original index might not provide adequate statistical information. Therefore, Oracle generally uses the base table to compute the statistics, which will improve the statistics but may negatively affect performance. |
|
|
Additional methods of collecting statistics are available in PL/SQL packages and procedures. |
|
global_index_clause |
specifies that the partitioning of the index is user defined and is not equipartitioned with the underlying table. By default, nonpartitioned indexes are global indexes. |
|
|
|
specifies that the global index is partitioned on the ranges of values from the columns specified in column_list. You cannot specify this clause for a local index. |
|
(column_list) |
is the name of the column(s) of a table on which the index is partitioned. The column_list must specify a left prefix of the index column list. |
|
|
You cannot specify more than 32 columns in column_list, and the columns cannot contain the |
|
|
Note: If your enterprise has or will have databases using different character sets, use caution when partitioning on character columns. The sort sequence of characters is not identical in all character sets. See Also: Oracle8i National Language Support Guide for more information on character set support. |
|
|
describes the individual partitions. The number of clauses determines the number of partitions. If you omit partition, Oracle generates a name with the form |
|
|
specifies the (noninclusive) upper bound for the current partition in a global index. The value_list is a comma-separated, ordered list of literal values corresponding to column_list in the partition_by_range_clause. Always specify |
|
|
Note: If index is partitioned on a See Also:
|
|
|
Restriction: You cannot specify this clause for a local index. |
local_index_clauses |
specify that the index is partitioned on the same columns, with the same number of partitions and the same partition bounds as table. Oracle automatically maintains |
|
|
on_range_partitioned_table_clause |
describes an index on a range-partitioned table. |
|
|
describes the individual partitions. The number of clauses determines the number of partitions. For a local index, the number of index partitions must be equal to the number of the table partitions, and in the same order.
If you omit partition, Oracle generates a name that is consistent with the corresponding table partition. If the name conflicts with an existing index partition name, the form |
|
on_hash_partitioned_table_clause |
describes an index on a hash-partitioned table. If you do not specify partition, Oracle uses the name of the corresponding base table partition, unless it conflicts with an explicitly specified name of another index partition. In this case, Oracle generates a name of the form
You can optionally specify |
|
on_composite_partitioned_table_clause |
describes an index on a composite-partitioned table. The first
If you do not specify |
|
|
lets you specify how index hash partitions (for a hash-partitioned index) or index subpartitions (for a composite-partitioned index) are to be distributed across various tablespaces. The number of tablespaces does not have to equal the number of index partitions. If the number of index partitions is greater than the number of tablespaces, Oracle cycles through the names of the tablespaces. |
|
|
is valid only for a local index on a hash or composite-partitioned table. This clause overrides any tablespace specified at the index level for a partition or subpartition, and stores the index partition or subpartition in the same partition as the corresponding table partition or subpartition. |
|
index_subpartition_clause |
specifies one or more tablespaces in which to store all subpartitions in partition or one or more individual subpartitions in partition. The subpartition inherits all other attributes from partition. Attributes not specified for partition are inherited from index. |
domain_index_clause |
specifies that index is a domain index. Restrictions:
|
|
|
column |
specifies the table columns or object attributes on which the index is defined. Each column can have only one domain index defined on it. Restrictions: |
|
indextype |
specifies the name of the indextype. This name should be a valid schema object that you have already defined. See "CREATE INDEXTYPE". |
|
|
specifies the parameter string that is passed uninterpreted to the appropriate indextype routine. The maximum length of the parameter string is 1000 characters.
Once the domain index is created, Oracle invokes this routine (see Oracle8i Data Cartridge Developer's Guide for information on these routines.) If the routine does not return successfully, the domain index is marked |
parallel_clause |
causes creation of the index to be parallelized. For additional information, see the Notes to the parallel_clause of "CREATE TABLE". |
|
|
|
specifies serial execution. This is the default. |
|
|
causes Oracle to select a degree of parallelism equal to the number of CPUs available on all participating instances times the value of the |
|
|
specifies the degree of parallelism, which is the number of parallel threads used in the parallel operation. Each parallel thread may use one or two parallel execution servers. Normally Oracle calculates the optimum degree of parallelism, so it is not necessary for you to specify integer. |
The following statement creates an index using 10 parallel execution servers, 5 to scan SCOTT.EMP
and another 5 to populate the EMP_IDX
index:
CREATE INDEX emp_idx ON scott.emp (ename) PARALLEL 5;
To create an index with the COMPRESS
clause, you might issue the following statement:
CREATE INDEX emp_idx2 ON emp(job, ename) COMPRESS 1;
The index will compress repeated occurrences of JOB
column values.
To quickly create an index in parallel on a table that was created using a fast parallel load (so all rows are already sorted), you might issue the following statement. (Oracle will choose the appropriate degree of parallelism.)
CREATE INDEX i_loc ON big_table (akey) NOSORT NOLOGGING PARALLEL;
To create an index for the EMPLOYEE
cluster, issue the following statement:
CREATE INDEX ic_emp ON CLUSTER employee;
No index columns are specified, because the index is automatically built on all the columns of the cluster key. For cluster indexes, all rows are indexed.
Consider the following statement:
SELECT ename FROM emp WHERE comm IS NULL;
The above query does not use an index created on the COMM
column unless it is a bitmap index.
The following statements creates a function-based index on the EMP
table based on an uppercase evaluation of the ENAME
column:
CREATE INDEX emp_i ON emp (UPPER(ename));
To ensure that Oracle will use the index rather than performing a full table scan, be sure that the value of the function is not null in subsequent queries. For example, the statement
SELECT * FROM emp WHERE UPPER(ename) IS NOT NULL ORDER BY UPPER(ename);
is guaranteed to use the index, but without the WHERE
clause, Oracle may perform a full table scan.
In the next statements showing index creation and subsequent query, Oracle will use index EMP_FI
even though the columns are in reverse order in the query:
CREATE INDEX emp_fi ON emp(cola + colb); SELECT * FROM emp WHERE colb + cola > 500;
This example entails an object type RECTANGLE
containing two number attributes: length and width. The AREA()
method computes the area of the rectangle.
CREATE TYPE rectangle AS OBJECT ( length NUMBER, width NUMBER, MEMBER FUNCTION area RETURN NUMBER DETERMINISTIC ); CREATE OR REPLACE TYPE BODY rectangle AS MEMBER FUNCTION area RETURN NUMBER IS BEGIN RETURN (length*width); END; END;
Now, if you create a table RECTAB
of type RECTANGLE
, you can create a function-based index on the AREA()
method as follows:
CREATE TABLE recttab OF rectangle; CREATE INDEX area_idx ON recttab x (x.area());
You can use this index efficiently to evaluate a query of the form:
SELECT * FROM recttab x WHERE x.area() > 100;
The following statement collects statistics on the nonpartitioned EMP_INDX
index:
CREATE INDEX emp_indx ON emp(empno) COMPUTE STATISTICS;
The type of statistics collected depends on the type of index you are creating.
The following statement creates a global prefixed index STOCK_IX
on table STOCK_XACTIONS
with two partitions, one for each half of the alphabet. The index partition names are system generated:
CREATE INDEX stock_ix ON stock_xactions (stock_symbol, stock_series) GLOBAL PARTITION BY RANGE (stock_symbol) (PARTITION VALUES LESS THAN ('N') TABLESPACE ts3, PARTITION VALUES LESS THAN (MAXVALUE) TABLESPACE ts4);
This statement creates a local index on the ITEM
column of the SALES
table. The STORE IN
clause immediately following LOCAL
indicates that SALES
is hash partitioned. Oracle will distribute the hash partitions between the TBS1
and TBS2
tablespaces:
CREATE INDEX sales_idx ON sales(item) LOCAL STORE IN (tbs1, tbs2);
This statement creates a local index on the SALES table, which is composite-partitioned. The STORAGE
clause specifies default storage attributes for the index. The STORE IN
clause specifies one or more default tablespaces for the index subpartitions. However, this default is overridden for the four subpartitions of partition Q3_1997
, because separate TABLESPACE
is specified.
CREATE INDEX sales_idx ON sales(sale_date, item) STORAGE (INITIAL 1M, MAXEXTENTS UNLIMITED) LOCAL STORE IN (tbs1, tbs2, tbs3, tbs4, tbs5) (PARTITION q1_1997, PARTITION q2_1997, PARTITION q3_1997 (SUBPARTITION q3_1997_s1 TABLESPACE ts2, SUBPARTITION q3_1997_s2 TABLESPACE ts4, SUBPARTITION q3_1997_s3 TABLESPACE ts6, SUBPARTITION q3_1997_s4 TABLESPACE ts8), PARTITION q4_1997, PARTITION q1_1998);
To create a bitmap partitioned index on a table with four partitions, issue the following statement:
CREATE BITMAP INDEX partno_ixON lineitem(partno) TABLESPACE ts1 LOCAL (PARTITION quarter1 TABLESPACE ts2, PARTITION quarter2 STORAGE (INITIAL 10K NEXT 2K), PARTITION quarter3 TABLESPACE ts2, PARTITION quarter4);
In the following example, UNIQUE
index UNIQ_PROJ_INDX
is created on storage table NESTED_PROJECT_TABLE
. Including pseudocolumn NESTED_TABLE_ID
ensures distinct rows in nested table column PROJS_MANAGED
:
CREATE TYPE proj_type AS OBJECT (proj_num NUMBER, proj_name VARCHAR2(20)); CREATE TYPE proj_table_type AS TABLE OF proj_type; CREATE TABLE employee ( emp_num NUMBER, emp_name CHAR(31), projs_managed proj_table_type ) NESTED TABLE projs_managed STORE AS nested_project_table; CREATE UNIQUE INDEX uniq_proj_indx ON nested_project_table ( NESTED_TABLE_ID, proj_num);
|
![]() Copyright © 1999 Oracle Corporation. All Rights Reserved. |
|