Oracle9i Data Warehousing Guide Release 2 (9.2) Part Number A96520-01 |
|
This chapter describes how to use indexes in a data warehousing environment and discusses the following types of index:
See Also:
Oracle9i Database Concepts for general information regarding indexing |
Bitmap indexes are widely used in data warehousing environments. The environments typically have large amounts of data and ad hoc queries, but a low level of concurrent DML transactions. For such applications, bitmap indexing provides:
Fully indexing a large table with a traditional B-tree index can be prohibitively expensive in terms of space because the indexes can be several times larger than the data in the table. Bitmap indexes are typically only a fraction of the size of the indexed data in the table.
Note: Bitmap indexes are available only if you have purchased the Oracle9i Enterprise Edition. See Oracle9i Database New Features for more information about the features available in Oracle9i and the Oracle9i Enterprise Edition. |
An index provides pointers to the rows in a table that contain a given key value. A regular index stores a list of rowids for each key corresponding to the rows with that key value. In a bitmap index, a bitmap for each key value replaces a list of rowids.
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. A mapping function converts the bit position to an actual rowid, so that the bitmap index provides the same functionality as a regular index. If the number of different key values is small, bitmap indexes save space.
Bitmap indexes are most effective for queries that contain multiple conditions in the WHERE
clause. Rows that satisfy some, but not all, conditions are filtered out before the table itself is accessed. This improves response time, often dramatically.
Bitmap indexes are primarily intended for data warehousing applications where users query the data rather than update it. They are not suitable for OLTP applications with large numbers of concurrent transactions modifying the data.
Parallel query and parallel DML work with bitmap indexes as they do with traditional indexes. Bitmap indexing also supports parallel create indexes and concatenated indexes.
See Also:
Chapter 17, "Schema Modeling Techniques" for further information about using bitmap indexes in data warehousing environments |
The advantages of using bitmap indexes are greatest for columns in which the ratio of the number of distinct values to the number of rows in the table is under 1%. We refer to this ratio as the degree of cardinality. A gender column, which has only two distinct values (male and female), is ideal for a bitmap index. However, data warehouse administrators also build bitmap indexes on columns with higher cardinalities.
For example, on a table with one million rows, a column with 10,000 distinct values is a candidate for a bitmap index. A bitmap index on this column can outperform a B-tree index, particularly when this column is often queried in conjunction with other indexed columns. In fact, in a typical data warehouse environments, a bitmap index can be considered for any non-unique column.
B-tree indexes are most effective for high-cardinality data: that is, for data with many possible values, such as customer_name
or phone_number
. In a data warehouse, B-tree indexes should be used only for unique columns or other columns with very high cardinalities (that is, columns that are almost unique). The majority of indexes in a data warehouse should be bitmap indexes.
In ad hoc queries and similar situations, bitmap indexes can dramatically improve query performance. AND
and OR
conditions in the WHERE
clause of a query can be resolved quickly by performing the corresponding Boolean operations directly on the bitmaps before converting the resulting bitmap to rowids. If the resulting number of rows is small, the query can be answered quickly without resorting to a full table scan.
The following shows a portion of a company's customers
table.
SELECT cust_id, cust_gender, cust_marital_status, cust_income_level FROM customers; CUST_ID C CUST_MARITAL_STATUS CUST_INCOME_LEVEL ---------- - -------------------- --------------------- ... 70 F D: 70,000 - 89,999 80 F married H: 150,000 - 169,999 90 M single H: 150,000 - 169,999 100 F I: 170,000 - 189,999 110 F married C: 50,000 - 69,999 120 M single F: 110,000 - 129,999 130 M J: 190,000 - 249,999 140 M married G: 130,000 - 149,999 ...
Because cust_gender
, cust_marital_status
, and cust_income_level
are all low-cardinality columns (there are only three possible values for marital status and region, two possible values for gender, and 12 for income level), bitmap indexes are ideal for these columns. Do not create a bitmap index on cust_id
because this is a unique column. Instead, a unique B-tree index on this column provides the most efficient representation and retrieval.
Table 6-1 illustrates the bitmap index for the cust_gender
column in this example. It consists of two separate bitmaps, one for gender.
gender='M' | gender='F' | |
---|---|---|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
Each entry (or bit) in the bitmap corresponds to a single row of the customers
table. The value of each bit depends upon the values of the corresponding row in the table. For instance, the bitmap cust_gender='F'
contains a one as its first bit because the region is east
in the first row of the customers
table. The bitmap cust_gender='F'
has a zero for its third bit because the gender of the third row is not F
.
An analyst investigating demographic trends of the company's customers might ask, "How many of our married customers have an income level of G or H?" This corresponds to the following SQL query:
SELECT COUNT(*) FROM customers WHERE cust_marital_status = 'married' AND cust_income_level IN ('H: 150,000 - 169,999', 'G: 130,000 - 149,999');
Bitmap indexes can efficiently process this query by merely counting the number of ones in the bitmap illustrated in Figure 6-1. The result set will be found by using bitmap or merge operations without the necessity of a conversion to rowids. To identify additional specific customer attributes that satisfy the criteria, use the resulting bitmap to access the table after a bitmap to rowid conversion.
Unlike most other types of indexes, bitmap indexes include rows that have NULL
values. Indexing of nulls can be useful for some types of SQL statements, such as queries with the aggregate function COUNT
.
SELECT COUNT(*) FROM customers WHERE cust_marital_status IS NULL;
This query uses a bitmap index on cust_marital_status
. Note that this query would not be able to use a B-tree index.
SELECT COUNT(*) FROM employees;
Any bitmap index can be used for this query because all table rows are indexed, including those that have NULL
data. If nulls were not indexed, the optimizer would be able to use indexes only on columns with NOT NULL
constraints.
You can create bitmap indexes on partitioned tables but they must be local to the partitioned table--they cannot be global indexes. (Global bitmap indexes are supported only on nonpartitioned tables). Bitmap indexes on partitioned tables must be local indexes.
In addition to a bitmap index on a single table, you can create a bitmap join index, which is a bitmap index for the join of two or more tables. A bitmap join index is a space efficient way of reducing the volume of data that must be joined by performing restrictions in advance. For each value in a column of a table, a bitmap join index stores the rowids of corresponding rows in one or more other tables. In a data warehousing environment, the join condition is an equi-inner join between the primary key column or columns of the dimension tables and the foreign key column or columns in the fact table.
Bitmap join indexes are much more efficient in storage than materialized join views, an alternative for materializing joins in advance. This is because the materialized join views do not compress the rowids of the fact tables.
Using the example in "Bitmap Index", create a bitmap join index with the following sales
table:
SELECT time_id, cust_id, amount FROM sales; TIME_ID CUST_ID AMOUNT --------- ---------- ---------- 01-JAN-98 29700 2291 01-JAN-98 3380 114 01-JAN-98 67830 553 01-JAN-98 179330 0 01-JAN-98 127520 195 01-JAN-98 33030 280 ... CREATE BITMAP INDEX sales_cust_gender_bjix ON sales(customers.cust_gender) FROM sales, customers WHERE sales.cust_id = customers.cust_id LOCAL;
The following query shows how to use this bitmap join index and illustrates its bitmap pattern:
SELECT sales.time_id, customers.cust_gender, sales.amount FROM sales, customers WHERE sales.cust_id = customers.cust_id; TIME_ID C AMOUNT --------- - ---------- 01-JAN-98 M 2291 01-JAN-98 F 114 01-JAN-98 M 553 01-JAN-98 M 0 01-JAN-98 M 195 01-JAN-98 M 280 01-JAN-98 M 32 ...
Table 6-2 illustrates the bitmap join index in this example:
cust_gender='M' | cust_gender='F' | |
---|---|---|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
You can create other bitmap join indexes using more than one column or more than one table, as shown in these examples.
You can create a bitmap join index on more than one column, as in the following example, which uses customers(gender, marital_status)
:
CREATE BITMAP INDEX sales_cust_gender_ms_bjix ON sales(customers.cust_gender, customers.cust_marital_status) FROM sales, customers WHERE sales.cust_id = customers.cust_id LOCAL NOLOGGING;
You can create a bitmap join index on more than one table, as in the following, which uses customers(gender)
and products(category)
:
CREATE BITMAP INDEX sales_c_gender_p_cat_bjix ON sales(customers.cust_gender, products.prod_category) FROM sales, customers, products WHERE sales.cust_id = customers.cust_id AND sales.prod_id = products.prod_id LOCAL NOLOGGING;
You can create a bitmap join index on more than one table, in which the indexed column is joined to the indexed table by using another table. For example, we can build an index on countries.country_name
, even though the countries
table is not joined directly to the sales
table. Instead, the countries
table is joined to the customers
table, which is joined to the sales table. This type of schema is commonly called a snowflake schema.
CREATE BITMAP INDEX sales_c_gender_p_cat_bjix ON sales(customers.cust_gender, products.prod_category) FROM sales, customers, products WHERE sales.cust_id = customers.cust_id AND sales.prod_id = products.prod_id LOCAL NOLOGGING;
Join results must be stored, therefore, bitmap join indexes have the following restrictions:
See Also:
Oracle9i SQL Reference for further details |
A B-tree index is organized like an upside-down tree. The bottom level of the index holds the actual data values and pointers to the corresponding rows, much as the index in a book has a page number associated with each index entry.
See Also:
Oracle9i Database Concepts for an explanation of B-tree structures |
In general, use B-tree indexes when you know that your typical query refers to the indexed column and retrieves a few rows. In these queries, it is faster to find the rows by looking at the index. However, using the book index analogy, if you plan to look at every single topic in a book, you might not want to look in the index for the topic and then look up the page. It might be faster to read through every chapter in the book. Similarly, if you are retrieving most of the rows in a table, it might not make sense to look up the index to find the table rows. Instead, you might want to read or scan the table.
B-tree indexes are most commonly used in a data warehouse to index unique or near-unique keys. In many cases, it may not be necessary to index these columns in a data warehouse, because unique constraints can be maintained without an index, and because typical data warehouse queries may not work better with such indexes. Bitmap indexes should be more common than B-tree indexes in most data warehouse environments.
B-tree indexes on partitioned tables can be global or local. With Oracle8i and earlier releases, Oracle recommended that global indexes not be used in data warehouse environments because a partition DDL statement (for example, ALTER
TABLE
... DROP
PARTITION
) would invalidate the entire index, and rebuilding the index is expensive. In Oracle9i, global indexes can be maintained without Oracle marking them as unusable after DDL. This enhancement makes global indexes more effective for data warehouse environments.
However, local indexes will be more common than global indexes. Global indexes should be used when there is a specific requirement which cannot be met by local indexes (for example, a unique index on a non-partitioning key, or a performance requirement).
Bitmap indexes on partitioned tables are always local.
See Also:
"Types of Partitioning" for further details |
|
Copyright © 1996, 2002 Oracle Corporation. All Rights Reserved. |
|