
出品丨TeacherWhat
题图:Oracle Middle East Headquarter
关键字:Optimizer Statistics Advisor,统计信息 ,ORA-20001 ,ORA-4036,AUTO_STATS_ADVISOR_TASK
正文约4000字,建议阅读时间8分钟
目录结构:
1. 概述
2. 问题1:ORA-12012, ORA-20001 error错误
3. 问题2:SYSAUX表空间增长过快,导致可用表空间不足
4. 问题3:CDB/PDB中EXECUTION_DAYS_TO_EXPIRE设置问题
5. 问题4:超过PGA限制引起ORA-4036
6.问题5:禁用优化器统计顾问功能
优化器统计顾问(Optimizer Statistics Advisor)概述
对于Oracle的CBO优化器而言,统计信息是其最重要的组成部分。
因此,Oracle在统计信息的准确性方面不断地进行优化和加强。
从12.2版本开始,Oracle推出了优化器统计顾问(Optimizer Statistics Advisor),根据事先定义的规则,定期执行,提供给用户参考的统计信息收集相关的建议。

详细参考:
Home/Database/Oracle/Oracle Database/Release 12.2SQL Tuning Guide https://docs.oracle.com/en/database/oracle/oracle-database/12.2/tgsql/optimizer-statistics-advisor.html#GUID-054F4B76-DD57-46EE-98EA-0FF04F49D1B3>18 Analyzing Statistics Using Optimizer Statistics Advisor
统计信息收集相关文章内容:
自动统计信息收集(Automatic Optimizer Statistics Collection)
在12.2.0.1以后的版本上运行该功能时,遇到问题的报告很多, 但是Oracle也在不断地修正着相关地问题,所以保持数据库为最新版本通常是一个最佳的选择。
问题1:ORA-12012, ORA-20001 error错误
由于12.2.0.1等版本上的设计不足(Bug) 等,可能会在告警日志(alert log)或者JOB跟踪日志中,发现ORA-12012, ORA-20001等错误。
错误例:
>ORA-12012: error on auto execute of job "SYS"."ORA$AT_OS_OPT_SY_nn">ORA-20001: Statistics Advisor: Invalid Task Name For the current user>ORA-06512: at "SYS.DBMS_STATS", line 46861>ORA-06512: at "SYS.DBMS_STATS_ADVISOR", line 734>ORA-06512: at "SYS.DBMS_STATS_INTERNAL", line 19930>ORA-06512: at "SYS.DBMS_STATS_INTERNAL", line 21934>ORA-06512: at "SYS.DBMS_STATS", line 46851
可以参考如下方法尝试解决。
1.通过dbms_stats.init_package()程序包,重新创建优化器统计顾问任务。例:EXEC dbms_stats.init_package();2. 首先看看这个bug 27983174和27774706是否被修复,如果存在则建议打上补丁或打上最新的RU.如果没有被修复,可向官方技术支持申请Patch 27983174 和Patch 27774706 补丁并应用。3. 应用Patch 27774706 补丁后,执行如下操作:$ sqlplus as sysdbadrop table WRI$_ADV_DEFINITIONS;@?/rdbms/admin/catadvtb.sql@?/rdbms/admin/utlrp.sqlexecute dbms_advisor.setup_repository;EXEC dbms_stats.init_package();4.如果应用Patch 27774706 补丁过程中出错的话,试着执行如下命令手动更新状态。UPDATE dba_registry_sqlpatchSET status = 'SUCCESS', action_time = SYSTIMESTAMPWHERE patch_id = 27774706 and status='WITH ERRORS' and rownum=1;commit;很多问题会在19c以后的版本进行修复,所以有可能的话注意保持版本的更新。参考:Recurring ORA-12012, ORA-20001, ORA-06512 In Container Database (Doc ID 2420581.1) 12.2.0.0.2Automatic Statistics Advisor Job Errors with Statistics Fatal Error (Doc ID 2448436.1) Version 12.2.0.1 to 18.3.0.0.0ORA-12012 Error on auto execute of job "SYS"."ORA$AT_OS_OPT_SY_<NN> in 12.2.0 Database version or higher release (like 18c) (Doc ID 2127675.1) Version 12.2.0.1 and later
问题2:SYSAUX表空间增长过快,导致可用表空间不足
由于优化器统计顾问的执行,SYSAUX表空间增长过快,导致可用表空间不足。
问题特征:
V$SYSAUX_OCCUPANTS中,SM/ADVISOR占据大量空间DBA_SEGMENTS中,WRI$_ADV_OBJECTS占据大量空间
解决方法:
1. 尝试删除Statistics Advisor 任务(AUTO_STATS_ADVISOR_TASK),然后重建。
具体删除方法例:
connect as sysdba--1.1 删除Statistics Advisor 任务DECLAREv_tname VARCHAR2(32767);BEGINv_tname := 'AUTO_STATS_ADVISOR_TASK';DBMS_STATS.DROP_ADVISOR_TASK(v_tname);END;/--1.2 删除任务之后,重组表和所有索引SQL> ALTER TABLE WRI$_ADV_OBJECTS MOVE;SQL> ALTER INDEX WRI$_ADV_OBJECTS_IDX_01 REBUILD;SQL> ALTER INDEX WRI$_ADV_OBJECTS_PK REBUILD;注:如果在删除过程中,发生ORA-20001等错误的话,可以执行下面的方法重建AUTO_STATS_ADVISOR_TASK来解决,然后再执行上面的删除方法,最终达到删除Statistics Advisor 任务(AUTO_STATS_ADVISOR_TASK)的目的。SQL> connect as sysdbaSQL> EXEC DBMS_STATS.INIT_PACKAGE();
2. 缩短任务执行历史的保存时间
-- 确认当前设定的保持期间select task_name, parameter_name, parameter_value FROM DBA_ADVISOR_PARAMETERSwhere task_name='AUTO_STATS_ADVISOR_TASK' and PARAMETER_NAME like '%EXPIRE%';-- 修改设定的保持期间可以通过下面的命令,将EXECUTION_DAYS_TO_EXPIRE修改为10天,即执行历史数据的保存时间为10天:connect as sysdbaBEGINDBMS_SQLTUNE.SET_TUNING_TASK_PARAMETER (task_name => 'AUTO_STATS_ADVISOR_TASK', parameter => 'EXECUTION_DAYS_TO_EXPIRE', value => 10);END;/参考:How To Set DAYS_TO_EXPIRE and EXECUTION_DAYS_TO_EXPIRE of Automatic Statistics Advisor Task (Doc ID 2544788.1)
3. 12.2.0.1版本由于Bug 26764561的影响,即使EXECUTION_DAYS_TO_EXPIRE设成10天后,优化器统计顾问相关段依然不断增加。 所以首先看看这个bug是否被修复,如果存在则建议打上补丁或打上最新的RU。
参考:
AUTO_STATS_ADVISOR_TASK Not Purging Even Though Setting EXECUTION_DAYS_TO_EXPIRE (Doc ID 2615851.1)>Bug 26764561(Doc ID 26764561.8)
※注意打补丁后的Postinstallation内容
4.关于EXECUTION_DAYS_TO_EXPIRE的默认值:
■ver<=18.3SQL> EXEC DBMS_STATS.INIT_PACKAGE();PL/SQL procedure successfully completed.SQL> SELECT parameter_name, parameter_value FROM DBA_ADVISOR_PARAMETERSWHERE task_name='AUTO_STATS_ADVISOR_TASK'and PARAMETER_NAME IN 'EXECUTION_DAYS_TO_EXPIRE';2 3PARAMETER_NAME--------------------------------------------------------------------------------PARAMETER_VALUE--------------------------------------------------------------------------------EXECUTION_DAYS_TO_EXPIREUNLIMITED■Version 19.3.0.0.0 &18.5 (Bug 27983174修复后)SQL> SELECT parameter_name, parameter_value FROM DBA_ADVISOR_PARAMETERS WHERE task_name='AUTO_STATS_ADVISOR_TASK'and PARAMETER_NAME IN 'EXECUTION_DAYS_TO_EXPIRE'; 2 3PARAMETER_NAME--------------------------------------------------------------------------------PARAMETER_VALUE--------------------------------------------------------------------------------EXECUTION_DAYS_TO_EXPIRE30
问题3:多租户环境中 BEXECUTION_DAYS_TO_EXPIRE设置问题
对于多租户环境中,CDB/PDB的设置相对独立,互相不影响。
EXECUTION_DAYS_TO_EXPIRE的CDB/PDB设置测试例:
---CDB側SQL> conn as sysdbaConnected.SQL> SELECT parameter_name, parameter_value FROM DBA_ADVISOR_PARAMETERSWHERE task_name='AUTO_STATS_ADVISOR_TASK'and PARAMETER_NAME IN 'EXECUTION_DAYS_TO_EXPIRE';23PARAMETER_NAME--------------------------------------------------------------------------------PARAMETER_VALUE--------------------------------------------------------------------------------EXECUTION_DAYS_TO_EXPIREUNLIMITEDSQL> show pdbsCON_ID CON_NAME OPEN MODERESTRICTED---------- ------------------------------ ---------- ----------2 PDB$SEED READ ONLYNO3 PDB1 READ WRITE NOSQL>BEGINDBMS_SQLTUNE.SET_TUNING_TASK_PARAMETER (task_name => 'AUTO_STATS_ADVISOR_TASK', parameter => 'EXECUTION_DAYS_TO_EXPIRE', value => 30);END;/SQL> 2345678PL/SQL procedure successfully completed.SQL> SELECT parameter_name, parameter_value FROM DBA_ADVISOR_PARAMETERSWHERE task_name='AUTO_STATS_ADVISOR_TASK'and PARAMETER_NAME IN 'EXECUTION_DAYS_TO_EXPIRE'; 23PARAMETER_NAME--------------------------------------------------------------------------------PARAMETER_VALUE--------------------------------------------------------------------------------EXECUTION_DAYS_TO_EXPIRE30---PDB側SQL> alter session set container=pdb1;Session altered.SQL> SELECT parameter_name, parameter_value FROM DBA_ADVISOR_PARAMETERSWHERE task_name='AUTO_STATS_ADVISOR_TASK'and PARAMETER_NAME IN 'EXECUTION_DAYS_TO_EXPIRE';PARAMETER_NAME--------------------------------------------------------------------------------PARAMETER_VALUE--------------------------------------------------------------------------------EXECUTION_DAYS_TO_EXPIREUNLIMITEDSQL> show pdbsCON_ID CON_NAME OPEN MODERESTRICTED---------- ------------------------------ ---------- ----------3 PDB1 READ WRITE NOSQL>
PDB/CDB的JOB关联性的测试:
SQL> conn as sysdbaConnected.SQL> select name, ctime, how_created,OWNER_NAME from sys.wri$_adv_taskswhere name in ('AUTO_STATS_ADVISOR_TASK','INDIVIDUAL_STATS_ADVISOR_TASK');2AUTO_STATS_ADVISOR_TASK25-SEP-19 CMD SYSSQL> DECLAREv_tname VARCHAR2(32767);BEGINv_tname := 'AUTO_STATS_ADVISOR_TASK';DBMS_STATS.DROP_ADVISOR_TASK(v_tname);END;/234567PL/SQL procedure successfully completed.SQL> select name, ctime, how_created,OWNER_NAME from sys.wri$_adv_taskswhere name in ('AUTO_STATS_ADVISOR_TASK','INDIVIDUAL_STATS_ADVISOR_TASK');2no rows selectedSQL> show pdbs2 PDB$SEED READ ONLYNO3 PDB1 READ WRITE NO---PDB中JOB的状态SQL> alter session set container=pdb1;Session altered.SQL> select name, ctime, how_created,OWNER_NAME from sys.wri$_adv_taskswhere name in ('AUTO_STATS_ADVISOR_TASK','INDIVIDUAL_STATS_ADVISOR_TASK');2AUTO_STATS_ADVISOR_TASK 26-JAN-17 CMD SYSINDIVIDUAL_STATS_ADVISOR_TASK26-JAN-17 CMD SYSSQL> DECLAREv_tname VARCHAR2(32767);BEGINv_tname := 'AUTO_STATS_ADVISOR_TASK';DBMS_STATS.DROP_ADVISOR_TASK(v_tname);END;/234567PL/SQL procedure successfully completed.SQL> select name, ctime, how_created,OWNER_NAME from sys.wri$_adv_taskswhere name in ('AUTO_STATS_ADVISOR_TASK','INDIVIDUAL_STATS_ADVISOR_TASK');2INDIVIDUAL_STATS_ADVISOR_TASK 26-JAN-17 CMD SYS---CDB 不会影响PDBSQL> conn as sysdbaConnected.SQL>EXEC DBMS_STATS.INIT_PACKAGE();PL/SQL procedure successfully completed.SQL> select name, ctime, how_created,OWNER_NAME from sys.wri$_adv_taskswhere name in ('AUTO_STATS_ADVISOR_TASK','INDIVIDUAL_STATS_ADVISOR_TASK');2AUTO_STATS_ADVISOR_TASK 15-NOV-19 CMD SYSINDIVIDUAL_STATS_ADVISOR_TASK15-NOV-19 CMD SYSSQL> alter session set container=pdb1;Session altered.SQL> select name, ctime, how_created,OWNER_NAME from sys.wri$_adv_taskswhere name in ('AUTO_STATS_ADVISOR_TASK','INDIVIDUAL_STATS_ADVISOR_TASK');2INDIVIDUAL_STATS_ADVISOR_TASK26-JAN-17 CMD SYSSQL>
问题4:超过PGA 限制引起ORA-4036
在执行统计信息收集JOB等的过程中会调用优化器统计顾问任务。
如果Statistics Advisor 任务的数据过多,有可能导致在执行统计信息收集JOB过程中引发ORA-4036.
例如输出的跟踪日志中的HEAP DUMP中qosadvCreateSu Chunk占用了较大空间,qosadvCreateSu是Statistics Advisor运行时所需的heap。
PRIVATE HEAP SUMMARY DUMP2582 MB total:1969 MB commented, 975 KB permanent612 MB free (0 KB in empty extents),2557 MB, 2 heaps: "callheap "607 MB free held------------------------------------------------------Summary of subheaps at depth 11962 MB total:1957 MB commented, 4805 KB permanent1136 KB free (0 KB in empty extents),1940 MB, 1 heap:"qosadvCreateSu " ★
可以通过定期删除Statistics Advisor 任务的数据 或者增加PGA_AGGREGATE_LIMIT的大小来解决。
问题5 如果禁用优化器统计顾问功能
由于这个功能可能引起一些问题,所以Oracle通过Enghance Bug 26749785提供了禁用该功能.
Bug 26749785将在未来版本20.1中默认修复,12.2/18c/19c的版本可以通过申请Bug 26749785的补丁来增加这个功能。
打了Bug 26749785的补丁后,就可以通过如下方法将这个功能禁用。
禁用优化器统计顾问(Optimizer Statistics Advisor)功能:SQL> exec dbms_stats.set_global_prefs('AUTO_STATS_ADVISOR_TASK','FALSE');确认设置情况:SQL> select dbms_stats.get_prefs('AUTO_STATS_ADVISOR_TASK') from dual;DBMS_STATS.GET_PREFS('AUTO_STATS_ADVISOR_TASK')--------------------------------------------------------------------------------FALSE再次启用优化器统计顾问(Optimizer Statistics Advisor)功能:SQL> exec dbms_stats.set_global_prefs('AUTO_STATS_ADVISOR_TASK','TRUE');
参考:
How To Disable Optimizer Statistics Advisor From 12.2 Onwards (Doc ID 2686022.1)
——End——
专注于技术不限于技术!
用碎片化的时间,一点一滴地提高数据库技术和个人能力。
欢迎关注!
关于小编:
10+年数据库运维/开发/技术支持经验,多年项目维护/开发/团队管理经验,熟悉Oracle/MySQL/DB2等关系型数据库,翻译出版《MySQL基础教程》,Oracle 11g OCM大师认证、10g/11g/12c OCP、RAC&GI OCE、Cloud等认证专家,IBM DB2 数据库V8.1 DBA认证。
本公众号文章仅作学习交流之用,内容代表个人观点,与任何公司无关。




