環境:Oracle 11.2.0.3 RAC
問題:統計信息自動收集任務失效原因排查
- 1.查看自動任務的狀態
- 2.進一步查看其它信息
- 3.解決問題
1.查看自動任務的狀態
查看自動任務的狀態,確認是enabled狀態:
SQL> select client_name,status from dba_autotask_client;CLIENT_NAME STATUS
---------------------------------------------------------------- --------
auto optimizer stats collection ENABLED
auto space advisor ENABLED
sql tuning advisor ENABLEDElapsed: 00:01:03.88
一般來說,這樣的結果,就意味著統計信息自動收集是打開的,如今卻是沒有自動收集。說明確實是有故障,需要進一步深入排查。
若對這些自動任務的狀態不理解可以參考之前文章:
- Oracle的窗口和自動任務
2.進一步查看其它信息
根據 Why Auto Optimizer Statistics Collection May Appear to be "Stuck" and Not Running? (文檔 ID 1320246.1)
排查以下項:
The 'auto optimizer stats collection' task is enabled in auto task
STATISTICS_LEVEL has already been set to TYPICAL or FULL
dba_autotask_client_history is empty
Statistics on tables are stale.
Some scheduler window is active and LAST_START_DATE is several days ago.
具體操作記錄如下:
--STATISTICS_LEVEL:
SQL> show parameter STATISTICS_LEVEL NAME TYPE VALUE
------------------------------------ ----------- ------------------------------
statistics_level string TYPICAL--dba_autotask_client_history is empty:
SQL> select * from dba_autotask_client_history;no rows selectedElapsed: 00:01:04.79--Some scheduler window is active and LAST_START_DATE 是20-SEP-12 10.00.00.010777 PM
SELECT window_name, last_start_date, enabled, active FROM dba_scheduler_windows;
SQL> SELECT window_name ,2 last_start_date,3 enabled ,4 active5 FROM dba_scheduler_windows;WINDOW_NAME LAST_START_DATE ENABL ACTIV
------------------------------ --------------------------------------------------------------------------- ----- -----
MONDAY_WINDOW 22-JAN-18 10.00.00.014299 PM PRC TRUE FALSE
TUESDAY_WINDOW 23-JAN-18 10.00.01.076798 PM PRC TRUE FALSE
WEDNESDAY_WINDOW 24-JAN-18 10.00.00.055066 PM PRC TRUE FALSE
THURSDAY_WINDOW 20-SEP-12 10.00.00.010777 PM PRC TRUE TRUE
FRIDAY_WINDOW 26-JAN-18 10.00.00.725176 PM PRC TRUE FALSE
SATURDAY_WINDOW 27-JAN-18 06.00.00.010751 AM PRC TRUE FALSE
SUNDAY_WINDOW 28-JAN-18 06.00.00.593207 AM PRC TRUE FALSE
WEEKNIGHT_WINDOW FALSE FALSE
WEEKEND_WINDOW FALSE FALSE9 rows selected.Elapsed: 00:00:00.01
可以看到,如今的環境確實完全匹配文檔列出的這些特征項。
另外,看下統計信息自動收集任務的WINDOW_GROUP以及對應的MEMBER_NAME:
SQL> select client_name,window_group2 from DBA_AUTOTASK_CLIENT3 where client_name = 'auto optimizer stats collection';CLIENT_NAME WINDOW_GROUP
---------------------------------------------------------------- ----------------------------------------------------------------
auto optimizer stats collection ORA$AT_WGRP_OSElapsed: 00:01:05.39
SQL> SELECT * FROM dba_scheduler_group_members2 where group_name='ORA$AT_WGRP_OS';OWNER GROUP_NAME MEMBER_NAME
------------------------------ ------------------------------ -----------------------------------------------------------------------------------------------------------------------------------
SYS ORA$AT_WGRP_OS "SYS"."MONDAY_WINDOW"
SYS ORA$AT_WGRP_OS "SYS"."TUESDAY_WINDOW"
SYS ORA$AT_WGRP_OS "SYS"."WEDNESDAY_WINDOW"
SYS ORA$AT_WGRP_OS "SYS"."THURSDAY_WINDOW"
SYS ORA$AT_WGRP_OS "SYS"."FRIDAY_WINDOW"
SYS ORA$AT_WGRP_OS "SYS"."SATURDAY_WINDOW"
SYS ORA$AT_WGRP_OS "SYS"."SUNDAY_WINDOW"7 rows selected.Elapsed: 00:00:00.04
可以看到,正常應該是一周7天都有的,但是由于THURSDAY_WINDOW 的窗口ACTIVE是TRUE,導致2012年9月27號(周四)統計信息收集失敗。根據MOS描述,會影響其后的窗口都打開失敗,進而導致之后所有自動任務的執行都失敗。
我實際在我的測試環境驗證也是如此,現象如下:
SQL> SELECT window_name, last_start_date, enabled, active FROM dba_scheduler_windows;WINDOW_NAME LAST_START_DATE ENABLED ACTIVE
------------------------------------------------------------ --------------------------------------------------------------------------- ---------- ----------
MONDAY_WINDOW 22-JAN-18 10.00.00.011111 PM EST5EDT TRUE FALSE
TUESDAY_WINDOW 23-JAN-18 10.22.54.068776 PM EST5EDT TRUE FALSE
WEDNESDAY_WINDOW 24-JAN-18 10.00.00.005654 PM EST5EDT TRUE FALSE
THURSDAY_WINDOW 25-JAN-18 10.00.00.009885 PM EST5EDT TRUE FALSE
FRIDAY_WINDOW 26-JAN-18 10.00.00.010077 PM EST5EDT TRUE FALSE
SATURDAY_WINDOW 27-JAN-18 05.00.00.004156 PM EST5EDT TRUE FALSE
SUNDAY_WINDOW 28-JAN-18 01.00.00.010044 PM EST5EDT TRUE TRUE
WEEKNIGHT_WINDOW FALSE FALSE
WEEKEND_WINDOW FALSE FALSE9 rows selected.SQL> EXECUTE DBMS_SCHEDULER.OPEN_WINDOW ('MONDAY_WINDOW','');
BEGIN DBMS_SCHEDULER.OPEN_WINDOW ('MONDAY_WINDOW',''); END;*
ERROR at line 1:
ORA-27480: window "SUNDAY_WINDOW" is currently open
ORA-06512: at "SYS.DBMS_ISCHED", line 493
ORA-06512: at "SYS.DBMS_SCHEDULER", line 1220
ORA-06512: at line 1SQL>
可以看到我測試環境,因為周日的窗口已經是ACTIVE,再嘗試打開周一的窗口就會報錯,看起來同時就只能有一個窗口ACTIVE,這與MOS的描述也完全一致。
3.解決問題
根據MOS解決建議手工關閉活動的窗口,我這里就是關閉THURSDAY_WINDOW窗口:
SQL> EXECUTE DBMS_SCHEDULER.CLOSE_WINDOW ('THURSDAY_WINDOW');PL/SQL procedure successfully completed.Elapsed: 00:00:00.14
再次查詢狀態,確認窗口狀態已關閉:
SQL> SELECT window_name ,2 last_start_date,3 enabled ,4 active5 FROM dba_scheduler_windows;WINDOW_NAME LAST_START_DATE ENABL ACTIV
------------------------------ --------------------------------------------------------------------------- ----- -----
MONDAY_WINDOW 22-JAN-18 10.00.00.014299 PM PRC TRUE FALSE
TUESDAY_WINDOW 23-JAN-18 10.00.01.076798 PM PRC TRUE FALSE
WEDNESDAY_WINDOW 24-JAN-18 10.00.00.055066 PM PRC TRUE FALSE
THURSDAY_WINDOW 20-SEP-12 10.00.00.010777 PM PRC TRUE FALSE
FRIDAY_WINDOW 26-JAN-18 10.00.00.725176 PM PRC TRUE FALSE
SATURDAY_WINDOW 27-JAN-18 06.00.00.010751 AM PRC TRUE FALSE
SUNDAY_WINDOW 28-JAN-18 06.00.00.593207 AM PRC TRUE FALSE
WEEKNIGHT_WINDOW FALSE FALSE
WEEKEND_WINDOW FALSE FALSE9 rows selected.
這樣就找到了問題,另外因為離統計信息信息自動收集關閉已有多年,目前生產環境運行平穩,所以最終決定保守處理,即:先將生產環境的自動任務都關閉,等在備庫測試驗證后再考慮生產環境開啟自動任務。
Reference
- Why Auto Optimizer Statistics Collection May Appear to be "Stuck" and Not Running? (文檔 ID 1320246.1)