-
Notifications
You must be signed in to change notification settings - Fork 13
/
Copy pathsqlperf_noawr.sql
866 lines (710 loc) · 28.4 KB
/
sqlperf_noawr.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
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
------------------------------------------------------------------------------------------------------------------------------------------------------
-- Retrieve a lot of information about query performance, based on sql_id
--
-- Script sqlperf_noawr.sql
-- Run as DBA
--
-- Purpose This script will retrieve info about a query, based on sql_id and create a HTML report
--
-- Input sql_id, child_number
--
-- Author M. Krijgsman
--
-- Remarks A Diagnostics Pack license is not required for this script
--
-- Version When Who What?
-- ------- ----------- -------------- ----------------------------------------------------------------------------------------------
-- 1.6 04 mar 2014 M. Krijgsman Initial version based on regular sqlperf.sql. I'm keeping version numbers in line with sqlperf.sql
-- to avoid (my) confusion.
------------------------------------------------------------------------------------------------------------------------------------------------------
column v_datetime new_value datetime noprint
select to_char(sysdate, 'YYYYMMDDHH24MISS') v_datetime from dual;
store set /tmp/your_sqlplus_env_&datetime..sql REPLACE
set linesize 3000
set feedback off
set verify off
set pause off
set timing off
set echo off
set heading on
set pages 999
set trimspool on
set newpage none
set define on
column vl_dbname new_value l_dbname noprint
select lower(name) vl_dbname from v$database;
prompt =============================================
prompt = =
prompt = sqlperf_noawr.sql =
prompt = This script will retrieve all kinds of =
prompt = information about SQLs based on sql_id =
prompt = =
prompt = (Version 10g or higher) =
prompt = =
prompt =============================================
prompt
accept sql_id default '' -
prompt 'Please provide the sql_id: '
prompt This instance.
prompt -----------------------------------
col instance_name for a16
col status for a16
select instance_name, instance_number, status
from v$instance;
prompt
prompt
prompt Different versions of the query.
prompt -----------------------------------
prompt (This should return only a handful of rows, or no binds have been used)
prompt
column vl_inst_id new_value l_inst_id noprint
select instance_number vl_inst_id from v$instance;
col sql_id for a20
col last_active_time for a16
col last_load_time for a20
col instance for a16
select a.sql_id, a.child_number
, case
when a.inst_id = &l_inst_id then 'THIS ONE'
else (select instance_name
from gv$instance
where instance_number=a.inst_id)
end instance, a.last_load_time
, to_char(a.last_active_time, 'DD-MON HH24:MI:SS') last_active_time
, a.loaded_versions, a.open_versions, a.users_opening
from gv$sql a
where sql_id='&sql_id';
prompt
prompt
prompt When the query has been runned from a different instance, run this script there.
prompt
prompt
accept childnr default '' -
prompt 'To what child_number is this case related?: '
prompt
spool sqlperf_&l_dbname._&sql_id._&datetime..html
/* head '-
<title>SQL report for &sql_id on &l_dbname</title> -
<style type="text/css"> -
body {font:9pt Arial,Helvetica,sans-serif; color:black; background:White;} -
p {font:9pt Arial,Helvetica,sans-serif; color:black; background:White;} -
tr,td {font:9pt Courier New, Courier; color:Black; background:#EEEEEE;} -
table {font:9pt Courier New, Courier; color:Black; background:#EEEEEE;} -
th {font:bold 9pt Arial,Helvetica,sans-serif; color:#314299; background:#befdfd;} -
h1 {font:bold 12pt Arial,Helvetica,sans-serif; color:#003399; background-color:White;} -
h2 {font:bold 10pt Arial,Helvetica,sans-serif; color:#FF9933; background-color:White;} -
a {font:9pt Arial,Helvetica,sans-serif; color:#0F0066; margin-top:0pt; margin-bottom:0pt; vertical-align:top;} -
a.link {font:9pt Arial,Helvetica,sans-serif; color:#0F0066; margin-top:0pt; margin-bottom:0pt; vertical-align:top;} -
a.noLink {font:9pt Arial,Helvetica,sans-serif; color:#0F0066; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;} -
a.noLinkBlue {font:9pt Arial,Helvetica,sans-serif; color:#0000ff; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;} -
a.noLinkDarkBlue {font:9pt Arial,Helvetica,sans-serif; color:#000099; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;} -
a.noLinkRed {font:9pt Arial,Helvetica,sans-serif; color:#ff0000; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;} -
a.noLinkDarkRed {font:9pt Arial,Helvetica,sans-serif; color:#990000; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;} -
a.noLinkGreen {font:9pt Arial,Helvetica,sans-serif; color:#00ff00; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;} -
a.noLinkDarkGreen {font:9pt Arial,Helvetica,sans-serif; color:#009900; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;} -
</style>' */
set heading off
prompt <TITLE>SQL report for &sql_id on &l_dbname</TITLE>
prompt <STYLE TYPE="text/css">
prompt body {font:9pt Arial,Helvetica,sans-serif; color:black; background:White;}
prompt p {font:9pt Arial,Helvetica,sans-serif; color:black; background:White;}
prompt tr,td {font:9pt Courier New, Courier; color:Black; background:#EEEEEE;}
prompt table {font:9pt Courier New, Courier; color:Black; background:#EEEEEE;}
prompt th {font:bold 9pt Arial,Helvetica,sans-serif; color:#314299; background:#befdfd;}
prompt h1 {font:bold 12pt Arial,Helvetica,sans-serif; color:#003399; background-color:White;}
prompt h2 {font:bold 10pt Arial,Helvetica,sans-serif; color:#FF9933; background-color:White;}
prompt h4 {font:bold 9pt Arial,Helvetica,sans-serif; color:Grey; background-color:White;}
prompt a {font:9pt Arial,Helvetica,sans-serif; color:#0F0066; margin-top:0pt; margin-bottom:0pt; vertical-align:top;}
prompt a.link {font:9pt Arial,Helvetica,sans-serif; color:#0F0066; margin-top:0pt; margin-bottom:0pt; vertical-align:top;}
prompt a.noLink {font:9pt Arial,Helvetica,sans-serif; color:#0F0066; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;}
prompt a.noLinkBlue {font:9pt Arial,Helvetica,sans-serif; color:#0000ff; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;}
prompt a.noLinkDarkBlue {font:9pt Arial,Helvetica,sans-serif; color:#000099; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;}
prompt a.noLinkRed {font:9pt Arial,Helvetica,sans-serif; color:#ff0000; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;}
prompt a.noLinkDarkRed {font:9pt Arial,Helvetica,sans-serif; color:#990000; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;}
prompt a.noLinkGreen {font:9pt Arial,Helvetica,sans-serif; color:#00ff00; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;}
prompt a.noLinkDarkGreen {font:9pt Arial,Helvetica,sans-serif; color:#009900; text-decoration: none; margin-top:0pt; margin-bottom:0pt; vertical-align:top;}
prompt </STYLE>
prompt </head>
prompt <body text="#000000" bgcolor="#FFFFFF" link="#0000FF"
prompt vlink="#000080" alink="#FF0000">
set markup html on spool on preformat off entmap on
--body 'BGCOLOR="#C5CDC5"' table 'WIDTH="90%" BORDER="1"'
set markup html on entmap off
set head off
set markup HTML ON ENTMAP OFF
prompt <h1>SQL report, based on sql_id.</h1>
prompt <p>This file was created with:
prompt sqlperf_noawr.sql
prompt version 1.6 (2014)
prompt
prompt dbname: &l_dbname
prompt SQL_ID: &sql_id
prompt date: &datetime
prompt </p>
set markup HTML OFF ENTMAP OFF
prompt <center>
prompt <font size="+2" face="Arial,Helvetica,Geneva,sans-serif" color="#314299"><b>Report Index</b></font>
prompt <hr align="center" width="250">
prompt
prompt
prompt <table width="90%" border="1">
prompt <tr><th colspan="4">Query and execution plan</th></tr>
prompt <tr>
prompt <td nowrap align="center" width="25%"><a class="link" href="#qversions">Different versions of the query</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#childs">Childs and hash values</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#sqltext">Full text of the query</a></td>
prompt <td nowrap align="center" width="25%"></td>
prompt </tr>
prompt <tr>
prompt <td nowrap align="center" width="25%"><a class="link" href="#execplan">Execution plan (memory)</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#blineallplans">Execution plans (from baselines)</a></td>
prompt <td nowrap align="center" width="25%"></td>
prompt <td nowrap align="center" width="25%"></td>
prompt </tr>
prompt <tr><th colspan="4">SQL plan baselines and SQL profiles</th>
prompt </tr>
prompt <tr>
prompt <td nowrap align="center" width="25%"><a class="link" href="#baselines">SQL and SQL plan baselines</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#blineinfo">SQL plan baseline info</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#sqlprofile">SQL profiles</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#sqlprofmeta">SQL profile metadata</a></td>
prompt </tr>
prompt <tr>
prompt <td nowrap align="center" width="25%"><a class="link" href="#profsnblines">SQL, profiles and baselines</a></td>
prompt <td nowrap align="center" width="25%"></td>
prompt <td nowrap align="center" width="25%"></td>
prompt <td nowrap align="center" width="25%"></td>
prompt </tr>
prompt <tr><th colspan="4">Run statistics</th>
prompt </tr>
prompt <tr>
prompt <td nowrap align="center" width="25%"><a class="link" href="#execsnrows">Executions, number of rows</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#respcpuwait">Response time, cpu time and wait time</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#memndisk">Memory and disk reads</a></td>
prompt <td nowrap align="center" width="25%"></td>
prompt </tr>
prompt <tr><th colspan="4">Binds</th>
prompt </tr>
prompt <tr>
prompt <td nowrap align="center" width="25%"><a class="link" href="#bindaware">Bind awareness</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#adapcursh">Adaptive cursor sharing</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#bindmism">Bind mismatches</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#bindcontent">Content of bind variabeles</a></td>
prompt </tr>
prompt <tr>
prompt <td nowrap align="center" width="25%"><a class="link" href="#bindsqlplus">Bind variables as SQL*Plus commands</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#bindsothers">Values of bind variables of other childs</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#blinedrop">Dropping associated SQL plan baselines</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#blinedrop">Purge the SQL statement from memory</a></td>
prompt </tr>
prompt <tr><th colspan="4">Object statistics</th>
prompt </tr>
prompt <tr>
prompt <td nowrap align="center" width="25%"><a class="link" href="#tablestats">Table statistics</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#tabparts">Table partitions</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#indexstats">Index statistics</a></td>
prompt <td nowrap align="center" width="25%"><a class="link" href="#indparts">Index partitions</a></td>
prompt </tr>
prompt <tr>
prompt <td nowrap align="center" width="25%"><a class="link" href="#indcolstats">Indexed column statistics</a></td>
prompt <td nowrap align="center" width="25%"></td>
prompt <td nowrap align="center" width="25%"></td>
prompt <td nowrap align="center" width="25%"></td>
prompt </tr>
prompt </table>
prompt </center>
prompt
set heading on
set markup HTML ON ENTMAP OFF
prompt
prompt
prompt
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <h2>This instance.</h2>
set markup HTML ON ENTMAP ON
col instance_name for a20
col status for a20
select instance_name, instance_number, status
from v$instance;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <h2>Selected sql_id and child_number.</h2>
set markup HTML ON ENTMAP ON
select instance_name, '&sql_id' sql_id, '&childnr' childnr
from v$instance;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="qversions"></A><h2>Different versions of the query.</h2>
prompt <p>(This should return only a handful of rows, or no binds have been used)</p>
set markup HTML ON ENTMAP ON
col sql_id for a20
col last_active_time for a16
col last_load_time for a20
col instance for a16
select a.sql_id, a.child_number
, case
when a.inst_id = &l_inst_id then 'THIS ONE'
else (select instance_name
from gv$instance
where instance_number=a.inst_id)
end instance, a.last_load_time
, to_char(a.last_active_time, 'DD-MON HH24:MI:SS') last_active_time
, a.loaded_versions, a.open_versions, a.users_opening
from gv$sql a
where sql_id='&sql_id';
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="childs"></A><h2>Childs and hash values.</h2>
set markup HTML ON ENTMAP ON
col last_active_time for a16
col last_load_time for a20
select a.sql_id, a.child_number
, (select instance_name
from gv$instance
where instance_number=a.inst_id) instance_name
, a.hash_value, a.old_hash_value, a.plan_hash_value
from gv$sql a
where a.sql_id='&sql_id';
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="sqltext"></A><h2>Full text of the query (up to 50000 characters).</h2>
set markup HTML ON ENTMAP ON
set long 50000
col sql_fulltext for a4000
select sql_fulltext
from v$sql
where sql_id='&sql_id'
and child_number=&childnr;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="baselines"></A><h2>SQL vs. SQL Plan Baselines.</h2>
set markup HTML ON ENTMAP ON
col sql_id for a20
col plan_name for a35
col created for a30
col FORCE_MATCHING_SIGNATURE for 9999999999999999999
select sql.sql_id, sql.child_number, sql.inst_id, sql.force_matching_signature, sql.plan_hash_value, bl.plan_name, bl.enabled, bl.accepted, bl.fixed, bl.optimizer_cost
from gv$sql sql
, dba_sql_plan_baselines bl
where sql.sql_id='&sql_id'
and sql.child_number=&childnr
and sql.force_matching_signature=bl.SIGNATURE;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="blineinfo"></A><h2>SQL Plan Baseline information.</h2>
set markup HTML ON ENTMAP ON
col SQL_HANDLE for a30
col origin for a16
col last_modified for a30
col last_verified for a30
select sql_handle, plan_name, origin, created, last_modified, last_verified
from dba_sql_plan_baselines
where signature in (select force_matching_signature
from v$sql
where sql_id='&sql_id'
and child_number=&childnr);
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="sqlprofile"></A><h2>SQL Profile information.</h2>
set markup HTML ON ENTMAP ON
col name for a30
col task_exec_name for a16
col category for a10
select sql.sql_id, prof.name, prof.category, prof.created, prof.task_exec_name, prof.status
from DBA_SQL_PROFILES prof
, gv$sql sql
where sql.sql_id='&sql_id'
and sql.child_number=&childnr
and sql.force_matching_signature=prof.SIGNATURE;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="sqlprofmeta"></A><h2>SQL Profile metadata.</h2>
set markup HTML ON ENTMAP ON
set heading off
col outline_hints for a132
select extractvalue(value(d), '/hint') as outline_hints
from xmltable('/*/outline_data/hint' passing
(select xmltype(other_xml) as xmlval
from v$sql_plan
where sql_id='&sql_id'
and child_number=&childnr
and other_xml is not null
)
) d;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="profsnblines"></A><h2>SQL, profiles and baselines.</h2>
set markup HTML ON ENTMAP ON
set heading on
col sql_profile for a30
col sql_patch for a30
col sql_plan_baseline for a35
select sql_id, child_number, inst_id, sql_profile, sql_plan_baseline, sql_patch
from gv$sql
where sql_id='&sql_id'
and child_number=&childnr
order by sql_id, inst_id, child_number;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="execsnrows"></A><h2>Executions, number of rows.</h2>
set markup HTML ON ENTMAP ON
select executions, parse_calls, loads, rows_processed, sorts
from v$sql
where sql_id='&sql_id'
and child_number=&childnr;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="respcpuwait"></A><h2>Response time, cpu time and wait time (in seconds).</h2>
set markup HTML ON ENTMAP ON
select trunc(elapsed_time/1000000,1) elapsed_time, trunc(application_wait_time/1000000,1) applic_wait_time, trunc(cpu_time/1000000,1) cpu_time
, trunc(user_io_wait_time/1000000,1) user_io_wait_time, trunc(concurrency_wait_time/1000000,1) concurr_time
from v$sql
where sql_id='&sql_id'
and child_number=&childnr;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="memndisk"></A><h2>Memory and disk reads.</h2>
set markup HTML ON ENTMAP ON
select buffer_gets, disk_reads, (sharable_mem+persistent_mem+runtime_mem) sql_area_used
from v$sql
where sql_id='&sql_id'
and child_number=&childnr;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <h2>Who ran the query?</h2>
set markup HTML ON ENTMAP ON
col username for a30
col PARSING_SCHEMA_NAME for a30
col module for a40
col action for a30
col service for a30
select u.username, s.PARSING_SCHEMA_NAME, s.SERVICE, s.MODULE, s.ACTION
from v$sql s
, dba_users u
where s.sql_id='&sql_id'
and s.child_number=&childnr
and u.user_id=s.PARSING_USER_ID;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="bindaware"></A><h2>Bind aware, sharable?</h2>
set markup HTML ON ENTMAP ON
col IS_OBSOLETE for a11
col IS_BIND_SENSITIVE for a17
col IS_BIND_AWARE for a13
col IS_SHAREABLE for a12
select IS_OBSOLETE, IS_BIND_SENSITIVE, IS_BIND_AWARE, IS_SHAREABLE
from v$sql
where sql_id='&sql_id'
and child_number=&childnr;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="adapcursh"></A><h2>Adaptive cursor sharing.</h2>
set markup HTML ON ENTMAP ON
col PREDICATE for a30
select inst_id, sql_id, child_number, predicate,range_id, low, high
from GV$SQL_CS_SELECTIVITY
where sql_id = '&sql_id'
order by inst_id, child_number;
prompt
prompt
select * from GV$SQL_CS_HISTOGRAM
where sql_id = '&sql_id'
order by inst_id, child_number;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="bindmism"></A><h2>Bind mismatches.</h2>
set markup HTML ON ENTMAP ON
select *
from
xmltable( 'for $a at $i in /ROWSET/ROW
,$r in $a/*
return element ROW{
element ROW_NUM{$i}
,element COL_NAME{$r/name()}
,element COL_VALUE{$r/text()}
}'
passing xmltype(cursor( select *
from v$sql_shared_cursor
where sql_id='&sql_id'
and child_number=&childnr
))
columns
row_num int
,col_name varchar2(30)
,col_value varchar2(100)
);
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="bindcontent"></A><h2>Content of bind variabeles (use as example).</h2>
set markup HTML ON ENTMAP ON
col name for a10
col value_string for a50
col datatype_string for a50
select child_number, name, position
, case datatype
when 180 then to_char(anydata.accesstimestamp(value_anydata),'DD-MON-YYYY HH24:MI:SS')
when 12 then to_char(anydata.accessdate(value_anydata),'DD-MON-YYYY HH24:MI:SS')
else value_string
end value_string
, datatype_string
from v$sql_bind_capture
where sql_id='&sql_id'
and child_number=&childnr
order by position;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="bindsqlplus"></A><h2>Bind variables as SQL*Plus commands.</h2>
set markup HTML ON ENTMAP ON
set heading off
select 'variable '||replace(name, ':', 'BIND_')||' '||decode(datatype_string, 'TIMESTAMP', 'VARCHAR2(128)', datatype_string) datatype_string
from v$sql_bind_capture
where sql_id='&sql_id'
and child_number=&childnr
order by position;
prompt
select 'exec '||replace(name, ':', ':BIND_')||' := '||
case datatype
when 180 then to_char(anydata.accesstimestamp(value_anydata),'DD-MON-YYYY HH24:MI:SS')
when 12 then to_char(anydata.accessdate(value_anydata),'DD-MON-YYYY HH24:MI:SS')
else value_string
end value_string
from v$sql_bind_capture
where sql_id='&sql_id'
and child_number=&childnr
and datatype_string NOT LIKE '%CHAR%'
and datatype_string NOT IN ('DATE', 'CLOB', 'TIMESTAMP')
order by position;
select 'exec '||replace(name, ':', ':BIND_')||' := '''||value_string||''''
from (
select name
, case datatype
when 180 then to_char(anydata.accesstimestamp(value_anydata),'DD-MON-YYYY HH24:MI:SS')
when 12 then to_char(anydata.accessdate(value_anydata),'DD-MON-YYYY HH24:MI:SS')
else value_string
end value_string
, position
from v$sql_bind_capture
where sql_id='&sql_id'
and child_number=&childnr
and (datatype_string LIKE '%CHAR%'
OR datatype_string IN ('DATE', 'CLOB', 'TIMESTAMP'))
)
order by position;
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="bindsothers"></A><h2>Values of bind variables of other childs.</h2>
set markup HTML ON ENTMAP ON
set heading on
col name for a10
col value_string for a50
col datatype_string for a50
select child_number, name, position
, case datatype
when 180 then to_char(anydata.accesstimestamp(value_anydata),'DD-MON-YYYY HH24:MI:SS')
when 12 then to_char(anydata.accessdate(value_anydata),'DD-MON-YYYY HH24:MI:SS')
else value_string
end value_string
, datatype_string
from v$sql_bind_capture
where sql_id='&sql_id'
and child_number <> &childnr
order by child_number, position;
set heading off
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="execplan"></A><h2>Execution plan of the query.</h2>
set markup HTML OFF ENTMAP OFF
prompt <pre xml:space="preserve" class="oac_no_warn">
SELECT plan_table_output
FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR('&sql_id', &childnr, 'ALL'));
prompt </pre>
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt
prompt <A NAME="blineallplans"></A><h2>All execution plans in sql plan baselines.</h2>
prompt <p>Run as SYS to see this.</p>
set markup HTML ON ENTMAP ON
column v_sql_handle new_value l_sql_handle noprint
set markup HTML OFF ENTMAP OFF
prompt <pre xml:space="preserve" class="oac_no_warn">
select distinct plan.SQL_HANDLE v_sql_handle
from dba_sql_plan_baselines plan
, gv$sql sql
where sql.sql_id='&sql_id'
and sql.child_number=&childnr
and sql.force_matching_signature=plan.SIGNATURE;
prompt </pre>
prompt <pre xml:space="preserve" class="oac_no_warn">
SELECT * FROM TABLE(dbms_xplan.display_sql_plan_baseline(sql_handle=>'&l_sql_handle'));
prompt </pre>
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="blinedrop"></A><h2>Dropping associated SQL plan baselines.</h2>
prompt <p>(Based on SQL_HANDLE gives an error, but works.</p>
select distinct 'select sys.dbms_spm.DROP_SQL_PLAN_BASELINE('''||sql_handle||''') from dual;' "Based on SQL_HANDLE"
from dba_sql_plan_baselines
where signature in (select force_matching_signature
from v$sql
where sql_id='&sql_id'
and child_number=&childnr);
prompt
select 'declare v_pls PLS_INTEGER; BEGIN v_pls :=dbms_spm.drop_sql_plan_baseline(sql_handle=>'''||sql_handle||''', plan_name=>'''||plan_name||'''); END;'
from dba_sql_plan_baselines
where signature in (select force_matching_signature
from v$sql
where sql_id='&sql_id'
and child_number=&childnr);
prompt
prompt
prompt
prompt <A NAME="planpurge"></A><h2>Generated statement to purge your SQL statement from the shared pool.</h2>
select 'exec sys.dbms_shared_pool.purge('''||address||', '||hash_value||''', ''c'')'
from v$sql
where sql_id = '&sql_id'
and child_number=&childnr;
prompt
prompt
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="tablestats"></A><h2>Tables accessed in the execution plan.</h2>
set markup HTML ON ENTMAP ON
set heading on
SELECT owner, table_name, last_analyzed, sample_size, num_rows, avg_row_len, blocks, partitioned, global_stats
FROM dba_tables
WHERE table_name IN (
select distinct rtrim(substr(plan_table_output, instr(plan_table_output, '|', 1, 3)+2, (instr(plan_table_output, '|', 1, 4)-instr(plan_table_output, '|', 1, 3)-2)), ' ')
from (
SELECT plan_table_output
FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR('&sql_id', &childnr, 'BASIC'))
)
where plan_table_output like '%TABLE ACCESS%'
)
ORDER BY owner, table_name
/
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="tabparts"></A><h2>Partitions of tables accessed in the execution plan.</h2>
set markup HTML ON ENTMAP ON
SELECT table_owner, table_name, partition_name, subpartition_count, last_analyzed, sample_size, num_rows, avg_row_len
FROM dba_tab_partitions
WHERE table_name IN (
select distinct rtrim(substr(plan_table_output, instr(plan_table_output, '|', 1, 3)+2, (instr(plan_table_output, '|', 1, 4)-instr(plan_table_output, '|', 1, 3)-2)), ' ')
from (
SELECT plan_table_output
FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR('&sql_id', &childnr, 'BASIC'))
)
where plan_table_output like '%TABLE ACCESS%'
)
ORDER BY table_owner, table_name, partition_name
/
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="indexstats"></A><h2>Indexes accessed in the execution plan.</h2>
set markup HTML ON ENTMAP ON
SELECT owner, index_name, table_name, last_analyzed, sample_size, num_rows, partitioned, global_stats
FROM dba_indexes
WHERE index_name IN (
select distinct rtrim(substr(plan_table_output, instr(plan_table_output, '|', 1, 3)+2, (instr(plan_table_output, '|', 1, 4)-instr(plan_table_output, '|', 1, 3)-2)), ' ')
from (
SELECT plan_table_output
FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR('&sql_id', &childnr, 'BASIC'))
)
where plan_table_output like '%INDEX%'
)
ORDER BY owner, table_name, index_name
/
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="indparts"></A><h2>Partitions of indexes accessed in the execution plan.</h2>
set markup HTML ON ENTMAP ON
SELECT index_owner, index_name, partition_name, subpartition_count, last_analyzed, sample_size, num_rows
FROM dba_ind_partitions
WHERE index_name IN (
select distinct rtrim(substr(plan_table_output, instr(plan_table_output, '|', 1, 3)+2, (instr(plan_table_output, '|', 1, 4)-instr(plan_table_output, '|', 1, 3)-2)), ' ')
from (
SELECT plan_table_output
FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR('&sql_id', &childnr, 'BASIC'))
)
where plan_table_output like '%INDEX%'
)
ORDER BY index_owner, index_name, partition_name
/
prompt
prompt
prompt
set markup HTML ON ENTMAP OFF
prompt <A NAME="indcolstats"></A><h2>Statistics indexed columns for indexes used in the execution plan.</h2>
set markup HTML ON ENTMAP ON
SELECT ic.index_owner, ic.index_name, ic.table_name, ic.column_name, ic.column_position col_pos, tc.last_analyzed, tc. sample_size, tc.num_distinct, tc.num_nulls, tc.density, tc.histogram, tc.num_buckets
FROM dba_ind_columns ic
, dba_tab_columns tc
WHERE ic.index_name IN (
select distinct rtrim(substr(plan_table_output, instr(plan_table_output, '|', 1, 3)+2, (instr(plan_table_output, '|', 1, 4)-instr(plan_table_output, '|', 1, 3)-2)), ' ')
from (
SELECT plan_table_output
FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR('&sql_id', &childnr, 'BASIC'))
)
where plan_table_output like '%INDEX%'
)
AND ic.table_owner=tc.owner
AND ic.table_name=tc.table_name
AND ic.column_name=tc.column_name
ORDER BY ic.table_owner, ic.table_name, ic.index_name, ic.column_position
/
spool off
@/tmp/your_sqlplus_env_&datetime..sql