The GATHER_SCHEMA_STATS procedure is used to collect statistics for all objects in the specified schema.
Syntax
DBMS_STATS.GATHER_SCHEMA_STATS (
ownname VARCHAR2,
estimate_percent NUMBER DEFAULT AUTO_SAMPLE_SIZE,
block_sample BOOLEAN DEFAULT FALSE,
method_opt VARCHAR2 DEFAULT DEFAULT_METHOD_OPT,
degree NUMBER DEFAULT NULL,
granularity VARCHAR2 DEFAULT DEFAULT_GRANULARITY,
cascade BOOLEAN DEFAULT NULL,
no_invalidate BOOLEAN DEFAULT FALSE,
stattype VARCHAR2 DEFAULT 'DATA',
force BOOLEAN DEFAULT FALSE);
Parameters
| Parameter | Description |
|---|---|
| ownname | The schema where the table is located. |
| estimate_percent | The percentage of rows to estimate. Valid range: [0.000001,100]. |
| block_sample | Specifies whether to use random block sampling (TRUE) or random row sampling (FALSE). The default value is FALSE. Random block sampling is more efficient, but if the data is not randomly distributed on the disk, the sample values may be correlated. |
| method_opt | When setting preferences at the global, schema, database, or dictionary level, only the FOR ALL syntax is allowed. Otherwise, method_opt can be one of the following options, or a combination of them:
FOR ALL COLUMNS SIZE AUTO. |
| degree | The degree of parallelism. The default value is NULL. NULL indicates that the table's default value, specified by the DEGREE clause in the CREATE TABLE or ALTER TABLE statement, will be used. When using DEGREE=>NULL or DEGREE=>n, if the object size does not guarantee parallel execution, DBMS_STATS may use serial execution. |
| granularity | The granularity of the statistics to collect (only applicable when the table is partitioned).
|
| cascade | In addition to collecting table and column statistics, also collect statistics for indexes, equivalent to running the GATHER_INDEX_STATS procedure on each index in the schema. |
| no_invalidate | Specifies whether to invalidate the plan cache when collecting statistics. Setting this to TRUE means the plan cache will not be invalidated when collecting statistics. |
| stattype | The current location where the statistics are stored. |
| force | Whether to forcibly collect statistics, ignoring the lock status. The default is FALSE. If set to TRUE, statistics will be collected even if they are locked. |
Exceptions
| Error Code | Description |
|---|---|
| ORA-20000 | The schema does not exist or the user does not have sufficient privileges. |
| ORA-20001 | Invalid input value. |
Considerations
To call this procedure, you must be the owner of the table. For objects owned by SYS, you must be the owner or have the SYSDBA privilege to call this procedure.
Examples
Collect statistics for all tables in the hr schema.
obclient> CALL DBMS_STATS.GATHER_SCHEMA_STATS ('hr', degree=>64,no_invalidate=>TRUE);
Query OK, 0 rows affected
References
For more information on collecting statistics for all objects in a specified schema, see Manually collect statistics.