forked from abdulirfan3/Oracle_SQL_Scripts
-
Notifications
You must be signed in to change notification settings - Fork 0
/
awr_event_trends.sql
335 lines (325 loc) · 17.8 KB
/
awr_event_trends.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
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
/**********************************************************************
* File: awr_evtrends.sql
* Type: SQL*Plus script
* Author: Tim Gorman (Evergreen Database Technologies, Inc.)
* Date: 15-Jul-2003
*
* Description:
* Query to display "trends" for specific wait-events captured in
* the AWR repository, and display summarized totals daily and
* hourly as a ratio using the RATIO_FOR_REPORT analytic function.
*
* The intent is to find the readings with the greatest deviation
* from the average value, as these are likely to be "periods of
* interest" for further, more detailed research...
*
* Modifications:
* TGorman 25aug08 adapted from similar script for STATSPACK
* TGorman 22apr10 added average wait times
* TGorman 23mar11 added top-level rollup level as well snap-by-snap
* detailed level (if snaps taken more frequently
* than hourly)
*********************************************************************/
set echo off feedback off timing off pagesize 500 linesize 160
set trimout on trimspool on verify off
col sort0 noprint
col day format a6 heading "Day"
col hr format a6 heading "Hour"
col event_name format a30 heading "Event Name"
col total_waits format 999,990 heading "Total|Waits (m)"
col time_waited format 999,990.00 heading "Secs|Waited"
col tot_wts format 990.00 heading "% Total|Waits"
col tot_pct format 990.00 heading "% Secs|Waited"
col avg_wait format 990.00 heading "Avg|hSecs|Per|Wait"
col avg_pct format 990.00 heading "% Avg|hSecs|Per|Wait"
col wt_graph format a18 heading "Graphical view|of % total|waits overall"
col tot_graph format a18 heading "Graphical view|of % total|secs waited overall"
col avg_graph format a18 heading "Graphical view|of % avg hSecs|per wait overall"
ttitle off
clear breaks computes
accept V_NBR_DAYS prompt "How many days of AWR information should we use? "
break on wait_class on report
prompt
prompt Some useful database wait-events upon which to search:
col wait_class format a20 heading "Wait Class"
col name format a60 heading "Name"
select chr(9)||wait_class, name name
from v$event_name
order by wait_class, name;
accept V_EVENTNAME prompt "Which wait-event from this list do you wish to analyze? "
col spoolname new_value V_SPOOLNAME noprint
col instance_name new_value V_INST_NAME noprint
col instance_number new_value V_INST_NBR noprint
col dbid new_value V_DBID noprint
select replace(replace(replace(lower('&&V_EVENTNAME'),' ','_'),'(',''),')','') spoolname,
i.instance_name,
i.instance_number,
d.dbid
from v$instance i,
v$database d;
--spool awr_evtrends_&&V_INST_NAME._&&V_SPOOLNAME
clear breaks computes
ttitle center 'Trends for waits on "&&V_EVENTNAME" over the past &&V_NBR_DAYS days' skip line
col total_waits format 999,990.00 heading "Waits (m)"
prompt
select event_name,
total_waits/1000000 total_waits,
(ratio_to_report(total_waits) over ()*100) tot_wts,
rpad('*', round((ratio_to_report(total_waits) over ()*100)/6, 0), '*') wt_graph,
time_waited,
(ratio_to_report(time_waited) over ()*100) tot_pct,
rpad('*', round((ratio_to_report(time_waited) over ()*100)/6, 0), '*') tot_graph,
avg_wait*100 avg_wait,
(ratio_to_report(avg_wait) over ()*100) avg_pct,
rpad('*', round((ratio_to_report(avg_wait) over ()*100)/6, 0), '*') avg_graph
from (select event_name,
sum(total_waits) total_waits,
sum(time_waited)/1000000 time_waited,
decode(sum(total_waits),0,0,(sum(time_waited)/sum(total_waits))/1000000) avg_wait
from (select s.event_name,
s.snap_id,
nvl(decode(greatest(s.time_waited_micro,
lag(s.time_waited_micro,1,0)
over (partition by s.dbid,
s.instance_number
order by s.snap_id)),
s.time_waited_micro,
s.time_waited_micro - lag(s.time_waited_micro)
over (partition by s.dbid,
s.instance_number
order by s.snap_id),
s.time_waited_micro), 0) time_waited,
nvl(decode(greatest(s.total_waits,
lag(s.total_waits,1,0)
over (partition by s.dbid,
s.instance_number
order by s.snap_id)),
s.total_waits,
s.total_waits - lag(s.total_waits)
over (partition by s.dbid,
s.instance_number
order by s.snap_id),
s.total_waits), 0) total_waits
from dba_hist_system_event s,
dba_hist_snapshot ss
where s.event_name like '%'||'&&V_EVENTNAME'||'%'
and s.instance_number = &&V_INST_NBR
and s.dbid = &&V_DBID
and ss.snap_id = s.snap_id
and ss.dbid = s.dbid
and ss.instance_number = s.instance_number
and ss.begin_interval_time >= trunc(sysdate) - &&V_NBR_DAYS)
group by event_name)
order by time_waited desc;
clear breaks computes
break on report
compute avg of total_waits on report
compute avg of time_waited on report
compute avg of avg_wait on report
ttitle center 'Daily trends for waits on "&&V_EVENTNAME" over the past &&V_NBR_DAYS days' skip line
col total_waits format 999,990.00 heading "Waits (m)"
prompt
select sort_day || trim(to_char(999999999999999-time_waited,'000000000000000')) sort0,
day,
event_name,
total_waits/1000000 total_waits,
(ratio_to_report(total_waits) over ()*100) tot_wts,
rpad('*', round((ratio_to_report(total_waits) over ()*100)/6, 0), '*') wt_graph,
time_waited,
(ratio_to_report(time_waited) over ()*100) tot_pct,
rpad('*', round((ratio_to_report(time_waited) over ()*100)/6, 0), '*') tot_graph,
avg_wait*100 avg_wait,
(ratio_to_report(avg_wait) over ()*100) avg_pct,
rpad('*', round((ratio_to_report(avg_wait) over ()*100)/6, 0), '*') avg_graph
from (select sort_day,
day,
event_name,
sum(total_waits) total_waits,
sum(time_waited)/1000000 time_waited,
decode(sum(total_waits),0,0,(sum(time_waited)/sum(total_waits))/1000000) avg_wait
from (select to_char(ss.begin_interval_time, 'YYYYMMDD') sort_day,
to_char(ss.begin_interval_time, 'DD-MON') day,
s.event_name,
s.snap_id,
nvl(decode(greatest(s.time_waited_micro,
lag(s.time_waited_micro,1,0)
over (partition by s.dbid,
s.instance_number
order by s.snap_id)),
s.time_waited_micro,
s.time_waited_micro - lag(s.time_waited_micro)
over (partition by s.dbid,
s.instance_number
order by s.snap_id),
s.time_waited_micro), 0) time_waited,
nvl(decode(greatest(s.total_waits,
lag(s.total_waits,1,0)
over (partition by s.dbid,
s.instance_number
order by s.snap_id)),
s.total_waits,
s.total_waits - lag(s.total_waits)
over (partition by s.dbid,
s.instance_number
order by s.snap_id),
s.total_waits), 0) total_waits
from dba_hist_system_event s,
dba_hist_snapshot ss
where s.event_name like '%'||'&&V_EVENTNAME'||'%'
and s.instance_number = &&V_INST_NBR
and s.dbid = &&V_DBID
and ss.snap_id = s.snap_id
and ss.dbid = s.dbid
and ss.instance_number = s.instance_number
and ss.begin_interval_time >= trunc(sysdate) - &&V_NBR_DAYS)
group by sort_day,
day,
event_name)
order by sort0;
clear breaks computes
ttitle center 'Hourly trends for waits on "&&V_EVENTNAME" over the past &&V_NBR_DAYS days' skip line
col total_waits format 9,990.00 heading "Waits (m)"
break on day skip 1 on hr on report
compute avg of total_waits on report
compute avg of time_waited on report
compute avg of avg_wait on report
prompt
select sort_hr || trim(to_char(999999999999999-time_waited,'000000000000000')) sort0,
day,
hr,
event_name,
total_waits/1000000 total_waits,
(ratio_to_report(total_waits) over (partition by day)*100) tot_wts,
rpad('*', round((ratio_to_report(total_waits) over (partition by day)*100)/4, 0), '*') wt_graph,
time_waited,
(ratio_to_report(time_waited) over (partition by day)*100) tot_pct,
rpad('*', round((ratio_to_report(time_waited) over (partition by day)*100)/4, 0), '*') tot_graph,
avg_wait*100 avg_wait,
(ratio_to_report(avg_wait) over (partition by day)*100) avg_pct,
rpad('*', round((ratio_to_report(avg_wait) over (partition by day)*100)/4, 0), '*') avg_graph
from (select sort_hr,
day,
hr,
event_name,
sum(total_waits) total_waits,
sum(time_waited)/1000000 time_waited,
decode(sum(total_waits),0,0,(sum(time_waited)/sum(total_waits))/1000000) avg_wait
from (select to_char(ss.begin_interval_time, 'YYYYMMDDHH24') sort_hr,
to_char(ss.begin_interval_time, 'DD-MON') day,
to_char(ss.begin_interval_time, 'HH24')||':00' hr,
s.event_name,
s.snap_id,
nvl(decode(greatest(s.time_waited_micro,
lag(s.time_waited_micro,1,0)
over (partition by s.dbid,
s.instance_number
order by s.snap_id)),
s.time_waited_micro,
s.time_waited_micro - lag(s.time_waited_micro)
over (partition by s.dbid,
s.instance_number
order by s.snap_id),
s.time_waited_micro), 0) time_waited,
nvl(decode(greatest(s.total_waits,
lag(s.total_waits,1,0)
over (partition by s.dbid,
s.instance_number
order by s.snap_id)),
s.total_waits,
s.total_waits - lag(s.total_waits)
over (partition by s.dbid,
s.instance_number
order by s.snap_id),
s.total_waits), 0) total_waits
from dba_hist_system_event s,
dba_hist_snapshot ss
where s.event_name like '%'||'&&V_EVENTNAME'||'%'
and s.instance_number = &&V_INST_NBR
and s.dbid = &&V_DBID
and ss.snap_id = s.snap_id
and ss.dbid = s.dbid
and ss.instance_number = s.instance_number
and ss.begin_interval_time >= trunc(sysdate) - &&V_NBR_DAYS)
group by sort_hr,
day,
hr,
event_name)
order by sort0;
ttitle off
col avg_snap_frequency new_value V_AVG_SNAP_FREQUENCY noprint
select decode(greatest(count(*), &&V_NBR_DAYS * 4), &&V_NBR_DAYS * 4, 'HOURLY', 'MULTIPLE TIMES/HOUR') avg_snap_frequency
from (select count(*) cnt
from dba_hist_snapshot
where begin_interval_time >= trunc(sysdate) - &&V_NBR_DAYS
and dbid = &&V_DBID
and instance_number = &&V_INST_NBR
group by trunc(begin_interval_time, 'HH24')
having count(*) > 1);
clear breaks computes
ttitle center 'Snapshot-by-snapshot trends for waits on "&&V_EVENTNAME" over the past &&V_NBR_DAYS days' skip line
col total_waits format 9,990.00 heading "Waits (m)"
REM break on day skip 1 on hr on report
REM compute avg of total_waits on report
REM compute avg of time_waited on report
REM compute avg of avg_wait on report
select sort_snap || trim(to_char(999999999999999-time_waited,'000000000000000')) sort0,
day,
tm,
event_name,
total_waits/1000000 total_waits,
(ratio_to_report(total_waits) over (partition by day)*100) tot_wts,
rpad('*', round((ratio_to_report(total_waits) over (partition by day)*100)/4, 0), '*') wt_graph,
time_waited,
(ratio_to_report(time_waited) over (partition by day)*100) tot_pct,
rpad('*', round((ratio_to_report(time_waited) over (partition by day)*100)/4, 0), '*') tot_graph,
avg_wait*100 avg_wait,
(ratio_to_report(avg_wait) over (partition by day)*100) avg_pct,
rpad('*', round((ratio_to_report(avg_wait) over (partition by day)*100)/4, 0), '*') avg_graph
from (select sort_snap,
day,
tm,
event_name,
total_waits total_waits,
time_waited/1000000 time_waited,
decode(total_waits,0,0,((time_waited/total_waits)/1000000)) avg_wait
from (select to_char(ss.begin_interval_time, 'YYYYMMDDHH24MI') sort_snap,
to_char(ss.begin_interval_time, 'DD-MON') day,
to_char(ss.begin_interval_time, 'HH24:MI') tm,
s.event_name,
s.snap_id,
nvl(decode(greatest(s.time_waited_micro,
lag(s.time_waited_micro,1,0)
over (partition by s.dbid,
s.instance_number
order by s.snap_id)),
s.time_waited_micro,
s.time_waited_micro - lag(s.time_waited_micro)
over (partition by s.dbid,
s.instance_number
order by s.snap_id),
s.time_waited_micro), 0) time_waited,
nvl(decode(greatest(s.total_waits,
lag(s.total_waits,1,0)
over (partition by s.dbid,
s.instance_number
order by s.snap_id)),
s.total_waits,
s.total_waits - lag(s.total_waits)
over (partition by s.dbid,
s.instance_number
order by s.snap_id),
s.total_waits), 0) total_waits
from dba_hist_system_event s,
dba_hist_snapshot ss
where '&&V_AVG_SNAP_FREQUENCY' <> 'HOURLY'
and s.event_name like '%'||'&&V_EVENTNAME'||'%'
and s.instance_number = &&V_INST_NBR
and s.dbid = &&V_DBID
and ss.snap_id = s.snap_id
and ss.dbid = s.dbid
and ss.instance_number = s.instance_number
and ss.begin_interval_time >= trunc(sysdate) - &&V_NBR_DAYS))
order by sort0;
--spool off
ttitle off
clear breaks computes