Oracle8i SQL Reference Release 3 (8.1.7) Part Number A85397-01 |
|
SQL Statements:
ALTER TABLE to constraint_clause, 8 of 14
Use the ANALYZE statement to:
For most statistics collection purposes, Oracle Corporation recommends that you use the DBMS_STATS package. That package lets you collect statistics in parallel, collect global statistics for partitioned objects, and fine tune your statistics collection in other ways.
However, you can use this statement for any of the purposes described in this section, and you must use this statement (rather than the DBMS_STATS package) for the following purposes:
VALIDATE
or LIST
CHAINED
ROWS
clauses
The schema object to be analyzed must be local, and it must be in your own schema or you must have the ANALYZE
ANY
system privilege.
If you want to list chained rows of a table or cluster into a list table, the list table must be in your own schema, or you must have INSERT
privilege on the list table, or you must have INSERT
ANY
TABLE
system privilege.
If you want to validate a partitioned table, you must have INSERT
privilege on the table into which you list analyzed rowids, or you must have INSERT
ANY
TABLE
system privilege.
schema
Specify the schema containing the index, table, or cluster. If you omit schema
, Oracle assumes the index, table, or cluster is in your own schema.
INDEX
index
Specify an index to be analyzed (if no for_clause
is used).
Oracle collects the following statistics for an index. Statistics marked with an asterisk are always computed exactly. For conventional indexes, the statistics appear in the data dictionary views USER_INDEXES
, ALL_INDEXES
, and DBA_INDEXES
in the columns in parentheses.
BLEVEL
)
LEAF_BLOCKS
)
DISTINCT_KEYS
)
AVG_LEAF_BLOCKS_PER_KEY
)
AVG_DATA_BLOCKS_PER_KEY
)
CLUSTERING_FACTOR
)
For domain indexes, this statement invokes the user-defined statistics collection function specified in the statistics type associated with the index (see ASSOCIATE STATISTICS). If no statistics type is associated with the domain index, the statistics type associated with its indextype is used. If no statistics type exists for either the index or its indextype, no user-defined statistics are collected. User-defined index statistics appear in the STATISTICS
column of the data dictionary views USER_USTATS
, ALL_USTATS
, and DBA_USTATS
.
Restriction: You cannot analyze a domain index that is marked LOADING
or FAILED
.
See Also:
|
TABLE
table
Specify a table to be analyzed. When you collect statistics for a table, Oracle also automatically collects the statistics for each of the table's indexes and domain indexes, provided that no for_clauses
are used.
When you analyze a table, Oracle collects statistics about expressions occurring in any function-based indexes as well. Therefore, be sure to create function-based indexes on the table before analyzing the table.
When analyzing a table, Oracle skips all domain indexes marked LOADING
or FAILED
.
Oracle collects the following statistics for a table. Statistics marked with an asterisk are always computed exactly. Table statistics, including the status of domain indexes, appear in the data dictionary views USER_TABLES
, ALL_TABLES
, and DBA_TABLES
in the columns shown in parentheses.
NUM_ROWS
)
BLOCKS
)
EMPTY_BLOCKS
)
AVG_SPACE
)
CHAIN_COUNT
)
AVG_ROW_LEN
)
Restrictions:
ANALYZE
to collect statistics on data dictionary tables.
ANALYZE
to collect default statistics on a temporary table. However, if you have created an association between one or more columns of a temporary table and a user-defined statistics type, you can use ANALYZE
to collect the user-defined statistics on the temporary table. (The association must already exist.)
LONGs
, or object types. However, if a statistics type is associated with such a column, user-defined statistics are collected.
PARTITION
| SUBPARTITION
Specify the partition
or subpartition
on which you want statistics to be gathered. You cannot use this clause when analyzing clusters.
If you specify PARTITION
and table
is composite-partitioned, Oracle analyzes all the subpartitions within the specified partition.
CLUSTER
cluster
Specify a cluster to be analyzed. When you collect statistics for a cluster, Oracle also automatically collects the statistics for all the cluster's tables and all their indexes, including the cluster index.
For both indexed and hash clusters, Oracle collects the average number of data blocks taken up by a single cluster key (AVG_BLOCKS_PER_KEY
). These statistics appear in the data dictionary views ALL_CLUSTERS
, USER_CLUSTERS
and DBA_CLUSTERS
.
COMPUTE
STATISTICS
COMPUTE
STATISTICS
instructs Oracle to compute exact statistics about the analyzed object and store them in the data dictionary. When you analyze a table, both table and column statistics are collected.
Both computed and estimated statistics are used by the Oracle optimizer to choose the execution plan for SQL statements that access analyzed objects. These statistics may also be useful to application developers who write such statements.
for_clause
The for_clause
lets you specify whether an entire table or index, or just particular columns, will be analyzed. The following clauses apply only to the ANALYZE TABLE version of this statement:
|
Specify |
|
|
Specify |
|
|
Specify |
|
|
Specify |
|
|
Column statistics can be based on the entire column or can use a histogram by specifying SIZE integer (see below). Oracle collects the following column statistics:
|
|
|
Column statistics appear in the data dictionary views |
|
|
||
|
If a user-defined statistics type has been associated with any columns, the for_clause collects user-defined statistics using that statistics type. If no statistics type is associated with a column, Oracle checks to see if any statistics type has been associated with the type of the column, and uses that statistics type. If no statistics type has been associated with either the column or its user-defined type, no user-defined statistics are collected. User-defined column statistics appear in the |
|
|
If you want to collect statistics on both the table as a whole and on one or more columns, be sure to generate the statistics for the table first, and then for the columns. Otherwise, the table-only ANALYZE TABLE emp ESTIMATE STATISTICS; ANALYZE TABLE emp ESTIMATE STATISTICS FOR ALL COLUMNS; |
|
|
|
Specify |
|
|
Specify |
|
SIZE |
Specify the maximum number of buckets in the histogram. The default value is 75, minimum value is 1, and maximum value is 254. |
|
|
|
ESTIMATE
STATISTICS
ESTIMATE
STATISTICS
instructs Oracle to estimate statistics about the analyzed object and stores them in the data dictionary.
Both computed and estimated statistics are used by the Oracle optimizer to choose the execution plan for SQL statements that access analyzed objects. These statistics may also be useful to application developers who write such statements.
See the description under COMPUTE STATISTICS |
||
|
Specify the amount of data from the analyzed object Oracle should sample to estimate statistics. If you omit this parameter, Oracle samples 1064 rows. |
|
|
The default sample value is adequate for tables up to a few thousand rows. If your tables are larger, specify a higher value for |
|
|
DELETE
STATISTICS
Specify DELETE
STATISTICS
to delete any statistics about the analyzed object that are currently stored in the data dictionary. Use this statement when you no longer want Oracle to use the statistics.
When you use this clause on a table, Oracle also automatically removes statistics for all the table's indexes. When you use this clause on a cluster, Oracle also automatically removes statistics for all the cluster's tables and all their indexes, including the cluster index.
If user-defined column or index statistics were collected for an object, Oracle also removes the user-defined statistics by invoking the statistics deletion function specified in the statistics type that was used to collect the statistics.
VALIDATE
REF
UPDATE
Specify VALIDATE
REF
UPDATE
to validate the REFs in the specified table, checks the rowid portion in each REF, compares it with the true rowid, and corrects, if necessary. You can use this clause only when analyzing a table.
|
|
|
|
VALIDATE
STRUCTURE
Specify VALIDATE
STRUCTURE
to validate the structure of the analyzed object. The statistics collected by this clause are not used by the Oracle optimizer, as are statistics collected by the COMPUTE
STATISTICS
and ESTIMATE
STATISTICS
clauses.
INVALID_ROWS
table.
Oracle stores statistics about the index in the data dictionary views INDEX_STATS
and INDEX_HISTOGRAM.
Validating the structure of an object prevents SELECT
, INSERT
, UPDATE
, and DELETE statements from concurrently accessing the object. Therefore, do not use this clause on the tables, clusters, and indexes of your production applications during periods of high database activity.
If Oracle encounters corruption in the structure of the object, an error message is returned to you. In this case, drop and re-create the object.
LIST
CHAINED
ROWS
LIST
CHAINED
ROWS
lets you identify migrated and chained rows of the analyzed table or cluster. You cannot use this clause when analyzing an index.
|
Specify a table into which Oracle lists the migrated and chained rows. If you omit |
|
|
You can create the
If you create your own chained-rows table, it must follow the format prescribed by one of these two scripts.
|
See Also:
|
The following statement estimates statistics for the cust_history
table and all of its indexes:
ANALYZE TABLE cust_history ESTIMATE STATISTICS;
The following statement deletes statistics about the cust_history
table and all its indexes from the data dictionary:
ANALYZE TABLE cust_history DELETE STATISTICS;
The following statement creates a 10-band histogram on the SAL column of the EMP
table:
ANALYZE TABLE emp COMPUTE STATISTICS FOR COLUMNS sal SIZE 10;
You can then query the USER_TAB_COLUMNS
data dictionary view to retrieve statistics:
SELECT NUM_DISTINCT, NUM_BUCKETS, SAMPLE_SIZE FROM USER_TAB_COLUMNS WHERE TABLE_NAME = 'EMP' AND COLUMN_NAME = 'SAL'; NUM_DISTINCT NUM_BUCKETS SAMPLE_SIZE ------------ ----------- ----------- 12 7 14
Even though the ANALYZE statement specified 10 buckets, Oracle created only 7 in this example. For an explanation, see the note on SIZE integer.
You can also collect histograms for a single partition of a table. The following statement analyzes the emp
table partition p1
:
ANALYZE TABLE emp PARTITION (p1) COMPUTE STATISTICS;
The following statement validates the structure of the index parts_index
:
ANALYZE INDEX parts_index VALIDATE STRUCTURE;
The following statement analyzes the emp
table and all of its indexes:
ANALYZE TABLE emp VALIDATE STRUCTURE CASCADE;
For a table, the VALIDATE
REF
UPDATE
clause verifies the REFs in the specified table, checks the rowid portion of each REF, and then compares it with the true rowid. If the result is an incorrect rowid, the REF is updated so that the rowid portion is correct.
The following statement validates the REFs in the emp table:
ANALYZE TABLE emp VALIDATE REF UPDATE;
The following statement analyzes the order_custs
cluster, all of its tables, and all of their indexes, including the cluster index:
ANALYZE CLUSTER order_custs VALIDATE STRUCTURE CASCADE;
The following statement collects information about all the chained rows of the table order_hist
:
ANALYZE TABLE order_hist LIST CHAINED ROWS INTO cr;
The preceding statement places the information into the table cr
. You can then examine the rows with this query:
SELECT * FROM cr; OWNER_NAME TABLE_NAME CLUSTER_NAME HEAD_ROWID TIMESTAMP ---------- ---------- ------------ ------------------ --------- SCOTT ORDER_HIST AAAAZzAABAAABrXAAA 15-MAR-96
COMPUTE
STATISTICS
Example
The following statement calculates statistics for a scalar object attribute:
ANALYZE TABLE emp COMPUTE STATISTICS FOR COLUMNS addr.street;
|
![]() Copyright © 1996-2000, Oracle Corporation. All Rights Reserved. |
|