暂无图片
暂无图片
暂无图片
暂无图片
暂无图片
sqlhistory.txt
77
6页
2次
2023-12-26
5墨值下载
/**********************************************************************
* File: sqlhistory.sql
* Type: SQL*Plus script
* Author: Tim Gorman (Evergreen Database Technologies, Inc.)
* Date: 1May2015
*
* Description:
* SQL*Plus script to query the "history" of a specified SQL
* statement, using its "SQL ID" across all database instances
* in a database, using the AWR repository. This report is useful
* for obtaining an hourly perspective on SQL statements seen in
* more aggregated reports.
*
* Modifications:
* TGorman 29sep08 adapted from the earlier STATSPACK-based
* "sphistory.sql" script
* Anbob 2015/5/1 add instance number indentify
* Anbob 07Api23 add more delta
* Call:
* @sqlhistory --request sql_id and days
*********************************************************************/
set echo off
set feedback off timing off verify off pagesize 100 linesize 300 recsep off
set serveroutput on size 1000000 format wrapped trimout on trimspool on
col phv heading "Plan|Hash Value"
col snap_time format a12 truncate heading "Snapshot|Time"
col execs format 999,990 heading "Execs"
col lio_per_exec format 999,999,990.00 heading "Avg LIO|Per Exec"
col rows_per_exec format 999,999,990.00 heading "Avg Rows|Per Exec"
col pio_per_exec format 999,999,990.00 heading "Avg PIO|Per Exec"
col cpu_per_exec format 999,999,990.00 heading "Avg|CPU (secs)|Per Exec"
col ela_per_exec format 999,999,990.00 heading "Avg|Elapsed (secs)|Per Exec"
col IOW_per_exec format 9,999,990.00 heading "Avg|IO(secs)|Per Exec"
col CLW_per_exec format 9,999,990.00 heading "Avg|Clus(secs)|Per Exec"
col AQW_per_exec format 9,999,990.00 heading "Avg|APP (secs)|Per Exec"
col CCW_per_exec format 9,999,990.00 heading "Avg|Conc(secs)|Per Exec"
col off_per_exec format 9,999,990.00 heading "Avg|Celoff(secs)|Per Exec"
col VERSION_COUNT format 999 "Ver|cnt"
col sql_text format a64 heading "Text of SQL statement"
col instance_number for 9999 heading "Inst"
clear breaks computes
ttitle off
btitle off
accept V_SQL_ID prompt "Enter the SQL_ID: "
accept V_NBR_DAYS prompt "Enter number of days (backwards from this hour) to
report (default: ALL): "
variable v_nbr_days number
spool sqlhistory_&&V_SQL_ID
declare
cursor get_phv(in_sql_id in varchar2, in_days in integer)
is
select ss.plan_hash_value,
min(s.begin_interval_time) min_time,
max(s.begin_interval_time) max_time,
min(s.snap_id) min_snap,
max(s.snap_id) max_snap,
sum(ss.executions_delta) sum_execs,
sum(ss.disk_reads_delta) sum_disk_reads,
sum(ss.buffer_gets_delta) sum_buffer_gets,
sum(ss.cpu_time_delta)/1000000 sum_cpu_time,
sum(ss.elapsed_time_delta)/1000000 sum_elapsed_time
from dba_hist_sqlstat ss,
dba_hist_snapshot s
where ss.dbid = s.dbid
and ss.instance_number = s.instance_number
and ss.snap_id = s.snap_id
and ss.sql_id = in_sql_id
and ss.executions_delta > 0
and s.begin_interval_time >= sysdate-in_days
group by ss.plan_hash_value
order by sum_elapsed_time desc;
--
cursor get_xplan(in_sql_id in varchar2, in_phv in number)
is
select plan_table_output
from table(dbms_xplan.display_awr(in_sql_id, in_phv, null, 'ALL
-ALIAS'));
--
v_prev_plan_hash_value number := -1;
v_text_lines number := 0;
v_errcontext varchar2(100);
v_errmsg varchar2(100);
v_display_sql_text boolean;
--
begin
--
v_errcontext := 'query NBR_DAYS from DUAL';
select
decode('&&V_NBR_DAYS','',10,to_number(nvl('&&V_NBR_DAYS','10')))
into :v_nbr_days
from dual;
--
v_errcontext := 'open/fetch get_phv';
for phv in get_phv('&&V_SQL_ID', :v_nbr_days) loop
--
if get_phv%rowcount = 1 then
--
dbms_output.put_line('+'||
rpad('-',12,'-')||
rpad('-',10,'-')||
rpad('-',10,'-')||
rpad('-',12,'-')||
rpad('-',15,'-')||
rpad('-',15,'-')||
rpad('-',12,'-')||
rpad('-',12,'-')||'+');
dbms_output.put_line('|'||
rpad('Plan HV',12,' ')||
rpad('Min Snap',10,' ')||
rpad('Max Snap',10,' ')||
rpad('Execs',12,' ')||
rpad('LIO',15,' ')||
rpad('PIO',15,' ')||
rpad('CPU',12,' ')||
rpad('Elapsed',12,' ')||'|');
dbms_output.put_line('+'||
rpad('-',12,'-')||
rpad('-',10,'-')||
rpad('-',10,'-')||
of 6
5墨值下载
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文档的来源(墨天轮),文档链接,文档作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。

评论

关注
最新上传
暂无内容,敬请期待...
下载排行榜
Top250 周榜 月榜