Oracle8(TM) Server Tuning
Release 8.0

A54638-01

Library

Product

Contents

Index

Prev Next

10
Data Access Methods

This chapter provides an overview of data access methods that can enhance performance, and warns of situations to avoid. You can use hints to force various approaches. Topics in this chapter include:

Using Clusters

Follow these guidelines when deciding whether to cluster tables:

Consider the benefits and drawbacks of clusters with respect to the needs of your application. For example, you may decide that the performance gain for join statements outweighs the performance loss for statements that modify cluster key values. You may want to experiment and compare processing times with your tables both clustered and stored separately. To create a cluster, use the CREATE CLUSTER command.

See Also: For more information on creating clusters, see the Oracle8 Server Application Developer's Guide.

Using Hash Clusters

Hash clusters cluster table data based on the result of applying a hash function to each row's cluster key value. All rows with the same hash key value are stored together on disk. Consider the benefits and drawbacks of hash clusters with respect to the needs of your application. You may want to experiment and compare processing times with a table both stored in a hash cluster and stored alone with an index. This section describes:

When to Use a Hash Cluster

Follow these guidelines for choosing when to use hash clusters:

How to Use a Hash Cluster

To create a hash cluster, use the CREATE CLUSTER command with the HASH and HASHKEYS parameters.

When you create a hash cluster, you must use the HASHKEYS parameter of the CREATE CLUSTER statement to specify the number of hash values for the hash cluster. For best performance of hash scans, choose a HASHKEYS value that is at least as large as the number of cluster key values. Such a value reduces the chance of collisions, or multiple cluster key values resulting in the same hash value. Collisions force Oracle to test the rows in each block for the correct cluster key value after performing a hash scan. Collisions reduce the performance of hash scans.

Oracle always rounds up the HASHKEYS value that you specify to the nearest prime number to obtain the actual number of hash values. This rounding is designed to reduce collisions.

See Also: For more information on creating hash clusters, see the Oracle8 Server Application Developer's Guide.

Using Indexes

This section describes:

When to Create Indexes

Indexes improve the performance of queries that select a small percentage of rows from a table. As a general guideline, you should create indexes on tables that are often queried for less than 2% or 4% of the table's rows. This value may be higher in situations where all data can be retrieved from an index, or where the indexed columns can be used for joining to other tables.

This guideline is based on these assumptions:

If these assumptions do not describe the data in your table and the queries that access it, the percentage of the table's rows selected under which an index is helpful may increase to as much as 25%.

Tuning the Logical Structure

Although cost-based optimization is excellent at avoiding the use of non-selective indexes within query execution, the SQL engine must continue to maintain all indexes defined against a table whether they are ever used or not. Index maintenance presents a significant CPU and I/O resource demand in any I/O intensive application. Put another way, building indexes "just in case" is not a good practice; indexes should not be built until required.

Indexes which are not used should be dropped. If all of the application SQL can be processed through EXPLAIN PLAN and the resulting plans are captured then any indexes which are not referenced in any execution plan can be detected. These indexes are typically, though not necessarily, non-selective.
However, indexes may have uses which are not immediately apparent from a survey of the execution plans of the statements within the application. In particular, Oracle8 uses "pins" (non-transactional locks) on foreign key indexes in order to avoid the need to place share locks on the parent table when enforcing foreign key constraints.

In many applications this foreign key index is never (or rarely) used to support a query. In the example shown there may be no normal requirement to locate all of the order lines for a given product. However when no index exists with LINES(PCODE) as its leading edge then a share lock will be placed on the Products table each time DML is performed against the Lines table. This in turn will only be a problem if the Products table itself is subject to frequent DML and in the example shown we might assume that the column QTY_ON_HAND is volatile, and that the table level share locks would cause severe contention problems.

If this contention starts to occur, then to remove it the application must either

Fortunately this issue does not normally affect traditional master/detail relationships where the foreign key is generally used as the leading edge of the primary key as in the example.

Figure 10-1: Foreign Key Constraint

How to Choose Columns to Index

Follow these guidelines for choosing columns to index:

Note: Oracle implicitly creates indexes on the columns of all unique and primary keys that you define with integrity constraints. These indexes are the most selective and the most effective in optimizing performance.
You can determine the selectivity of an index by dividing the number of rows in the table by the number of distinct indexed values. You can obtain these values using the ANALYZE command. A selectivity calculated in this manner should be interpreted as a percentage.
When choosing whether to index a column, consider whether the performance gain for queries is worth the performance loss for INSERT, UPDATE, and DELETE statements and the use of the space required to store the index. You may want to experiment and compare the processing times of your SQL statements with and without indexes. You can measure processing time with the SQL trace facility.

See Also: Chapter 22, "The SQL Trace Facility and TKPROF"

Oracle8 Server Concepts regarding the effects of foreign keys on locking.

How to Choose Composite Indexes

A composite index contains more than one column. Composite indexes can provide additional advantages over single-column indexes:

better selectivity  

Sometimes two or more columns, each with poor selectivity, can be combined in a composite index with good selectivity.  

additional data storage  

If all the columns selected by a query are in a composite index, Oracle can return these values from the index without accessing the table.  

A SQL statement can use an access path involving a composite index if the statement contains constructs that use a leading portion of the index. A leading portion of an index is a set of one or more columns that were specified first and consecutively in the list of columns in the CREATE INDEX statement that created the index. Consider this CREATE INDEX statement:

CREATE INDEX comp_ind
ON tab1(x, y, z);

These combinations of columns are leading portions of the index: X, XY, and XYZ. These combinations of columns are not leading portions of the index: YZ and Z.

Follow these guidelines for choosing columns for composite indexes:

Of course, consider the guidelines associated with the general performance advantages and trade-offs of indexes described in the previous sections. Follow these guidelines for ordering columns in composite indexes:

How to Write Statements that Use Indexes

After you create an index, the optimizer cannot use an access path that uses the index simply because the index exists. The optimizer can only choose such an access path for a SQL statement if it contains a construct that makes the access path available.

To be sure that a SQL statement can use an access path that uses an index, be sure the statement contains a construct that makes such an access path available. If you are using the cost-based approach, you should also generate statistics for the index. Once you have made the access path available for the statement, the optimizer may or may not choose to use the access path, based on the availability of other access paths.

If you create new indexes to tune statements, you can also use the EXPLAIN PLAN command to determine whether the optimizer will choose to use these indexes when the application is run. If you create new indexes to tune a statement that is currently parsed, Oracle invalidates the statement. When the statement is next executed, the optimizer automatically chooses a new execution plan that could potentially use the new index. If you create new indexes on a remote database to tune a distributed statement, the optimizer considers these indexes when the statement is next parsed.

Also keep in mind that the means you use to tune one statement may affect the optimizer's choice of execution plans for others. For example, if you create an index to be used by one statement, the optimizer may choose to use that index for other statements in your application as well. For this reason, you should re-examine your application's performance and rerun the SQL trace facility after you have tuned those statements that you initially identified for tuning.

How to Write Statements that Avoid Using Indexes

In some cases, you may want to prevent a SQL statement from using an access path that uses an existing index. You may want to do this if you know that the index is not very selective and that a full table scan would be more efficient. If the statement contains a construct that makes such an index access path available, you can force the optimizer to use a full table scan through one of these methods:

Since the behavior of the optimizer may change in future versions of Oracle, relying on methods such as the first to choose access paths may not be a good long-range plan. Instead, use hints to suggest specific access paths to the optimizer.

Assessing the Value of Indexes

A brute force way to determine whether an index is good is to create it, analyze it, and use EXPLAIN PLAN on your query to see if the optimizer uses it. If it does, keep the index unless it is very expensive to maintain. This, however, is very time and resource expensive. You can also assess the value of the index by comparing the optimizer cost (in the first row of EXPLAIN PLAN output) of the plans with and without the index.

The parallel query feature utilizes indexes effectively. It does not perform parallel index range scans, but it does perform parallel index lookups for parallel nested loop join execution. If an index is very selective (there are few rows per index entry), then it may be better to use sequential index lookup than parallel table scan.

Recreating an Index

You may wish to recreate an index in order to compact it and clean up fragmented space, or to change the index's storage characteristics. When creating a new index which is a subset of an existing index, or when rebuilding an existing index with new storage characteristics, Oracle uses the existing index instead of the base table to improve performance.

Consider, for example, a table named CUST with columns NAME, CUSTID, PHONE, ADDR, BALANCE, and an index named I_CUST_CUSTINFO on columns NAME, CUSTID and BALANCE of the table. To create a new index named I_CUST_CUSTNO on columns CUSTID and NAME, you would enter:

CREATE INDEX I_CUST_CUSTNO on CUST(CUSTID,NAME)

Oracle will automatically use the existing index (I_CUST_CUSTINFO) to create the new index rather than accessing the entire table. Note that the syntax used is the same as if the index I_CUST_CUSTINFO did not exist.

Similarly, if you have an index on the EMPNO and MGR columns of the EMP table, and you want to change the storage characteristics of that composite index, Oracle can use the existing index to create the new index.

Use the ALTER INDEX REBUILD statement to reorganize or compact an existing index, or to change its storage characteristics. The REBUILD uses the existing index as the basis for the new index. All index storage commands are supported, such as STORAGE (for extent allocation), TABLESPACE (to move the index to a new tablespace), and INITRANS (to change the initial number of entries).

ALTER INDEX REBUILD is usually faster than dropping and recreating an index because it utilizes the fast full scan feature. It thus reads all the index blocks using multiblock I/O, then discards the branch blocks. A further advantage of this approach is that the old index is still available for queries (but not for DML) while the rebuild is in progress.

See Also: Oracle8 Server SQL Reference for more information about the CREATE INDEX and ALTER INDEX commands.

Using Existing Indexes to Enforce Uniqueness

You can use an existing index on a table to enforce uniqueness, either for UNIQUE constraints or the unique aspect of a PRIMARY KEY constraint. The advantage of this approach is that the index remains available and valid when the constraint is disabled. Therefore, enabling a disabled UNIQUE or PRIMARY KEY constraint does not require that you rebuild the unique index associated with the constraint. This can yield significant time savings on enable operations for large tables.

In addition, using a non-unique index to enforce uniqueness allows you to eliminate redundant indexes. You do not need a unique index on a primary key column if that column already is included as the prefix of a concatenated index. The existing index can be used to enable and enforce the constraint and you can save significant space by not duplicating the index.

Non-unique indexes also have significant advantages when enabling enforced constraints. If you use a non-unique index to enforce a UNIQUE constraint, then when you change the constraint from disabled to enforced, you do not need to re-build the constraint's index. The existing index is used and the enable operation happens very quickly.

Using Enforced Constraints

An enforced constraint behaves similarly to an enabled constraint. Placing a constraint in the enforced state signifies that any new data entered into the table must conform to the constraint. Any existing data is not checked. Placing a constraint in the enforced state allows you to enable the constraint without locking the table.

If the constraint is changed from disabled to enabled, the table must be locked and no new DML, queries, or DDL can occur. This is because there is no mechanism to ensure that operations on the table conform to the constraint while the enable operation occurs. The enforced state ensures that no operation violating the constraint can be performed upon the table. Therefore, a constraint can go from enabled to enforced with a parallel, consistent-read query of the table to determine whether any data violates the constraint.

No locking is performed, and the enable operation does not block readers or writers to the table. In addition, enforced constraints can now be enabled in parallel: multiple constraints can be enabled at the same time, and each constraint's validity check can performed using parallel query processors.

The best approach to creating a table with integrity constraints is as follows:

  1. For UNIQUE or PRIMARY KEY constraints, create the table with the constraints disabled. For all other constraints, create the table with the constraints enabled.
  2. For UNIQUE or PRIMARY KEY constraints, create a non-unique index on the UNIQUE or PRIMARY KEY columns.
  3. For UNIQUE or PRIMARY KEY constraints, enable the constraints.
  4. Begin entering data into the table.
  5. During an IMPORT or load operation, you may wish to disable the constraint for faster processing.
  6. Immediately after the IMPORT or load, place the constraint into the ENFORCED state.
  7. After enforcing the constraint, perform an ALTER TABLE ENABLE CONSTRAINT operation for all of the constraints on the table.

Constraints can be created as enforced. Disabled constraints can be made enforced with the statement

ALTER TABLE tablename ENFORCE CONSTRAINT constraint; 

This statement is about as fast as ALTER TABLE tablename DISABLE, since both statements lock the table but need not check anything.

The IMPORT utility automatically enforces, then enables, named constraints. It enables constraints more slowly if the name is system-generated.

See Also: Oracle8 Server Concepts for a complete discussion of integrity constraints.

Using Bitmap Indexes

This section describes:

See Also: Oracle8 Server Concepts, for a general introduction to bitmap indexing.

When to Use Bitmap Indexing

This section describes three aspects of the indexing scheme you must evaluate when considering whether to use bitmap indexing on a given table: performance, storage, and maintenance.

Performance Considerations

Bitmap indexes can substantially improve performance of queries with the following characteristics:

Multiple bitmap indexes can be used to evaluate the conditions on a single table. Bitmap indexes are thus highly advantageous for complex ad hoc queries that contain lengthy WHERE clauses. Bitmap indexes can also provide optimal performance for aggregate queries.

Storage Considerations

Bitmap indexes can provide considerable storage savings over the use of multiple-column B*-tree indexes. In databases that only contain B*-tree indexes, a DBA must anticipate the columns that would commonly be accessed together in a single query, and create a multi-column (or concatenated) B*-tree index on these columns. Not only would this B*-tree index require a large amount of space, but it would also be ordered. That is, a B*-tree index on (MARITAL_STATUS, REGION, GENDER) is useless for a query that only accesses REGION and GENDER. To completely index the database, the DBA would have to create indexes on the other permutations of these columns. For the simple case of three low-cardinality columns, there are six possible concatenated B*-tree indexes. DBAs must consider the trade-offs between disk space and performance needs when determining which multiple-column B*-tree indexes to create.

Bitmap indexes solve this dilemma. Because bitmap indexes can be efficiently combined during query execution, three small single-column bitmap indexes can do the job of six three-column B*-tree indexes. Although the bitmap indexes may not be quite as efficient during execution as the appropriate concatenated B*-tree indexes, the space savings more than justifies their use.

If a bitmap index is created on a unique key column, it will require more space than a regular B*-tree index. However, for columns where each value is repeated hundreds or thousands of times, a bitmap index will typically be less than 25 percent of the size of a regular B*-tree index. The bitmaps themselves are stored in compressed format.

Simply comparing the relative sizes of B*-tree and bitmap indexes is not an accurate measure, however. Because of their different performance characteristics, you should keep B*-tree indexes on high-cardinality data, while creating bitmap indexes on low-cardinality data.

Maintenance Considerations

Bitmap indexes are most appropriate for data warehousing applications. DML and DDL statements such as UPDATE, DELETE, DROP TABLE, and so on, affect bitmap indexes the same way they do traditional indexes: the consistency model is the same. A compressed bitmap for a key value is made up of one or more bitmap segments, each of which is at most half a block in size (but may be smaller). The locking granularity is one such bitmap segment. This may affect performance in environments where many transactions make simultaneous updates.

A B*-tree index entry contains a single rowid. Therefore, when the index entry is locked, a single row is locked. With bitmap indexes, an entry can potentially contain a range of rowids. When a bitmap index entry is locked, the entire range of rowids is locked. The number of rowids in this range affects concurrency. For example, a bitmap index on a column with unique values would lock one rowid per value: concurrency would be the same as for B*-tree indexes. As rowids increase in a bitmap segment, concurrency decreases.

Locking issues affect data manipulation language operations, and thus may impact heavy OLTP environments. Locking issues do not, however, affect query performance. As with other types of indexes, updating bitmap indexes is a costly operation. Nonetheless, for bulk inserts and updates where many rows are inserted or many updates are made in a single statement, performance with bitmap indexes can be better than with regular B*-tree indexes.

Although bitmap indexes are not appropriate for OLTP applications with a heavy load of concurrent insert, update, and delete operations, their effectiveness in a data warehousing environment is not diminished. In such environments, data is usually maintained via bulk inserts and updates. Index maintenance is deferred until the end of each DML operation. For example, if you insert 1000 rows, the inserted rows are all placed into a sort buffer and then the updates of all 1000 index entries are batched. Thus each bitmap segment is updated only once per DML operation, even if more than one row in that segment changes. This is why SORT_AREA_SIZE must be set properly for good performance with inserts and updates on bitmap indexes.

Note: The sorts described above are regular sorts and use the regular sort area, determined by SORT_AREA_SIZE. The parameters BITMAP_MERGE_AREA_SIZE and CREATE_BITMAP_AREA_SIZE only affect the specific operations indicated by the parameter names.

If numerous DML operations have caused increased index size and decreasing performance for queries, you can use the ALTER INDEX REBUILD command to compact the index and restore efficient performance.

How to Create a Bitmap Index

To create a bitmap index, use the BITMAP keyword in the CREATE INDEX command:

CREATE BITMAP INDEX ...

All CREATE INDEX parameters except NOSORT are applicable to bitmap indexes. Multi-column (concatenated) bitmap indexes are supported; they can be defined over at most 30 columns. Other SQL statements concerning indexes, such as DROP, ANALYZE, ALTER, and so on, can refer to bitmap indexes without any extra keyword. The command ANALYZE INDEX VALIDATE STRUCTURE, however, is not applicable to bitmap indexes.

Note: The COMPATIBLE initialization parameter must be set to 7.3.2 or higher, for bitmap indexing to be available.

Index Type

System index views USER_INDEXES, ALL_INDEXES, and DBA_INDEXES indicate bitmap indexes by the word BITMAP appearing in the TYPE column. A bitmap index cannot be declared as UNIQUE.

Using Hints

The INDEX hint works with bitmap indexes in the same way as with traditional indexes.

Using the INDEX_COMBINE hint you can indicate to the optimizer those indexes which are cost-effective to use. The optimizer recognizes all indexes which can potentially be combined, given the predicates in the WHERE clause. However, it may not be cost effective to use all of them, so the optimizer must decide which of them to actually use.

In doing so, the optimizer includes non-hinted indexes that look cost-effective as well as indexes which are named in the hint. If certain indexes are given as arguments for the hint, the optimizer tries to use some combination of those particular bitmap indexes.

If no indexes are named in the hint, all indexes are considered hinted. Hence, the optimizer will try to combine as many as is possible given the WHERE clause, without regard to cost effectiveness. The optimizer always tries to use hinted indexes in the plan regardless of whether or not it considers them cost effective.

See Also: "INDEX_COMBINE" on page 8-19

Performance and Storage Tips

To obtain optimal performance and disk space usage with bitmap indexes, note the following considerations:

See Also: Chapter 21, "The EXPLAIN PLAN Command" for information about bitmap EXPLAIN PLAN output.

Initialization Parameters for Bitmap Indexing

The following initialization parameters have an impact on performance:

CREATE_BITMAP_AREA_SIZE: This parameter determines the amount of memory allocated for bitmap creation. The default value is 8 Mb. A larger value may lead to faster index creation. If cardinality is very small, you can set a small value for this parameter. For example, if cardinality is only 2 then the value can be on the order of kilobytes rather than megabytes. As a general rule, the higher the cardinality, the more memory is needed for optimal performance. This parameter is not dynamically alterable at the session level.

BITMAP_MERGE_AREA_SIZE: This parameter determines the amount of memory used to merge bitmaps retrieved from a range scan of the index. The default value is 1 Mb. A larger value should improve performance because the bitmap segments must be sorted before being merged into a single bitmap. This parameter is not dynamically alterable at the session level.

Using Bitmap Access Plans on Regular B*-tree Indexes

If there exists at least one bitmap index on the table, the optimizer will consider using a bitmap access path using regular B*-tree indexes for that table. This access path may involve combinations of B*-tree and bitmap indexes, but might not involve any bitmap indexes at all. However, the optimizer will not generate a bitmap access path using a single B*-tree index unless instructed to do so by a hint.

In order to use bitmap access paths for B*-tree indexes, the rowids stored in the indexes must be converted to bitmaps. Once such a conversion has taken place, the various boolean operations available for bitmaps can be used. As an example, consider the following query, where there is a bitmap index on column C1, and regular B*-tree indexes on columns C2 and C3.

EXPLAIN PLAN FOR
SELECT COUNT(*) FROM T
WHERE
C1 = 2 AND C2 = 6
OR
C3 BETWEEN 10 AND 20;
SELECT STATEMENT
SORT AGGREGATE
BITMAP CONVERSION COUNT
BITMAP OR
BITMAP AND
BITMAP INDEX C1_IND SINGLE VALUE
BITMAP CONVERSION FROM ROWIDS
INDEX C2_IND RANGE SCAN
BITMAP CONVERSION FROM ROWIDS
SORT ORDER BY
INDEX C3_IND RANGE SCAN

Here, a COUNT option for the BITMAP CONVERSION row source is used to count the number of rows matching the query. There are also conversions FROM ROWIDS in the plan in order to generate bitmaps from the rowids retrieved from the B*-tree indexes. The occurrence of the ORDER BY SORT in the plan is due to the fact that the conditions on columns C3 result in more than one list of rowids being returned from the B*-tree index. These lists are sorted before they can be converted into a bitmap.

Estimating Bitmap Index Size

Although it is not possible to exactly size a bitmap index, you can estimate its size. This section describes how to extrapolate the size of a bitmap index for a table from the computed size of a B*-tree index. It also illustrates how cardinality, not null constraints and number of distinct values, affects bitmap size.

To estimate the size of a bitmap index for a given table, you may extrapolate from the size of a B*-tree index for the table. Use the following approach:

  1. Use the standard formula described in Oracle8 Server Concepts to compute the size of a B*-tree index for the table.
  2. Determine the cardinality of the table data.
  3. From the cardinality value, extrapolate the size of a bitmap index according to the graph in Figure 10-2 or Figure 10-3.

For a 1 million row table, Figure 10-2 shows index size on columns with different numbers of distinct values, for B*-tree indexes and bitmap indexes. Using Figure 10-2 you can estimate the size of a bitmap index relative to that of a B*-tree index for the table. Sizing is not exact: results will vary somewhat from table to table.

Note that randomly distributed data was used to generate the graph. If, in your data, particular values tend to cluster close together you may generate considerably smaller bitmap indexes than indicated by the graph. Bitmap indexes may be slightly smaller than those in the graph if columns contain not null constraints.

Figure 10-2: Extrapolating Bitmap Index Size: 1 Million Row Table

Figure 10-3 shows similar data for a table with 5 million rows. Note that when cardinality exceeds 100,000, bitmap index size does not increase as fast as it does in Figure 10-2. For a table with more rows, there are more repeating values for a given cardinality.

Figure 10-3: Extrapolating Bitmap Index Size: 5 Million Row Table

Bitmap Index Restrictions

Bitmap indexes have the following restrictions:

For bitmap indexes with direct load, the SORTED_INDEX flag does not apply.

Performing an ALTER TABLE command that adds or modifies a bitmap-indexed column may cause indexes to be invalidated.

Bitmap indexes are not considered by the rule-based optimizer.

Bitmap indexes cannot be used for referential integrity checking.

For normal indexes, a subquery can be used as an index driver if there is a predicate of the form col = (subquery). Such subqueries cannot be used as keys for a bitmap index.




Prev

Next
Oracle
Copyright © 1997 Oracle Corporation.

All Rights Reserved.

Library

Product

Contents

Index