--//有时候上班业务突然出现异常,想快速了解昨天晚上那些表做了分析。
--//可以查看DBA_OPTSTAT_OPERATIONS视图,了解做了那些操作。当然许多视图也能了解什么时间做了分析.
--//oracle的DBMS_STATS.REPORT_STATS_OPERATIONS也可以实现类似功能测试看看。
1.环境:
SCOTT@test01p> @ ver1
PORT_STRING VERSION BANNER CON_ID
------------------------------ -------------- -------------------------------------------------------------------------------- ----------
IBMPC/WIN_NT64-9.1.0 12.2.0.1.0 Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production 0
2.分析表:
--//顺便找两个表T1,T2分析看看。
3.测试DBMS_STATS.REPORT_STATS_OPERATIONS:
--//然后执行如下:
column my_report format a200
variable my_report clob;
BEGIN
:my_report := DBMS_STATS.REPORT_STATS_OPERATIONS (
since => SYSDATE-1
, until => SYSDATE
, detail_level => 'TYPICAL'
, format => 'TEXT'
);
END;
/
SCOTT@test01p> print :my_report
MY_REPORT
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
| CDB Id | Operation Id | Operation | Target | Start Time | End Time | Status | Total Tasks | Successful Tasks | Failed Tasks | Active Tasks |
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
| 3 | 5484 | gather_table_stats | SCOTT.T2 | 2023-09-06 21:31:18.340000 | 2023-09-06 21:31:19.922000 | COMPLETED | 2 | 2 | 0 | 0 |
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
| 3 | 5464 | gather_table_stats | SCOTT.T1 | 2023-09-06 21:31:09.927000 | 2023-09-06 21:31:13.899000 | COMPLETED | 1 | 1 | 0 | 0 |
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
4.可以单独执行DBMS_STATS.REPORT_SINGLE_STATS_OPERATION函数了解一些细节:
BEGIN
:my_report :=DBMS_STATS.REPORT_SINGLE_STATS_OPERATION (
OPID => 5484
, FORMAT => 'TEXT'
);
END;
/
SCOTT@test01p> print my_report
MY_REPORT
--------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
| Operation Id | Operation | Target | Start Time | End Time | Status | Total Tasks | Successful Tasks | Failed Tasks | Active Tasks |
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
| 5484 | gather_table_stats | SCOTT.T2 | 2023-09-06 21:31:18.340000 | 2023-09-06 21:31:19.922000 | COMPLETED | 2 | 2 | 0 | 0 |
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
| |
| --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- |
| T A S K S |
| --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- |
| --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- |
| | Target | Type | Start Time | End Time | Status | |
| --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- |
| | SCOTT.T2 | TABLE | 2023-09-06 21:31:18.353000 | 2023-09-06 21:31:19.903000 | COMPLETED | |
| --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- |
| | SCOTT.T2_I2 | INDEX | 2023-09-06 21:31:19.196000 | 2023-09-06 21:31:19.831000 | COMPLETED | |
| --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- |
| |
| |
-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
--//有点太花俏,估计很少查细节。也可以支持html格式。
BEGIN
:my_report :=DBMS_STATS.REPORT_SINGLE_STATS_OPERATION (
OPID => 5484
, FORMAT => 'HTML'
);
END;
/
SCOTT@test01p> spool myoutput.html
SCOTT@test01p> print my_report
...
SCOTT@test01p> spool off
SCOTT@test01p> host "E:\Progra~1\Mozill~1\firefox.exe" d:\tmp\myoutput.html
--//可以打开浏览器查看。不知道为什么仅仅支持"E:\Progra~1\Mozill~1\firefox.exe"这样写,如果有空格解析错误.
4.根据前面测试可以建立脚本如下:
$ cat report_stats.sql
column my_report format a200
variable my_report clob;
BEGIN
:my_report := DBMS_STATS.REPORT_STATS_OPERATIONS (
since => &1
, until => &2
, detail_level => 'TYPICAL'
, format => 'TEXT'
);
END;
/
prompt BEGIN
prompt :my_report :=DBMS_STATS.REPORT_SINGLE_STATS_OPERATION (
prompt OPID => &OPID
prompt , FORMAT => 'TEXT'
prompt );;
prompt END;;
prompt /
prompt
prompt print :my_report
print :my_report
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。
Oracle RAC 一键安装翻车?手把手教你如何排错!
Lucifer三思而后行
578次阅读
2025-04-15 17:24:06
【纯干货】Oracle 19C RU 19.27 发布,如何快速升级和安装?
Lucifer三思而后行
526次阅读
2025-04-18 14:18:38
Oracle SQL 执行计划分析与优化指南
Digital Observer
482次阅读
2025-04-01 11:08:44
墨天轮个人数说知识点合集
JiekeXu
467次阅读
2025-04-01 15:56:03
XTTS跨版本迁移升级方案(11g to 19c RAC for Linux)
zwtian
464次阅读
2025-04-08 09:12:48
Oracle数据库一键巡检并生成HTML结果,免费脚本速来下载!
陈举超
453次阅读
2025-04-20 10:07:02
【ORACLE】记录一些ORACLE的merge into语句的BUG
DarkAthena
449次阅读
2025-04-22 00:20:37
【ORACLE】你以为的真的是你以为的么?--ORA-38104: Columns referenced in the ON Clause cannot be updated
DarkAthena
423次阅读
2025-04-22 00:13:51
Oracle 19c RAC更换IP实战,运维必看!
szrsu
410次阅读
2025-04-08 23:57:08
【活动】分享你的压箱底干货文档,三篇解锁进阶奖励!
墨天轮编辑部
399次阅读
2025-04-17 17:02:24