-
Notifications
You must be signed in to change notification settings - Fork 18
/
Copy pathexafriendly.sql
337 lines (317 loc) · 9.68 KB
/
exafriendly.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
336
--------------------------------------------------------------------------------
-- File name: exafriendly.sql (report non-exadata-friendly SQL and their stats)
--
-- Purpose: This script is a collection of queries against ASH, which will
-- report and drill down into workloads which don't use Exadata smart
-- scanning and are doing buffered full table scans or random single
-- block reads instead. It uses the 11g new ASH columns
-- (SQL_PLAN_OPERATION, SQL_PLAN_OPTIONS) which give SQL plan line
-- level activity breakdown.
--
-- Note that this script is not a single SQL performance diagnosis tool,
-- for looking into a single SQL, use the SQL Monitoring report. This
-- exafriendly.sql script is aimed for giving you a high-level
-- bird's-eye view of "exadata-friendiness" of your workloads, so you'd
-- detect systemic problems and drill down where needed.
--
-- Usage: @exafriendly.sql <ash_data_source>
--
-- Examples: @exafriendly.sql gv$active_session_history
--
-- @exafriendly.sql "dba_hist_active_sess_history WHERE snap_time > SYSDATE-1"
--
-- Author: Tanel Poder ( http://blog.tanelpoder.com | tanel@tanelpoder.com )
--
-- Copyright: (c) 2012 All Rights Reserved
--
--
-- Other: I strongly recommend you to read through the script to understand
-- what it's doing and how the drilldown happens. You likely need
-- to customize things (or at least adjust filters) when you diagnose
-- stuff in your environment.
--
--------------------------------------------------------------------------------
COL wait_class FOR A20
COL event FOR A40
COL plan_line FOR A40
COL command_name FOR A15
COL pct FOR 999.9
define ash=&1
SELECT MAX(sample_time) - MIN(sample_time)
FROM &ash
/
PROMPT Report the top active SQL statements regardless of their CPU usage/wait event breakdown
SELECT * FROM (
SELECT
sql_id
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM &ash
WHERE
session_type = 'FOREGROUND'
GROUP BY
sql_id
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report the top session state/wait class breakdown
SELECT * FROM (
SELECT
session_state,wait_class
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM &ash
GROUP BY
session_state,wait_class
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report the top session state/wait event breakdown (just like TOP-5 Timed Events in AWR)
SELECT * FROM (
SELECT
session_state,wait_class,event
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM &ash
GROUP BY
session_state,wait_class,event
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report the top SQL waiting for buffered single block reads
SELECT * FROM (
SELECT
session_state,wait_class,event,sql_id
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM &ash
WHERE
session_state = 'WAITING'
AND event = 'cell single block physical read'
GROUP BY
session_state,wait_class,event,sql_id
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report the top SQL waiting for buffered single block reads the most (with sampled execution count)
SELECT * FROM (
SELECT
sql_plan_operation||' '||sql_plan_options plan_line,event,sql_id
, COUNT(DISTINCT(sql_exec_id)) noticed_executions
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM &ash
WHERE
session_state = 'WAITING'
AND event = 'cell single block physical read'
GROUP BY
sql_plan_operation||' '||sql_plan_options,event,sql_id
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report what kind of SQL execution plan operations, executed by which user wait for buffered single block reads the most
SELECT * FROM (
SELECT
sql_plan_operation||' '||sql_plan_options plan_line,u.username,event
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM &ash a
, dba_users u
WHERE
a.user_id = u.user_id
AND session_state = 'WAITING'
AND event = 'cell single block physical read'
GROUP BY
sql_plan_operation||' '||sql_plan_options,event,u.username
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report what kind of execution plan operations wait for buffered single block reads
SELECT * FROM (
SELECT
sql_plan_operation||' '||sql_plan_options plan_line,event
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM &ash
WHERE
session_state = 'WAITING'
AND event = 'cell single block physical read'
GROUP BY
sql_plan_operation||' '||sql_plan_options,event
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report what kind of execution plan operations wait for buffered single block reads - against which schemas
SELECT * FROM (
SELECT
sql_plan_operation||' '||sql_plan_options plan_line,p.object_owner,event
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM
v$active_session_history a
, v$sql_plan p
WHERE
a.sql_id = p.sql_id
AND a.sql_child_number = p.child_number
AND a.sql_plan_line_id = p.id
AND session_state = 'WAITING'
AND event = 'cell single block physical read'
GROUP BY
sql_plan_operation||' '||sql_plan_options,p.object_owner,event
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report what kind of execution plan operations wait for buffered single block reads - against which objects
SELECT * FROM (
SELECT
sql_plan_operation||' '||sql_plan_options plan_line,p.object_owner,p.object_name,event
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM
v$active_session_history a
, v$sql_plan p
WHERE
a.sql_id = p.sql_id
AND a.sql_child_number = p.child_number
AND a.sql_plan_line_id = p.id
AND session_state = 'WAITING'
AND event = 'cell single block physical read'
GROUP BY
sql_plan_operation||' '||sql_plan_options,p.object_owner,p.object_name,event
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report which SQL command type consumes the most time (broken down by wait class)
SELECT * FROM (
SELECT
command_name,session_state,wait_class
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM &ash, v$sqlcommand
WHERE &ash..sql_opcode = v$sqlcommand.command_type
GROUP BY
command_name,session_state,wait_class
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report what kind of execution plan operations wait for buffered multiblock reads the most
SELECT * FROM (
SELECT
sql_plan_operation||' '||sql_plan_options plan_line,event
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM
&ash
WHERE
session_state = 'WAITING'
AND event = 'cell multiblock physical read'
GROUP BY
sql_plan_operation||' '||sql_plan_options,event
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report what kind of execution plan operations wait for buffered multiblock reads - against which objects
SELECT * FROM (
SELECT
sql_plan_operation||' '||sql_plan_options plan_line,p.object_owner,p.object_name,event
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM
v$active_session_history a
, v$sql_plan p
WHERE
a.sql_id = p.sql_id
AND a.sql_child_number = p.child_number
AND a.sql_plan_line_id = p.id
AND session_state = 'WAITING'
AND event = 'cell multiblock physical read'
GROUP BY
sql_plan_operation||' '||sql_plan_options,p.object_owner,p.object_name,event
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/
PROMPT Report any PARALLEL full table scans which use buffered reads (in-memory PX)
SELECT * FROM (
SELECT
sql_id
, sql_plan_operation||' '||sql_plan_options plan_line
, CASE WHEN qc_session_id IS NULL THEN 'SERIAL' ELSE 'PARALLEL' END is_parallel
-- , px_flags
, session_state
, wait_class
, event
, COUNT(*)
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM &ash
WHERE
sql_plan_operation = 'TABLE ACCESS'
AND sql_plan_options = 'STORAGE FULL'
AND session_state = 'WAITING'
AND event IN ('cell single block physical read', 'cell multiblock physical read', 'cell list of blocks physical read')
AND qc_session_id IS NOT NULL -- is a px session
GROUP BY
sql_id
, sql_plan_operation||' '||sql_plan_options
, CASE WHEN qc_session_id IS NULL THEN 'SERIAL' ELSE 'PARALLEL' END --is_parallel
-- , px_flags
, session_state
, wait_class
, event
ORDER BY COUNT(*) DESC
)
WHERE rownum <= 20
/
DEF sqlid=4mpjt2rhwd1p4
PROMPT Report a single SQL_ID &sqlid
SELECT * FROM (
SELECT
sql_plan_operation||' '||sql_plan_options plan_line,session_state,event
, SUM(1) seconds
, ROUND(RATIO_TO_REPORT(COUNT(*)) OVER () * 100, 1) pct
FROM &ash
WHERE
sql_id = '&sqlid'
GROUP BY
sql_plan_operation||' '||sql_plan_options,session_state,event
ORDER BY
seconds DESC
)
WHERE
rownum <= 10
/