-
Notifications
You must be signed in to change notification settings - Fork 9
/
Copy paths06_run_awr_topsql_segstat_topn_by_exec-ts-custom.sql
133 lines (119 loc) · 7.99 KB
/
s06_run_awr_topsql_segstat_topn_by_exec-ts-custom.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
set feedback off term off head on und off trimspool on echo off lines 4000 colsep ',' arraysize 5000 verify off newpage none
COLUMN dbid NEW_VALUE _dbid NOPRINT
select dbid from v$database;
COLUMN dbname NEW_VALUE _dbname NOPRINT
select lower(db_unique_name) dbname from v$database;
COLUMN name NEW_VALUE _instname NOPRINT
select lower(instance_name) name from v$instance;
COLUMN name NEW_VALUE _hostname NOPRINT
select lower(host_name) name from v$instance;
COLUMN conname NEW_VALUE _conname NOPRINT
select case
when a.conname = 'CDB$ROOT' then 'ROOT'
when a.conname = 'PDB$SEED' then 'SEED'
else a.conname
end as conname
from (select SYS_CONTEXT('USERENV', 'CON_NAME') conname from dual) a;
COLUMN conid NEW_VALUE _conid NOPRINT
select SYS_CONTEXT('USERENV', 'CON_ID') conid from dual;
VARIABLE g_retention NUMBER
DEFINE p_default = 8
DEFINE p_max = 300
SET VERIFY OFF
DECLARE
v_default NUMBER(3) := &p_default;
v_max NUMBER(3) := &p_max;
BEGIN
select
((TRUNC(SYSDATE) + RETENTION - TRUNC(SYSDATE)) * 86400)/60/60/24 AS RETENTION_DAYS
into :g_retention
from dba_hist_wr_control
where dbid in (select dbid from v$database);
if :g_retention > v_default then
:g_retention := v_max;
else
:g_retention := v_default;
end if;
END;
/
col fms format 99999999999999999999999999
spool awr_topsql_segstat_topn_by_exec-ts-custom-&_instname-&_conname-&_conid..csv
with st_temp as (select a.sql_id, a.dbid, a.sql_text, a.sqldetail
from (select /*+ MATERIALIZE NO_MERGE */
sql_id,
dbid,
nvl(b.name, a.command_type) sql_text,
REPLACE(REPLACE( dbms_lob.substr(sql_text,50,1), CHR(10) ), CHR(13) ) sqldetail
from dba_hist_sqltext a, audit_actions b
where a.command_type = b.action(+)) a
where a.sqldetail not like '%SQL Analyze%'
and a.sqldetail not like '%sys.ora%'
)
select trim('&_dbname') db , a.*, st.sqldetail sqldetail from
(
SELECT s0.snap_id snap_id,
TO_CHAR(s0.END_INTERVAL_TIME,'MM/DD/YY HH24:MI:SS') tm,
s0.instance_number inst,
s.parsing_schema_name pschema,
s.module module,
spacesql.object_name obj_name,
s.sql_id,
s.plan_hash_value,
s.force_matching_signature fms,
stt.sql_text,
decode((sum(s.executions_delta)), 0, to_number(null), ((sum(s.elapsed_time_delta)) / (sum(s.executions_delta)) / 1000000)) elapexec,
sum(s.executions_delta) execs,
sum(s.elapsed_time_delta) / 1000000 etime,
sum(s.cpu_time_delta)/1000000 cputime,
sum(s.iowait_delta)/1000000 iotime,
sum(s.disk_reads_delta) pio,
sum(s.buffer_gets_delta) lio,
DENSE_RANK() OVER (PARTITION BY s0.snap_id, spacesql.object_name, stt.sql_text ORDER BY sum(s.executions_delta) DESC) time_rank
FROM
dba_hist_snapshot s0,
dba_hist_snapshot s1,
dba_hist_sqlstat s,
st_temp stt,
(SELECT sql_id, object_name
FROM dba_hist_sql_plan
WHERE object_name in (
'ALCOHOL_IMAGE',
'ALCOHOL_SCHEDULE',
'ALCOHOL_SCHEDULE_BLOCK',
'APP_2_APP_NOTIFICATION',
'DATA_CHANGE_LOG',
'SCHEDULE',
'SCHEDULE_ITEM',
'TO_ADDRESS_VISIT',
'TO_MONITORED_EVENT_NOTE',
'TO_MONITORED_EVENT_PSTEP',
'TO_OPEN_VIOS',
'TRACKED_OFFENDER_ADDRESS',
'TRACKED_OFFENDER_ASSOCIATION',
'TRACKED_OFFENDER_DEVICE',
'TRACKED_OFFENDER_LAST_CONTACT',
'TRACKED_OFFENDER_PROFILE',
'USER_CONTACT',
'USER_NOTIFICATION',
'VT_USER_PROFILE',
'ZONE'
) ) spacesql
WHERE s0.dbid = &_dbid -- CHANGE THE DBID HERE!
AND s1.dbid = s0.dbid
and s.dbid = s0.dbid
AND s1.instance_number = s0.instance_number
and s.instance_number = s0.instance_number
AND s1.snap_id = s0.snap_id + 1
and s.snap_id = s0.snap_id + 1
AND s.sql_id = spacesql.sql_id
AND s.sql_id = stt.sql_id
AND s.PARSING_SCHEMA_NAME NOT IN ('SYS','SYSTEM','DBSNMP','SYSMAN','AUDSYS','MDSYS','ORDSYS','XDB','APEX_PUBLIC_USER','ORACLE_OCM','APEX_050100','GSMADMIN_INTERNAL','ORDS_METADATA')
GROUP BY s0.snap_id, s0.END_INTERVAL_TIME, s0.instance_number, s.parsing_schema_name, s.module, spacesql.object_name, s.sql_id, s.plan_hash_value, s.force_matching_signature, stt.sql_text
) a,
(select sql_id, sql_text, sqldetail
from st_temp) st
where st.sql_id(+) = a.sql_id
and a.time_rank <= 15
order by snap_id,obj_name, st.sql_text, time_rank
/
spool off