Oracle9i SQL Reference Release 2 (9.2) Part Number A96540-02 |
|
|
View PDF |
Use the ANALYZE
statement to collect non-optimizer statistics, for example, to:
Note: Oracle Corporation strongly recommends that you use the However, you must use the |
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, then 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, then you must have INSERT
privilege on the table into which you list analyzed rowids, or you must have INSERT
ANY
TABLE
system privilege.
analyze::=
for_clause::=
into_clause::=
Specify the schema containing the index, table, or cluster. If you omit schema
, then Oracle assumes the index, table, or cluster is in your own schema.
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, then the statistics type associated with its indextype is used. If no statistics type exists for either the index or its indextype, then 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
.
You cannot analyze a domain index that is marked IN_PROGRESS
or FAILED
.
See Also:
|
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, as long as 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.
See Also:
CREATE INDEX for more information about function-based indexes |
When analyzing a table, Oracle skips all domain indexes marked LOADING
or FAILED
.
For an index-organized table, Oracle also analyzes any mapping table and calculates its PCT_ACCESSS_DIRECT
statistics. These statistics estimate the accuracy of "guess" data block addresses stored as part of the local rowids in the mapping table.
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
)ANALYZE
to collect statistics on data dictionary tables.ANALYZE
to collect statistics on an external table. However, you can use the DBMS_STATS
package for this purpose.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, then you can use ANALYZE
to collect the user-defined statistics on the temporary table. (The association must already exist.)REF
s, varrays, nested tables, LOBs (LOBs are not analyzed, they are skipped), LONG
s, or object types. However, if a statistics type is associated with such a column, then user-defined statistics are collected.
See Also:
|
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, then Oracle analyzes all the subpartitions within the specified partition.
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
.
See Also:
Oracle9i Database Reference for information on the data dictionary views and "Analyzing a Cluster: Example" |
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.
Specify SYSTEM
if you want Oracle to compute only system (not user-defined statistics). If you omit SYSTEM
, then Oracle collects both system-generated statistics and statistics generated by the collection functions declared in a statistics type.
See Also:
|
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 FOR
TABLE
to restrict the statistics collected to only table statistics rather than table and column statistics.
Specify FOR
COLUMNS
to restrict the statistics collected to only column statistics for the specified columns and scalar object attributes, rather than for all columns and attributes; attribute
specifies the qualified column name of an item in an object.
Specify FOR
ALL
COLUMNS
to collect column statistics for all columns and scalar object attributes.
Specify FOR
ALL
INDEXED
COLUMNS
to collect column statistics for all indexed columns in the table.
Column statistics can be based on the entire column or can use a histogram by specifying SIZE
.
Oracle collects the following column statistics:
See Also:
Oracle9i Database Performance Tuning Guide and Reference and "Creating Histograms: Examples" for more information on histograms |
Column statistics appear in the data dictionary views USER_TAB_COLUMNS
, ALL_TAB_COLUMNS
, and DBA_TAB_COLUMNS
. Histograms appear in the data dictionary views USER_TAB_HISTOGRAMS
, DBA_TAB_HISTOGRAMS
, and ALL_TAB_HISTOGRAMS
; USER_PART_HISTOGRAMS
, DBA_PART_HISTOGRAMS
, and ALL_PART_HISTOGRAMS
; and USER_SUBPART_HISTOGRAMS
, DBA_SUBPART_HISTOGRAMS
, and ALL_SUBPART_HISTOGRAMS
.
If a user-defined statistics type has been associated with any columns, then the for_clause
collects user-defined statistics using that statistics type. If no statistics type is associated with a column, then 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, then no user-defined statistics are collected. User-defined column statistics appear in the STATISTICS
column of the data dictionary views USER_USTATS
, ALL_USTATS
, and DBA_USTATS
.
If you want to collect statistics on both the table as a whole and on one or more columns, then be sure to generate the statistics for the table first, and then for the columns. Otherwise, the table-only ANALYZE
will overwrite the histograms generated by the column ANALYZE
. For example, issue the following statements:
ANALYZE TABLE emp ESTIMATE STATISTICS; ANALYZE TABLE emp ESTIMATE STATISTICS FOR ALL COLUMNS;
Specify FOR
ALL
INDEXES
if you want all indexes associated with the table to be analyzed.
Specify FOR
ALL
LOCAL
INDEXES
if you want all local index partitions to be analyzed. You must specify the keyword LOCAL
if the PARTITION
clause and INDEX
are specified.
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
instructs Oracle to estimate statistics about the analyzed object and store 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.
Specify SYSTEM
if you want Oracle to estimate only system (not user-defined statistics). If you omit SYSTEM
, then Oracle estimates both system-generated statistics and statistics generated by the collection functions declared in a statistics type.
See Also:
Oracle9i Data Cartridge Developer's Guide for information on creating statistics collection functions and "Estimating Statistics: Example" |
See the description under compute_statistics_clause
Specify the amount of data from the analyzed object Oracle should sample to estimate statistics. If you omit this parameter, then 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 SAMPLE. If you specify more than half of the data, then Oracle reads all the data and computes the statistics.
ROWS
causes Oracle to sample integer
rows of the table or cluster or integer
entries from the index. The integer must be at least 1.PERCENT
causes Oracle to sample integer
percent of the rows from the table or cluster or integer
percent of the index entries. The integer can range from 1 to 99.
See Also:
Oracle9i Database Performance Tuning Guide and Reference for information on how these statistics are used |
The validation clauses let you validate REF
s and the structure of the analyzed object.
Specify VALIDATE
REF
UPDATE
to validate the REF
s in the specified table, check the rowid portion in each REF
, compare it with the true rowid, and correct, if necessary. You can use this clause only when analyzing a table.
SET
DANGLING
TO
NULL
sets to NULL
any REF
s (whether or not scoped) in the specified table that are found to point to an invalid or nonexistent object.
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 also computes compression statistics (optimal prefix compression count) for all normal indexes
Oracle stores statistics about the index in the data dictionary views INDEX_STATS
and INDEX_HISTOGRAM
.
See Also:
Oracle9i Database Reference for information on these views |
If Oracle encounters corruption in the structure of the object, then an error message is returned to you. In this case, drop and re-create the object.
The INTO
clause of VALIDATE
STRUCTURE
is valid only for partitioned tables. Specify a table into which Oracle lists the rowids of the partitions whose rows do not collate correctly. If you omit schema
, then Oracle assumes the list is in your own schema. If you omit this clause altogether, then Oracle assumes that the table is named INVALID_ROWS
. The SQL script used to create this table is UTLVALID.SQL
.
Specify CASCADE
if you want Oracle to validate the structure of the indexes associated with the table or cluster. If you use this clause when validating a table, then Oracle also validates the table's indexes. If you use this clause when validating a cluster, then Oracle also validates all the clustered tables' indexes, including the cluster index.
If you use this clause to validate an enabled (but previously disabled) function-based index, then validation errors may result. In this case, you must rebuild the index.
Specify ONLINE
to enable Oracle to run the validation while DML operations are ongoing within the object. Oracle reduces the amount of validation performed to allow for concurrency.
Note: When you validate the structure of an object |
Specify OFFLINE
, to maximize the amount of validation performed. This setting prevents INSERT
, UPDATE
, and DELETE
statements from concurrently accessing the object during validation but allows queries. This is the default.
You cannot specify ONLINE
when analyzing a clustered object.
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.
In the INTO
clause, specify a table into which Oracle lists the migrated and chained rows. If you omit schema
, then Oracle assumes the list table is in your own schema. If you omit this clause altogether, then Oracle assumes that the table is named CHAINED_ROWS
. The list table must be on your local database.
You can create the CHAINED_ROWS
table using one of these scripts:
UTLCHAIN.SQL
uses physical rowids. Therefore it can accommodate rows from conventional tables but not from index-organized tables. (See the Note that follows.)UTLCHN1.SQL
uses universal rowids, so it can accommodate rows from both conventional and index-organized tables.If you create your own chained-rows table, then it must follow the format prescribed by one of these two scripts.
See Also:
|
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.
Specify SYSTEM
if you want Oracle to delete only system (not user-defined statistics). If you omit SYSTEM
, and if user-defined column or index statistics were collected for an object, then 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.
The following statement computes statistics for the sample table oe.orders
:
ANALYZE TABLE orders COMPUTE STATISTICS;
The following statement computes only system statistics on the sample table oe.orders
:
ANALYZE TABLE orders COMPUTE SYSTEM STATISTICS; The following statement calculates statistics for a scalar object attribute: ANALYZE TABLE customers COMPUTE STATISTICS FOR COLUMNS cust_address.postal_code;
The following statement estimates statistics for the sample table oe.
orders and all of its indexes:
ANALYZE TABLE orders ESTIMATE STATISTICS;
The following statement deletes statistics about the sample table oe.
orders and all its indexes from the data dictionary:
ANALYZE TABLE orders DELETE STATISTICS;
The following statement creates a 10-band histogram on the location_id
column of the sample table hr.locations
:
ANALYZE TABLE locations COMPUTE STATISTICS FOR COLUMNS country_id 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 = 'LOCATIONS' AND COLUMN_NAME = 'COUNTRY_ID'; NUM_DISTINCT NUM_BUCKETS SAMPLE_SIZE ------------ ----------- ----------- 14 7 23
Depending on the size of your table, even though the ANALYZE
statement specified 10 buckets, Oracle may create fewer buckets that you specify in the ANALYZE
statement. For an explanation, see the note on SIZE
.
You can also collect histograms for a single partition of a table. The following statement analyzes partition sales_q2_2000 of the sample table sh.sales
:
ANALYZE TABLE sales PARTITION (sales_q2_2000) COMPUTE STATISTICS;
The following statement validates the structure of the sample index oe.inv_product_ix
:
ANALYZE INDEX inv_product_ix VALIDATE STRUCTURE;
The following statement analyzes the sample table hr.employees
and all of its indexes:
ANALYZE TABLE employees VALIDATE STRUCTURE CASCADE;
For a table, the VALIDATE
REF
UPDATE
clause verifies the REF
s 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, then the REF
is updated so that the rowid portion is correct.
The following statement validates the REF
s in the sample table oe.customers
:
ANALYZE TABLE customers VALIDATE REF UPDATE;
The following statements validates the structure of the sample table oe.customers
while allowing simultaneous DML:
ANALYZE TABLE customers VALIDATE STRUCTURE ONLINE;
The following statement analyzes the personnel
cluster (created in "Creating a Cluster: Example"), all of its tables, and all of their indexes, including the cluster index:
ANALYZE CLUSTER personnel VALIDATE STRUCTURE CASCADE;
The following statement collects information about all the chained rows of the table orders
:
ANALYZE TABLE orders LIST CHAINED ROWS INTO chained_rows;
The preceding statement places the information into the table chained_rows
. You can then examine the rows with this query (no rows will be returned if the table contains no chained rows):
SELECT owner_name, table_name, head_rowid, analyze_timestamp FROM chained_rows; OWNER_NAME TABLE_NAME HEAD_ROWID ANALYZE_TIMESTAMP ---------- ---------- ------------------ ----------------- OE ORDERS AAAAZzAABAAABrXAAA 25-SEP-2000