Oracle® Database PL/SQL Packages and Types Reference 11g Release 1 (11.1) Part Number B28419-01 |
|
|
View PDF |
With the DBMS_STATS
package you can view and modify optimizer statistics gathered for database objects.
See Also:
Oracle Database Performance Tuning GuideThis chapter contains the following topics:
Overview
Types
Constants
Operational Notes
Deprecated Subprograms
Examples
This section contains topics which relate to using the DBMS_STATS
package.
The Oracle RDBMS allows you to collect statistics of many different kinds as an aid to improving performance. This package is concerned with optimizer statistics only. Given that Oracle sets automatic statistics collection of this kind on by default, this package is intended for only specialized cases.
The statistics of interest to be viewed or modified can reside in the dictionary or in a table created in the user's schema for this purpose. You can also collect and manage user-defined statistics for tables and domain indexes using this package.
For example, if the DELETE_COLUMN_STATS
procedure is invoked on a column for which an association is defined, user-defined statistics for that column are deleted in addition to deletion of the standard statistics.
Only statistics stored in the dictionary have an impact on the cost-based optimizer. You can also use DBMS_STATS
to gather statistics in parallel
See Also:
Oracle Database Performance Tuning Guide for more information about "Managing Optimizer Statistics".Types for the minimum and maximum values and histogram endpoints include:
TYPE numarray IS VARRAY(256) OF NUMBER; TYPE datearray IS VARRAY(256) OF DATE; TYPE chararray IS VARRAY(256) OF VARCHAR2(4000); TYPE rawarray IS VARRAY(256) OF RAW(2000); TYPE fltarray IS VARRAY(256) OF BINARY_FLOAT; TYPE dblarray IS VARRAY(256) OF BINARY_DOUBLE; TYPE StatRec IS RECORD ( epc NUMBER, minval RAW(2000), maxval RAW(2000), bkvals NUMARRAY, novals NUMARRAY);
Types for listing stale tables include:
TYPE ObjectElem IS RECORD ( ownname VARCHAR2(30), -- owner objtype VARCHAR2(6), -- 'TABLE' or 'INDEX' objname VARCHAR2(30), -- table/index partname VARCHAR2(30), -- partition subpartname VARCHAR2(30)); -- subpartition type ObjectTab is TABLE of ObjectElem;
Type for displaying statistics difference report:
TYPE DiffRepElem IS RECORD ( report CLOB, -- stats difference report maxdiffpct number); -- max stats difference (percentage) type DiffRepTab is table of DiffRepElem;
The DBMS_STATS
package uses the constants shown in Table 127-1:
Table 127-1 DBMS_AUTO_TASK_ADMIN Constants
Name | Type | Value | Description |
---|---|---|---|
AUTO_CASCADE |
BOOLEAN |
NULL |
Lets Oracle decide whether to collect statistics for indexes or not |
AUTO_DEGREE |
NUMBER |
32768 |
Lets Oracle select the degree of parallelism based on size of the object, number of CPUs and initialization parameters |
AUTO_INVALIDATE |
BOOLEAN |
NULL | Lets Oracle decide when to invalidate dependent cursors |
AUTO_SAMPLE_SIZE |
NUMBER |
0 |
Indicates that auto-sample size algorithms should be used |
The DBMS_STATS
subprograms perform the following general operations:
Most of the DBMS_STATS
procedures include the three parameters statown
, stattab
, and statid
. These parameters allow you to store statistics in your own tables (outside of the dictionary), which does not affect the optimizer. Therefore, you can maintain and experiment with sets of statistics.
The stattab
parameter specifies the name of a table in which to hold statistics, and it is assumed that it resides in the same schema as the object for which statistics are collected (unless the statown
parameter is specified). You can create multiple tables with different stattab
identifiers to hold separate sets of statistics.
Additionally, you can maintain different sets of statistics within a single stattab
by using the statid
parameter, which avoids cluttering the user's schema.
For the SET
and GET
procedures, if stattab
is not provided (that is, NULL
), then the operation works directly on the dictionary statistics; therefore, you do not need to create these statistics tables if they only plan to modify the dictionary directly. However, if stattab
is not NULL
, then the SET
or GET
operation works on the specified user statistics table, and not the dictionary.
You can change the default values of some of the parameters of DBMS_STATS
procedures using the SET_PARAM Procedure.
Most of the procedures in this package commit the current transaction, perform the operation, and then commit again.
Most of the procedures have a parameter, force
which allows you to override any lock on statistics.Whenever statistics in dictionary are modified, old versions of statistics are saved automatically for future restoring.
Gathering Optimizer Statistics
Use the following subprograms to gather certain classes of optimizer statistics, with possible performance improvements over the ANALYZE
command:
The GATHER_*
procedures also collect user-defined statistics for columns and domain indexes.
The statown
, stattab
, and statid
parameters instruct the package to back up current statistics in the specified table before gathering new statistics.
Oracle also provides the following procedure for generating statistics for derived objects when you have sufficient statistics on related objects:
Setting or Getting Statistics
Use the following subprograms to store and retrieve individual column-related, index-related, and table-related statistics:
In the special versions of the SET_*_STATS
procedures for setting user-defined statistics, the following, if provided, are stored in the dictionary or external statistics table:
User-defined statistics (extstats
)
The statistics type schema name (statsschema
)
The statistics type name (statsname
)
The user-defined statistics and the corresponding statistics type are inserted into the USTATS$
dictionary table. You can specify user-defined statistics without specifying the statistics type name.
The special versions of the GET_*_STATS
procedures return user-defined statistics and the statistics type owner and name as OUT
arguments corresponding to the schema object specified. If user-defined statistics are not collected, NULL
values are returned.
Deleting Statistics
The DELETE_*
procedures delete both user-defined statistics and the standard statistics for the given schema object.
Transferring Statistics
Use the following procedures for creating and dropping the user statistics table.
Use the following procedures to transfer statistics
from the dictionary to a user statistics table (EXPORT_
*)
from a user statistics table to the dictionary (IMPORT_
*)
Note:
Oracle does not support export or import of statistics across databases of different character sets.Locking or Unlocking Statistics
Use the following procedures to lock and unlock statistics on objects.
The LOCK_*
procedures either freeze the current set of the statistics or to keep the statistics empty (uncollected).When statistics on a table are locked, all the statistics depending on the table, including table statistics, column statistics, histograms and statistics on all dependent indexes, are considered to be locked.
Restoring and Purging Statistics History
Use the following procedures to restore statistics as of a specified timestamp. This is useful in case newly collected statistics leads to some sub-optimal execution plans and the administrator wants to revert to the previous set of statistics.
Whenever statistics in dictionary are modified, old versions of statistics are saved automatically for future restoring. The old statistics are purged automatically at regular intervals based on the statistics history retention setting and the time of recent statistics gathering performed in the system. Retention is configurable using the ALTER_STATS_HISTORY_RETENTION Procedure.
The other DBMS_STATS
procedures related to restoring statistics are:
PURGE_STATS Procedure: This procedure lets you manually purge old versions beyond a time stamp.
GET_STATS_HISTORY_RETENTION Function: This function gets the current statistics history retention value.
GET_STATS_HISTORY_AVAILABILITY Function: This function gets the oldest time stamp where statistics history is available. Users cannot restore statistics to a time stamp older than the oldest time stamp.
RESTORE_*
operations are not supported for user defined statistics.
User-Defined Statistics
The DBMS_STATS
package supports operations on user-defined statistics. When a domain index or column is associated with a statistics type (using the associate
statement), operations on the index or column manipulate user-defined statistics. For example, gathering statistics for a domain index (for which an association with a statistics type exists) using the GET_INDEX_STATS Procedures invokes the user-defined statistics collection method of the associated statistics type. Similarly, delete, transfer, import, and export operations manipulate user-defined statistics.
SET_*
and GET_*
operations for user-defined statistics are also supported using a special version of the SET
and GET
interfaces for columns and indexes.
EXPORT_*
, IMPORT_*
and RESTORE_*
operations are not supported for user defined statistics.
Pending Statistics
The package gather statistics and stores it in the dictionary by default. User's can store these statistics in the system's private area instead of the dictionary by turning the PUBLISH
option to FALSE
using the SET*PREFS
procedures. The default value for PUBLISH
is TRUE
.The statistics stored in private area are not used by Cost Based Optimizer unless parameter optimizer_use_private_statistics
is set to TRUE
. The default value of this parameter is FALSE
and this boolean parameter can be set at the session/system level. Users can verify the impact of the new statistics on query plans by using the pending statistics on a session.
Pending statistics provide a mechanism to verify the impact of the new statistics on query plans before making them available for general use. There are two scenarios to verify the query plans:
Export the pending statistics (use the EXPORT_PENDING_STATS Procedure) to a test system, then run the query workload and check the performance or plans.
Set optimizer_use_pending_statistics
to TRUE
in a session on the system where pending statistics have been gathered, run the workload, and check the performance or plans.
Once the performance or query plans have been verified, the pending statistics can be published (run the PUBLISH_PENDING_STATS Procedure) if the performance is acceptable or delete (run the DELETE_PENDING_STATS Procedure) if not.
Pending statistics can be published, exported, or deleted. The following procedures are provided to manage pending statistics:
Comparing Statistics
The DIFF_TABLE_STATS_
* statistics can be used to compare statistics for a table from two different sources. The statistics can be from:
two different user statistics tables
a single user statistics table containing two sets of statistics that can be identified using statids
a user statistics table and dictionary history
pending statistics
The functions also compare the statistics of the dependent objects (indexes, columns, partitions). They displays statistics of the object(s) from both sources if the difference between those statistics exceeds a certain threshold (%). The threshold can be specified as an argument to the function, with a default of 10%. The statistics corresponding to the first source (stattab1
or time1
) will be used as basis for computing the differential percentage.
Extended Statistics
This package allows you to collect statistics for column groups and expressions (known as "statistics extensions"). The statistics collected for column groups and expressions are called "extended statistics".
Statistics on Column groups are used by optimizer for accounting correlation between columns. For example, if a query has predicates c1=1 and c2=1 and if there are statistics on (c1, c2), the optimizer will use this statistics for estimating the combined selectivity of the predicates.The expression statistics are used by optimizer for estimating selectivity of predicates on those expressions. The extended statistics are similar to column statistics and the procedures that take columns names will accept extension names in place of column names.
Related subprograms:
The following subprograms are obsolete with Release 11g:
Instead, use GET_PREFS Function
Instead, use SET_GLOBAL_PREFS Procedure
RESET_GLOBAL_PREFS_DEFAULTS Procedure
Instead use RESET_GLOBAL_PREF_DEFAULTS Procedure
Using Pending Statistics
Assume many modifications have been made to the employees
table since the last time statistics were gathered. To ensure that the cost-based optimizer is still picking the best plan, statistics should be gathered once again; however, the user is concerned that new statistics will cause the optimizer to choose bad plans when the current ones are acceptable. The user can do the following:
EXEC DBMS_STATS.SET_TABLE_PREFS('hr', 'employees', 'PUBLISH', 'false');
By setting the employees tables publish preference to FALSE
, any statistics gather from now on will not be automatically published. The newly gathered statistics will be marked as pending.
EXEC DBMS_STATS.GATHER_TABLE_STATS ('hr', 'employees');
To test the newly gathered statistics, set optimizer_pending_statistics
to TRUE
in a session and run sample queries.
ALTER SESSION SET optimizer_use_pending_statistics = TRUE;
If the pending statistics generate sound execution plans, they can be published:
EXEC DBMS_STATS.PUBLISH_PENDING_STATS('hr', 'employees'); EXEC DBMS_STATS.SET_TABLE_PREF('hr', 'employees', 'PUBLISH', 'true');
Gathering Daytime System Statistics
Assume that you want to perform database application processing OLTP transactions during the day and run reports at night.
To collect daytime system statistics, gather statistics for 720 minutes. Store the statistics in the MYSTATS
table.
BEGIN DBMS_STATS.GATHER_SYSTEM_STATS ( interval => 720, stattab => 'mystats', statid => 'OLTP'); END;
To collect nighttime system statistics, gather statistics for 720 minutes. Store the statistics in the MYSTATS
table.
BEGIN DBMS_STATS.GATHER_SYSTEM_STATS ( interval => 720, stattab => 'mystats', statid => 'OLAP'); END;
Update the dictionary with the gathered statistics.
VARIABLE jobno number; BEGIN DBMS_JOB.SUBMIT (:jobno, 'DBMS_STATS.IMPORT_SYSTEM_STATS (''mystats'',''OLTP'');' sysdate, 'sysdate + 1'); COMMIT; END; BEGIN DBMS_JOB.SUBMIT (:jobno, 'DBMS_STATS.IMPORT_SYSTEM_STATS (''mystats'',''OLAP'');' sysdate + 0.5, 'sysdate + 1'); COMMIT; END;
Table 127-2 DBMS_STATS Package Subprograms
Subprogram | Description |
---|---|
ALTER_STATS_HISTORY_RETENTION Procedure |
Changes the statistics history retention value |
CONVERT_RAW_VALUE Procedures |
Convert the internal representation of a minimum or maximum value into a datatype-specific value |
CONVERT_RAW_VALUE_NVARCHAR Procedure |
Convert the internal representation of a minimum or maximum value into a datatype-specific value |
CONVERT_RAW_VALUE_ROWID Procedure |
Convert the internal representation of a minimum or maximum value into a datatype-specific value |
COPY_TABLE_STATS Procedure |
Copies the statistics of the source [sub] partition to the destination [sub] partition after scaling |
CREATE_EXTENDED_STATS Function |
Creates a virtual column for a user specified column group or an expression in a table |
CREATE_STAT_TABLE Procedure |
Creates a table with name stattab in ownname's schema which is capable of holding statistics |
DELETE_COLUMN_STATS Procedure |
Deletes column-related statistics |
DELETE_DATABASE_PREFS Procedure |
Deletes the statistics preferences of all the tables, excluding the tables owned by Oracle. |
DELETE_DATABASE_STATS Procedure |
Deletes statistics for the entire database |
DELETE_DICTIONARY_STATS Procedure |
Deletes statistics for all dictionary schemas ('SYS ', 'SYSTEM ' and RDBMS component schemas) |
DELETE_FIXED_OBJECTS_STATS Procedure |
Deletes statistics of all fixed tables |
DELETE_INDEX_STATS Procedure |
Deletes index-related statistics |
DELETE_PENDING_STATS Procedure |
Deletes the private statistics that have been collected but have not been published |
DELETE_SCHEMA_PREFS Procedure |
Deletes the statistics preferences of all the tables owned by the specified owner name |
DELETE_SCHEMA_STATS Procedure |
Deletes schema-related statistics |
DELETE_SYSTEM_STATS Procedure |
Deletes system statistics |
DELETE_TABLE_PREFS Procedure |
Deletes statistics preferences of the specified table in the specified schema |
DELETE_TABLE_STATS Procedure |
Deletes table-related statistics |
DIFF_TABLE_STATS_IN_HISTORY Function |
Compares statistics for a table from two timestamps in past and compare the statistics as of that timestamps |
DIFF_TABLE_STATS_IN_PENDING Function |
Compares pending statistics and statistics as of a timestamp or statistics from dictionary. |
DIFF_TABLE_STATS_IN_STATTAB Function |
Compares statistics for a table from two different sources |
DROP_EXTENDED_STATS Procedure |
Drops the statistics entry that is created for the user specified extension |
DROP_STAT_TABLE Procedure |
Drops a user statistics table created by CREATE_STAT_TABLE |
EXPORT_COLUMN_STATS Procedure |
Retrieves statistics for a particular column and stores them in the user statistics table identified by stattab |
EXPORT_DATABASE_PREFS Procedure |
Exports the statistics preferences of all the tables, excluding the tables owned by Oracle. |
EXPORT_DATABASE_STATS Procedure |
Retrieves statistics for all objects in the database and stores them in the user statistics table identified by statown .stattab |
EXPORT_DICTIONARY_STATS Procedure |
Retrieves statistics for all dictionary schemas ('SYS ', 'SYSTEM ' and RDBMS component schemas) and stores them in the user statistics table identified by stattab |
EXPORT_FIXED_OBJECTS_STATS Procedure |
Retrieves statistics for fixed tables and stores them in the user statistics table identified by stattab |
EXPORT_INDEX_STATS Procedure |
Retrieves statistics for a particular index and stores them in the user statistics table identified by stattab |
EXPORT_PENDING_STATS Procedure |
Exports the statistics gathered and stored as pending |
EXPORT_SCHEMA_PREFS Procedure |
Exports the statistics preferences of all the tables owned by the specified owner name |
EXPORT_SCHEMA_STATS Procedure |
Retrieves statistics for all objects in the schema identified by ownname and stores them in the user statistics table identified by stattab |
EXPORT_SYSTEM_STATS Procedure |
Retrieves system statistics and stores them in the user statistics table |
EXPORT_TABLE_PREFS Procedure |
Exports statistics preferences of the specified table in the specified schema into the specified statistics table |
EXPORT_TABLE_STATS Procedure |
Retrieves statistics for a particular table and stores them in the user statistics table |
FLUSH_DATABASE_MONITORING_INFO Procedure |
Flushes in-memory monitoring information for all the tables to the dictionary |
GATHER_DATABASE_STATS Procedures |
Gathers statistics for all objects in the database |
GATHER_DICTIONARY_STATS Procedure |
Gathers statistics for dictionary schemas 'SYS ', 'SYSTEM ' and schemas of RDBMS components |
GATHER_FIXED_OBJECTS_STATS Procedure |
Gathers statistics of fixed objects |
GATHER_INDEX_STATS Procedure |
Gathers index statistics |
GATHER_SCHEMA_STATS Procedures |
Gathers statistics for all objects in a schema |
GATHER_SYSTEM_STATS Procedure |
Gathers system statistics |
GATHER_TABLE_STATS Procedure |
Gathers table and column (and index) statistics |
GENERATE_STATS Procedure |
Generates object statistics from previously collected statistics of related objects |
GET_COLUMN_STATS Procedures |
Gets all column-related information |
GET_INDEX_STATS Procedures |
Gets all index-related information |
GET_PARAM Function |
Gets the default value of parameters of DBMS_STATS procedures [see Deprecated Subprograms ] |
GET_STATS_HISTORY_AVAILABILITY Function |
Gets the oldest timestamp where statistics history is available |
GET_STATS_HISTORY_RETENTION Function |
Returns the current retention value |
GET_SYSTEM_STATS Procedure |
Gets system statistics from stattab, or from the dictionary if stattab is NULL |
GET_TABLE_STATS Procedure |
Gets all table-related information |
IMPORT_COLUMN_STATS Procedure |
Retrieves statistics for a particular column from the user statistics table identified by stattab and stores them in the dictionary |
IMPORT_DATABASE_PREFS Procedure |
Imports the statistics preferences of all the tables, excluding the tables owned by Oracle. |
IMPORT_DATABASE_STATS Procedure |
Retrieves statistics for all objects in the database from the user statistics table and stores them in the dictionary |
IMPORT_DICTIONARY_STATS Procedure |
Retrieves statistics for all dictionary schemas ('SYS ', 'SYSTEM ' and RDBMS component schemas) from the user statistics table and stores them in the dictionary |
IMPORT_FIXED_OBJECTS_STATS Procedure |
Retrieves statistics for fixed tables from the user statistics table identified by stattab and stores them in the dictionary |
IMPORT_INDEX_STATS Procedure |
Retrieves statistics for a particular index from the user statistics table identified by stattab and stores them in the dictionary |
IMPORT_SCHEMA_PREFS Procedure |
Imports the statistics preferences of all the tables owned by the specified owner name |
IMPORT_SCHEMA_STATS Procedure |
Retrieves statistics for all objects in the schema identified by ownname from the user statistics table and stores them in the dictionary |
IMPORT_SYSTEM_STATS Procedure |
Retrieves system statistics from the user statistics table and stores them in the dictionary |
IMPORT_TABLE_PREFS Procedure |
Sets the statistics preferences of the specified table in the specified schema. |
IMPORT_TABLE_STATS Procedure |
Retrieves statistics for a particular table from the user statistics table identified by stattab and stores them in the dictionary |
LOCK_PARTITION_STATS Procedure |
Locks statistics for a partition |
LOCK_SCHEMA_STATS Procedure |
Locks the statistics of all tables of a schema |
LOCK_TABLE_STATS Procedure |
Locks the statistics on the table |
PREPARE_COLUMN_VALUES Procedures |
Converts user-specified minimum, maximum, and histogram endpoint datatype-specific values into Oracle's internal representation for future storage using the SET_COLUMN_STATS Procedures |
PREPARE_COLUMN_VALUES_NVARCHAR2 Procedure |
Converts user-specified minimum, maximum, and histogram endpoint datatype-specific values into Oracle's internal representation for future storage using the SET_COLUMN_STATS Procedures |
PREPARE_COLUMN_VALUES_ROWID Procedure |
Converts user-specified minimum, maximum, and histogram endpoint datatype-specific values into Oracle's internal representation for future storage using the SET_COLUMN_STATS Procedures |
PUBLISH_PENDING_STATS Procedure |
Publishes the statistics gathered and stored as pending |
PURGE_STATS Procedure |
Purges old versions of statistics saved in the dictionary |
RESET_GLOBAL_PREFS_DEFAULTS Procedure |
Resets the default values of all parameters to Oracle recommended values |
RESET_PARAM_DEFAULTS Procedure |
Resets global preferences to default values |
RESTORE_DICTIONARY_STATS Procedure |
Restores statistics of all dictionary tables (tables of 'SYS ', 'SYSTEM ' and RDBMS component schemas) as of a specified timestamp |
RESTORE_FIXED_OBJECTS_STATS Procedure |
Restores statistics of all fixed tables as of a specified timestamp |
RESTORE_SCHEMA_STATS Procedure |
Restores statistics of all tables of a schema as of a specified timestamp |
RESTORE_SYSTEM_STATS Procedure |
Restores statistics of all tables of a schema as of a specified timestamp |
RESTORE_TABLE_STATS Procedure |
Restores statistics of a table as of a specified timestamp (as_of_timestamp), as well as statistics of associated indexes and columns |
SET_COLUMN_STATS Procedures |
Sets column-related information |
SET_DATABASE_PREFS Procedure |
Sets the statistics preferences of all the tables, excluding the tables owned by Oracle |
SET_GLOBAL_PREFS Procedure |
Sets the global statistics preferences |
SET_INDEX_STATS Procedures |
Sets index-related information |
SET_PARAM Procedure |
Sets default values for parameters of DBMS_STATS procedures [see Deprecated Subprograms ] |
SET_SCHEMA_PREFS Procedure |
Sets the statistics preferences of all the tables owned by the specified owner name |
SET_SYSTEM_STATS Procedure |
Sets system statistics |
SET_TABLE_PREFS Procedure |
Sets the statistics preferences of the specified table in the specified schema |
SET_TABLE_STATS Procedure |
Sets table-related information |
SHOW_EXTENDED_STATS_NAME Function |
Returns the name of the virtual column that is created for the user-specified extension |
UNLOCK_PARTITION_STATS Procedure |
Unlocks the statistics for a partition |
UNLOCK_SCHEMA_STATS Procedure |
Unlocks the statistics on all the table in a schema |
UNLOCK_TABLE_STATS Procedure |
Unlocks the statistics on the table |
UPGRADE_STAT_TABLE Procedure |
Upgrades user statistics on an older table |
This procedure changes the statistics history retention value. Statistics history retention is used by both the automatic purge and PURGE_STATS Procedure.
Syntax
DBMS_STATS.ALTER_STATS_HISTORY_RETENTION ( retention IN NUMBER);
Parameters
Table 127-3 ALTER_STATS_HISTORY_RETENTION Procedure Parameters
Parameter | Description |
---|---|
retention |
The retention time in days. The statistics history will be retained for at least these many number of days.The valid range is [1,365000]. Also you can use the following values for special purposes:
|
Usage Notes
To run this procedure, you must have the SYSDBA
or both ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privilege.
Exceptions
ORA-20000
: Insufficient privileges.
This procedure converts the internal representation of a minimum or maximum value into a datatype-specific value. The minval and maxval fields of the StatRec
structure as filled in by GET_COLUMN_STATS
or PREPARE_COLUMN_VALUES
are appropriate values for input.
Syntax
DBMS_STATS.CONVERT_RAW_VALUE ( rawval RAW, resval OUT BINARY_FLOAT); DBMS_STATS.CONVERT_RAW_VALUE ( rawval RAW, resval OUT BINARY_DOUBLE); DBMS_STATS.CONVERT_RAW_VALUE ( rawval RAW, resval OUT DATE); DBMS_STATS.CONVERT_RAW_VALUE ( rawval RAW, resval OUT NUMBER); DBMS_STATS.CONVERT_RAW_VALUE ( rawval RAW, resval OUT VARCHAR2);
Pragmas
pragma restrict_references(convert_raw_value, WNDS, RNDS, WNPS, RNPS);
Parameters
Table 127-4 CONVERT_RAW_VALUE Procedure Parameters
Parameter | Description |
---|---|
rawval |
The raw representation of a column minimum or maximum datatype-specific output parameters |
resval |
The converted, type-specific value |
This procedure converts the internal representation of a minimum or maximum value into a datatype-specific value. The minval and maxval fields of the StatRec
structure as filled in by GET_COLUMN_STATS
or PREPARE_COLUMN_VALUES
are appropriate values for input.
Syntax
DBMS_STATS.CONVERT_RAW_VALUE_NVARCHAR ( rawval RAW, resval OUT NVARCHAR2);
Pragmas
pragma restrict_references(convert_raw_value_nvarchar, WNDS, RNDS, WNPS, RNPS);
Parameters
Table 127-5 CONVERT_RAW_VALUE_NVARCHAR Procedure Parameters
Parameter | Description |
---|---|
rawval |
The raw representation of a column minimum or maximum datatype-specific output parameters |
resval |
The converted, type-specific value |
This procedure converts the internal representation of a minimum or maximum value into a datatype-specific value. The minval and maxval fields of the StatRec
structure as filled in by GET_COLUMN_STATS
or PREPARE_COLUMN_VALUES
are appropriate values for input.
Syntax
DBMS_STATS.CONVERT_RAW_VALUE_ROWID ( rawval RAW, resval OUT ROWID);
Pragmas
pragma restrict_references(convert_raw_value_rowid, WNDS, RNDS, WNPS, RNPS);
Parameters
Table 127-6 CONVERT_RAW_VALUE_ROWID Procedure Parameters
Parameter | Description |
---|---|
rawval |
The raw representation of a column minimum or maximum datatype-specific output parameters |
resval |
The converted, type-specific value |
This procedure copies the statistics of the source [sub] partition to the destination [sub] partition after scaling (the number of blks, number of rows). It sets the high bound partitioning value as the maximum value of the first partitioning column and high bound partitioning value of the previous partition as the minimum value of the first partitioning column for a range partitioned table. It finds the maximum and minimum from the list of values for the list partitioned table. It also sets the normalized maximum and minimum values. If the destination partition is the first partition then minimum values are equal to maximum values. If the statistics for source are not available then nothing is copied.
Syntax
DBMS_STATS.COPY_TABLE_STATS ( ownname VARCHAR2, tabname VARCHAR2, srcpartname VARCHAR2, dstpartname VARCHAR2, scale_factor VARCHAR2 DEFAULT 1, force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-7 COPY_TABLE_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Schema of index to analyze |
tabname |
Table name of source and destination [sub] partitions |
srcpartname |
Source [sub] partition |
dtspartname |
Destination [sub] partition |
scale_factor |
Scale factor to scale nblks, nrows etc. in dstpartname |
force |
When value of this argument is TRUE , copy statistics even if locked |
Exceptions
ORA-20000
: Invalid partition name
ORA-20001
: Bad input value
This function creates a column statistics entry in the system for a user specified column group or an expression in a table. Statistics for this extension will be gathered when user or auto statistics gathering job gathers statistics for the table. We call statistics for such an extension, "extended statistics". This function returns the name of this newly created entry for the extension.
Syntax
DBMS_STATS.CREATE_EXTENDED_STATS ( ownname VARCHAR2, tabname VARCHAR2, extension VARCHAR2) RETURN VARCHAR2;
Parameters
Table 127-8 CREATE_EXTENDED_STATS Function Parameters
Parameter | Description |
---|---|
ownname |
Owner name of a table |
tabname |
Name of the table |
extension |
Can be either a column group or an expression. Suppose the specified table has two column c1 , c2 . An example column group can be "(c1 , c2 )" and an example expression can be "(c1 + c2 )". |
Return Values
This function returns the name of this newly created entry for the extension.
Exceptions
ORA-20000
: Insufficient privileges / creating extension is not supported
ORA-20001
: Error when processing extension
ORA-20007
: Extension already exists
ORA-20008
: Reached the upper limit on number of extensions
Usage Notes
There are nine restrictions on the extension:
The extension cannot contain a virtual column.
Extensions cannot be created on tables owned by SYS.
Extensions cannot be created on cluster tables or index organized tables.
The total number of extensions in a table cannot be greater than a maximum of (20, 10% of number of non-virtual columns in the table).
The number of columns in a column group must be in the range [2, 32].
A column can not appear more than once in a column group.
A column group can not contain expressions.
An expression must contain at least one column.
An expression can not contain a subquery.
This procedure creates a table with name stattab
in ownname
's schema which is capable of holding statistics. The columns and types that compose this table are not relevant as it should be accessed solely through the procedures in this package.
Syntax
DBMS_STATS.CREATE_STAT_TABLE ( ownname VARCHAR2, stattab VARCHAR2, tblspace VARCHAR2 DEFAULT NULL);
Parameters
Table 127-9 CREATE_STAT_TABLE Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
stattab |
Name of the table to create. This value should be passed as the stattab parameter to other procedures when the user does not want to modify the dictionary statistics directly. |
tblspace |
Tablespace in which to create the statistics tables. If none is specified, then they are created in the user's default tablespace. |
Exceptions
ORA-20000
: Table already exists or insufficient privileges.
ORA-20001
: Tablespace does not exist.
This procedure deletes column-related statistics.
Syntax
DBMS_STATS.DELETE_COLUMN_STATS ( ownname VARCHAR2, tabname VARCHAR2, colname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, cascade_parts BOOLEAN DEFAULT TRUE, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE, col_stat_type VARCHAR2 DEFAULT 'ALL');
Parameters
Table 127-10 DELETE_COLUMN_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
tabname |
Name of the table to which this column belongs |
colname |
Name of the column or extension |
partname |
Name of the table partition for which to delete the statistics. If the table is partitioned and if partname is NULL , then global column statistics are deleted. |
stattab |
User statistics table identifier describing from where to delete the statistics. If stattab is NULL , then the statistics are deleted directly from the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ). |
cascade_parts |
If the table is partitioned and if partname is NULL , then setting this to true causes the deletion of statistics for this column for all underlying partitions as well. |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
When value of this argument is TRUE , deletes column statistics even if locked |
col_stat_type |
Type of column statistics to be deleted.This argument takes the following values:
|
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20005
: Object statistics are locked.
This procedure is used to delete the statistics preferences of all the tables, excluding the tables owned by Oracle. These tables can by included by passing TRUE
for the add_sys
parameter.
Syntax
DBMS_STATS.DELETE_DATABASE_PREFS ( pname IN VARCHAR2, add_sys IN BOOLEAN DEFAULT FALSE);
Parameters
Table 127-11 DELETE_DATABASE_PREFS Procedure Parameters
Parameter | Description |
---|---|
pname |
Preference name. The default value for following parameters can be set:
|
. | CASCADE - The value determines whether or not index statistics are collected as part of gathering table statistics. |
. | DEGREE - The value determines degree of parallelism used for gathering statistics. |
. | ESTIMATE_PERCENT - The value determines the percentage of rows to estimate. The valid range is [0.000001,100]. Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default. |
. | METHOD_OPT - The value controls column statistics collection and histogram creation. It accepts either of the following options, or both in combination:
- integer : Number of histogram buckets. Must be in the range [1,254].- REPEAT : Collects histograms only on the columns that already have histograms.- AUTO : Oracle determines the columns to collect histograms based on data distribution and the workload of the columns.- SKEWONLY : Oracle determines the columns to collect histograms based on the data distribution of the columns.- column_name : name of a column- extension : can be either a column group in the format of (column_name, colume_name [, ...]) or an expression
The default is |
. | NO_INVALIDATE - The value controls the invalidation of dependent cursors of the tables for which statistics are being gathered. Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE to have Oracle decide when to invalidate dependent cursors. This is the default. |
. | GRANULARITY - The value determines granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
. | PUBLISH - This value determines whether or not newly gathered statistics will be published once the gather job has completed. Prior to Prior to Oracle Database 11g, Release 1 (11.1), once a statistic gathering job completed the new statistics were automatically published into the dictionary tables. The user now has the ability to gather statistics but not publish them immediately. This allows the DBA to test the new statistics before publishing them. |
. | INCREMENTAL - This value determines whether or not the global statistics of a partitioned table will be maintained without doing a full table scan. With partitioned tables it is very common to load new data into a new partition. As new partitions are added and data loaded, the global table statistics need to be kept up to date. Oracle will update the global table statistics by scanning only the partitions that have been changed instead of the entire table if the following conditions hold:
If the |
. | STALE_PERCENT - This value determines the percentage of rows in a table that have to change before the statistics on that table are deemed stale and should be regathered. The default value is 10%. |
add_sys |
Value TRUE will include the Oracle-owned tables |
Exceptions
ORA-20000
: Insufficient privileges
ORA-20001
: Invalid or Illegal input values
Usage Notes
To run this procedure, you need to have the SYSDBA
role or both ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privileges.
All pname
arguments are of type VARCHAR2
and values are enclosed in quotes, even when they represent numbers.
Examples
DBMS_STATS.DELETE_DATABASE_PREFS('CASCADE', FALSE); DBMS_STATS.DELETE_DATABASE_PREFS('ESTIMATE_PERCENT',TRUE);
This procedure deletes statistics for all the tables in a database.
Syntax
DBMS_STATS.DELETE_DATABASE_STATS ( stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-12 DELETE_DATABASE_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
User statistics table identifier describing from where to delete the statistics. If stattab is NULL , then the statistics are deleted directly in the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ) |
statown |
Schema containing stattab (if different from current schema) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
When the value of this argument is TRUE , deletes statistics of tables in a database even if they are locked |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
This procedure deletes statistics for all dictionary schemas ('SYS
', 'SYSTEM
' and RDBMS component schemas).
Syntax
DBMS_STATS.DELETE_DICTIONARY_STATS ( stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-13 DELETE_DICTIONARY_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
User statistics table identifier describing from where to delete the statistics. If stattab is NULL , then the statistics are deleted directly in the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ) |
statown |
Schema containing stattab (if different from current schema) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
When the value of this argument is TRUE , deletes statistics of tables in a database even if they are locked |
Usage Notes
You must have the SYSDBA
or both ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privilege to execute this procedure.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20002
: Bad user statistics table, may need to upgrade it.
This procedure deletes statistics of all fixed tables.
Syntax
DBMS_STATS.DELETE_FIXED_OBJECTS_STATS ( stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-14 DELETE_FIXED_OBJECTS_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
The user statistics table identifier describing from where to delete the current statistics. If stattab is NULL , the statistics will be deleted directly in the dictionary. |
statid |
The (optional) identifier to associate with these statistics within stattab. This only applies if stattab is not NULL . |
statown |
Schema containing stattab (if different from current schema) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
Ignores the statistics lock on objects and deletes the statistics if set to TRUE |
Usage Notes
You must have the SYSDBA
or ANALYZE
ANY
DICTIONARY
system privilege to execute this procedure.
Exceptions
ORA-20000
: Insufficient privileges.
ORA-20002
: Bad user statistics table, may need to upgrade it.
This procedure deletes index-related statistics.
Syntax
DBMS_STATS.DELETE_INDEX_STATS ( ownname VARCHAR2, indname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, cascade_parts BOOLEAN DEFAULT TRUE, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-15 DELETE_INDEX_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
indname |
Name of the index |
partname |
Name of the index partition for which to delete the statistics. If the index is partitioned and if partname is NULL , then index statistics are deleted at the global level. |
stattab |
User statistics table identifier describing from where to delete the statistics. If stattab is NULL , then the statistics are deleted directly from the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ) |
cascade_parts |
If the index is partitioned and if partname is NULL , then setting this to TRUE causes the deletion of statistics for this index for all underlying partitions as well |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
When value of this argument is TRUE , deletes index statistics even if locked |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20005
: Object statistics are locked.
This procedure is used to delete the pending statistics that have been collected but have not been published.
Syntax
DBMS_STATS.DELETE_PENDING_STATS ( ownname IN VARCHAR2 DEFAULT USER, tabname IN VARCHAR2);
Parameters
Table 127-16 DELETE_PENDING_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name |
tabname |
Table name |
Exceptions
ORA-20000
: Insufficient privileges
Usage Notes
If the parameter tabname
is NULL
then delete applies to all tables of the specified schema.
The default owner/schema is the user who runs the procedure.
To run this procedure, you need to have the same privilege for gathering statistics on the tables that will be touched by this procedure.
Examples
DBMS_STATS.DELETE_PENDING_STATS('SH', 'SALES');
This procedure is used to delete the statistics preferences of all the tables owned by the specified owner name.
Syntax
DBMS_STATS.DELETE_SCHEMA_PREFS ( ownname IN VARCHAR2, pname IN VARCHAR2);
Parameters
Table 127-17 DELETE_SCHEMA_PREFS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name |
pname |
Preference name. The default value for following parameters can be set:
|
. | CASCADE - The value determines whether or not index statistics are collected as part of gathering table statistics. |
. | DEGREE - The value determines degree of parallelism used for gathering statistics. |
. | ESTIMATE_PERCENT - The value determines the percentage of rows to estimate. The valid range is [0.000001,100]. Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default. |
. | METHOD_OPT - The value controls column statistics collection and histogram creation. It accepts either of the following options, or both in combination:
- integer : Number of histogram buckets. Must be in the range [1,254].- REPEAT : Collects histograms only on the columns that already have histograms.- AUTO : Oracle determines the columns to collect histograms based on data distribution and the workload of the columns.- SKEWONLY : Oracle determines the columns to collect histograms based on the data distribution of the columns.- column_name : name of a column- extension : can be either a column group in the format of (column_name, colume_name [, ...]) or an expression
The default is |
. | NO_INVALIDATE - Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
. | GRANULARITY - The value determines granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
. | PUBLISH - This value determines whether or not newly gathered statistics will be published once the gather job has completed. Prior to Prior to Oracle Database 11g, Release 1 (11.1), once a statistic gathering job completed the new statistics were automatically published into the dictionary tables. The user now has the ability to gather statistics but not publish them immediately. This allows the DBA to test the new statistics before publishing them. |
. | INCREMENTAL - This value determines whether or not the global statistics of a partitioned table will be maintained without doing a full table scan. With partitioned tables it is very common to load new data into a new partition. As new partitions are added and data loaded, the global table statistics need to be kept up to date. Oracle will update the global table statistics by scanning only the partitions that have been changed instead of the entire table if the following conditions hold:
If the |
. | STALE_PERCENT - This value determines the percentage of rows in a table that have to change before the statistics on that table are deemed stale and should be regathered. The default value is 10%. |
Exceptions
ORA-20000
: Insufficient privileges / Schema "<schema>" does not exist
ORA-20001
: Invalid or Illegal input values
Usage Notes
To run this procedure, you need to connect as owner, or have the SYSDBA
privilege, or have the ANALYZE
ANY
system privilege.
All arguments are of type VARCHAR2
and values are enclosed in quotes, even when they represent numbers.
Examples
DBMS_STATS.DELETE_SCHEMA_PREFS('SH', 'CASCADE'); DBMS_STATS.DELETE_SCHEMA_PREFS('SH', 'ESTIMATE_PERCENT'); DBMS_STATS.DELETE_SCHEMA_PREFS('SH', 'DEGREE');
This procedure deletes statistics for an entire schema.
Syntax
DBMS_STATS.DELETE_SCHEMA_STATS ( ownname VARCHAR2, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-18 DELETE_SCHEMA_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
stattab |
User statistics table identifier describing from where to delete the statistics. If stattab is NULL , then the statistics are deleted directly in the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ) |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
When value of this argument is TRUE , deletes statistics of tables in a schema even if locked |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges
This procedure deletes workload statistics (collected using the 'INTERVAL
' or 'START
' and 'STOP
' options) and resets the default to noworkload
statistics (collected using 'NOWORKLOAD
' option) if stattab
is not specified. If stattab
is specified, the subprogram deletes all system statistics with the associated statid
from the stattab
.
Syntax
DBMS_STATS.DELETE_SYSTEM_STATS ( stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-19 DELETE_SYSTEM_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
Identifier of the user statistics table where the statistics will be saved |
statid |
Optional identifier associated with the statistics saved in the stattab |
statown |
Schema containing stattab (if different from current schema) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20002
: Bad user statistics table; may need to be upgraded.
This procedure is used to delete the statistics preferences of the specified table in the specified schema.
Syntax
DBMS_STATS.DELETE_TABLE_PREFS ( ownname IN VARCHAR2, tabname IN VARCHAR2, pname IN VARCHAR2);
Parameters
Table 127-20 DELETE_TABLE_PREFS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name |
tabname |
Table name |
pname |
Preference name. The default value for following parameters can be set:
|
. | CASCADE - The value determines whether or not index statistics are collected as part of gathering table statistics. |
. | DEGREE - The value determines degree of parallelism used for gathering statistics. |
. | ESTIMATE_PERCENT - The value determines the percentage of rows to estimate. The valid range is [0.000001,100]. Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default. |
. | METHOD_OPT - The value controls column statistics collection and histogram creation. It accepts either of the following options, or both in combination:
- integer : Number of histogram buckets. Must be in the range [1,254].- REPEAT : Collects histograms only on the columns that already have histograms.- AUTO : Oracle determines the columns to collect histograms based on data distribution and the workload of the columns.- SKEWONLY : Oracle determines the columns to collect histograms based on the data distribution of the columns.- column_name : name of a column- extension : can be either a column group in the format of (column_name, colume_name [, ...]) or an expression
The default is |
. | NO_INVALIDATE - The value controls the invalidation of dependent cursors of the tables for which statistics are being gathered. Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE to have Oracle decide when to invalidate dependent cursors. This is the default. |
. | GRANULARITY - The value determines granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
. | PUBLISH - This value determines whether or not newly gathered statistics will be published once the gather job has completed. Prior to Prior to Oracle Database 11g, Release 1 (11.1), once a statistic gathering job completed the new statistics were automatically published into the dictionary tables. The user now has the ability to gather statistics but not publish them immediately. This allows the DBA to test the new statistics before publishing them. |
. | INCREMENTAL - This value determines whether or not the global statistics of a partitioned table will be maintained without doing a full table scan. With partitioned tables it is very common to load new data into a new partition. As new partitions are added and data loaded, the global table statistics need to be kept up to date. Oracle will update the global table statistics by scanning only the partitions that have been changed instead of the entire table if the following conditions hold:
If the |
. | STALE_PERCENT - This value determines the percentage of rows in a table that have to change before the statistics on that table are deemed stale and should be regathered. The default value is 10%. |
pvalue | Preference value. If NULL is specified, it will set the Oracle default value. |
Exceptions
ORA-20000
: Insufficient privileges
ORA-20001
: Invalid or Illegal input values
Usage Notes
To run this procedure, you need to connect as owner of the table, be granted ANALYZE
privilege on the table, or ANALYZE
ANY
system privilege.
All arguments are of type VARCHAR2
and values are enclosed in quotes, even when they represent numbers.
Examples
DBMS_STATS.DELETE_TABLE_PREFS('SH', 'SALES', 'CASCADE'); DBMS_STATS.DELETE_TABLE_PREFS('SH', 'SALES', 'DEGREE');
This procedure deletes table-related statistics.
Syntax
DBMS_STATS.DELETE_TABLE_STATS ( ownname VARCHAR2, tabname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, cascade_parts BOOLEAN DEFAULT TRUE, cascade_columns BOOLEAN DEFAULT TRUE, cascade_indexes BOOLEAN DEFAULT TRUE, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-21 DELETE_TABLE_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
tabname |
Name of the table to which this column belongs |
partname |
Name of the table partition from which to get the statistics. If the table is partitioned and if partname is NULL , then the statistics are retrieved from the global table level. |
stattab |
User statistics table identifier describing from where to retrieve the statistics. If stattab is NULL , then the statistics are retrieved directly from the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ) |
cascade_parts |
If the table is partitioned and if partname is NULL , then setting this to TRUE causes the deletion of statistics for this table for all underlying partitions as well |
cascade_columns |
Indicates that DELETE_COLUMN_STATS should be called for all underlying columns (passing the cascade_parts parameter) |
cascade_indexes |
Indicates that DELETE_INDEX_STATS should be called for all underlying indexes (passing the cascade_parts parameter) |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
When value of this argument is TRUE , deletes table statistics even if locked |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20002
: Bad user statistics table, may need to upgrade it
ORA
-20005
: Object statistics are locked
This function can be used to compare statistics for a table from two timestamps in past and compare the statistics as of that timestamps.
Syntax
DBMS_STATS.DIFF_TABLE_STATS_IN_HISTORY( ownname IN VARCHAR2, tabname IN VARCHAR2, time1 IN TIMESTAMP WITH TIME ZONE, time2 IN TIMESTAMP WITH TIME ZONE DEFAULT NULL, pctthreshold IN NUMBER DEFAULT 10) RETURN DiffRepTab pipelined;
Parameters
Table 127-22 DIFF_TABLE_STATS_IN_HISTORY Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner of the table. Specify NULL for current schema. |
tabname |
Table for which statistics are to be compared |
time1 |
First timestamp 1 |
time2 |
Second timestamp 2 |
pctthreshold |
The function reports difference in statistics only if it exceeds this limit. The default value is 10. |
Usage Notes
If the second timestamp is NULL
, the function compares the current statistics in dictionary with the statistics as of the other timestamp.
This function compares pending statistics and statistics as of a timestamp or statistics from dictionary.
Syntax
DBMS_STATS.DIFF_TABLE_STATS_IN_PENDING( ownname IN VARCHAR2, tabname IN VARCHAR2, timestamp IN TIMESTAMP WITH TIME ZONE, pctthreshold IN NUMBER DEFAULT 10) RETURN DiffRepTab pipelined;
Parameters
Table 127-23 DIFF_TABLE_STATS_IN_PENDING Function Parameters
Parameter | Description |
---|---|
ownname |
Owner of the table. Specify NULL for current schema. |
tabname |
Table for which statistics are to be compared |
timestamp |
Time stamp to get statistics from the history |
pctthreshold |
The function reports difference in statistics only if it exceeds this limit. The default value is 10. |
Usage Notes
If the second timestamp is NULL
, the function compares the current statistics in dictionary with the statistics as of the other timestamp.
This function can be used to compare statistics for a table from two different sources. The statistics can be drawn from
two different user statistics tables
a single user statistics table containing 2 sets of statistics that can be identified using statids
a user statistics table and dictionary
The function also compares the statistics of the dependent objects (indexes, columns, partitions) as well. It displays statistics of the object(s) from both sources if the difference between those statistics exceeds a certain threshold (%). The threshold can be specified as an argument to the function. The statistics corresponding to the first source (stattab1
or time1
) will be used as basis for computing the difference percentage.
Syntax
DBMS_STATS.DIFF_TABLE_STATS_IN_STATTAB( ownname IN VARCHAR2, tabname IN VARCHAR2, stattab1 IN VARCHAR2, stattab2 IN VARCHAR2 DEFAULT NULL, pctthreshold IN NUMBER DEFAULT 10, statid1 IN VARCHAR2 DEFAULT NULL, statid2 IN VARCHAR2 DEFAULT NULL, stattab1own IN VARCHAR2 DEFAULT NULL, stattab2own IN VARCHAR2 DEFAULT NULL) RETURN DiffRepTab pipelined;
Parameters
Table 127-24 DIFF_TABLE_STATS_IN_STATTAB Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner of the table. Specify NULL for current schema. |
tabname |
Table for which statistics are to be compared |
stattab1 |
User statistics table 1 |
stattab2 |
User statistics table 2. If NULL , statistics in stattab1 is compared with current statistics in dictionary. This is the default. Specify same table as stattab1 to compare two sets within the statistics table (see statid below). |
pctthreshold |
The function reports difference in statistics only if it exceeds this limit. The default value is 10. |
stadid1 |
(optional) Identifies statistics set within stattab1 . |
stadid2 |
(optional) Identifies statistics set within stattab2 |
stattab1own |
Schema containing stattab1 (if other than ownname ) |
stattab2own |
Schema containing stattab2 (if other than ownname ) |
This function drops the statistics entry that is created for the user specified extension. This cancels the effects of the CREATE_EXTENDED_STATS Function.
Syntax
DBMS_STATS.DROP_EXTENDED_STATS ( ownname VARCHAR2, tabname VARCHAR2, extension VARCHAR2);
Parameters
Table 127-25 DROP_EXTENDED_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name of a table |
tabname |
Name of the table |
extension |
Can be either a column group or an expression. Suppose the specified table has two column c1 , c2 . An example column group can be "(c1 , c2 )" and an example expression can be "(c1 + c2 )". |
Usage Notes
If no extended statistics set is created for the extension, this function throws an error.
Exceptions
ORA-20000
: Insufficient privileges or extension does not exist.
ORA-20001
: Error when processing extension
This procedure drops a user statistics table.
Syntax
DBMS_STATS.DROP_STAT_TABLE ( ownname VARCHAR2, stattab VARCHAR2);
Parameters
Table 127-26 DROP_STAT_TABLE Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
stattab |
User statistics table identifier |
Exceptions
ORA-20000
: Table does not exists or insufficient privileges.
This procedure retrieves statistics for a particular column and stores them in the user statistics table identified by stattab
.
Syntax
DBMS_STATS.EXPORT_COLUMN_STATS ( ownname VARCHAR2, tabname VARCHAR2, colname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-27 EXPORT_COLUMN_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
tabname |
Name of the table to which this column belongs |
colname |
Name of the column or extension |
partname |
Name of the table partition. If the table is partitioned and if partname is NULL , then global and partition column statistics are exported. |
stattab |
User statistics table identifier describing where to store the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
statown |
Schema containing stattab (if different than ownname ) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure is used to export the statistics preferences of all the tables, excluding the tables owned by Oracle. These tables can by included by passing TRUE
for the add_sys
parameter.
Syntax
DBMS_STATS.EXPORT_DATABASE_PREFS ( stattab IN VARCHAR2, statid IN VARCHAR2 DEFAULT NULL, statown IN VARCHAR2 DEFAULT NULL add_sys IN BOOLEAN DEFAULT FALSE);
Parameters
Table 127-28 EXPORT_DATABASE_PREFS Procedure Parameters
Parameter | Description |
---|---|
stattab |
Statistics table name to where statistics should be exported |
statid | (Optional) Identifier to associate with these statistics within stattab |
statown | Schema containing stattab (if other than ownname ) |
add_sys |
Value TRUE will include the Oracle-owned tables |
Exceptions
ORA-20000
: Insufficient privileges
Usage Notes
To run this procedure, you need to have the SYSDBA role, or both ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privileges.
All arguments are of type VARCHAR2
and values are enclosed in quotes.
Oracle does not support export or import of statistics across databases of different character sets.
Examples
DBMS_STATS.EXPORT_DATABASE_PREFS('STATTAB', statown=>'SH');
This procedure retrieves statistics for all objects in the database and stores them in the user statistics tables identified by statown
.stattab
.
Syntax
DBMS_STATS.EXPORT_DATABASE_STATS ( stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-29 EXPORT_DATABASE_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
User statistics table identifier describing where to store the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
statown |
Schema containing stattab (if different from current schema) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure retrieves statistics for all dictionary schemas ('SYS
', 'SYSTEM
' and RDBMS component schemas) and stores them in the user statistics table identified by stattab
.
Syntax
DBMS_STATS.EXPORT_DICTIONARY_STATS ( stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-30 EXPORT_DICTIONARY_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
User statistics table identifier describing where to store the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
statown |
Schema containing stattab (if different from current schema) |
Usage Notes
You must have the SYSDBA
or ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privilege to execute this procedure.
Oracle does not support export or import of statistics across databases of different character sets.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20002
: Bad user statistics table, may need to upgrade it.
This procedure retrieves statistics for fixed tables and stores them in the user statistics table identified by stattab
.
Syntax
DBMS_STATS.EXPORT_FIXED_OBJECTS_STATS ( stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-31 EXPORT_FIXED_OBJECTS_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
User statistics table identifier describing where to store the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
statown |
Schema containing stattab (if different from current schema) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20002
: Bad user statistics table, may need to upgrade it.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure retrieves statistics for a particular index and stores them in the user statistics table identified by stattab
.
Syntax
DBMS_STATS.EXPORT_INDEX_STATS ( ownname VARCHAR2, indname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-32 EXPORT_INDEX_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
indname |
Name of the index |
partname |
Name of the index partition. If the index is partitioned and if partname is NULL , then global and partition index statistics are exported. |
stattab |
User statistics table identifier describing where to store the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
statown |
Schema containing stattab (if different than ownname ) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure is used to export the statistics gathered and stored as pending.
Syntax
DBMS_STATS.EXPORT_PENDING_STATS ( ownname IN VARCHAR2 DEFAULT USER, tabname IN VARCHAR2, stattab IN VARCHAR2, statid IN VARCHAR2 DEFAULT NULL, statown IN VARCHAR2 DEFAULT USER);
Parameters
Table 127-33 EXPORT_PENDING_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name |
tabname |
Table name |
stattab |
Statistics table name to where to export the statistics |
statid | (Optional) Identifier to associate with these statistics within stattab |
statown | Schema containing stattab (if other than ownname ) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
Usage Notes
If the parameter tabname
is NULL
then export applies to all tables of the specified schema.
The default owner/schema is the user who runs the procedure.
To run this procedure, you need to have the same privilege for gathering statistics on the tables that will be touched by this procedure.
All arguments are of type VARCHAR2
and values are enclosed in quotes.
Oracle does not support export or import of statistics across databases of different character sets.
Examples
DBMS_STATS.EXPORT_PENDING_STATS(NULL, NULL, 'MY_STAT_TABLE');
This procedure is used to export the statistics preferences of all the tables owned by the specified owner name.
Syntax
DBMS_STATS.EXPORT_SCHEMA_PREFS ( ownname IN VARCHAR2, stattab IN VARCHAR2, statid IN VARCHAR2 DEFAULT NULL, statown IN VARCHAR2 DEFAULT NULL);
Parameters
Table 127-34 EXPORT_SCHEMA_PREFS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name |
stattab |
Statistics table name to where to export the statistics |
statid | (Optional) Identifier to associate with these statistics within stattab |
statown | Schema containing stattab (if different than ownname ) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
Usage Notes
To run this procedure, you need to connect as owner, or have the SYSDBA
privilege, or have the ANALYZE
ANY
system privilege.
All arguments are of type VARCHAR2
and values are enclosed in quotes.
Oracle does not support export or import of statistics across databases of different character sets.
Examples
DBMS_STATS.EXPORT_SCHEMA_PREFS('SH', 'STAT');
This procedure retrieves statistics for all objects in the schema identified by ownname
and stores them in the user statistics tables identified by stattab
.
Syntax
DBMS_STATS.EXPORT_SCHEMA_STATS ( ownname VARCHAR2, stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-35 EXPORT_SCHEMA_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
stattab |
User statistics table identifier describing where to store the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
statown |
Schema containing stattab (if different than ownname ) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure retrieves system statistics and stores them in the user statistics table, identified by stattab
.
Syntax
DBMS_STATS.EXPORT_SYSTEM_STATS ( stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-36 EXPORT_SYSTEM_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
Identifier of the user statistics table that describes where the statistics will be stored. |
statid |
Optional identifier associated with the statistics stored from the stattab |
statown |
Schema containing stattab (if different from current schema) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20002
: Bad user statistics table; may need to be upgraded.
ORA-20003
: Unable to export system statistics.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure is used to export the statistics preferences of the specified table in the specified schema into the specified statistics table.
Syntax
DBMS_STATS.EXPORT_TABLE_PREFS ( ownname IN VARCHAR2, tabname IN VARCHAR2, stattab IN VARCHAR2, statid IN VARCHAR2 DEFAULT NULL, statown IN VARCHAR2 DEFAULT NULL);
Parameters
Table 127-37 EXPORT_TABLE_PREFS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name |
tabname |
Table name |
stattab |
Statistics table name where to export the statistics |
statid | Optional identifier to associate with these statistics within stattab |
statown | Schema containing stattab (if other than ownname ) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
Usage Notes
To run this procedure, you need to connect as owner of the table, or have the ANALYZE
ANY
system privilege.
All arguments are of type VARCHAR2
and values are enclosed in quotes.
Oracle does not support export or import of statistics across databases of different character sets.
Examples
DBMS_STATS.EXPORT_TABLE_PREFS('SH', 'SALES', 'STAT');
This procedure retrieves statistics for a particular table and stores them in the user statistics table. Cascade results in all index statistics associated with the specified table being exported as well.
Syntax
DBMS_STATS.EXPORT_TABLE_STATS ( ownname VARCHAR2, tabname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, cascade BOOLEAN DEFAULT TRUE, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-38 EXPORT_TABLE_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
tabname |
Name of the table |
partname |
Name of the table partition. If the table is partitioned and if partname is NULL , then global and partition table statistics are exported. |
stattab |
User statistics table identifier describing where to store the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
cascade |
If true, then column and index statistics for this table are also exported |
statown |
Schema containing stattab (if different than ownname ) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure flushes in-memory monitoring information for all tables in the dictionary. Corresponding entries in the *_TAB_MODIFICATIONS
, *_TAB_STATISTICS
and *_IND_STATISTICS
views are updated immediately, without waiting for the Oracle database to flush them periodically. This procedure is useful when you need up-to-date information in those views. Because the GATHER_*_STATS
procedures internally flush monitoring information, it is not necessary to run this procedure before gathering the statistics.
Syntax
DBMS_STATS.FLUSH_DATABASE_MONITORING_INFO;
Exceptions
ORA-20000
: Insufficient privileges.
Usage Notes
The ANALYZE_ANY
system privilege is required to run this procedure.
This procedure gathers statistics for all objects in the database.
Syntax
DBMS_STATS.GATHER_DATABASE_STATS ( estimate_percent NUMBER DEFAULT to_estimate_percent_type (get_param('ESTIMATE_PERCENT')), block_sample BOOLEAN DEFAULT FALSE, method_opt VARCHAR2 DEFAULT get_param('METHOD_OPT'), degree NUMBER DEFAULT to_degree_type(get_param('DEGREE')), granularity VARCHAR2 DEFAULT GET_PARAM('GRANULARITY'), cascade BOOLEAN DEFAULT to_cascade_type(get_param('CASCADE')), stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, options VARCHAR2 DEFAULT 'GATHER', objlist OUT ObjectTab, statown VARCHAR2 DEFAULT NULL, gather_sys BOOLEAN DEFAULT TRUE, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), obj_filter_list ObjectTab DEFAULT NULL); DBMS_STATS.GATHER_DATABASE_STATS ( estimate_percent NUMBER DEFAULT to_estimate_percent_type (get_param('ESTIMATE_PERCENT')), block_sample BOOLEAN DEFAULT FALSE, method_opt VARCHAR2 DEFAULT get_param('METHOD_OPT'), degree NUMBER DEFAULT to_degree_type(get_param('DEGREE')), granularity VARCHAR2 DEFAULT GET_PARAM('GRANULARITY'), cascade BOOLEAN DEFAULT to_cascade_type(get_param('CASCADE')), stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, options VARCHAR2 DEFAULT 'GATHER', statown VARCHAR2 DEFAULT NULL, gather_sys BOOLEAN DEFAULT TRUE, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), obj_filter_list ObjectTab DEFAULT NULL);
Parameters
Table 127-39 GATHER_DATABASE_STATS Procedure Parameters
Parameter | Description |
---|---|
estimate_percent |
Percentage of rows to estimate (NULL means compute): The valid range is [0.000001,100]. Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default.The default value can be changed using the SET_PARAM Procedure. |
block_sample |
Whether or not to use random block sampling instead of random row sampling. Random block sampling is more efficient, but if the data is not randomly distributed on disk, then the sample values may be somewhat correlated. Only pertinent when doing an estimate statistics. |
method_opt |
Accepts:
size_clause is defined as size_clause := SIZE {integer | REPEAT | AUTO | SKEWONLY} - integer : Number of histogram buckets. Must be in the range [1,254].- REPEAT : Collects histograms only on the columns that already have histograms.- AUTO : Oracle determines the columns to collect histograms based on data distribution and the workload of the columns.- SKEWONLY : Oracle determines the columns to collect histograms based on the data distribution of the columns.
The default is |
degree |
Degree of parallelism. The default for degree is NULL . The default value can be changed using the SET_PARAM Procedure. NULL means use the table default value specified by the DEGREE clause in the CREATE TABLE or ALTER TABLE statement. Use the constant DBMS_STATS.DEFAULT_DEGREE to specify the default value based on the initialization parameters. The AUTO_DEGREE value determines the degree of parallelism automatically. This is either 1 (serial execution) or DEFAULT_DEGREE (the system default value based on number of CPUs and initialization parameters) according to size of the object. |
granularity |
Granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
cascade |
Gather statistics on the indexes as well. Index statistics gathering is not parallelized. Using this option is equivalent to running the GATHER_INDEX_STATS Procedure on each of the indexes in the database in addition to gathering table and column statistics. Use the constant DBMS_STATS.AUTO_CASCADE to have Oracle determine whether index statistics to be collected or not. This is the default. The default value can be changed using the SET_PARAM Procedure. |
stattab |
User statistics table identifier describing where to save the current statistics.
The statistics table is assumed to reside in the same schema as the object being analyzed, so there must be one such table in each schema to use this option. |
statid |
Identifier (optional) to associate with these statistics within stattab . |
options |
Further specification of which objects to gather statistics for:
|
objlist |
List of objects found to be stale or empty |
statown |
Schema containing stattab (if different from current schema) |
gather_sys |
Gathers statistics on the objects owned by the 'SYS' user |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
obj_filter_list |
A list of object filters. When provided, GATHER_DATABASE_STATS will gather statistics only on objects which satisfy at least one object filter in the list as needed. In a single object filter, we can specify the constraints on the object attributes. The attribute values specified in the object filter are case- insensitive unless double-quoted. Wildcard is allowed in the attribute values. Suppose non-NULL values s1, s2, ... are specified for attributes a1, a2, ... in one object filter. An object o is said to satisfy this object filter if (o.a1 like s1) and (o.a2 like s2) and ... is true. See Applying an Object Filter List. |
Usage Notes
Statistics for external tables are not collected by this procedure.
Exceptions
ORA-20000
: Insufficient privileges.
ORA-20001
: Bad input value.
This procedure gathers statistics for dictionary schemas 'SYS
', 'SYSTEM
' and schemas of RDBMS components.
Syntax
DBMS_STATS.GATHER_DICTIONARY_STATS ( comp_id VARCHAR2 DEFAULT NULL, estimate_percent NUMBER DEFAULT to_estimate_percent_type (get_param('ESTIMATE_PERCENT')), block_sample BOOLEAN DEFAULT FALSE, method_opt VARCHAR2 DEFAULT get_param('METHOD_OPT'), degree NUMBER DEFAULT to_degree_type(get_param('DEGREE')), granularity VARCHAR2 DEFAULT GET_PARAM('GRANULARITY'), cascade BOOLEAN DEFAULT to_cascade_type(get_param('CASCADE')), stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, options VARCHAR2 DEFAULT 'GATHER AUTO', objlist OUT ObjectTab, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), obj_filter_list ObjectTab DEFAULT NULL); DBMS_STATS.GATHER_DICTIONARY_STATS ( comp_id VARCHAR2 DEFAULT NULL, estimate_percent NUMBER DEFAULT to_estimate_percent_type(GET_PARAM('ESTIMATE_PERCENT')), block_sample BOOLEAN DEFAULT FALSE, method_opt VARCHAR2 DEFAULT GET_PARAM('METHOD_OPT'), degree NUMBER DEFAULT to_degree_type(GET_PARAM('DEGREE')), granularity VARCHAR2 DEFAULT GET_PARAM('GRANULARITY'), cascade BOOLEAN DEFAULT to_cascade_type(GET_PARAM('CASCADE')), stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, options VARCHAR2 DEFAULT 'GATHER AUTO', statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type(get_param('NO_INVALIDATE')), obj_filter_list ObjectTab DEFAULT NULL);
Parameters
Table 127-40 GATHER_DICTIONARY_STATS Procedure Parameters
Parameter | Description |
---|---|
comp_id |
The component id of the schema to analyze (NULL will result in analyzing schemas of all RDBMS components).Please refer to comp_id column of DBA_REGISTRY view. The procedure always gather statistics on 'SYS ' and 'SYSTEM ' schemas regardless of this argument. |
estimate_percent |
Percentage of rows to estimate (NULL means compute). The valid range is [0.000001,100] . Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default.The default value can be changed using the SET_PARAM Procedure. |
block_sample |
Determines whether or not to use random block sampling instead of random row sampling. Random block sampling is more efficient, but if the data is not randomly distributed on disk then the sample values may be somewhat correlated. Only pertinent when performing estimate statistics. |
method_opt |
Accepts:
size_clause is defined as size_clause := SIZE {integer | REPEAT | AUTO | SKEWONLY} - integer : Number of histogram buckets. Must be in the range [1,254].- REPEAT : Collects histograms only on the columns that already have histograms.- AUTO : Oracle determines the columns to collect histograms based on data distribution and the workload of the columns.- SKEWONLY : Oracle determines the columns to collect histograms based on the data distribution of the columns.
The default is |
degree |
Degree of parallelism. The default for degree is NULL . The default value can be changed using the SET_PARAM Procedure. NULL means use of table default value that was specified by the DEGREE clause in the CREATE or ALTER INDEX statement. Use the constant DBMS_STATS.DEFAULT_DEGREE for the default value based on the initialization parameters. The AUTO_DEGREE value determines the degree of parallelism automatically. This is either 1 (serial execution) or DEFAULT_DEGREE (the system default value based on number of CPUs and initialization parameters) according to size of the object. |
granularity |
Granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
cascade |
Gathers statistics on indexes also.Index statistics gathering will not be parallelized. Using this option is equivalent to running the GATHER_INDEX_STATS Procedure on each of the indexes in the schema in addition to gathering table and column statistics. Use the constant DBMS_STATS.AUTO_CASCADE to have Oracle determine whether index statistics to be collected or not. This is the default.The default value can be changed using the SET_PARAM Procedure. |
stattab |
User statistics table identifier describing where to save the current statistics |
statid |
The (optional) identifier to associate with these statistics within stattab |
options |
Further specification of objects for which to gather statistics:
|
objlist |
The list of objects found to be stale or empty |
statown |
Schema containing stattab (if different from current schema) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
obj_filter_list |
A list of object filters. When provided, this will gather statistics only on objects which satisfy at least one object filter in the list as needed. In a single object filter, we can specify the constraints on the object attributes. The attribute values specified in the object filter are case- insensitive unless double-quoted. Wildcard is allowed in the attribute values. Suppose non-NULL values s1, s2, ... are specified for attributes a1, a2, ... in one object filter. An object o is said to satisfy this object filter if (o.a1 like s1) and (o.a2 like s2) and ... is true. See Applying an Object Filter List. |
Usage Notes
You must have the SYSDBA
or both ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privilege to execute this procedure.
Exceptions
ORA-20000
: Index does not exist or insufficient privileges.
ORA-20001
: Bad input value.
ORA-20002
: Bad user statistics table, may need to upgrade it.
This procedure gathers statistics for all fixed objects (dynamic performance tables).
Syntax
DBMS_STATS.GATHER_FIXED_OBJECTS_STATS ( stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')));
Parameters
Table 127-41 GATHER_FIXED_OBJECTS_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
The user statistics table identifier describing where to save the current statistics |
statid |
The (optional) identifier to associate with these statistics within stattab |
statown |
Schema containing stattab (if different from current schema) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
Usage Notes
You must have the SYSDBA
or ANALYZE
ANY
DICTIONARY
system privilege to execute this procedure.
Exceptions
ORA-20000
: Insufficient privileges.
ORA-20001
: Bad input value.
ORA-20002
: Bad user statistics table, may need to upgrade it.
This procedure gathers index statistics. It attempts to parallelize as much of the work as possible. Restrictions are described in the individual parameters. This operation will not parallelize with certain types of indexes, including cluster indexes, domain indexes, and bitmap join indexes. The granularity
and no_invalidate
arguments are not relevant to these types of indexes.
Syntax
DBMS_STATS.GATHER_INDEX_STATS ( ownname VARCHAR2, indname VARCHAR2, partname VARCHAR2 DEFAULT NULL, estimate_percent NUMBER DEFAULT to_estimate_percent_type (GET_PARAM('ESTIMATE_PERCENT')), stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, degree NUMBER DEFAULT to_degree_type(get_param('DEGREE')), granularity VARCHAR2 DEFAULT GET_PARAM('GRANULARITY'), no_invalidate BOOLEAN DEFAULT to_no_invalidate_type (GET_PARAM('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-42 GATHER_INDEX_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Schema of index to analyze |
indname |
Name of index |
partname |
Name of partition |
estimate_percent |
Percentage of rows to estimate (NULL means compute). The valid range is [0.000001,100] . Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default.The default value can be changed using the SET_PARAM Procedure. |
stattab |
User statistics table identifier describing where to save the current statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
statown |
Schema containing stattab (if different than ownname ) |
degree |
Degree of parallelism. The default for degree is NULL . The default value can be changed using the SET_PARAM Procedure. NULL means use of table default value that was specified by the DEGREE clause in the CREATE/ALTER INDEX statement. Use the constant DBMS_STATS.DEFAULT_DEGREE for the default value based on the initialization parameters. The AUTO_DEGREE value determines the degree of parallelism automatically. This is either 1 (serial execution) or DEFAULT_DEGREE (the system default value based on number of CPUs and initialization parameters) according to size of the object . |
granularity |
Granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
Gather statistics on object even if it is locked |
Exceptions
ORA-20000
: Index does not exist or insufficient privileges.
ORA-20001
: Bad input value.
This procedure gathers statistics for all objects in a schema.
Syntax
DBMS_STATS.GATHER_SCHEMA_STATS ( ownname VARCHAR2, estimate_percent NUMBER DEFAULT to_estimate_percent_type (get_param('ESTIMATE_PERCENT')), block_sample BOOLEAN DEFAULT FALSE, method_opt VARCHAR2 DEFAULT get_param('METHOD_OPT'), degree NUMBER DEFAULT to_degree_type(get_param('DEGREE')), granularity VARCHAR2 DEFAULT GET_PARAM('GRANULARITY'), cascade BOOLEAN DEFAULT to_cascade_type(get_param('CASCADE')), stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, options VARCHAR2 DEFAULT 'GATHER', objlist OUT ObjectTab, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE, obj_filter_list ObjectTab DEFAULT NULL); DBMS_STATS.GATHER_SCHEMA_STATS ( ownname VARCHAR2, estimate_percent NUMBER DEFAULT to_estimate_percent_type (get_param('ESTIMATE_PERCENT')), block_sample BOOLEAN DEFAULT FALSE, method_opt VARCHAR2 DEFAULT get_param('METHOD_OPT'), degree NUMBER DEFAULT to_degree_type(get_param('DEGREE')), granularity VARCHAR2 DEFAULT GET_PARAM('GRANULARITY'), cascade BOOLEAN DEFAULT to_cascade_type(get_param('CASCADE')), stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, options VARCHAR2 DEFAULT 'GATHER', statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE'), force BOOLEAN DEFAULT FALSE, obj_filter_list ObjectTab DEFAULT NULL);
Parameters
Table 127-43 GATHER_SCHEMA_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Schema to analyze (NULL means current schema) |
estimate_percent |
Percentage of rows to estimate (NULL means compute): The valid range is [0.000001,100]. Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default.The default value can be changed using the SET_PARAM Procedure. |
block_sample |
Whether or not to use random block sampling instead of random row sampling. Random block sampling is more efficient, but if the data is not randomly distributed on disk, then the sample values may be somewhat correlated. Only pertinent when doing an estimate statistics. |
method_opt |
Accepts:
size_clause is defined as size_clause := SIZE {integer | REPEAT | AUTO | SKEWONLY} - integer : Number of histogram buckets. Must be in the range [1,254].- REPEAT : Collects histograms only on the columns that already have histograms.- AUTO : Oracle determines the columns to collect histograms based on data distribution and the workload of the columns.- SKEWONLY : Oracle determines the columns to collect histograms based on the data distribution of the columns.
The default is |
degree |
Degree of parallelism. The default for degree is NULL . The default value can be changed using the SET_PARAM Procedure. NULL means use the table default value specified by the DEGREE clause in the CREATE TABLE or ALTER TABLE statement. Use the constant DBMS_STATS.DEFAULT_DEGREE to specify the default value based on the initialization parameters.The AUTO_DEGREE value determines the degree of parallelism automatically. This is either 1 (serial execution) or DEFAULT_DEGREE (the system default value based on number of CPUs and initialization parameters) according to size of the object. |
granularity |
Granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
cascade |
Gather statistics on the indexes as well.Index statistics gathering is not parallelized. Using this option is equivalent to running the GATHER_INDEX_STATS Procedure on each of the indexes in the schema in addition to gathering table and column statistics. Use the constant DBMS_STATS.AUTO_CASCADE to have Oracle determine whether index statistics to be collected or not. This is the default. The default value can be changed using the SET_PARAM Procedure. |
stattab |
User statistics table identifier describing where to save the current statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
options |
Further specification of which objects to gather statistics for:
|
objlist |
List of objects found to be stale or empty |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
Gather statistics on objects even if they are locked |
obj_filter_list |
A list of object filters. When provided, GATHER_SCHEMA_STATS will gather statistics only on objects which satisfy at least one object filter in the list as needed. In a single object filter, we can specify the constraints on the object attributes. The attribute values specified in the object filter are case- insensitive unless double-quoted. Wildcard is allowed in the attribute values. Suppose non-NULL values s1, s2, ... are specified for attributes a1, a2, ... in one object filter. An object o is said to satisfy this object filter if (o.a1 like s1) and (o.a2 like s2) and ... is true. See Applying an Object Filter List. |
Usage Notes
When you use a specific value for the sampling percentage, DBMS_STATS
honors it except for when:
The result is less than 2500 rows (too small a sample) and
The specified percentage is more than the certain percentage.
Statistics for external tables are not collected by this procedure.
Exceptions
ORA-20000
: Schema does not exist or insufficient privileges.
ORA-20001
: Bad input value.
Examples
Applying an Object Filter List
The following example specifies that any table with a "T
" prefix in the SAMPLE
schema and any table in the SYS
schema, if stale, will have statistics gathered upon it.
DECLARE filter_lst DBMS_STATS.OBJECTTAB := DBMS_STATS.OBJECTTAB(); BEGIN filter_lst.extend(2); filter_lst(1).ownname := 'SAMPLE'; filter_lst(1).objname := 'T%'; filter_lst(2).ownname := 'SYS'; DBMS_STATS.GATHER_SCHEMA_STATS(NULL, obj_filter_list => filter_lst, options => 'gather_stale'); END;
This procedure gathers system statistics.
Syntax
DBMS_STATS.GATHER_SYSTEM_STATS ( gathering_mode VARCHAR2 DEFAULT 'NOWORKLOAD', interval INTEGER DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-44 GATHER_SYSTEM_STATS Procedure Parameters
Parameter | Description |
---|---|
gathering_mode |
Mode values are:
|
interval |
Time, in minutes, to gather statistics. This parameter applies only when gathering_mode='INTERVAL' |
stattab |
Identifier of the user statistics table where the statistics will be saved |
statid |
Optional identifier associated with the statistics saved in the stattab |
statown |
Schema containing stattab (if different from current schema) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid input value.
ORA-20002
: Bad user statistics table; may need to be upgraded.
ORA-20003
: Unable to gather system statistics.
ORA-20004
: Error in the INTERVAL
mode: system parameter job_queue_processes
must be >0.
This procedure gathers table and column (and index) statistics. It attempts to parallelize as much of the work as possible, but there are some restrictions as described in the individual parameters.
Syntax
DBMS_STATS.GATHER_TABLE_STATS ( ownname VARCHAR2, tabname VARCHAR2, partname VARCHAR2 DEFAULT NULL, estimate_percent NUMBER DEFAULT to_estimate_percent_type (get_param('ESTIMATE_PERCENT')), block_sample BOOLEAN DEFAULT FALSE, method_opt VARCHAR2 DEFAULT get_param('METHOD_OPT'), degree NUMBER DEFAULT to_degree_type(get_param('DEGREE')), granularity VARCHAR2 DEFAULT GET_PARAM('GRANULARITY'), cascade BOOLEAN DEFAULT to_cascade_type(get_param('CASCADE')), stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-45 GATHER_TABLE_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Schema of table to analyze |
tabname |
Name of table |
partname |
Name of partition |
estimate_percent |
Percentage of rows to estimate (NULL means compute) The valid range is [0.000001,100]. Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default.The default value can be changed using the SET_PARAM Procedure. |
block_sample |
Whether or not to use random block sampling instead of random row sampling. Random block sampling is more efficient, but if the data is not randomly distributed on disk, then the sample values may be somewhat correlated. Only pertinent when doing an estimate statistics. |
method_opt |
Accepts either of the following options, or both in combination:
- integer : Number of histogram buckets. Must be in the range [1,254].- REPEAT : Collects histograms only on the columns that already have histograms.- AUTO : Oracle determines the columns to collect histograms based on data distribution and the workload of the columns.- SKEWONLY : Oracle determines the columns to collect histograms based on the data distribution of the columns.- column_name : name of a column- extension : can be either a column group in the format of (column_name , colume_name [, ...]) or an expression
The default is |
degree |
Degree of parallelism. The default for degree is NULL . The default value can be changed using the SET_PARAM Procedure NULL means use the table default value specified by the DEGREE clause in the CREATE TABLE or ALTER TABLE statement. Use the constant DBMS_STATS.DEFAULT_DEGREE to specify the default value based on the initialization parameters. The AUTO_DEGREE value determines the degree of parallelism automatically. This is either 1 (serial execution) or DEFAULT_DEGREE (the system default value based on number of CPUs and initialization parameters) according to size of the object. |
granularity |
Granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
cascade |
Gathers statistics on the indexes for this table. Using this option is equivalent to running the GATHER_INDEX_STATS Procedure on each of the table's indexes. Use the constant DBMS_STATS.AUTO_CASCADE to have Oracle determine whether index statistics are to be collected or not. This is the default. The default value can be changed using the SET_PARAM Procedure. |
stattab |
User statistics table identifier describing where to save the current statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
Gather statistics of table even if it is locked |
Usage Notes
Index statistics collection can be parellelized except for cluster, domain and join indexes.
Exceptions
ORA-20000
: Table does not exist or insufficient privileges.
ORA-20001
: Bad input value.
Examples
An extension can be either a column group (see Example 1) or an expression (see Example 2).
Example 1
DBMS_STATS.GATHER_TABLE_STATS( 'SH', 'SALES', method_opt => 'FOR COLUMNS (empno, deptno)');
Example 2
DBMS_STATS.GATHER_TABLE_STATS( 'SH', 'SALES', method_opt => 'FOR COLUMNS (sal+comm)');
This procedure generates object statistics from previously collected statistics of related objects. The currently supported objects are b-tree and bitmap indexes.
Syntax
DBMS_STATS.GENERATE_STATS ( ownname VARCHAR2, objname VARCHAR2, organized NUMBER DEFAULT 7, force BOOLEAN default FALSE);
Parameters
Table 127-46 GENERATE_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Schema of object |
objname |
Name of object |
organized |
Amount of ordering associated between the index and its underlying table. A heavily organized index would have consecutive index keys referring to consecutive rows on disk for the table (the same block). A heavily disorganized index would have consecutive keys referencing different table blocks on disk.
This parameter is only used for b-tree indexes. The number can be in the range of 0-10, with 0 representing a completely organized index and 10 a completely disorganized one. |
force |
If TRUE , generates statistics for the target object even if it is locked |
Usage Notes
For fully populated schemas, the gather procedures should be used instead when more accurate statistics are desired.
Exceptions
ORA-20000
: Unsupported object type of object does not exist.
ORA-20001
: Invalid option or invalid statistics.
These procedures gets all column-related information. In the form of this procedure that deals with user-defined statistics, the statistics type returned is the type stored, in addition to the user-defined statistics.
Syntax
DBMS_STATS.GET_COLUMN_STATS ( ownname VARCHAR2, tabname VARCHAR2, colname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, distcnt OUT NUMBER, density OUT NUMBER, nullcnt OUT NUMBER, srec OUT StatRec, avgclen OUT NUMBER, statown VARCHAR2 DEFAULT NULL);
Use the following for user-defined statistics:
DBMS_STATS.GET_COLUMN_STATS ( ownname VARCHAR2, tabname VARCHAR2, colname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, ext_stats OUT RAW, stattypown OUT VARCHAR2 DEFAULT NULL, stattypname OUT VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-47 GET_COLUMN_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
tabname |
Name of the table to which this column belongs |
colname |
Name of the column or extension |
partname |
Name of the table partition from which to get the statistics. If the table is partitioned and if partname is NULL , then the statistics are retrieved from the global table level. |
stattab |
User statistics table identifier describing from where to retrieve the statistics. If stattab is NULL , then the statistics are retrieved directly from the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ) |
ext_stats |
The user-defined statistics |
stattypown |
Schema of the statistics type |
stattypname |
Name of the statistics type |
distcnt |
Number of distinct values |
density |
Column density |
nullcnt |
Number of NULLs |
srec |
Structure holding internal representation of column minimum, maximum, and histogram values |
avgclen |
Average length of the column (in bytes) |
statown |
Schema containing stattab (if different than ownname ) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges or no statistics have been stored for requested object.
These procedures get all index-related information. In the form of this procedure that deals with user-defined statistics, the statistics type returned is the type stored, in addition to the user-defined statistics.
Syntax
DBMS_STATS.GET_INDEX_STATS ( ownname VARCHAR2, indname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, numrows OUT NUMBER, numlblks OUT NUMBER, numdist OUT NUMBER, avglblk OUT NUMBER, avgdblk OUT NUMBER, clstfct OUT NUMBER, indlevel OUT NUMBER, statown VARCHAR2 DEFAULT NULL, cachedblk OUT NUMBER, cachehit OUT NUMBER); DBMS_STATS.GET_INDEX_STATS ( ownname VARCHAR2, indname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, numrows OUT NUMBER, numlblks OUT NUMBER, numdist OUT NUMBER, avglblk OUT NUMBER, avgdblk OUT NUMBER, clstfct OUT NUMBER, indlevel OUT NUMBER, statown VARCHAR2 DEFAULT NULL, guessq OUT NUMBER, cachedblk OUT NUMBER, cachehit OUT NUMBER);
Use the following for user-defined statistics:
DBMS_STATS.GET_INDEX_STATS ( ownname VARCHAR2, indname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, ext_stats OUT RAW, stattypown OUT VARCHAR2 DEFAULT NULL, stattypname OUT VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, cachedblk OUT NUMBER, cachehit OUT NUMBER);
Parameters
Table 127-48 GET_INDEX_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
indname |
Name of the index |
partname |
Name of the index partition for which to get the statistics. If the index is partitioned and if partname is NULL , then the statistics are retrieved for the global index level. |
stattab |
User statistics table identifier describing from where to retrieve the statistics. If stattab is NULL , then the statistics are retrieved directly from the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ) |
ext_stats |
The user-defined statistics |
stattypown |
Schema of the statistics type |
stattypname |
Name of the statistics type |
numrows |
Number of rows in the index (partition) |
numlblks |
Number of leaf blocks in the index (partition) |
numdist |
Number of distinct keys in the index (partition) |
avglblk |
Average integral number of leaf blocks in which each distinct key appears for this index (partition) |
avgdblk |
Average integral number of data blocks in the table pointed to by a distinct key for this index (partition) |
clstfct |
Clustering factor for the index (partition) |
indlevel |
Height of the index (partition) |
statown |
Schema containing stattab (if different than ownname ) |
guessq |
Guess quality for the index (partition) |
cachedblk |
The average number of blocks in the buffer cache for the segment (index/table/index partition/table partition) |
cachehit |
The average cache hit ratio for the segment (index/table/index partition/table partition) |
Usage Notes
The Optimizer uses the cached data to estimate number of cached blocks for index or statistics table access. The total cost of the operation will be combined from the I/O cost of reading not cached blocks from disk, the CPU cost of getting cached blocks from the buffer cache, and the CPU cost of processing the data.
Oracle maintains cachedblk
and cachehit
at all times but uses correspondent caching statistics for optimization as part of the table and index statistics only when the user calls DBMS_STATS.GATHER_[TABLE/INDEX/SCHEMA/DATABASE]_STATS
procedure for auto mode or DBMS_STATS.GATHER_SYSTEM_STATS
for manual mode. In order to prevent the user from utilizing inaccurate and unreliable data, the optimizer will compute a 'confidence factor' for each cachehit
and a cachedblk
for each object. If the 'confidence factor' for the value meets confidence criteria, this value will be used, otherwise the defaults will be used.
The automatic maintenance algorithm for object caching statistics assumes that there is only one major workload for the system and adjusts statistics to this workload, ignoring other "minor" workloads. If this is not the case, you must use manual mode for maintaining object caching statistics.
The object caching statistics maintenance algorithm for auto mode prevents you from using statistics in the following situations
When not enough data has been analyzed, such as when an object has been recently create
When the system does not have one major workload resulting in averages not corresponding to real values.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges or no statistics have been stored for requested object.
Note:
This subprogram has been replaced by improved technology and is maintained only for purposes of backward compatibility. In this case, use the GET_PREFS Function.See also Deprecated Subprograms.
This function returns the default value of parameters of DBMS_STATS
procedures.
Syntax
DBMS_STATS.GET_PARAM ( pname IN VARCHAR2) RETURN VARCHAR2;
Parameters
Exceptions
ORA-20001
: Invalid input values
This function returns the default value of the specified preference.
Syntax
DBMS_STATS.GET_PREFS ( pname IN VARCHAR2, ownname IN VARCHAR2 DEFAULT NULL, tabname IN VARCHAR2 DEFAULT NULL) RETURN VARCHAR2;
Parameters
Table 127-50 GET_PREFS Function Parameters
Parameter | Description |
---|---|
pname |
Preference name. The default value for following parameters can be set:
|
. | CASCADE - The value determines whether or not index statistics are collected as part of gathering table statistics. |
. | DEGREE - The value determines degree of parallelism used for gathering statistics. |
. | ESTIMATE_PERCENT - The value determines the percentage of rows to estimate. The valid range is [0.000001,100]. Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default. |
. | METHOD_OPT - The value controls column statistics collection and histogram creation. It accepts either of the following options, or both in combination:
- integer : Number of histogram buckets. Must be in the range [1,254].- REPEAT : Collects histograms only on the columns that already have histograms.- AUTO : Oracle determines the columns to collect histograms based on data distribution and the workload of the columns.- SKEWONLY : Oracle determines the columns to collect histograms based on the data distribution of the columns.- column_name : name of a column- extension : can be either a column group in the format of (column_name, colume_name [, ...]) or an expression
The default is |
. | NO_INVALIDATE - The value controls the invalidation of dependent cursors of the tables for which statistics are being gathered. Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE to have Oracle decide when to invalidate dependent cursors. This is the default. |
. | GRANULARITY - The value determines granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
. | PUBLISH - This value determines whether or not newly gathered statistics will be published once the gather job has completed. Prior to Prior to Oracle Database 11g, Release 1 (11.1), once a statistic gathering job completed the new statistics were automatically published into the dictionary tables. The user now has the ability to gather statistics but not publish them immediately. This allows the DBA to test the new statistics before publishing them. |
. | INCREMENTAL - This value determines whether or not the global statistics of a partitioned table will be maintained without doing a full table scan. With partitioned tables it is very common to load new data into a new partition. As new partitions are added and data loaded, the global table statistics need to be kept up to date. Oracle will update the global table statistics by scanning only the partitions that have been changed instead of the entire table if the following conditions hold:
If the |
. | STALE_PERCENT - This value determines the percentage of rows in a table that have to change before the statistics on that table are deemed stale and should be regathered. The default value is 10%. |
ownname |
Owner name |
tabname |
Table name |
Exceptions
ORA-20001
: Invalid input values
Usage Notes
If the ownname and tabname are provided and a preference has been entered for the table, the function returns the preference as specified for the table. In all other cases it returns the global preference if it has been specified, otherwise the default value is returned.
This function returns oldest timestamp where statistics history is available.Users cannot restore statistics to a timestamp older than this one.
Syntax
DBMS_STATS.GET_STATS_HISTORY_AVAILABILITY RETURN TIMESTAMP WITH TIMEZONE;
This function returns the current retention value.
Syntax
DBMS_STATS.GET_STATS_HISTORY_RETENTION RETURN NUMBER;
This procedure gets system statistics from stattab
, or from the dictionary if stattab
is NULL
.
Syntax
DBMS_STATS.GET_SYSTEM_STATS ( status OUT VARCHAR2, dstart OUT DATE, dstop OUT DATE, pname VARCHAR2, pvalue OUT NUMBER, stattab IN VARCHAR2 DEFAULT NULL, statid IN VARCHAR2 DEFAULT NULL, statown IN VARCHAR2 DEFAULT NULL);
Parameters
Table 127-51 GET_SYSTEM_STATS Procedure Parameters
Parameter | Description |
---|---|
status |
Output is one of the following:
|
dstart |
Date when statistics gathering started.
If |
dstop |
Date when statistics gathering stopped.
|
pname |
The parameter name to get, which can have one of the following values:
|
pvalue |
The parameter value to get |
stattab |
Identifier of the user statistics table where the statistics will be obtained. If stattab is null, the statistics will be obtained from the dictionary. |
statid |
Optional identifier associated with the statistics saved in the stattab |
statown |
Schema containing stattab (if different from current schema) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20002
: Bad user statistics table; may need to be upgraded.
ORA-20003
: Unable to gather system statistics.
ORA-20004
: Parameter does not exist.
This procedure gets all table-related information.
Syntax
DBMS_STATS.GET_TABLE_STATS ( ownname VARCHAR2, tabname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, numrows OUT NUMBER, numblks OUT NUMBER, avgrlen OUT NUMBER, statown VARCHAR2 DEFAULT NULL, cachedblk OUT NUMBER, cachehit OUT NUMBER);
Parameters
Table 127-52 GET_TABLE_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema. |
tabname |
Name of the table to which this column belongs. |
partname |
Name of the table partition from which to get the statistics. If the table is partitioned and if partname is NULL , then the statistics are retrieved from the global table level. |
stattab |
User statistics table identifier describing from where to retrieve the statistics. If stattab is NULL , then the statistics are retrieved directly from the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ). |
numrows |
Number of rows in the table (partition). |
numblks |
Number of blocks the table (partition) occupies. |
avgrlen |
Average row length for the table (partition). |
statown |
Schema containing stattab (if different than ownname ). |
cachedblk |
|
cachehit |
Usage Notes
The Optimizer uses the cached data to estimate number of cached blocks for index or statistics table access. The total cost of the operation will be combined from the I/O cost of reading not cached blocks from disk, the CPU cost of getting cached blocks from the buffer cache, and the CPU cost of processing the data.
Oracle maintains cachedblk
and cachehit
at all times but uses correspondent caching statistics for optimization as part of the table and index statistics only when the user calls DBMS_STATS.GATHER_[TABLE/INDEX/SCHEMA/DATABASE]_STATS
procedure for auto mode or DBMS_STATS.GATHER_SYSTEM_STATS
for manual mode. In order to prevent the user from utilizing inaccurate and unreliable data, the optimizer will compute a 'confidence factor' for each cachehit
and a cachedblk
for each object. If the 'confidence factor' for the value meets confidence criteria, this value will be used, otherwise the defaults will be used.
The automatic maintenance algorithm for object caching statistics assumes that there is only one major workload for the system and adjusts statistics to this workload, ignoring other "minor" workloads. If this is not the case, you must use manual mode for maintaining object caching statistics.
The object caching statistics maintenance algorithm for auto mode prevents you from using statistics in the following situations
When not enough data has been analyzed, such as when an object has been recently create
When the system does not have one major workload resulting in averages not corresponding to real values.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges or no statistics have been stored for requested object
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure retrieves statistics for a particular column from the user statistics table identified by stattab
and stores them in the dictionary.
Syntax
DBMS_STATS.IMPORT_COLUMN_STATS ( ownname VARCHAR2, tabname VARCHAR2, colname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-53 IMPORT_COLUMN_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
The name of the schema |
tabname |
The name of the table to which this column belongs |
colname |
Name of the column or extension |
partname |
The name of the table partition. If the table is partitioned and if partname is NULL , then global and partition column statistics are imported. |
stattab |
The user statistics table identifier describing from where to retrieve the statistics |
statid |
The (optional) identifier to associate with these statistics within stattab |
statown |
The schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
If set to TRUE , imports statistics even if statistics are locked |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values in the user statistics table.
ORA-20005
: Object statistics are locked.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure is used to import the statistics preferences of all the tables, excluding the tables owned by Oracle. These tables can by included by passing TRUE
for the add_sys
parameter.
Syntax
DBMS_STATS.IMPORT_DATABASE_PREFS ( stattab IN VARCHAR2, statid IN VARCHAR2 DEFAULT NULL, statown IN VARCHAR2 DEFAULT NULL add_sys IN BOOLEAN DEFAULT FALSE);
Parameters
Table 127-54 IMPORT_DATABASE_PREFS Procedure Parameters
Parameter | Description |
---|---|
stattab |
Statistics table name where to import the statistics |
statid | Optional identifier to associate with these statistics within stattab |
statown | Schema containing stattab (if different than ownname ) |
add_sys |
Value TRUE will include the Oracle-owned tables |
Exceptions
ORA-20000
: Insufficient privileges.
Usage Notes
To run this procedure, you need to have the SYSDBA role, or both ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privileges.
Oracle does not support export or import of statistics across databases of different character sets.
Examples
DBMS_STATS.IMPORT_DATABASE_PREFS('STATTAB', statown=>'SH');
This procedure retrieves statistics for all objects in the database from the user statistics table(s) and stores them in the dictionary.
Syntax
DBMS_STATS.IMPORT_DATABASE_STATS ( stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-55 IMPORT_DATABASE_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
User statistics table identifier describing from where to retrieve the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
statown |
Schema containing stattab (if different from current schema) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
Overrides statistics locked at the object (table) level:
|
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values in the user statistics table.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure retrieves statistics for all dictionary schemas ('SYS
', 'SYSTEM
' and RDBMS component schemas) from the user statistics table and stores them in the dictionary.
Syntax
DBMS_STATS.IMPORT_DICTIONARY_STATS ( stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-56 IMPORT_DICTIONARY_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
User statistics table identifier describing from where to retrieve the statistics |
statid |
The (optional) identifier to associate with these statistics within stattab |
statown |
Schema containing stattab (if different from current schema) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
Overrides statistics lock at the object (table) level:
|
Usage Notes
You must have the SYSDBA
or both ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privilege to execute this procedure.
Oracle does not support export or import of statistics across databases of different character sets.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values in the user statistics table.
ORA-20002
: Bad user statistics table, may need to upgrade it.
This procedure retrieves statistics for fixed tables from the user statistics table(s) and stores them in the dictionary.
Syntax
DBMS_STATS.IMPORT_FIXED_OBJECTS_STATS ( stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-57 IMPORT_FIXED_OBJECTS_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
User statistics table identifier describing from where to retrieve the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
statown |
Schema containing stattab (if different from current schema) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
Overrides statistics lock:
|
Usage Notes
You must have the SYSDBA
or ANALYZE
ANY
DICTIONARY
system privilege to execute this procedure.
Oracle does not support export or import of statistics across databases of different character sets.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values in the user statistics table.
ORA-20002
: Bad user statistics table, may need to upgrade it.
This procedure retrieves statistics for a particular index from the user statistics table identified by stattab
and stores them in the dictionary.
Syntax
DBMS_STATS.IMPORT_INDEX_STATS ( ownname VARCHAR2, indname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-58 IMPORT_INDEX_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
indname |
Name of the index |
partname |
Name of the index partition. If the index is partitioned and if partname is NULL , then global and partition index statistics are imported. |
stattab |
User statistics table identifier describing from where to retrieve the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab . |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
Imports statistics even if index statistics are locked |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges
ORA-20001
: Invalid or inconsistent values in the user statistics table
ORA-20005
: Object statistics are locked
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure is used to import the statistics preferences of all the tables owned by the specified owner name.
Syntax
DBMS_STATS.IMPORT_SCHEMA_PREFS ( ownname IN VARCHAR2, stattab IN VARCHAR2, statid IN VARCHAR2 DEFAULT NULL, statown IN VARCHAR2 DEFAULT NULL);
Parameters
Table 127-59 IMPORT_SCHEMA_PREFS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name |
stattab |
Statistics table name from where to import the statistics |
statid | (Optional) Identifier to associate with these statistics within stattab |
statown | Schema containing stattab (if other than ownname ) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges
Usage Notes
To run this procedure, you need to connect as owner, or have the SYSDBA
privilege, or have the ANALYZE
ANY
system privilege.
All arguments are of type VARCHAR2
and values are enclosed in quotes.
Oracle does not support export or import of statistics across databases of different character sets.
Examples
DBMS_STATS.IMPORT_SCHEMA_PREFS('SH', 'STAT');
This procedure retrieves statistics for all objects in the schema identified by ownname from the user statistics table and stores them in the dictionary.
Syntax
DBMS_STATS.IMPORT_SCHEMA_STATS ( ownname VARCHAR2, stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULTto_no_invalidate_type( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-60 IMPORT_SCHEMA_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
stattab |
User statistics table identifier describing from where to retrieve the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
Overrides statistics locked at the object (table) level:
|
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values in the user statistics table.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
http://usunnab06.us.oracle.com:80/servers/MifChecker/Out/Y10312_01.htm retrieves system statistics from the user statistics table, identified by stattab, and stores the statistics in the dictionary.
Syntax
DBMS_STATS.IMPORT_SYSTEM_STATS ( stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL);
Parameters
Table 127-61 IMPORT_SYSTEM_STATS Procedure Parameters
Parameter | Description |
---|---|
stattab |
Identifier of the user statistics table where the statistics will be retrieved |
statid |
Optional identifier associated with the statistics retrieved from the stattab |
statown |
Schema containing stattab (if different from current schema) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values in the user statistics table.
ORA-20002
: Bad user statistics table; may need to be upgraded.
ORA-20003
: Unable to import system statistics.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure is used to set the statistics preferences of the specified table in the specified schema.
Syntax
DBMS_STATS.IMPORT_TABLE_PREFS ( ownname IN VARCHAR2, tabname IN VARCHAR2, stattab IN VARCHAR2, statid IN VARCHAR2 DEFAULT NULL, statown IN VARCHAR2 DEFAULT NULL);
Parameters
Table 127-62 IMPORT_TABLE_PREFS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name |
tabname |
Table name |
stattab |
Statistics table name from where to import the statistics |
statid | (Optional) Identifier to associate with these statistics within stattab |
statown | Schema containing stattab (if other than ownname) |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
Usage Notes
To run this procedure, you need to connect as owner of the table, or have the ANALYZE
ANY
system privilege.
All arguments are of type VARCHAR2
and values are enclosed in quotes.
Oracle does not support export or import of statistics across databases of different character sets.
Examples
DBMS_STATS.IMPORT_TABLE_PREFS('SH', 'SALES', 'STAT');
This procedure retrieves statistics for a particular table from the user statistics table identified by stattab
and stores them in the dictionary. Cascade results in all index statistics associated with the specified table being imported as well.
Syntax
DBMS_STATS.IMPORT_TABLE_STATS ( ownname VARCHAR2, tabname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2, statid VARCHAR2 DEFAULT NULL, cascade BOOLEAN DEFAULT TRUE, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-63 IMPORT_TABLE_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
tabname |
Name of the table |
partname |
Name of the table partition. If the table is partitioned and if partname is NULL , then global and partition table statistics are imported. |
stattab |
User statistics table identifier describing from where to retrieve the statistics |
statid |
Identifier (optional) to associate with these statistics within stattab |
cascade |
If true, then column and index statistics for this table are also imported |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
Imports statistics even if table statistics are locked |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values in the user statistics table.
Usage Notes
Oracle does not support export or import of statistics across databases of different character sets.
This procedure enables the user to lock statistics for a partition.
Syntax
DBMS_STATS.LOCK_PARTITION_STATS ( ownname VARCHAR2, tabname VARCHAR2, partname VARCHAR2);
Parameters
Table 127-64 LOCK_PARTITION_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema to lock |
tabname |
Name of the table |
partname |
Partition name |
This procedure locks the statistics of all tables of a schema.
Syntax
DBMS_STATS.LOCK_SCHEMA_STATS ( ownname VARCHAR2);
Parameters
Table 127-65 LOCK_SCHEMA_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
The name of the schema to lock |
Usage Notes
See "Usage Notes" for LOCK_TABLE_STATS Procedure.
This procedure locks the statistics on the table.
Syntax
DBMS_STATS.LOCK_TABLE_STATS ( ownname VARCHAR2, tabname VARCHAR2);
Parameters
Table 127-66 LOCK_TABLE_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
The name of the schema |
tabname |
The name of the table |
Usage Notes
When statistics on a table are locked, all the statistics depending on the table, including table statistics, column statistics, histograms and statistics on all dependent indexes, are considered to be locked.
The SET_*,
DELETE_*,
IMPORT_*,
GATHER_*
procedures that modify statistics in the dictionary of an individual table, index or column will raise an error if statistics of the object is locked.
Procedures that operates on multiple objects (such as GATHER_SCHEMA_STATS
) will skip modifying the statistics of an object if it is locked. Many procedures have force argument to override the lock.
This procedure either freezes the current set of the statistics or keeps the statistics empty (uncollected) to use Dynamic Sampling.
The locked or unlocked state is not exported along with the table statistics when using EXPORT_*_STATS
procedures.
These procedures convert user-specified minimum, maximum, and histogram endpoint datatype-specific values into Oracle's internal representation for future storage using SET_COLUMN_STATS
.
Syntax
DBMS_STATS.PREPARE_COLUMN_VALUES ( srec IN OUT StatRec, charvals CHARARRAY); DBMS_STATS.PREPARE_COLUMN_VALUES ( srec IN OUT StatRec, datevals DATEARRAY); DBMS_STATS.PREPARE_COLUMN_VALUES ( srec IN OUT StatRec, dblvals DBLARRAY); DBMS_STATS.PREPARE_COLUMN_VALUES ( srec IN OUT StatRec, fltvals FLTARRAY); DBMS_STATS.PREPARE_COLUMN_VALUES ( srec IN OUT StatRec, numvals NUMARRAY); DBMS_STATS.PREPARE_COLUMN_VALUES ( srec IN OUT StatRec, rawvals RAWARRAY);
Pragmas
pragma restrict_references(prepare_column_values, WNDS, RNDS, WNPS, RNPS); pragma restrict_references(prepare_column_values_nvarchar, WNDS, RNDS, WNPS, RNPS); pragma restrict_references(prepare_column_values_rowid, WNDS, RNDS, WNPS, RNPS);
Parameters
Table 127-67 PREPARE_COLUMN_VALUES Procedure Parameters
Parameter | Description |
---|---|
srec.epc |
Number of values specified in charvals , datevals , dblvals , fltvals , numvals , or rawvals . This value must be between 2 and 256, inclusive, and it should be set to 2 for procedures which do not allow histogram information (nvarchar and rowid ).
The first corresponding array entry should hold the minimum value for the column, and the last entry should hold the maximum. If there are more than two entries, then all the others hold the remaining height-balanced or frequency histogram endpoint values (with in-between values ordered from next-smallest to next-largest). This value may be adjusted to account for compression, so the returned value should be left as is for a call to |
srec.bkvals |
If you want a frequency distribution, then this array contains the number of occurrences of each distinct value specified in charvals , datevals , dblvals , fltvals , numvals , or rawvals . Otherwise, it is merely an output parameter, and it must be set to NULL when this procedure is called. |
Datatype-specific input parameters (use one) are shown in Table 127-68.
Table 127-68 Datatype-Specific Input Parameters
Type | Description |
---|---|
charvals |
The array of values when the column type is character-based. Up to the first 32 bytes of each string should be provided. Arrays must have between 2 and 256 entries, inclusive. If the datatype is fixed CHAR , the strings must be space-padded to 15 characters for correct normalization. |
datevals |
The array of values when the column type is date-based |
dblvals |
The array of values when the column type is double-based |
fltvals |
The array of values when the column type is float-based |
numvals |
The array of values when the column type is numeric-based |
rawvals |
The array of values when the column type is RAW . Up to the first 32 bytes of each strings should be provided. |
nvmin, nvmax |
The minimum and maximum values when the column type is national character set based. No histogram information can be provided for a column of this type. If the datatype is fixed CHAR , the strings must be space-padded to 15 characters for correct normalization. |
rwmin, rwmax |
The minimum and maximum values when the column type is rowid . No histogram information is provided for a column of this type. |
Output Parameters
Table 127-69 PREPARE_COLUMN_VALUES Procedure Output Parameters
Parameter | Description |
---|---|
srec.minval |
Internal representation of the minimum suitable for use in a call to SET_COLUMN_STATS |
srec.maxval |
Internal representation of the maximum suitable for use in a call to SET_COLUMN_STATS |
srec.bkvals |
Array suitable for use in a call to SET_COLUMN_STATS |
srec.novals |
Array suitable for use in a call to SET_COLUMN_STATS |
Exceptions
ORA-20001
: Invalid or inconsistent input values.
This procedure converts user-specified minimum, maximum, and histogram endpoint datatype-specific values into Oracle's internal representation for future storage using SET_COLUMN_STATS
.
Syntax
DBMS_STATS.PREPARE_COLUMN_VALUES_NVARCHAR2 ( srec IN OUT StatRec, nvmin NVARCHAR2, nvmax NVARCHAR2);
Pragmas
pragma restrict_references(prepare_column_values_nvarchar, WNDS, RNDS, WNPS, RNPS);
Parameters
Table 127-70 PREPARE_COLUMN_VALUES_NVARCHAR2 Procedure Parameters
Parameter | Description |
---|---|
srec.epc |
Number of values specified in charvals , datevals , dblvals , fltvals , numvals , or rawvals . This value must be between 2 and 256, inclusive, and it should be set to 2 for procedures which do not allow histogram information (nvarchar and rowid ).
The first corresponding array entry should hold the minimum value for the column, and the last entry should hold the maximum. If there are more than two entries, then all the others hold the remaining height-balanced or frequency histogram endpoint values (with in-between values ordered from next-smallest to next-largest). This value may be adjusted to account for compression, so the returned value should be left as is for a call to |
srec.bkvals |
If you want a frequency distribution, then this array contains the number of occurrences of each distinct value specified in charvals , datevals , dblvals , fltvals , numvals , or rawvals . Otherwise, it is merely an output parameter, and it must be set to NULL when this procedure is called. |
Datatype-specific input parameters (use one) are shown in Table 127-68.
Table 127-71 Datatype-Specific Input Parameters
Type | Description |
---|---|
nvmin, nvmax |
The minimum and maximum values when the column type is national character set based. No histogram information can be provided for a column of this type. If the datatype is fixed CHAR , the strings must be space-padded to 15 characters for correct normalization. |
Output Parameters
Table 127-72 PREPARE_COLUMN_VALUES Procedure Output Parameters
Parameter | Description |
---|---|
srec.minval |
Internal representation of the minimum suitable for use in a call to SET_COLUMN_STATS |
srec.maxval |
Internal representation of the maximum suitable for use in a call to SET_COLUMN_STATS |
srec.bkvals |
Array suitable for use in a call to SET_COLUMN_STATS . |
srec.novals |
Array suitable for use in a call to SET_COLUMN_STATS |
Exceptions
ORA-20001
: Invalid or inconsistent input values.
This procedure converts user-specified minimum, maximum, and histogram endpoint datatype-specific values into Oracle's internal representation for future storage using SET_COLUMN_STATS
.
Syntax
DBMS_STATS.PREPARE_COLUMN_VALUES_ROWID ( srec IN OUT StatRec, rwmin ROWID, rwmax ROWID);
Pragmas
pragma restrict_references(prepare_column_values_rowid, WNDS, RNDS, WNPS, RNPS);
Parameters
Table 127-73 PREPARE_COLUMN_VALUES_ROWID Procedure Parameters
Parameter | Description |
---|---|
srec.epc |
Number of values specified in charvals , datevals , dblvals , fltvals , numvals , or rawvals . This value must be between 2 and 256, inclusive, and it should be set to 2 for procedures which do not allow histogram information (nvarchar and rowid ).
The first corresponding array entry should hold the minimum value for the column, and the last entry should hold the maximum. If there are more than two entries, then all the others hold the remaining height-balanced or frequency histogram endpoint values (with in-between values ordered from next-smallest to next-largest). This value may be adjusted to account for compression, so the returned value should be left as is for a call to |
srec.bkvals |
If you want a frequency distribution, then this array contains the number of occurrences of each distinct value specified in charvals , datevals , dblvals , fltvals , numvals , or rawvals . Otherwise, it is merely an output parameter, and it must be set to NULL when this procedure is called. |
Datatype-specific input parameters (use one) are shown in Table 127-68.
Table 127-74 Datatype-Specific Input Parameters
Type | Description |
---|---|
rwmin, rwmax |
The minimum and maximum values when the column type is rowid . No histogram information is provided for a column of this type. |
Output Parameters
Table 127-75 PREPARE_COLUMN_VALUES Procedure Output Parameters
Parameter | Description |
---|---|
srec.minval |
Internal representation of the minimum suitable for use in a call to SET_COLUMN_STATS . |
srec.maxval |
Internal representation of the maximum suitable for use in a call to SET_COLUMN_STATS . |
srec.bkvals |
Array suitable for use in a call to SET_COLUMN_STATS . |
srec.novals |
Array suitable for use in a call to SET_COLUMN_STATS . |
Exceptions
ORA-20001
: Invalid or inconsistent input values.
This procedure is used to publish the statistics gathered and stored as pending.
Syntax
DBMS_STATS.PUBLISH_PENDING_STATS ( ownname IN VARCHAR2 DEFAULT USER, tabname IN VARCHAR2, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type(get_param('NO_INVALIDATE')), force IN BOOLEAN DEFAULT FALSE);
Parameters
Table 127-76 PUBLISH_PENDING_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name |
tabname | Table name |
no_invalidate | Do not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force | If TRUE , will override the lock |
Exceptions
ORA-20000
: Insufficient privileges
Usage Notes
If the parameter tabname
is NULL
then publish applies to all tables of the specified schema.
The default owner/schema is the user who runs the procedure.
To run this procedure, you need to have the same privilege for gathering statistics on the tables that will be touched by this procedure.
Examples
DBMS_STATS.PUBLISH_PENDING_STATS ('SH', null);
This procedure purges old versions of statistics saved in the dictionary. To run this procedure, you must have the SYSDBA
or both ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privilege.
Syntax
DBMS_STATS.PURGE_STATS( before_timestamp TIMESTAMP WITH TIME ZONE);
Parameters
Table 127-77 PURGE_STATS Procedure Parameters
Parameter | Description |
---|---|
before_timestamp |
Versions of statistics saved before this timestamp are purged. If NULL , it uses the purging policy used by automatic purge. The automatic purge deletes all history older than the older of (current time - statistics history retention) and (time of recent analyze in the system - 1). The statistics history retention value can be changed using ALTER_STATS_HISTORY_RETENTION Procedure.The default is 31 days. |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values.
This procedurere sets global preference, such as CASCADE
, ESTIMATE_PERCENT
and GRANULARITY
, to default values. This reverses the global preferences set by the SET_GLOBAL_PREFS Procedure.
Syntax
DBMS_STATS.RESET_GLOBAL_PREFS_DEFAULTS;
This procedure resets the default values of all parameters to Oracle recommended values.
Syntax
DBMS_STATS.RESET_PARAM_DEFAULTS;
This procedure restores statistics of all tables of the database as of a specified timestamp (as_of_timestamp
).
Syntax
DBMS_STATS.RESTORE_DATABSE_STATS( as_of_timestamp TIMESTAMP WITH TIME ZONE, force BOOLEAN DEFAULT FALSE, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type (GET_PARAM('NO_INVALIDATE')));
Parameters
Table 127-78 RESTORE_DATABASE_STATS Procedure Parameters
Parameter | Description |
---|---|
as_of_timestamp |
The timestamp to which to restore statistics |
force |
Restores statistics even if their statistics are locked |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values.
ORA-20006
: Unable to restore statistics, statistics history not available.
This procedure restores statistics of all dictionary tables (tables of 'SYS
', 'SYSTEM
' and RDBMS component schemas) as of a specified timestamp (as_of_timestamp
).
Syntax
DBMS_STATS.RESTORE_DICTIONARY_STATS( as_of_timestamp TIMESTAMP WITH TIME ZONE, force BOOLEAN DEFAULT FALSE, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type (GET_PARAM('NO_INVALIDATE')));
Parameters
Table 127-79 RESTORE_DICTIONARY_STATS Procedure Parameters
Parameter | Description |
---|---|
as_of_timestamp |
The timestamp to which to restore statistics |
force |
Restores statistics even if their statistics are locked |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
Usage Notes
To run this procedure, you must have the SYSDBA
or both ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privilege.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values.
ORA-20006
: Unable to restore statistics, statistics history not available.
This procedure restores statistics of all fixed tables as of a specified timestamp (as_of_timestamp
).
Syntax
DBMS_STATS.RESTORE_FIXED_OBJECTS_STATS( as_of_timestamp TIMESTAMP WITH TIME ZONE, force BOOLEAN DEFAULT FALSE, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type (GET_PARAM('NO_INVALIDATE')));
Parameters
Table 127-80 RESTORE_FIXED_OBJECTS_STATS Procedure Parameters
Parameter | Description |
---|---|
as_of_timestamp |
The timestamp to which to restore statistics |
force |
Restores statistics even if their statistics are locked |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
Usage Notes
To run this procedure, you must have the SYSDBA
or ANALYZE
ANY
DICTIONARY
system privilege.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values.
ORA-20006
: Unable to restore statistics, statistics history not available.
This procedure restores statistics of all tables of a schema as of a specified timestamp (as_of_timestamp
).
Syntax
DBMS_STATS.RESTORE_SCHEMA_STATS( ownname VARCHAR2, as_of_timestamp TIMESTAMP WITH TIME ZONE, force BOOLEAN DEFAULT FALSE, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type (GET_PARAM('NO_INVALIDATE')));
Parameters
Table 127-81 RESTORE_SCHEMA_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
The schema of the tables for which the statistics are to be restored |
as_of_timestamp |
The timestamp to which to restore statistics |
force |
Restores statistics even if their statistics are locked |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values.
ORA-20006
: Unable to restore statistics, statistics history not available.
This procedure restores system statistics as of a specified timestamp (as_of_timestamp
).
Syntax
DBMS_STATS.RESTORE_SCHEMA_STATS( as_of_timestamp TIMESTAMP WITH TIME ZONE);
Parameters
Table 127-82 RESTORE_SYSTEM_STATS Procedure Parameters
Parameter | Description |
---|---|
as_of_timestamp |
The timestamp to which to restore statistics |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values.
ORA-20006
: Unable to restore statistics, statistics history not available.
This procedure restores statistics of a table as of a specified timestamp (as_of_timestamp
). The procedure will restore statistics of associated indexes and columns as well. If the table statistics were locked at the specified timestamp the procedure will lock the statistics. The procedure will not restore user defined statistics.
Syntax
DBMS_STATS.RESTORE_TABLE_STATS ( ownname VARCHAR2, tabname VARCHAR2, as_of_timestamp TIMESTAMP WITH TIME ZONE, restore_cluster_index BOOLEAN DEFAULT FALSE, force BOOLEAN DEFAULT FALSE, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type (GET_PARAM('NO_INVALIDATE')));
Parameters
Table 127-83 RESTORE_TABLE_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
The schema of the table for which the statistics are to be restored |
tabname |
The table name |
as_of_timestamp |
The timestamp to which to restore statistics |
restore_cluster_index |
If the table is part of a cluster, restore statistics of the cluster index if set to TRUE |
force |
Restores statistics even if the table statistics are locked. If the table statistics were not locked at the specified timestamp, it unlocks the statistics. |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent values.
ORA-20006
: Unable to restore statistics, statistics history not available.
This procedure sets column-related information. In the version of this procedure that deals with user-defined statistics, the statistics type specified is the type to store in the dictionary, in addition to the actual user-defined statistics. If this statistics type is NULL
, the statistics type associated with the index or column is stored.
Syntax
DBMS_STATS.SET_COLUMN_STATS ( ownname VARCHAR2, tabname VARCHAR2, colname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, distcnt NUMBER DEFAULT NULL, density NUMBER DEFAULT NULL, nullcnt NUMBER DEFAULT NULL, srec StatRec DEFAULT NULL, avgclen NUMBER DEFAULT NULL, flags NUMBER DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Use the following for user-defined statistics:
DBMS_STATS.SET_COLUMN_STATS ( ownname VARCHAR2, tabname VARCHAR2, colname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, ext_stats RAW, stattypown VARCHAR2 DEFAULT NULL, stattypname VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type( get_param('NO_INVALIDATE')), force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-84 SET_COLUMN_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema. |
tabname |
Name of the table to which this column belongs. |
colname |
Name of the column or extension |
partname |
Name of the table partition in which to store the statistics. If the table is partitioned and partname is NULL , then the statistics are stored at the global table level. |
stattab |
User statistics table identifier describing where to store the statistics. If stattab is NULL , then the statistics are stored directly in the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ) |
ext_stats |
The user-defined statistics |
stattypown |
Schema of the statistics type |
stattypname |
Name of the statistics type |
distcnt |
Number of distinct values |
density |
Column density. If this value is NULL and if distcnt is not NULL , then density is derived from distcnt . |
nullcnt |
Number of NULLs |
srec |
StatRec structure filled in by a call to PREPARE_COLUMN_VALUES or GET_COLUMN_STATS |
avgclen |
Average length for the column (in bytes) |
flags |
For internal Oracle use (should be left as NULL ) |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
force |
Sets the values even if statistics of the column are locked |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or inconsistent input values.
ORA-20005
: Object statistics are locked.
This procedure is used to set the statistics preferences of all the tables, excluding the tables owned by Oracle. These tables can by included by passing TRUE
for the add_sys
parameter.
Syntax
DBMS_STATS.SET_DATABASE_PREFS ( pname IN VARCHAR2, pvalue IN VARCHAR2, add_sys IN BOOLEAN DEFAULT FALSE);
Parameters
Table 127-85 SET_DATABASE_PREFS Procedure Parameters
Parameter | Description |
---|---|
pname |
Preference name. The default value for following parameters can be set:
|
. | CASCADE - The value determines whether or not index statistics are collected as part of gathering table statistics. |
. | DEGREE - The value determines degree of parallelism used for gathering statistics. |
. | ESTIMATE_PERCENT - The value determines the percentage of rows to estimate. The valid range is [0.000001,100]. Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default. |
. | METHOD_OPT - The value controls column statistics collection and histogram creation. It accepts either of the following options, or both in combination:
- integer : Number of histogram buckets. Must be in the range [1,254].- REPEAT : Collects histograms only on the columns that already have histograms.- AUTO : Oracle determines the columns to collect histograms based on data distribution and the workload of the columns.- SKEWONLY : Oracle determines the columns to collect histograms based on the data distribution of the columns.- column_name : name of a column- extension : can be either a column group in the format of (column_name, colume_name [, ...]) or an expression
The default is |
. | NO_INVALIDATE - The value controls the invalidation of dependent cursors of the tables for which statistics are being gathered. Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE to have Oracle decide when to invalidate dependent cursors. This is the default. |
. | GRANULARITY - The value determines granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
. | PUBLISH - This value determines whether or not newly gathered statistics will be published once the gather job has completed. Prior to Prior to Oracle Database 11g, Release 1 (11.1), once a statistic gathering job completed the new statistics were automatically published into the dictionary tables. The user now has the ability to gather statistics but not publish them immediately. This allows the DBA to test the new statistics before publishing them. |
. | INCREMENTAL - This value determines whether or not the global statistics of a partitioned table will be maintained without doing a full table scan. With partitioned tables it is very common to load new data into a new partition. As new partitions are added and data loaded, the global table statistics need to be kept up to date. Oracle will update the global table statistics by scanning only the partitions that have been changed instead of the entire table if the following conditions hold:
If the |
. | STALE_PERCENT - This value determines the percentage of rows in a table that have to change before the statistics on that table are deemed stale and should be regathered. The default value is 10%. |
pvalue |
Preference value. If NULL is specified, it will set the Oracle default value.s |
add_sys |
Value TRUE will include the Oracle-owned tables |
Exceptions
ORA-20000
: Insufficient privileges.
ORA-20001
: Invalid or illegal input values.
Usage Notes
To run this procedure, you need to have the SYSDBA
role or both ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privileges.
Both arguments are of type VARCHAR2
and values are enclosed in quotes, even when they represent numbers.
Examples
DBMS_STATS.SET_DATABASE_PREFS('CASCADE', 'DBMS_STATS.AUTO_CASCADE'); DBMS_STATS.SET_DATABASE_PREFS('ESTIMATE_PERCENT','9'); DBMS_STATS.SET_DATABASE_PREFS('DEGREE','99');
This procedure is used to set the global statistics preferences.
Syntax
DBMS_STATS.SET_GLOBAL_PREFS ( pname IN VARCHAR2, pvalue IN VARCHAR2);
Parameters
Table 127-86 SET_GLOBAL_PREFS Procedure Parameters
Parameter | Description |
---|---|
pname |
Preference name. The default value for following parameters can be set:
|
. | CASCADE - The value determines whether or not index statistics are collected as part of gathering table statistics. |
. | DEGREE - The value determines degree of parallelism used for gathering statistics. |
. | ESTIMATE_PERCENT - The value determines the percentage of rows to estimate. The valid range is [0.000001,100]. Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default. |
. | METHOD_OPT - The value controls column statistics collection and histogram creation. It accepts either of the following options, or both in combination:
- integer : Number of histogram buckets. Must be in the range [1,254].- REPEAT : Collects histograms only on the columns that already have histograms.- AUTO : Oracle determines the columns to collect histograms based on data distribution and the workload of the columns.- SKEWONLY : Oracle determines the columns to collect histograms based on the data distribution of the columns.- column_name : name of a column- extension : can be either a column group in the format of (column_name, colume_name [, ...]) or an expression
The default is |
. | NO_INVALIDATE - The value controls the invalidation of dependent cursors of the tables for which statistics are being gathered. Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE to have Oracle decide when to invalidate dependent cursors. This is the default. |
. | GRANULARITY - The value determines granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
. | PUBLISH - This value determines whether or not newly gathered statistics will be published once the gather job has completed. Prior to Oracle Database 11g, Release 1 (11.1), once a statistic gathering job completed the new statistics were automatically published into the dictionary tables. The user now has the ability to gather statistics but not publish them immediately. This allows the DBA to test the new statistics before publishing them. |
. | INCREMENTAL - This value determines whether or not the global statistics of a partitioned table will be maintained without doing a full table scan. With partitioned tables it is very common to load new data into a new partition. As new partitions are added and data loaded, the global table statistics need to be kept up to date. Oracle will update the global table statistics by scanning only the partitions that have been changed instead of the entire table if the following conditions hold:
If the |
. | STALE_PERCENT - This value determines the percentage of rows in a table that have to change before the statistics on that table are deemed stale and should be regathered. The default value is 10%. |
pvalue |
Preference value. If NULL is specified, it will set the Oracle default value.s |
Exceptions
ORA-20000
: Insufficient privileges
ORA-20001
: Invalid or illegal input values
Usage Notes
This setting is honored only of there is no preference specified for the table to be analyzed.
To run this procedure, you need to have the SYSDBA
or both ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privilege.
Both arguments are of type VARCHAR2
and values are enclosed in quotes, even when they represent numbers.
Examples
DBMS_STATS.SET_GLOBAL_PREFS('ESTIMATE_PERCENT','9'); DBMS_STATS.SET_GLOBAL_PREFS('DEGREE','99');
These procedures set index-related information. In the version of this procedure that deals with user-defined statistics, the statistics type specified is the type to store in the dictionary, in addition to the actual user-defined statistics. If this statistics type is NULL, the statistics type associated with the index or column is stored.
Syntax
DBMS_STATS.SET_INDEX_STATS ( ownname VARCHAR2, indname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, numrows NUMBER DEFAULT NULL, numlblks NUMBER DEFAULT NULL, numdist NUMBER DEFAULT NULL, avglblk NUMBER DEFAULT NULL, avgdblk NUMBER DEFAULT NULL, clstfct NUMBER DEFAULT NULL, indlevel NUMBER DEFAULT NULL, flags NUMBER DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type( get_param('NO_INVALIDATE')), guessq NUMBER DEFAULT NULL, cachedblk NUMBER DEFAULT NULL, cachehit NUMBER DEFUALT NULL, force BOOLEAN DEFAULT FALSE);
Use the following for user-defined statistics:
DBMS_STATS.SET_INDEX_STATS ( ownname VARCHAR2, indname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, ext_stats RAW, stattypown VARCHAR2 DEFAULT NULL, stattypname VARCHAR2 DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type( get_param('NO_INVALIDATE')), cachedblk NUMBER DEFAULT NULL, cachehit NUMBER DEFUALT NULL, force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-87 SET_INDEX_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
indname |
Name of the index |
partname |
Name of the index partition in which to store the statistics. If the index is partitioned and if partname is NULL , then the statistics are stored at the global index level. |
stattab |
User statistics table identifier describing where to store the statistics. If stattab is NULL , then the statistics are stored directly in the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ) |
ext_stats |
The user-defined statistics |
stattypown |
Schema of the statistics type |
stattypname |
Name of the statistics type |
numrows |
Number of rows in the index (partition) |
numlblks |
Number of leaf blocks in the index (partition) |
numdist |
Number of distinct keys in the index (partition) |
avglblk |
Average integral number of leaf blocks in which each distinct key appears for this index (partition). If not provided, then this value is derived from numlblks and numdist . |
avgdblk |
Average integral number of data blocks in the table pointed to by a distinct key for this index (partition). If not provided, then this value is derived from clstfct and numdist . |
clstfct |
See clustering_factor column of the all_indexes view for a description |
indlevel |
Height of the index (partition) |
flags |
For internal Oracle use (should be left as NULL ) |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
guessq |
Guess quality. See the pct_direct_access column of the all_indexes view for a description. |
cachedblk |
The average number of blocks in the buffer cache for the segment (index/table/index partition/table partition) |
cachehit |
The average cache hit ratio for the segment (index/table/index partition/table partition) |
force |
Sets the values even if statistics of the index are locked |
Usage Notes
The Optimizer uses the cached data to estimate number of cached blocks for index or statistics table access. The total cost of the operation will be combined from the I/O cost of reading not cached blocks from disk, the CPU cost of getting cached blocks from the buffer cache, and the CPU cost of processing the data.
Oracle maintains cachedblk
and cachehit
at all times but uses correspondent caching statistics for optimization as part of the table and index statistics only when the user calls DBMS_STATS.GATHER_[TABLE/INDEX/SCHEMA/DATABASE]_STATS
procedure for auto mode or DBMS_STATS.GATHER_SYSTEM_STATS
for manual mode. In order to prevent the user from utilizing inaccurate and unreliable data, the optimizer will compute a 'confidence factor' for each cachehit
and a cachedblk
for each object. If the 'confidence factor' for the value meets confidence criteria, this value will be used, otherwise the defaults will be used.
The automatic maintenance algorithm for object caching statistics assumes that there is only one major workload for the system and adjusts statistics to this workload, ignoring other "minor" workloads. If this is not the case, you must use manual mode for maintaining object caching statistics.
The object caching statistics maintenance algorithm for auto mode prevents you from using statistics in the following situations
When not enough data has been analyzed, such as when an object has been recently create
When the system does not have one major workload resulting in averages not corresponding to real values.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid input value.
ORA-20005
: Object statistics are locked.
Note:
This subprogram has been replaced by improved technology and is maintained only for purposes of backward compatibility. In this case, use the SET_GLOBAL_PREFS Procedure.See also Deprecated Subprograms.
This procedure sets default values for parameters of DBMS_STATS
procedures. You can use the GET_PARAM
Function
to get the current default value of a parameter.
Syntax
DBMS_STATS.SET_PARAM ( pname IN VARCHAR2, pval IN VARCHAR2);
Parameters
Table 127-88 SET_PARAM Procedure Parameters
Parameter | Description |
---|---|
pname |
The parameter name The default value for following parameters can be set.
|
pval |
The parameter value. If NULL is specified, it will set the default value determined by Oracle. When pname is AUTOSTATS_TARGET , the following are valid values:
|
Usage Notes
To run this procedure, you must have the SYSDBA
or both the ANALYZE
ANY
DICTIONARY
and ANALYZE
ANY
system privileges.
Note that both arguments are of type VARCHAR2
and the values need to be enclosed in quotes even when they represent numbers.
Note also the difference between NULL
and 'NULL'
:
When NULL
is unquoted, this sets the parameter to the value Oracle recommends.
In the case of the quoted 'NULL'
, this sets the value of the parameter to NULL
.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or illegal input value.
Examples
DBMS_STATS.SET_PARAM('CASCADE','DBMS_STATS.AUTO_CASCADE'); DBMS_STATS.SET_PARAM('ESTIMATE_PERCENT','5'); DBMS_STATS.SET_PARAM('DEGREE','NULL');
This procedure is used to set the statistics preferences of all the tables owned by the specified owner name.
Syntax
DBMS_STATS.SET_SCHEMA_PREFS ( ownname IN VARCHAR2, pname IN VARCHAR2, pvalue IN VARCHAR2);
Parameters
Table 127-89 SET_SCHEMA_PREFS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name |
pname |
Preference name. The default value for following parameters can be set:
|
pvalue |
Preference value. If NULL is specified, it will set the Oracle default value.s |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid or illegal input value.
Usage Notes
To run this procedure, you need to connect as owner, or have the SYSDBA
privilege, or have the ANALYZE
ANY
system privilege.
Both arguments are of type VARCHAR2
and values are enclosed in quotes, even when they represent numbers.
Examples
DBMS_STATS.SET_SCHEMA_PREFS('SH','CASCADE', 'DBMS_STATS.AUTO_CASCADE'); DBMS_STATS.SET_SCHEMA_PREFS('SH' 'ESTIMATE_PERCENT','9'); DBMS_STATS.SET_SCHEMA_PREFS('SH', 'DEGREE','99');
This procedure sets systems statistics.
Syntax
DBMS_STATS.SET_SYSTEM_STATS ( pname VARCHAR2, pvalue NUMBER, stattab IN VARCHAR2 DEFAULT NULL, statid IN VARCHAR2 DEFAULT NULL, statown IN VARCHAR2 DEFAULT NULL);
Parameters
Table 127-90 SET_SYSTEM_STATS Procedure Parameters
Parameter | Description |
---|---|
pname |
The parameter name to get, which can have one of the following values:
|
pvalue |
Parameter value to get |
stattab |
Identifier of the user statistics table where the statistics will be obtained. If stattab is null, the statistics will be obtained from the dictionary. |
statid |
Optional identifier associated with the statistics saved in the stattab |
statown |
Schema containing stattab (if different from current schema) |
cachedblk |
The average number of blocks in the buffer cache for the segment (index/table/index partition/table partition) |
cachehit |
The average cache hit ratio for the segment (index/table/index partition/table partition) |
Usage Notes
The Optimizer uses the cached data to estimate number of cached blocks for index or statistics table access. The total cost of the operation will be combined from the I/O cost of reading not cached blocks from disk, the CPU cost of getting cached blocks from the buffer cache, and the CPU cost of processing the data.
Oracle maintains cachedblk
and cachehit
at all times but uses correspondent caching statistics for optimization as part of the table and index statistics only when the user calls DBMS_STATS.GATHER_[TABLE/INDEX/SCHEMA/DATABASE]_STATS
procedure for auto mode or DBMS_STATS.GATHER_SYSTEM_STATS
for manual mode. In order to prevent the user from utilizing inaccurate and unreliable data, the optimizer will compute a 'confidence factor' for each cachehit
and a cachedblk
for each object. If the 'confidence factor' for the value meets confidence criteria, this value will be used, otherwise the defaults will be used.
The automatic maintenance algorithm for object caching statistics assumes that there is only one major workload for the system and adjusts statistics to this workload, ignoring other "minor" workloads. If this is not the case, you must use manual mode for maintaining object caching statistics.
The object caching statistics maintenance algorithm for auto mode prevents you from using statistics in the following situations
When not enough data has been analyzed, such as when an object has been recently create
When the system does not have one major workload resulting in averages not corresponding to real values.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid input value.
ORA-20002
: Bad user statistics table; may need to be upgraded.
ORA-20003
: Unable to set system statistics.
ORA-20004
: Parameter does not exist.
This procedure is used to set the statistics preferences of the specified table in the specified schema.
Syntax
DBMS_STATS.SET_TABLE_PREFS ( ownname IN VARCHAR2, tabname IN VARCHAR2, pname IN VARCHAR2, pvalue IN VARCHAR2);
Parameters
Table 127-91 SET_TABLE_PREFS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Owner name |
tabname |
Table name |
pname |
Preference name. The default value for following parameters can be set:
|
. | CASCADE - The value determines whether or not index statistics are collected as part of gathering table statistics. |
. | DEGREE - The value determines degree of parallelism used for gathering statistics. |
. | ESTIMATE_PERCENT - The value determines the percentage of rows to estimate. The valid range is [0.000001,100]. Use the constant DBMS_STATS .AUTO_SAMPLE_SIZE to have Oracle determine the appropriate sample size for good statistics. This is the default. |
. | METHOD_OPT - The value controls column statistics collection and histogram creation. It accepts either of the following options, or both in combination:
- integer : Number of histogram buckets. Must be in the range [1,254].- REPEAT : Collects histograms only on the columns that already have histograms.- AUTO : Oracle determines the columns to collect histograms based on data distribution and the workload of the columns.- SKEWONLY : Oracle determines the columns to collect histograms based on the data distribution of the columns.- column_name : name of a column- extension : can be either a column group in the format of (column_name, colume_name [, ...]) or an expression
The default is |
. | NO_INVALIDATE - The value controls the invalidation of dependent cursors of the tables for which statistics are being gathered. Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE to have Oracle decide when to invalidate dependent cursors. This is the default. |
. | GRANULARITY - The value determines granularity of statistics to collect (only pertinent if the table is partitioned).
'
|
. | PUBLISH - This value determines whether or not newly gathered statistics will be published once the gather job has completed. Prior to Prior to Oracle Database 11g, Release 1 (11.1), once a statistic gathering job completed the new statistics were automatically published into the dictionary tables. The user now has the ability to gather statistics but not publish them immediately. This allows the DBA to test the new statistics before publishing them. |
. | INCREMENTAL - This value determines whether or not the global statistics of a partitioned table will be maintained without doing a full table scan. With partitioned tables it is very common to load new data into a new partition. As new partitions are added and data loaded, the global table statistics need to be kept up to date. Oracle will update the global table statistics by scanning only the partitions that have been changed instead of the entire table if the following conditions hold:
If the |
. | STALE_PERCENT - This value determines the percentage of rows in a table that have to change before the statistics on that table are deemed stale and should be regathered. The default value is 10%. |
pvalue | Preference value. If NULL is specified, it will set the Oracle default value. |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges
ORA-20001
: Invalid or illegal input values
Usage Notes
To run this procedure, you need to connect as owner of the table or should have the ANALYZE
ANY
system privilege.
All arguments are of type VARCHAR2
and values are enclosed in quotes, even when they represent numbers.
Examples
DBMS_STATS.SET_TABLE_PREFS('SH', 'SALES', 'CASCADE', 'DBMS_STATS.AUTO_CASCADE'); DBMS_STATS.SET_TABLE_PREFS('SH', 'SALES','ESTIMATE_PERCENT','9'); DBMS_STATS.SET_TABLE_PREFS('SH', 'SALES', 'DEGREE','99');
This procedure sets table-related information.
Syntax
DBMS_STATS.SET_TABLE_STATS ( ownname VARCHAR2, tabname VARCHAR2, partname VARCHAR2 DEFAULT NULL, stattab VARCHAR2 DEFAULT NULL, statid VARCHAR2 DEFAULT NULL, numrows NUMBER DEFAULT NULL, numblks NUMBER DEFAULT NULL, avgrlen NUMBER DEFAULT NULL, flags NUMBER DEFAULT NULL, statown VARCHAR2 DEFAULT NULL, no_invalidate BOOLEAN DEFAULT to_no_invalidate_type ( get_param('NO_INVALIDATE')), cachedblk NUMBER DEFAULT NULL, cachehit NUMBER DEFUALT NULL, force BOOLEAN DEFAULT FALSE);
Parameters
Table 127-92 SET_TABLE_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
tabname |
Name of the table |
partname |
Name of the table partition in which to store the statistics. If the table is partitioned and partname is NULL , then the statistics are stored at the global table level. |
stattab |
User statistics table identifier describing where to store the statistics. If stattab is NULL , then the statistics are stored directly in the dictionary. |
statid |
Identifier (optional) to associate with these statistics within stattab (Only pertinent if stattab is not NULL ) |
numrows |
Number of rows in the table (partition) |
numblks |
Number of blocks the table (partition) occupies |
avgrlen |
Average row length for the table (partition) |
flags |
For internal Oracle use (should be left as NULL ) |
statown |
Schema containing stattab (if different than ownname ) |
no_invalidate |
Does not invalidate the dependent cursors if set to TRUE . The procedure invalidates the dependent cursors immediately if set to FALSE . Use DBMS_STATS .AUTO_INVALIDATE . to have Oracle decide when to invalidate dependent cursors. This is the default. The default can be changed using the SET_PARAM Procedure. |
cachedblk |
The average number of blocks in the buffer cache for the segment (index/table/index partition/table partition) |
cachehit |
The average cache hit ratio for the segment (index/table/index partition/table partition) |
force |
Sets the values even if statistics of the table are locked |
Usage Notes
The Optimizer uses the cached data to estimate number of cached blocks for index or statistics table access. The total cost of the operation will be combined from the I/O cost of reading not cached blocks from disk, the CPU cost of getting cached blocks from the buffer cache, and the CPU cost of processing the data.
Oracle maintains cachedblk
and cachehit
at all times but uses correspondent caching statistics for optimization as part of the table and index statistics only when the user calls DBMS_STATS.GATHER_[TABLE/INDEX/SCHEMA/DATABASE]_STATS
procedure for auto mode or DBMS_STATS.GATHER_SYSTEM_STATS
for manual mode. In order to prevent the user from utilizing inaccurate and unreliable data, the optimizer will compute a 'confidence factor' for each cachehit
and a cachedblk
for each object. If the 'confidence factor' for the value meets confidence criteria, this value will be used, otherwise the defaults will be used.
The automatic maintenance algorithm for object caching statistics assumes that there is only one major workload for the system and adjusts statistics to this workload, ignoring other "minor" workloads. If this is not the case, you must use manual mode for maintaining object caching statistics.
The object caching statistics maintenance algorithm for auto mode prevents you from using statistics in the following situations
When not enough data has been analyzed, such as when an object has been recently create
When the system does not have one major workload resulting in averages not corresponding to real values.
Exceptions
ORA-20000
: Object does not exist or insufficient privileges.
ORA-20001
: Invalid input value.
ORA-20005
: Object statistics are locked.
This function returns the name of the statistics entry that is created for the user-specified extension. It raises an error if no extension has been created.
Syntax
DBMS_STATS.SHOW_EXTENDED_STATS_NAME ( ownname VARCHAR2, tabname VARCHAR2, extension VARCHAR2) RETURN VARCHAR2;
Parameters
Table 127-93 SHOW_EXTENDED_STATS_NAME Function Parameters
Parameter | Description |
---|---|
ownname |
Owner name of a table |
tabname |
Name of the table |
extension |
Can be either a column group or an expression. Suppose the specified table has two column c1 , c2 . An example column group can be "(c1 , c2 )" and an example expression can be "(c1 + c2 )". |
Exceptions
ORA-20000
: Object does not exist or insufficient privileges
ORA-20001
: Error when processing extension
This procedure enables the user to unlock statistics for a partition.
Syntax
DBMS_STATS.UNLOCK_PARTITION_STATS ( ownname VARCHAR2, tabname VARCHAR2, partname VARCHAR2);
Parameters
Table 127-94 UNLOCK_PARTITION_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema to unlock |
tabname |
Name of the table |
partname |
Partition name |
This procedure unlocks the statistics on all the tables in schema.
Syntax
DBMS_STATS.UNLOCK_SCHEMA_STATS ( ownname VARCHAR2);
Parameters
Table 127-95 UNLOCK_SCHEMA_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
The name of the schema |
Usage Notes
When statistics on a table is locked, all the statistics depending on the table, including table statistics, column statistics, histograms and statistics on all dependent indexes, are considered to be locked.
The SET_*,
DELETE_*,
IMPORT_*,
GATHER_*
procedures that modify statistics in the dictionary of an individual table, index or column will raise an error if statistics of the object is locked.
Procedures that operates on multiple objects (such as GATHER_SCHEMA_STATS
) will skip modifying the statistics of an object if it is locked. Many procedures have force argument to override the lock.
This procedure unlocks the statistics on the table.
Syntax
DBMS_STATS.UNLOCK_TABLE_STATS ( ownname VARCHAR2, tabname VARCHAR2);
Parameters
Table 127-96 UNLOCK_TABLE_STATS Procedure Parameters
Parameter | Description |
---|---|
ownname |
The name of the schema |
tabname |
The name of the table |
Usage Notes
When statistics on a table is locked, all the statistics depending on the table, including table statistics, column statistics, histograms and statistics on all dependent indexes, are considered to be locked.
The SET_*,
DELETE_*,
IMPORT_*,
GATHER_*
procedures that modify statistics in the dictionary of an individual table, index or column will raise an error if statistics of the object is locked.
Procedures that operates on multiple objects (such as GATHER_SCHEMA_STATS
) will skip modifying the statistics of an object if it is locked. Many procedures have force argument to override the lock.
This procedure upgrades a user statistics table from an older version.
Syntax
DBMS_STATS.UPGRADE_STAT_TABLE ( ownname VARCHAR2, stattab VARCHAR2);
Parameters
Table 127-97 UPGRADE_STAT_TABLE Procedure Parameters
Parameter | Description |
---|---|
ownname |
Name of the schema |
stattab |
Name of the table |
Exceptions
ORA-20000: Unable to upgrade table.