Oracle-11g 中当执行 DBMS_STATS 时,因数据泵外部表文件缺失 Alert Log 告警 "ORA-20011、ORA-29913" 以及 "KUP-XXXXX"错误

时间:2023-11-17 08:44:56


:first-child { margin-top: 0; } blockquote > :last-child { margin-bottom: 0; } img { border: 0; max-width: 100%; height: auto !important; margin: 2px 0; } table { border-collapse: collapse; border: 1px solid #bbbbbb; } td, th { padding: 4px 8px; border-collapse: collapse; border: 1px solid #bbbbbb; } @media only screen and (-webkit-max-device-width: 1024px), only screen and (-o-max-device-width: 1024px), only screen and (max-device-width: 1024px), only screen and (-webkit-min-device-pixel-ratio: 3), only screen and (-o-min-device-pixel-ratio: 3), only screen and (min-device-pixel-ratio: 3) { html, body { font-size: 17px; } body { line-height: 1.7; padding: 0.75rem 0.9375rem; color: #353c47; } h1 { font-size: 2.125rem; } h2 { font-size: 1.875rem; } h3 { font-size: 1.625rem; } h4 { font-size: 1.375rem; } h5 { font-size: 1.125rem; } h6 { color: inherit; } ul, ol { padding-left: 2.5rem; } blockquote { padding: 0 0.9375rem; } }
-->

div{font-size:15px;}.wiz-table-tools .wiz-table-menu-item.active .wiz-table-menu-sub {display: block}.wiz-table-tools .wiz-table-menu-sub:before, .wiz-table-tools .wiz-table-menu-sub:after {position: absolute;content: " ";border-style: solid;border-color: transparent;border-bottom-color: #cccccc;left: 22px;margin-left: -14px;top: -8px;border-width: 0 8px 8px 8px;z-index:10;}.wiz-table-tools .wiz-table-menu-sub:after {border-bottom-color: #ffffff;top: -7px;}.wiz-table-tools .wiz-table-menu-sub-item {padding: 4px 12px;font-size: 14px;}.wiz-table-tools .wiz-table-menu-sub-item.split {border-top: 1px solid #E0E0E0;}.wiz-table-tools .wiz-table-menu-sub-item:hover {background-color: #ececec;}.wiz-table-tools .wiz-table-menu-sub-item.disabled {color: #bbbbbb;cursor: default;}.wiz-table-tools .wiz-table-menu-sub-item.disabled:hover {background-color: transparent;}.wiz-table-tools .wiz-table-menu-item.wiz-table-cell-bg:hover .wiz-table-color-pad {display: block;}.wiz-table-tools .wiz-table-color-pad {display: none;padding: 10px;box-sizing: border-box;width: 85px;height: 88px;background-color: #fff;cursor: default;}.wiz-table-tools .wiz-table-color-pad > div{font-size:15px;}.wiz-table-tools .wiz-table-color-pad .wiz-table-color-pad-item {display: inline-block;width: 15px;height: 15px;margin-right: 9px;position: relative;}.wiz-table-tools .wiz-table-color-pad .wiz-table-color-pad-item i.pad-demo {position: absolute;top:3px;left:0;}.wiz-table-tools .wiz-table-color-pad .wiz-table-color-pad-item .icon-oblique_line{color: #cc0000;}.wiz-table-tools .wiz-table-color-pad .wiz-table-color-pad-item:last-child {margin-right: 0;}.wiz-table-tools .wiz-table-color-pad .wiz-table-color-pad-item.active i.editor-icon.icon-box {color: #448aff;}.wiz-table-tools .wiz-table-cell-align {display: none;padding: 10px;box-sizing: border-box;width: 85px;height: 65px;background-color: #fff;cursor: default;}.wiz-table-tools .wiz-table-cell-align .wiz-table-cell-align-item {display: inline-block;width: 15px;height: 15px;margin-right: 9px;position: relative;}.wiz-table-tools .wiz-table-cell-align .wiz-table-cell-align-item:last-child {margin-right:0}.wiz-table-tools .wiz-table-cell-align .wiz-table-cell-align-item i.valign{position: absolute;top:3px;left:0;color: #d2d2d2;}.wiz-table-tools .wiz-table-cell-align-item.active i.editor-icon.valign {color: #a1c4ff;}.wiz-table-tools .wiz-table-cell-align-item.active i.editor-icon.icon-box,.wiz-table-tools .wiz-table-cell-align-item.active i.editor-icon.align {color: #448aff;}.wiz-table-tools .wiz-table-color-pad .wiz-table-color-pad-item:last-child,.wiz-table-tools .wiz-table-cell-align .wiz-table-cell-align-item:last-child {margin-right: 0;}th.wiz-selected-cell-multi, td.wiz-selected-cell-multi {background: rgba(0,102,255,.05);}th:before,td:before,#wiz-table-col-line:before,#wiz-table-range-border_start_right:before,#wiz-table-range-border_range_right:before{content: " ";position: absolute;top: 0;bottom: 0;right: -5px;width: 9px;cursor: col-resize;background: transparent;z-index:100;}th:after,td:after,#wiz-table-row-line:before,#wiz-table-range-border_start_bottom:before,#wiz-table-range-border_range_bottom:before{content: " ";position: absolute;left: 0;right: 0;bottom: -5px;height: 9px;cursor: row-resize;background: transparent;z-index:100;}.wiz-table-container {}.wiz-table-body {position:relative;padding:0 0 10px;overflow-x:auto;overflow-y:hidden;-webkit-overflow-scrolling:touch;}.wiz-table-body table {margin:0;outline:none;}td,th {height:28px;word-break:break-all;box-sizing:border-box;outline:none;}body pre.prettyprint {padding:0;}body pre.prettyprint code {white-space: pre;}body pre.prettyprint.linenums {box-shadow:none; overflow: auto;-webkit-overflow-scrolling: touch;}body pre.prettyprint.linenums ol.linenums {box-shadow: 40px 0 0 #FBFBFC inset, 41px 0 0 #ECECF0 inset; padding: 10px 10px 10px 40px !important;}
-->

告警现象:

Alert Log 中 出现类似如下告警信息。
*** 2016-11-24 22:00:05.260
DBMS_STATS: GATHER_STATS_JOB: GATHER_TABLE_STATS('"ADM_ZSZ"','"ET$02D2001B0001"','""', ...)
DBMS_STATS: ORA-20011: Approximate NDV failed: ORA-29913: error in executing ODCIEXTTABLEOPEN callout
KUP-11024: This external table can only be accessed from within a Data Pump job.
告警原因:
当尝试读取外部表时,外部函数 "ODCIEXTTABLEOPEN" 报错。
真正原因是关联外部表的文件已不存在,而数据库却仍认为文件仍存在。数据库之所以认为文件仍存在是因为外部表的目录信息并未被改动。
而数据泵外部表文件缺失往往因为数据包作业没有正常结束导致。
处理步骤:
1.识别失效的数据泵作业
SQL> SELECT owner_name, job_name, rtrim(operation) "OPERATION", 
       rtrim(job_mode) "JOB_MODE", state, attached_sessions
  FROM dba_datapump_jobs
 WHERE job_name NOT LIKE 'BIN$%'
 AND state='NOT RUNNING'
 ORDER BY 1,2;
根据查询结果,识别出失效的数据泵作业。注意:并非所有"NOT RUNNING"的作业都是失效作业。
2.识别失效数据泵作业关联的数据表
SQL> SELECT o.status, o.object_id, o.object_type, 
       o.owner||'.'||object_name "OWNER.OBJECT" 
  FROM dba_objects o, dba_datapump_jobs j 
 WHERE o.owner=j.owner_name AND o.object_name=j.job_name 
   AND j.state='NOT RUNNING'
   AND j.job_name NOT LIKE 'BIN$%' ORDER BY 4,2; 
3.删除失效数据泵作业关联的数据表
根据步骤 2 "识别失效数据泵作业关联的数据表" 的结果,通过类似如下语句删除数据表。
SQL> DROP TABLE <schema>.<table_name> PURGE;
4.清理顽固的失效数据泵作业
重新执行步骤 1 "识别失效的数据泵作业" ,如果删除数据表后失效作业仍存在,则需要以作业所有用户连接数据库,执行类似如下语句。
例如:清理的失效作业的数据表名为 "SYS_EXPORT_TABLE_01",失效作业由 "SCOTT" 发起。
SQL> SET serveroutput on 
SET lines 100 
DECLARE 
   h1 NUMBER; 
BEGIN 
   h1 := DBMS_DATAPUMP.ATTACH('SYS_EXPORT_TABLE_01','SCOTT'); 
   DBMS_DATAPUMP.STOP_JOB (h1); 
END; 
/
5.识别数据泵作业关联的失效外部表
注意:为了避免潜在的干扰因素,在识别不存在的外部表过程中,请确保没有数据泵作业在运行
通过以下语句确定外部表
SQL> select owner, TABLE_NAME, TYPE_NAME, DEFAULT_DIRECTORY_NAME, ACCESS_TYPE
from dba_external_tables
order by 1,2;
通过以下语句确定数据泵作业的外部表
SQL> select OWNER,OBJECT_NAME,OBJECT_TYPE, status,
to_char(CREATED,'dd-mon-yyyy hh24:mi:ss') created
,to_char(LAST_DDL_TIME , 'dd-mon-yyyy hh24:mi:ss') last_ddl_time
from dba_objects
where object_name like 'ET$%';
6.删除数据泵作业关联的失效外部表
根据步骤 5 "识别数据泵作业关联的失效外部表" 的结果,确保外部表属于数据泵进程,通过类似如下语句删除外部表。
SQL> DROP TABLE <schema>.<table_name> PURGE;
参考文档:
(1).《How To Cleanup Orphaned DataPump Jobs In DBA_DATAPUMP_JOBS  (文档 ID 336014.1)》
(2).《ORA-20011 ORA-29913 and ORA-29400 with Associated KUP-XXXXX Errors from DBMS_STATS.GATHER_STATS_JOB (文档 ID 1274653.1)》