Skip Headers

Oracle9i SQL Reference
Release 2 (9.2)

Part Number A96540-02
Go to Documentation Home
Home
Go to Book List
Book List
Go to Table of Contents
Contents
Go to Index
Index
Go to Master Index
Master Index
Go to Feedback page
Feedback

Go to previous page Go to next page
View PDF

ANALYZE

Purpose

Use the ANALYZE statement to collect non-optimizer statistics, for example, to:

Prerequisites

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.

Syntax

analyze::=

Text description of statements_428.gif follows
Text description of analyze


compute_statistics_clause::=

Text description of statements_423.gif follows
Text description of compute_statistics_clause


estimate_statistics_clause::=

Text description of statements_410.gif follows
Text description of estimate_statistics_clause


validation_clauses::=

Text description of statements_414.gif follows
Text description of validation_clauses


for_clause::=

Text description of statements_415.gif follows
Text description of for_clause


into_clause::=

Text description of statements_422.gif follows
Text description of into_clause


Semantics

schema

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.

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.

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.

Restriction on Analyzing Indexes

You cannot analyze a domain index that is marked IN_PROGRESS 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, 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.

Restrictions on Analyzing Tables

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, then 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.

See Also:

Oracle9i Database Reference for information on the data dictionary views and "Analyzing a Cluster: Example"

compute_statistics_clause

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:
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.

FOR TABLE

Specify FOR TABLE to restrict the statistics collected to only table statistics rather than table and column statistics.

FOR COLUMNS

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.

FOR ALL COLUMNS

Specify FOR ALL COLUMNS to collect column statistics for all columns and scalar object attributes.

FOR ALL INDEXED COLUMNS

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:

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.


Note:

MAXVALUE and MINVALUE columns of USER_, DBA_, and ALL_TAB_COLUMNS have a length of 32 bytes. If you analyze columns with a length >32 bytes, and if the columns are padded with leading blanks, then Oracle may take into account only the leading blanks and return unexpected statistics.


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;
FOR ALL INDEXES

Specify FOR ALL INDEXES if you want all indexes associated with the table to be analyzed.

FOR ALL LOCAL INDEXES

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.

SIZE

Specify the maximum number of buckets in the histogram. The default value is 75, minimum value is 1, and maximum value is 254.


Note:

Oracle does not create a histogram with more buckets than the number of rows in the sample. Also, if the sample contains any values that are very repetitious, then Oracle creates the specified number of buckets, but the value indicated by the NUM_BUCKETS column of the ALL_, DBA_, and USER_TAB_COLUMNS views may be smaller because of an internal compression algorithm.


See Also:

"Creating Histograms: Examples"

estimate_statistics_clause

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"

for_clause

See the description under compute_statistics_clause

SAMPLE

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.

validation_clauses

The validation clauses let you validate REFs and the structure of the analyzed object.

VALIDATE REF UPDATE Clause

Specify VALIDATE REF UPDATE to validate the REFs 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

SET DANGLING TO NULL sets to NULL any REFs (whether or not scoped) in the specified table that are found to point to an invalid or nonexistent object.


Note:

If the owner of the table does not have SELECT object privilege on the referenced objects, then Oracle will consider them invalid and set them to NULL. Subsequently these REFs will not be available in a query, even if it is issued by a user with appropriate privileges on the objects.


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.

See Also:

"Validating a Table: Example"

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.

INTO

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.

CASCADE

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.

ONLINE | OFFLINE

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 ONLINE, Oracle does not collect any statistics, as it does when you validate the structure of the object OFFLINE.


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.

Restriction on ONLINE

You cannot specify ONLINE when analyzing a clustered 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.

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:

If you create your own chained-rows table, then it must follow the format prescribed by one of these two scripts.


Note:

If you are analyzing index-organized tables based on primary keys (rather than universal rowids), then you must create a separate chained-rows table for each index-organized table to accommodate its primary-key storage. Use the SQL scripts DBMSIOTC.SQL and PRVTIOTC.PLB to define the BUILD_CHAIN_ROWS_TABLE procedure, and then execute this procedure to create an IOT_CHAINED_ROWS table for each such index-organized table.


See Also:
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.

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.

See Also:

"Deleting Statistics: Example"

Examples

Computing Statistics: Examples

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;
Estimating Statistics: Example

The following statement estimates statistics for the sample table oe.orders and all of its indexes:

ANALYZE TABLE orders ESTIMATE STATISTICS; 
Deleting Statistics: Example

The following statement deletes statistics about the sample table oe.orders and all its indexes from the data dictionary:

ANALYZE TABLE orders DELETE STATISTICS; 
Creating Histograms: Examples

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;
Analyzing an Index: Example

The following statement validates the structure of the sample index oe.inv_product_ix:

ANALYZE INDEX inv_product_ix VALIDATE STRUCTURE; 
Validating a Table: Example

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 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, then the REF is updated so that the rowid portion is correct.

The following statement validates the REFs 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;
Analyzing a Cluster: Example

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; 
Listing Chained Rows: Example

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