Creating CBO statistics in Oracle

Since I am using the Cost Based Optimizer in Oracle (Oracle 7.3), I created the statistics needed for the optimizer with the command ‘ANALYZE TABLE’.I recently found out that since Oracle 7.4 this is not the optimal statement for creating statistics.

In Oracle 7.3.4 and Oracle 8.0 you should use the DBMS_UTILITY.ANALYZE_SCHEMA command.

From 8i you should use the DBMS_STATS.GATHER_SCHEMA_STATS command.

Analyze table

The analyze table can be used to create statistics for 1 table, index or cluster.

Syntax:

ANALYZE table tableName {compute|estimate|delete) statistics  options

ANALYZE table indexName {compute|estimate|delete) statistics  options

ANALYZE cluster clusterName {compute|estimate|delete) statistics options

Code examples   ANALYZE table scott compute statistics;  ANALYZE table scott estimate statistics sample 25 percent;  ANALYZE table scott estimate statistics sample 1000 rows;  analyze index sc_idx compute statistics;  analyze index sc_idx validate structure;

DBMS_UTILITY.ANALYZE_SCHEMA

With DBMS_UTILITY.ANALYZE_SCHEMA you can gather all the statistics for
all the tables,
clusters and indexes of a schema.

Code examples  exec DBMS_UTILITY.ANALYZE_SCHEMA('SCOTT','COMPUTE');  exec DBMS_UTILITY.ANALYZE_SCHEMA('SCOTT','ESTIMATE', estimate_rows => 1000);  exec DBMS_UTILITY.ANALYZE_SCHEMA('SCOTT','ESTIMATE', estimate_percent => 25);  exec DBMS_UTILITY.ANALYZE_SCHEMA('SCOTT','DELETE');

Note: It’s also possible to analyze the whole database with the
DBMS_UTILITY.ANALYZE_DATABASE(’COMPUTE’); command.

 

DBMS_STATS.GATHER_SCHEMA_STATS

From Oracle 8i the DBMS_STATS package is the preferred method
Oracle list a number of benefits to using it including parallel
execution, long term storage of statistics
and transfer of statistics between servers. Once again, it follows a
similar format to the other methods:

Syntax:

exec DBMS_STATS.GATHER_SCHEMA_STATS(ownname,estimate_percent, block_sample
, method_opt,degree,granularity,cascade,stattab, statid,options,statown
,no_invalidate, gather_temp,gather_fixed);

Code examples:   exec DBMS_STATS.GATHER_SCHEMA_STATS('SCOTT',DBMS_STATS.AUTO_SAMPLE_SIZE);  exec DBMS_STATS.GATHER_SCHEMA_STATS(ownname=>'SCOTT',estimate_percent=>DBMS_STATS.AUTO_SAMPLE_SIZE);  EXEC DBMS_STATS.gather_schema_stats(ownname => 'SCOTT', estimate_percent => 25);  EXEC DBMS_STATS.gather_table_stats('SCOTT', 'EMPLOYEES');  EXEC DBMS_STATS.gather_index_stats('SCOTT', 'EMPLOYEES_PK');   exec DBMS_STATS.DELETE_SCHEMA_STATS('SCOTT');

Note: It’s also possible to gather statistics for the whole database
with the
DBMS_STATS.gather_database_stats; command.

Transfering statistics between database.

It can be very handy to use production statistics on your development
database,
so that you can forecast the optimizer behavior.

You can do this the following way:

1. Create the statistics table.

exec DBMS_STATS.CREATE_STAT_TABLE(ownname =>’SCHEMA_NAME’
,stat_tab => ‘STATS_TABLE’
, tblspace => ‘STATS_TABLESPACE’);
Example:

exec DBMS_STATS.CREATE_STAT_TABLE(ownname =>’SYSTEM’,stat_tab =>
‘STATS_TABLE’);

2. Export statistics to statistics table

EXEC
DBMS_STATS.EXPORT_SCHEMA_STATS(’ORIGINAL_SCHEMA’
,’STATS_TABLE’,NULL,’SYSTEM’);

3. Import statistics into the data dictionary.

exec
DBMS_STATS.IMPORT_SCHEMA_STATS(’NEW_SCHEMA’,’STATS_TABLE’,NULL,’SYSTEM’);

4. Drop the statistics table.

exec DBMS_STATS.DROP_STAT_TABLE(’SYSTEM’,’STATS_TABLE’);

Leave a Reply

Your email address will not be published. Required fields are marked *