Oracle® Database Upgrade Guide 10g Release 2 (10.2) Part Number B14238-01 |
|
|
View PDF |
This appendix provides scripts that collect optimizer statistics for dictionary objects. By running these scripts prior to performing the actual database upgrade, you can decrease the amount of downtime incurred during the database upgrade.
This process should be tested on a test database just like any other aspect of the upgrade. Also, some schemas referenced in these scripts may not exist if some database components have not been installed.
If you are using Release 9.0.1 or 9.2.0, then you should use the DBMS_STATS.GATHER_SCHEMA_STATS
procedure to gather statistics. The following example shows a sample script that uses this procedure to collect statistics for system component schemas. The statistics collection may give errors if a particular component schema does not exist in the database. This can happen if a component is not installed or if it is invalid.
To run this script, connect to the database AS SYSDBA
using SQL*Plus.
spool gdict grant analyze any to sys; exec dbms_stats.gather_schema_stats('WMSYS',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('MDSYS',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('CTXSYS',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('XDB',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('WKSYS',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('LBACSYS',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('OLAPSYS',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('DMSYS',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('ODM',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('ORDSYS',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('ORDPLUGINS',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('SI_INFORMTN_SCHEMA',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('OUTLN',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('DBSNMP',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('SYSTEM',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); exec dbms_stats.gather_schema_stats('SYS',options=>'GATHER', estimate_percent => DBMS_STATS.AUTO_SAMPLE_SIZE, method_opt => 'FOR ALL COLUMNS SIZE AUTO', cascade => TRUE); spool off
This script creates the table, dictstattab
, and exports the statistics for the RDBMS component schemas into it. The export returns an error if a particular component schema does not exist in the database. This can happen if a component is not installed or if it is invalid.
This script is useful when you want to import the statistics back into the database. For example, the following PL/SQL subprograms import the statistics for the SYS
schema after deleting the existing statistics:
EXEC DBMS_STATS.DELETE_SCHEMA_STATS('SYS'); EXEC DBMS_STATS.IMPORT_SCHEMA_STATS('SYS','dictstattab');
To run the following script, connect to the database AS SYSDBA
using SQL*Plus.
spool sdict grant analyze any to sys; exec dbms_stats.create_stat_table('SYS','dictstattab'); exec dbms_stats.export_schema_stats('WMSYS','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('MDSYS','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('CTXSYS','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('XDB','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('WKSYS','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('LBACSYS','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('OLAPSYS','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('DMSYS','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('ODM','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('ORDSYS','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('ORDPLUGINS','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('SI_INFORMTN_SCHEMA','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('OUTLN','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('DBSNMP','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('SYSTEM','dictstattab',statown => 'SYS'); exec dbms_stats.export_schema_stats('SYS','dictstattab',statown => 'SYS'); spool off