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

如何排查ORA-1652: unable to extend temp segment

原创 大讲堂 2019-12-20
1828

问题描述

请问如何排查ORA-1652: unable to extend temp segment,提供一些诊断脚本,用于从 ASH 中找到最消耗 PGA 或者临时段的 sql_id。

专家解答

最消耗 PGA 的 sql_id:

select * from (select instance_number, sql_id, max(pga_sum_mb) pga_max from (select instance_number, sample_time, sql_id, round(sum(nvl(pga_allocated, 0))/1024/1024) pga_sum_mb from dba_hist_active_sess_history where sample_time between to_timestamp('&begin_timestamp', 'yyyy/mm/dd hh24:mi') and to_timestamp('&end_timestamp', 'yyyy/mm/dd hh24:mi') group by instance_number, sample_time, sql_id) group by instance_number, sql_id order by pga_max desc) where rownum <= 10;

最消耗临时段的 sql_id:

select * from (select instance_number, sql_id, max(temp_sum_mb) temp_max from (select instance_number, sample_time, sql_id, round(sum(nvl(temp_space_allocated, 0))/1024/1024) temp_sum_mb from dba_hist_active_sess_history where sample_time between to_timestamp('&begin_timestamp', 'yyyy/mm/dd hh24:mi') and to_timestamp('&end_timestamp', 'yyyy/mm/dd hh24:mi') group by instance_number, sample_time, sql_id) group by instance_number, sql_id order by temp_max desc) where rownum <= 10;
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论