暂无图片
暂无图片
1
暂无图片
暂无图片
暂无图片

检查当前undo配置并提供建议

579

参考:文档 ID 1579035.1
本文档旨在检查当前的undo配置,并根据以前的工作负载提供建议。

10g 及以上

请使用以下脚本。确保以SYSDBA执行

SET SERVEROUTPUT ON SET LINES 600 ALTER SESSION SET NLS_DATE_FORMAT = 'DD/MM/YYYY HH24:MI:SS'; DECLARE v_analyse_start_time DATE := SYSDATE - 7; v_analyse_end_time DATE := SYSDATE; v_cur_dt DATE; v_undo_info_ret BOOLEAN; v_cur_undo_mb NUMBER; v_undo_tbs_name VARCHAR2(100); v_undo_tbs_size NUMBER; v_undo_autoext BOOLEAN; v_undo_retention NUMBER(5); v_undo_guarantee BOOLEAN; v_instance_number NUMBER; v_undo_advisor_advice VARCHAR2(100); v_undo_health_ret NUMBER; v_problem VARCHAR2(1000); v_recommendation VARCHAR2(1000); v_rationale VARCHAR2(1000); v_retention NUMBER; v_utbsize NUMBER; v_best_retention NUMBER; v_longest_query NUMBER; v_required_retention NUMBER; BEGIN select sysdate into v_cur_dt from dual; DBMS_OUTPUT.PUT_LINE(CHR(9)); DBMS_OUTPUT.PUT_LINE('- Undo Analysis started at : ' || v_cur_dt || ' -'); DBMS_OUTPUT.PUT_LINE('--------------------------------------------------'); v_undo_info_ret := DBMS_UNDO_ADV.UNDO_INFO(v_undo_tbs_name, v_undo_tbs_size, v_undo_autoext, v_undo_retention, v_undo_guarantee); select sum(bytes)/1024/1024 into v_cur_undo_mb from dba_data_files where tablespace_name = v_undo_tbs_name; DBMS_OUTPUT.PUT_LINE('NOTE:The following analysis is based upon the database workload during the period -'); DBMS_OUTPUT.PUT_LINE('Begin Time : ' || v_analyse_start_time); DBMS_OUTPUT.PUT_LINE('End Time : ' || v_analyse_end_time); DBMS_OUTPUT.PUT_LINE(CHR(9)); DBMS_OUTPUT.PUT_LINE('Current Undo Configuration'); DBMS_OUTPUT.PUT_LINE('--------------------------'); DBMS_OUTPUT.PUT_LINE(RPAD('Current undo tablespace',55) || ' : ' || v_undo_tbs_name); DBMS_OUTPUT.PUT_LINE(RPAD('Current undo tablespace size (datafile size now) ',55) || ' : ' || v_cur_undo_mb || 'M'); DBMS_OUTPUT.PUT_LINE(RPAD('Current undo tablespace size (consider autoextend) ',55) || ' : ' || v_undo_tbs_size || 'M'); IF V_UNDO_AUTOEXT THEN DBMS_OUTPUT.PUT_LINE(RPAD('AUTOEXTEND for undo tablespace is',55) || ' : ON'); ELSE DBMS_OUTPUT.PUT_LINE(RPAD('AUTOEXTEND for undo tablespace is',55) || ' : OFF'); END IF; DBMS_OUTPUT.PUT_LINE(RPAD('Current undo retention',55) || ' : ' || v_undo_retention); IF v_undo_guarantee THEN DBMS_OUTPUT.PUT_LINE(RPAD('UNDO GUARANTEE is set to',55) || ' : TRUE'); ELSE dbms_output.put_line(RPAD('UNDO GUARANTEE is set to',55) || ' : FALSE'); END IF; DBMS_OUTPUT.PUT_LINE(CHR(9)); SELECT instance_number INTO v_instance_number FROM V$INSTANCE; DBMS_OUTPUT.PUT_LINE('Undo Advisor Summary'); DBMS_OUTPUT.PUT_LINE('---------------------------'); v_undo_advisor_advice := dbms_undo_adv.undo_advisor(v_analyse_start_time, v_analyse_end_time, v_instance_number); DBMS_OUTPUT.PUT_LINE(v_undo_advisor_advice); DBMS_OUTPUT.PUT_LINE(CHR(9)); DBMS_OUTPUT.PUT_LINE('Undo Space Recommendation'); DBMS_OUTPUT.PUT_LINE('-------------------------'); v_undo_health_ret := dbms_undo_adv.undo_health(v_analyse_start_time, v_analyse_end_time, v_problem, v_recommendation, v_rationale, v_retention, v_utbsize); IF v_undo_health_ret > 0 THEN DBMS_OUTPUT.PUT_LINE('Minimum Recommendation : ' || v_recommendation); DBMS_OUTPUT.PUT_LINE('Rationale : ' || v_rationale); DBMS_OUTPUT.PUT_LINE('Recommended Undo Tablespace Size : ' || v_utbsize || 'M'); ELSE DBMS_OUTPUT.PUT_LINE('Allocated undo space is sufficient for the current workload.'); END IF; SELECT dbms_undo_adv.best_possible_retention(v_analyse_start_time, v_analyse_end_time) into v_best_retention FROM dual; SELECT dbms_undo_adv.longest_query(v_analyse_start_time, v_analyse_end_time) into v_longest_query FROM dual; SELECT dbms_undo_adv.required_retention(v_analyse_start_time, v_analyse_end_time) into v_required_retention FROM dual; DBMS_OUTPUT.PUT_LINE(CHR(9)); DBMS_OUTPUT.PUT_LINE('Retention Recommendation'); DBMS_OUTPUT.PUT_LINE('------------------------'); DBMS_OUTPUT.PUT_LINE(RPAD('The best possible retention with current configuration is ',60) || ' : ' || v_best_retention || ' Seconds'); DBMS_OUTPUT.PUT_LINE(RPAD('The longest running query run for ',60) || ' : ' || v_longest_query || ' Seconds'); DBMS_OUTPUT.PUT_LINE(RPAD('The undo retention required to avoid errors is ',60) || ' : ' || v_required_retention || ' Seconds'); END; /

输出示例:

- Undo Analysis started at : 15/04/2022 17:20:10 - -------------------------------------------------- NOTE:The following analysis is based upon the database workload during the period - Begin Time : 08/04/2022 17:20:10 End Time : 15/04/2022 17:20:10 Current Undo Configuration -------------------------- Current undo tablespace : UNDOTBS1 Current undo tablespace size (datafile size now) : 210M Current undo tablespace size (consider autoextend) : 11582M AUTOEXTEND for undo tablespace is : ON Current undo retention : 900 UNDO GUARANTEE is set to : FALSE Undo Advisor Summary --------------------------- Finding 1:The undo tablespace is OK. Undo Space Recommendation ------------------------- Allocated undo space is sufficient for the current workload. Retention Recommendation ------------------------ The best possible retention with current configuration is : 5411998 Seconds The longest running query run for : 1915 Seconds The undo retention required to avoid errors is : 1915 Seconds
最后修改时间:2022-04-16 10:09:57
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论