从Oracle 10g 开始,Oracle提供了锁定/解锁表统计信息功能,它的目的是阻止数据库自动收集统计信息,防止可能会产生/出现的糟糕的计划。它对于数据频繁更改的Volatile Tables最有用,因为Volatile Tables的某些数据集可能会生成糟糕的计划。
官方的介绍如下:
Prevent automatic statistic gathering where this may otherwise produce poor plans. As such it is most useful for volatile tables whose data changes frequently and for whom poor plans may be generated with certain data sets.
注:什么是Volatile Tables呢?官方解释:Volatile tables are being deleted or truncated, and then rebuilt during the day. 还有一种解释指:Volatile Tables 是指变化比较大的表,即频繁进行Insert、Delete、Update 多种操作的表。
另外,数据库自动收集表的统计信息,大部分情况下,这种行为对于数据库的性能是有利的。但是也有一些情况,我们不想数据库自动收集某个表的统计信息,例如:
- 1:自动收集统计信息作业数据采样的比例过低,尤其对于一些大表,准确来说是对于一些数据不怎么变化的大表,我们想手工收集集统计信息(指定较高的采样比例)。这样有利于相关SQL生成正确的执行计划。
- 2:自动统计信息收集作业运行过后或运行期间,由于一些作业或业务逻辑出现了大量的DML,此时收集的的统计信息可能是不准确,也是就说自动统计信息收集对于这种表没有什么意义,反而浪费了大量资源,我们需要手工或设置相关作业去收集统计信息。那么我们就可以通过锁定表的统计信息,阻止数据库的自动收集统计信息作业去采集相关统计信息。
如果一些对象没有统计信息,而你又锁定了统计信息,那么此时数据库在执行SQL时,就会使用动态采样。这个也是锁定统计信息的另外一个功能。
When you set the statistics of a volatile object to null, Oracle Database dynamically gathers the necessary statistics during optimization using dynamic statistics. The OPTIMIZER_DYNAMIC_SAMPLING initialization parameter controls this feature.
This is useful when you wish to use dynamic sampling on a volatile table.
You may also lock statistics on a volatile table at a point when it is fully populated, so that the table statistics are more representative of the table population, so as to use those statistics to generate plans, whatever happens to the table data.
统计信息锁定
当不需要对某个表做收集的时候,可以采用锁定统计信息的方法,把不需要收集的表排除在外,这样可以使得此表上的统计信息不变,Oracle提供三种粒度的锁定统计信息的方法,如下所示
--锁定表的统计信息
EXEC DBMS_STATS.LOCK_TABLE_STATS();
参数:
PROCEDURE LOCK_TABLE_STATS
Argument Name Type In/Out Default?
------------------------------ ----------------------- ------ --------
OWNNAME VARCHAR2 IN
TABNAME VARCHAR2 IN
STATTYPE VARCHAR2 IN DEFAULT
--锁定表的分区统计信息
EXEC DBMS_STATS.LOCK_PARTITION_STATS();
参数
PROCEDURE LOCK_PARTITION_STATS
Argument Name Type In/Out Default?
------------------------------ ----------------------- ------ --------
OWNNAME VARCHAR2 IN
TABNAME VARCHAR2 IN
PARTNAME VARCHAR2 IN
--锁定用户统计信息
EXEC DBMS_STATS.LOCK_SCHEMA_STATS();
参数:
PROCEDURE LOCK_SCHEMA_STATS
Argument Name Type In/Out Default?
------------------------------ ----------------------- ------ --------
OWNNAME VARCHAR2 IN
STATTYPE VARCHAR2 IN DEFAULT
案例,如何锁定表scott.emp的统计信息,如下所示:
SQL> exec dbms_stats.lock_table_stats('scott', 'emp');
PL/SQL procedure successfully completed.
如果在锁定条件下收集统计信息,那么会出现如下报错:
SQL> exec dbms_stats.lock_table_stats('TEST', 'TEST');
PL/SQL procedure successfully completed.
SQL> exec dbms_stats.gather_table_stats('TEST', 'TEST');
BEGIN dbms_stats.gather_table_stats('TEST', 'TEST'); END;
*
ERROR at line 1:
ORA-20005: object statistics are locked (stattype = ALL)
ORA-06512: at "SYS.DBMS_STATS", line 40751
ORA-06512: at "SYS.DBMS_STATS", line 40035
ORA-06512: at "SYS.DBMS_STATS", line 9393
ORA-06512: at "SYS.DBMS_STATS", line 10317
ORA-06512: at "SYS.DBMS_STATS", line 39324
ORA-06512: at "SYS.DBMS_STATS", line 40183
ORA-06512: at "SYS.DBMS_STATS", line 40732
ORA-06512: at line 1
还有一个要注意的是,如果当表的统计信息被锁定时,此表上创建索引时,不会采集生成索引的相关统计信息,如下所示:
SQL> drop table test.test;
Table dropped.
SQL> create table test.test
2 as select * from dba_objects;
Table created.
SQL> exec dbms_stats.lock_table_stats('TEST', 'TEST');
PL/SQL procedure successfully completed.
SQL> create index test.idx_test_n1 on test.test(object_id, object_name);
Index created.
SQL> select num_rows, last_analyzed from dba_ind_statistics where index_name =upper('idx_test_n1');
NUM_ROWS LAST_ANALYZED
---------- -------------------
1 row selected.
如果表的统计信息锁定的时候,我们可以使用下面脚本来收集统计信息:
--使用参数force,强制收集统计信息
exec dbms_stats.gather_index_stats('TEST', 'idx_test_n1',force=>true);
SQL> exec dbms_stats.gather_index_stats('TEST', 'idx_test_n1',force=>true);
PL/SQL procedure successfully completed.
SQL> select num_rows, last_analyzed from dba_ind_statistics where index_name =upper('idx_test_n1');
NUM_ROWS LAST_ANALYZED
---------- -------------------
72502 2023-08-31 13:55:01
1 row selected.
如果要收集表的统计信息,使用下面SQL
exec dbms_stats.gather_table_stats('TEST', 'TEST',force=>true);
当然还有一种方法就是,先给表解锁统计信息,收集统计信息,然后锁定表的统计信息,如下所示:
exec dbms_stats.unlock_table_stats('TEST','TEST');
exec dbms_stats.gather_table_stats(ownname =>'TEST', tabname =>'TEST',cascade => true,method_opt=>'for all indexed columns size');
exec dbms_stats.lock_table_stats('TEST','TEST');
查看统计信息锁定的对象
我们可以使用如下的SQL查询数据库中哪些表或索引的统计信息被锁定了:
SET LINESIZE 680;
COL OWNER FOR A16
COL INDEX_NAME FOR A30
COL TABLE_OWNER FOR A16
COL TABLE_NAME FOR A30
COL PARTITION_NAME FOR A30
COL SUBPARTITION_NAME FOR A30
SELECT D.OWNER,
D.INDEX_NAME,
D.TABLE_OWNER,
D.TABLE_NAME,
D.PARTITION_NAME,
D.SUBPARTITION_NAME,
D.OBJECT_TYPE
FROM DBA_IND_STATISTICS D
WHERE STATTYPE_LOCKED IN('ALL', 'DATA', 'CACHE')
UNION ALL
SELECT '---',
'---',
D.OWNER,
D.TABLE_NAME,
D.PARTITION_NAME,
D.SUBPARTITION_NAME,
D.OBJECT_TYPE
FROM DBA_TAB_STATISTICS D
WHERE STATTYPE_LOCKED IN('ALL', 'DATA', 'CACHE');
STATTYPE_LOCKED为空代表统计信息未锁定。
查看统计信息锁定的表,可以使用下面SQL语句查询获取。
SET LINESIZE 680;
COL OWNER FOR A16
COL TABLE_OWNER FOR A16
COL TABLE_NAME FOR A30
COL PARTITION_NAME FOR A30
COL SUBPARTITION_NAME FOR A30
SELECT
D.OWNER,
D.TABLE_NAME,
D.PARTITION_NAME,
D.SUBPARTITION_NAME,
D.OBJECT_TYPE
FROM DBA_TAB_STATISTICS D
WHERE STATTYPE_LOCKED IN('ALL', 'DATA', 'CACHE');
解锁统计信息锁定
语法:
PROCEDURE UNLOCK_TABLE_STATS
Argument Name Type In/Out Default?
------------------------------ ----------------------- ------ --------
OWNNAME VARCHAR2 IN
TABNAME VARCHAR2 IN
STATTYPE VARCHAR2 IN DEFAULT
解锁单个表的统计信息
EXEC DBMS_STATS.UNLOCK_TABLE_STATS('scott','emp');
--解锁用户统计信息
EXEC DBMS_STATS.UNLOCK_SCHEMA_STATS('xxx');
解锁某个用户下(例如,scott用户)的表的统计信息
EXEC DBMS_STATS.UNLOCK_SCHEMA_STATS('scott');
参考资料:
Preserving Statistics using DBMS_STATS.LOCK_TABLE_STATS (Doc ID 283890.1)