-
Notifications
You must be signed in to change notification settings - Fork 9
/
Copy pathplanx.sql
2083 lines (2036 loc) · 83.3 KB
/
planx.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
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
----------------------------------------------------------------------------------------
--
-- File name: planx.sql
--
-- Purpose: Reports Execution Plans for one SQL_ID from RAC and AWR(opt)
--
-- Author: Carlos Sierra
--
-- Version: 2018/01/29
--
-- Usage: This script inputs two parameters. Parameter 1 is a flag to specify if
-- your database is licensed to use the Oracle Diagnostics Pack or not.
-- Parameter 2 specifies the SQL_ID for which you want to report all
-- execution plans from all nodes, plus all plans from AWR.
-- If you don't have the Oracle Diagnostics Pack license, or if you want
-- to omit the AWR portion then specify "N" on Parameter 1.
--
-- Example: @planx.sql Y f995z9antmhxn
--
-- Notes: Developed and tested on 11.2.0.3 and 12.0.1.0
--
-- For a more robust tool use SQLd360
--
---------------------------------------------------------------------------------------
--
CL COL;
SET FEED OFF VER OFF HEA ON LIN 2200 PAGES 50 TIMI OFF LONG 80000 LONGC 2000 TRIMS ON AUTOT OFF;
SET SERVEROUT OFF;
PRO
PRO 1. Enter Oracle Diagnostics Pack License Flag [ Y | N ] (required)
DEF input_license = '&1.';
PRO
PRO 2. Enter SQL_ID (required)
DEF sql_id = '&2.';
-- set license
VAR license CHAR(1);
BEGIN
SELECT UPPER(SUBSTR(TRIM('&input_license.'), 1, 1)) INTO :license FROM DUAL;
END;
/
-- get dbid
VAR dbid NUMBER;
BEGIN
SELECT dbid INTO :dbid FROM v$database;
END;
/
-- display adaptive plan
COL format_adaptive NEW_V format_adaptive
SELECT '+ADAPTIVE' format_adaptive FROM v$instance WHERE version >= '12.';
-- is_10g
DEF is_10g = '';
COL is_10g NEW_V is_10g NOPRI;
SELECT '--' is_10g FROM v$instance WHERE version LIKE '10%';
-- is_11g
DEF is_11g = '';
COL is_11g NEW_V is_11g NOPRI;
SELECT '--' is_11 FROM v$instance WHERE version LIKE '11%';
-- is_11r1
DEF is_11r1 = '';
COL is_11r1 NEW_V is_11r1 NOPRI;
SELECT '--' is_11r1 FROM v$instance WHERE version LIKE '11.1%';
-- get current time
COL current_time NEW_V current_time FOR A15;
SELECT 'current_time: ' x, TO_CHAR(SYSDATE, 'YYYYMMDD_HH24MISS') current_time FROM DUAL;
-- set min and max snap id
COL x_minimum_snap_id NEW_V x_minimum_snap_id NOPRI;
SELECT NVL(TO_CHAR(MAX(snap_id)), '0') x_minimum_snap_id FROM dba_hist_snapshot WHERE :license = 'Y' AND begin_interval_time < SYSDATE - 31;
SELECT '-1' x_minimum_snap_id FROM DUAL WHERE TRIM('&&x_minimum_snap_id.') IS NULL;
COL x_maximum_snap_id NEW_V x_maximum_snap_id NOPRI;
SELECT NVL(TO_CHAR(MAX(snap_id)), '&&x_minimum_snap_id.') x_maximum_snap_id FROM dba_hist_snapshot WHERE :license = 'Y';
SELECT '-1' x_maximum_snap_id FROM DUAL WHERE TRIM('&&x_maximum_snap_id.') IS NULL;
COL x_minimum_date NEW_V x_minimum_date NOPRI;
SELECT TO_CHAR(MIN(begin_interval_time), 'YYYY-MM-DD"T"HH24:MI:SS') x_minimum_date FROM dba_hist_snapshot WHERE :license = 'Y' AND snap_id = &&x_minimum_snap_id.;
COL x_maximum_date NEW_V x_maximum_date NOPRI;
SELECT TO_CHAR(MAX(end_interval_time), 'YYYY-MM-DD"T"HH24:MI:SS') x_maximum_date FROM dba_hist_snapshot WHERE :license = 'Y' AND snap_id = &&x_maximum_snap_id.;
-- get sql_text
VAR sql_id VARCHAR2(13);
EXEC :sql_id := '&&sql_id.';
VAR sql_text CLOB;
EXEC :sql_text := NULL;
VAR signature NUMBER;
VAR signaturef NUMBER;
BEGIN
SELECT exact_matching_signature, sql_text INTO :signature, :sql_text FROM gv$sql WHERE sql_id = '&&sql_id.' AND ROWNUM = 1;
END;
/
BEGIN
IF :sql_text IS NULL OR NVL(DBMS_LOB.GETLENGTH(:sql_text), 0) = 0 THEN
SELECT sql_fulltext
INTO :sql_text
FROM gv$sqlstats
WHERE sql_id = :sql_id
AND ROWNUM = 1;
END IF;
END;
/
BEGIN
IF :license = 'Y' AND (:sql_text IS NULL OR NVL(DBMS_LOB.GETLENGTH(:sql_text), 0) = 0) THEN
SELECT sql_text
INTO :sql_text
FROM dba_hist_sqltext
WHERE sql_id = :sql_id
AND ROWNUM = 1;
END IF;
END;
/
BEGIN
IF :signature IS NULL THEN
:signature := NVL(DBMS_SQLTUNE.SQLTEXT_TO_SIGNATURE(:sql_text), -1);
END IF;
END;
/
EXEC :signaturef := NVL(DBMS_SQLTUNE.SQLTEXT_TO_SIGNATURE(:sql_text, TRUE), -1);
COL signature NEW_V signature FOR A20;
COL signaturef NEW_V signaturef FOR A20;
SELECT TO_CHAR(:signature) signature, TO_CHAR(:signaturef) signaturef FROM DUAL;
BEGIN
IF :sql_text IS NULL THEN
:sql_text := 'Unknown SQL Text';
END IF;
END;
/
COL x_host_name NEW_V x_host_name;
SELECT host_name x_host_name FROM v$instance;
COL x_db_name NEW_V x_db_name;
SELECT name x_db_name FROM v$database;
COL x_container NEW_V x_container;
SELECT 'NONE' x_container FROM DUAL;
select case when sys_context('userenv', 'con_name') like '%ROOT' then 'CDBROOT' else sys_context('userenv', 'con_name') end x_container from dual;
DEF sql_handle = '';
COL sql_handle NEW_V sql_handle;
SELECT sql_handle FROM dba_sql_plan_baselines WHERE signature = &&signature. AND ROWNUM = 1;
COLUMN instname NEW_VALUE x_instname NOPRINT
select instance_name instname from v$instance;
-- spool and sql_text
SPO planx_&&x_db_name.-&&x_instname.-&&x_container-&&sql_id._&¤t_time..txt;
PRO SQL_ID: &&sql_id.
PRO SIGNATURE: &&signature.
PRO SIGNATUREF: &&signaturef.
PRO SQL_HANDLE: &&sql_handle.
PRO HOST: &&x_host_name.
PRO DATABASE: &&x_db_name.
PRO INSTANCE NAME: &&x_instname.
PRO PDB NAME: &&x_container.
PRO
SET PAGES 0;
PRINT :sql_text;
SET PAGES 50;
-- columns funky format
COL action_ff FOR A30 HEA "Action";
COL appl_wait_secs_ff FOR A18 HEA "Appl wait secs";
COL begin_interval_time_ff FOR A20 HEA "Begin interval time";
COL buffer_gets_ff FOR A20 HEA "Buffer Gets";
COL cluster_wait_secs_ff FOR A18 HEA "Cluster wait secs";
COL conc_wait_secs_ff FOR A18 HEA "Conc wait secs";
COL cpu_secs_ff FOR A18 HEA "CPU secs";
COL current_object_ff FOR A60 HEA "Current object";
COL direct_writes_ff FOR A20 HEA "Direct Writes";
COL disk_reads_ff FOR A20 HEA "Disk Reads";
COL elsapsed_secs_ff FOR A18 HEA "Elapsed secs";
COL end_interval_time_ff FOR A20 HEA "End interval time";
COL executions_ff FOR A20 HEA "Executions";
COL fetches_ff FOR A20 HEA "Fetches";
COL first_load_time_ff FOR A20 HEA "First load time";
COL inst_child_ff FOR A21 HEA "Inst child";
COL invalidations_ff FOR A8 HEA "Invalidations";
COL io_cell_offload_eligible_b_ff FOR A30 HEA "IO cell offload eligible bytes";
COL io_cell_offload_returned_b_ff FOR A30 HEA "IO cell offload returned bytes";
COL io_cell_uncompressed_bytes_ff FOR A30 HEA "IO cell uncompressed bytes";
COL io_interconnect_bytes_ff FOR A30 HEA "IO interconnect bytes";
COL io_saved_ff FOR A10 HEA "IO saved";
COL java_exec_secs_ff FOR A18 HEA "Java exec secs";
COL last_active_time_ff FOR A20 HEA "Last active time";
COL last_load_time_ff FOR A20 HEA "Last load time";
COL line_id_ff FOR 9999999 HEA "Line id";
COL loaded_ff FOR A6 HEA "Loaded";
COL loaded_versions_ff FOR A15 HEA "Loaded versions";
COL loads_ff FOR A8 HEA "Loads";
COL module_ff FOR A30 HEA "Module";
COL open_versions_ff FOR A15 HEA "Open versions";
COL operation_ff FOR A50 HEA "Operation";
COL parse_calls_ff FOR A20 HEA "Parse calls";
COL percent_ff FOR 9,990.0 HEA "Percent";
COL persistent_mem_ff FOR A20 HEA "Persistent mem";
COL plan_timestamp_ff FOR A19 HEA "Plan timestamp";
COL plsql_exec_secs_ff FOR A18 HEA "PLSQL exec secs";
COL px_servers_executions_ff FOR A20 HEA "PX servers executions";
COL rows_processed_ff FOR A20 HEA "Rows processed";
COL runtime_mem_ff FOR A20 HEA "Runtime mem";
COL samples_ff FOR 999,999,999,999 HEA "Samples";
COL service_ff FOR A30 HEA "Service";
COL sharable_mem_ff FOR A20 HEA "Sharable mem";
COL sorts_ff FOR A20 HEA "Sorts";
COL sql_profile_ff FOR A30 HEA "SQL Profile";
COL timed_event_ff FOR A70 HEA "Timed event";
COL total_sharable_mem_ff FOR A20 HEA "Total sharable mem";
COL user_io_wait_secs_ff FOR A18 HEA "User IO wait secs";
COL users_executing_ff FOR A15 HEA "Users executing";
COL users_opening_ff FOR A15 HEA "Users opening";
COL version_count_ff FOR A8 HEA "Version count";
COL obsl FOR A4;
COL sens FOR A4;
COL aware FOR A5;
COL shar FOR A4;
COL u_exec FOR 999999;
COL obj_sta FOR A7;
COL plan_name FOR A30;
COL created FOR A30;
COL last_executed FOR A30;
COL avg_et_ms_awr FOR A11 HEA 'ET Avg|AWR (ms)';
COL avg_et_ms_mem FOR A11 HEA 'ET Avg|MEM (ms)';
COL avg_cpu_ms_awr FOR A11 HEA 'CPU Avg|AWR (ms)';
COL avg_cpu_ms_mem FOR A11 HEA 'CPU Avg|MEM (ms)';
COL avg_bg_awr FOR 999,999,990 HEA 'BG Avg|AWR';
COL avg_bg_mem FOR 999,999,990 HEA 'BG Avg|MEM';
COL avg_row_awr FOR 999,999,990 HEA 'Rows Avg|AWR';
COL avg_row_mem FOR 999,999,990 HEA 'Rows Avg|MEM';
COL plan_hash_value FOR 9999999999 HEA 'Plan|Hash Value';
COL executions_awr FOR 999,999,999,999 HEA 'Executions|AWR';
COL executions_mem FOR 999,999,999,999 HEA 'Executions|MEM';
COL min_cost FOR 9,999,999 HEA 'MIN Cost';
COL max_cost FOR 9,999,999 HEA 'MAX Cost';
COL nl FOR 99;
COL hj FOR 99;
COL mj FOR 99;
COL p100_et_ms FOR A11 HEA 'ET 100th|Pctl (ms)';
COL p99_et_ms FOR A11 HEA 'ET 99th|Pctl (ms)';
COL p97_et_ms FOR A11 HEA 'ET 97th|Pctl (ms)';
COL p95_et_ms FOR A11 HEA 'ET 95th|Pctl (ms)';
COL p100_cpu_ms FOR A11 HEA 'CPU 100th|Pctl (ms)';
COL p99_cpu_ms FOR A11 HEA 'CPU 99th|Pctl (ms)';
COL p97_cpu_ms FOR A11 HEA 'CPU 97th|Pctl (ms)';
COL p95_cpu_ms FOR A11 HEA 'CPU 95th|Pctl (ms)';
PRO
PRO PLANS PERFORMANCE
PRO ~~~~~~~~~~~~~~~~~
WITH
pm AS (
SELECT plan_hash_value, operation,
CASE operation WHEN 'NESTED LOOPS' THEN COUNT(DISTINCT id) ELSE 0 END nl,
CASE operation WHEN 'HASH JOIN' THEN COUNT(DISTINCT id) ELSE 0 END hj,
CASE operation WHEN 'MERGE JOIN' THEN COUNT(DISTINCT id) ELSE 0 END mj
FROM gv$sql_plan
WHERE sql_id = TRIM('&&sql_id.')
GROUP BY
plan_hash_value,
operation ),
pa AS (
SELECT plan_hash_value, operation,
CASE operation WHEN 'NESTED LOOPS' THEN COUNT(DISTINCT id) ELSE 0 END nl,
CASE operation WHEN 'HASH JOIN' THEN COUNT(DISTINCT id) ELSE 0 END hj,
CASE operation WHEN 'MERGE JOIN' THEN COUNT(DISTINCT id) ELSE 0 END mj
FROM dba_hist_sql_plan
WHERE sql_id = TRIM('&&sql_id.')
AND :license = 'Y'
GROUP BY
plan_hash_value,
operation ),
pm_pa AS (
SELECT plan_hash_value, MAX(nl) nl, MAX(hj) hj, MAX(mj) mj
FROM pm
GROUP BY
plan_hash_value
UNION
SELECT plan_hash_value, MAX(nl) nl, MAX(hj) hj, MAX(mj) mj
FROM pa
GROUP BY
plan_hash_value ),
p AS (
SELECT plan_hash_value, MAX(nl) nl, MAX(hj) hj, MAX(mj) mj
FROM pm_pa
GROUP BY
plan_hash_value ),
phv_perf AS (
SELECT plan_hash_value,
snap_id,
SUM(elapsed_time_delta)/SUM(executions_delta) avg_et_us,
SUM(cpu_time_delta)/SUM(executions_delta) avg_cpu_us
FROM dba_hist_sqlstat
WHERE sql_id = TRIM('&&sql_id.')
AND executions_delta > 0
AND optimizer_cost > 0
AND :license = 'Y'
GROUP BY
plan_hash_value,
snap_id ),
phv_stats AS (
SELECT plan_hash_value,
MAX(avg_et_us) p100_et_us,
PERCENTILE_DISC(0.99) WITHIN GROUP (ORDER BY avg_et_us) p99_et_us,
PERCENTILE_DISC(0.97) WITHIN GROUP (ORDER BY avg_et_us) p97_et_us,
PERCENTILE_DISC(0.95) WITHIN GROUP (ORDER BY avg_et_us) p95_et_us,
MAX(avg_cpu_us) p100_cpu_us,
PERCENTILE_DISC(0.99) WITHIN GROUP (ORDER BY avg_cpu_us) p99_cpu_us,
PERCENTILE_DISC(0.97) WITHIN GROUP (ORDER BY avg_cpu_us) p97_cpu_us,
PERCENTILE_DISC(0.95) WITHIN GROUP (ORDER BY avg_cpu_us) p95_cpu_us
FROM phv_perf
GROUP BY
plan_hash_value ),
m AS (
SELECT plan_hash_value,
SUM(elapsed_time)/SUM(executions) avg_et_us,
SUM(cpu_time)/SUM(executions) avg_cpu_us,
ROUND(SUM(buffer_gets)/SUM(executions)) avg_buffer_gets,
ROUND(SUM(rows_processed)/SUM(executions)) avg_rows_processed,
SUM(executions) executions,
MIN(optimizer_cost) min_cost,
MAX(optimizer_cost) max_cost
FROM gv$sql
WHERE sql_id = TRIM('&&sql_id.')
AND executions > 0
AND optimizer_cost > 0
GROUP BY
plan_hash_value ),
a AS (
SELECT plan_hash_value,
SUM(elapsed_time_delta)/SUM(executions_delta) avg_et_us,
SUM(cpu_time_delta)/SUM(executions_delta) avg_cpu_us,
ROUND(SUM(buffer_gets_delta)/SUM(executions_delta)) avg_buffer_gets,
ROUND(SUM(rows_processed_delta)/SUM(executions_delta)) avg_rows_processed,
SUM(executions_delta) executions,
MIN(optimizer_cost) min_cost,
MAX(optimizer_cost) max_cost
FROM dba_hist_sqlstat
WHERE sql_id = TRIM('&&sql_id.')
AND executions_delta > 0
AND optimizer_cost > 0
AND :license = 'Y'
GROUP BY
plan_hash_value )
SELECT
p.plan_hash_value,
LPAD(TRIM(TO_CHAR(ROUND(a.avg_et_us/1e3, 6), '9999,990.000')), 11) avg_et_ms_awr,
LPAD(TRIM(TO_CHAR(ROUND(m.avg_et_us/1e3, 6), '9999,990.000')), 11) avg_et_ms_mem,
LPAD(TRIM(TO_CHAR(ROUND(a.avg_cpu_us/1e3, 6), '9999,990.000')), 11) avg_cpu_ms_awr,
LPAD(TRIM(TO_CHAR(ROUND(m.avg_cpu_us/1e3, 6), '9999,990.000')), 11) avg_cpu_ms_mem,
a.avg_buffer_gets avg_bg_awr,
m.avg_buffer_gets avg_bg_mem,
a.avg_rows_processed avg_row_awr,
m.avg_rows_processed avg_row_mem,
a.executions executions_awr,
m.executions executions_mem,
LEAST(NVL(m.min_cost, a.min_cost), NVL(a.min_cost, m.min_cost)) min_cost,
GREATEST(NVL(m.max_cost, a.max_cost), NVL(a.max_cost, m.max_cost)) max_cost,
p.nl,
p.hj,
p.mj,
LPAD(TRIM(TO_CHAR(ROUND(s.p100_et_us/1e3, 6), '9999,990.000')), 11) p100_et_ms,
LPAD(TRIM(TO_CHAR(ROUND(s.p99_et_us/1e3, 6), '9999,990.000')), 11) p99_et_ms,
LPAD(TRIM(TO_CHAR(ROUND(s.p97_et_us/1e3, 6), '9999,990.000')), 11) p97_et_ms,
LPAD(TRIM(TO_CHAR(ROUND(s.p95_et_us/1e3, 6), '9999,990.000')), 11) p95_et_ms,
LPAD(TRIM(TO_CHAR(ROUND(s.p100_cpu_us/1e3, 6), '9999,990.000')), 11) p100_cpu_ms,
LPAD(TRIM(TO_CHAR(ROUND(s.p99_cpu_us/1e3, 6), '9999,990.000')), 11) p99_cpu_ms,
LPAD(TRIM(TO_CHAR(ROUND(s.p97_cpu_us/1e3, 6), '9999,990.000')), 11) p97_cpu_ms,
LPAD(TRIM(TO_CHAR(ROUND(s.p95_cpu_us/1e3, 6), '9999,990.000')), 11) p95_cpu_ms
FROM p, m, a, phv_stats s
WHERE p.plan_hash_value = m.plan_hash_value(+)
AND p.plan_hash_value = a.plan_hash_value(+)
AND p.plan_hash_value = s.plan_hash_value(+)
ORDER BY
NVL(a.avg_et_us, m.avg_et_us), m.avg_et_us;
PRO
PRO GV$SQLSTATS (it shows only one row for SQL, with most recent info)
PRO ~~~~~~~~~~~
SPO planx_&&x_db_name.-&&x_instname.-&&x_container-&&sql_id._&¤t_time..txt APP;
SELECT inst_id
, plan_hash_value
, LPAD(TO_CHAR(parse_calls, '999,999,999,999,990'), 20) parse_calls_ff
, LPAD(TO_CHAR(executions, '999,999,999,999,990'), 20) executions_ff
, LPAD(TO_CHAR(px_servers_executions, '999,999,999,999,990'), 20) px_servers_executions_ff
, LPAD(TO_CHAR(fetches, '999,999,999,999,990'), 20) fetches_ff
, LPAD(TO_CHAR(rows_processed, '999,999,999,999,990'), 20) rows_processed_ff
, LPAD(TO_CHAR(version_count, '999,990'), 8) version_count_ff
, LPAD(TO_CHAR(loads, '999,990'), 8) loads_ff
, LPAD(TO_CHAR(invalidations, '999,990'), 8) invalidations_ff
, LPAD(TO_CHAR(buffer_gets, '999,999,999,999,990'), 20) buffer_gets_ff
, LPAD(TO_CHAR(disk_reads, '999,999,999,999,990'), 20) disk_reads_ff
, LPAD(TO_CHAR(direct_writes, '999,999,999,999,990'), 20) direct_writes_ff
, LPAD(TO_CHAR(ROUND(elapsed_time/1e6, 3), '999,999,990.000'), 18) elsapsed_secs_ff
, LPAD(TO_CHAR(ROUND(cpu_time/1e6, 3), '999,999,990.000'), 18) cpu_secs_ff
, LPAD(TO_CHAR(ROUND(user_io_wait_time/1e6, 3), '999,999,990.000'), 18) user_io_wait_secs_ff
, LPAD(TO_CHAR(ROUND(cluster_wait_time/1e6, 3), '999,999,990.000'), 18) cluster_wait_secs_ff
, LPAD(TO_CHAR(ROUND(application_wait_time/1e6, 3), '999,999,990.000'), 18) appl_wait_secs_ff
, LPAD(TO_CHAR(ROUND(concurrency_wait_time/1e6, 3), '999,999,990.000'), 18) conc_wait_secs_ff
, LPAD(TO_CHAR(ROUND(plsql_exec_time/1e6, 3), '999,999,990.000'), 18) plsql_exec_secs_ff
, LPAD(TO_CHAR(ROUND(java_exec_time/1e6, 3), '999,999,990.000'), 18) java_exec_secs_ff
, LPAD(TO_CHAR(sorts, '999,999,999,999,990'), 20) sorts_ff
, LPAD(TO_CHAR(sharable_mem, '999,999,999,999,990'), 20) sharable_mem_ff
, LPAD(TO_CHAR(total_sharable_mem, '999,999,999,999,990'), 20) total_sharable_mem_ff
, LPAD(TO_CHAR(last_active_time, 'YYYY-MM-DD"T"HH24:MI:SS'), 20) last_active_time_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(io_cell_offload_eligible_bytes, '999,999,999,999,999,999,990'), 30) io_cell_offload_eligible_b_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(io_interconnect_bytes, '999,999,999,999,999,999,990'), 30) io_interconnect_bytes_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(io_cell_uncompressed_bytes, '999,999,999,999,999,999,990'), 30) io_cell_uncompressed_bytes_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(io_cell_offload_returned_bytes, '999,999,999,999,999,999,990'), 30) io_cell_offload_returned_b_ff
&&is_10g.&&is_11r1., LPAD(CASE WHEN io_cell_offload_eligible_bytes > io_cell_offload_returned_bytes AND io_cell_offload_eligible_bytes > 0 THEN LPAD(TO_CHAR(ROUND((io_cell_offload_eligible_bytes - io_cell_offload_returned_bytes) * 100 / io_cell_offload_eligible_bytes, 2), '990.00')||' %', 9) END, 10) io_saved_ff
FROM gv$sqlstats
WHERE sql_id = :sql_id
ORDER BY inst_id
/
BREAK ON inst_id SKIP PAGE ON obj_sta SKIP PAGE ON obsl SKIP PAGE ON shar SKIP PAGE;
PRO
PRO GV$SQL (ordered by inst_id, object_status, is_obsolete, is_shareable, last_active_time and child_number)
PRO ~~~~~~
SPO planx_&&x_db_name.-&&x_instname.-&&x_container-&&sql_id._&¤t_time..txt APP;
SELECT inst_id
, SUBSTR(object_status, 1, 7) obj_sta
, is_obsolete obsl
, is_shareable shar
, LPAD(TO_CHAR(last_active_time, 'YYYY-MM-DD"T"HH24:MI:SS'), 20) last_active_time_ff
, child_number
, plan_hash_value
, LPAD(TO_CHAR(parse_calls, '999,999,999,999,990'), 20) parse_calls_ff
, LPAD(TO_CHAR(executions, '999,999,999,999,990'), 20) executions_ff
, LPAD(TO_CHAR(px_servers_executions, '999,999,999,999,990'), 20) px_servers_executions_ff
, LPAD(TO_CHAR(fetches, '999,999,999,999,990'), 20) fetches_ff
, LPAD(TO_CHAR(rows_processed, '999,999,999,999,990'), 20) rows_processed_ff
, LPAD(TO_CHAR(loaded_versions, '999,999,990'), 15) loaded_versions_ff
, LPAD(TO_CHAR(open_versions, '999,999,990'), 15) open_versions_ff
, LPAD(TO_CHAR(users_opening, '999,999,990'), 15) users_opening_ff
, LPAD(TO_CHAR(users_executing, '999,999,990'), 15) users_executing_ff
, LPAD(TO_CHAR(loads, '999,990'), 8) loads_ff
, LPAD(TO_CHAR(invalidations, '999,990'), 8) invalidations_ff
, LPAD(TO_CHAR(buffer_gets, '999,999,999,999,990'), 20) buffer_gets_ff
, LPAD(TO_CHAR(disk_reads, '999,999,999,999,990'), 20) disk_reads_ff
, LPAD(TO_CHAR(direct_writes, '999,999,999,999,990'), 20) direct_writes_ff
, LPAD(TO_CHAR(ROUND(elapsed_time/1e6, 3), '999,999,990.000'), 18) elsapsed_secs_ff
, LPAD(TO_CHAR(ROUND(cpu_time/1e6, 3), '999,999,990.000'), 18) cpu_secs_ff
, LPAD(TO_CHAR(ROUND(user_io_wait_time/1e6, 3), '999,999,990.000'), 18) user_io_wait_secs_ff
, LPAD(TO_CHAR(ROUND(cluster_wait_time/1e6, 3), '999,999,990.000'), 18) cluster_wait_secs_ff
, LPAD(TO_CHAR(ROUND(application_wait_time/1e6, 3), '999,999,990.000'), 18) appl_wait_secs_ff
, LPAD(TO_CHAR(ROUND(concurrency_wait_time/1e6, 3), '999,999,990.000'), 18) conc_wait_secs_ff
, LPAD(TO_CHAR(ROUND(plsql_exec_time/1e6, 3), '999,999,990.000'), 18) plsql_exec_secs_ff
, LPAD(TO_CHAR(ROUND(java_exec_time/1e6, 3), '999,999,990.000'), 18) java_exec_secs_ff
, LPAD(TO_CHAR(sorts, '999,999,999,999,990'), 20) sorts_ff
, LPAD(TO_CHAR(sharable_mem, '999,999,999,999,990'), 20) sharable_mem_ff
, LPAD(TO_CHAR(persistent_mem, '999,999,999,999,990'), 20) persistent_mem_ff
, LPAD(TO_CHAR(runtime_mem, '999,999,999,999,990'), 20) runtime_mem_ff
, LPAD(first_load_time, 20) first_load_time_ff
, LPAD(last_load_time, 20) last_load_time_ff
, optimizer_cost
, optimizer_env_hash_value
, parsing_schema_name
, service service_ff
, module module_ff
, action action_ff
, sql_profile sql_profile_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(io_cell_offload_eligible_bytes, '999,999,999,999,999,999,990'), 30) io_cell_offload_eligible_b_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(io_interconnect_bytes, '999,999,999,999,999,999,990'), 30) io_interconnect_bytes_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(io_cell_uncompressed_bytes, '999,999,999,999,999,999,990'), 30) io_cell_uncompressed_bytes_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(io_cell_offload_returned_bytes, '999,999,999,999,999,999,990'), 30) io_cell_offload_returned_b_ff
&&is_10g.&&is_11r1., LPAD(CASE WHEN io_cell_offload_eligible_bytes > io_cell_offload_returned_bytes AND io_cell_offload_eligible_bytes > 0 THEN LPAD(TO_CHAR(ROUND((io_cell_offload_eligible_bytes - io_cell_offload_returned_bytes) * 100 / io_cell_offload_eligible_bytes, 2), '990.00')||' %', 9) END, 10) io_saved_ff
FROM gv$sql
WHERE sql_id = :sql_id
ORDER BY inst_id
, SUBSTR(object_status, 1, 7) DESC
, is_obsolete
, is_shareable DESC
, last_active_time DESC
, child_number DESC
/
CLEAR BREAKS;
PRO
PRO GV$SQL (grouped by PHV and ordered by et_secs_per_exec)
PRO ~~~~~~
SELECT plan_hash_value
, TO_CHAR(ROUND(SUM(elapsed_time)/SUM(executions)/1e6,6), '999,990.000000') et_secs_per_exec
, TO_CHAR(ROUND(SUM(cpu_time)/SUM(executions)/1e6,6), '999,990.000000') cpu_secs_per_exec
, SUM(executions) executions
--, TO_CHAR(ROUND(SUM(elapsed_time)/1e6,6), '999,999,999,990') et_secs_tot
--, TO_CHAR(ROUND(SUM(cpu_time)/1e6,6), '999,999,999,990') cpu_secs_tot
, COUNT(DISTINCT child_number) cursors
, MAX(child_number) max_child
, SUM(CASE is_bind_sensitive WHEN 'Y' THEN 1 ELSE 0 END) bind_send
, SUM(CASE is_bind_aware WHEN 'Y' THEN 1 ELSE 0 END) bind_aware
, SUM(CASE is_shareable WHEN 'Y' THEN 1 ELSE 0 END) shareable
, SUM(CASE object_status WHEN 'VALID' THEN 1 ELSE 0 END) valid
, SUM(CASE object_status WHEN 'INVALID_UNAUTH' THEN 1 ELSE 0 END) invalid
, TO_CHAR(MAX(last_active_time), 'YYYY-MM-DD"T"HH24:MI:SS') last_active_time
, ROUND(SUM(buffer_gets)/SUM(executions)) buffers_per_exec
, TO_CHAR(ROUND(SUM(rows_processed)/SUM(executions), 3), '999,999,999,990.000') rows_per_exec
FROM gv$sql
WHERE sql_id = :sql_id
AND executions > 0
GROUP BY
plan_hash_value
ORDER BY
2
/
BREAK ON inst_id SKIP PAGE ON obj_sta SKIP PAGE ON obsl SKIP PAGE ON shar SKIP PAGE;
PRO
PRO GV$SQL (ordered by inst_id, object_status, is_obsolete, is_shareable, last_active_time and child_number)
PRO ~~~~~~
SELECT inst_id
, SUBSTR(object_status, 1, 7) obj_sta
, is_obsolete obsl
, is_shareable shar
, LPAD(TO_CHAR(last_active_time, 'YYYY-MM-DD"T"HH24:MI:SS'), 20) last_active_time_ff
, child_number
, plan_hash_value
, is_bind_sensitive sens
, is_bind_aware aware
, users_executing u_exec
, TO_CHAR(ROUND(elapsed_time/executions/1e6,6), '999,990.000000') et_secs_per_exec
, TO_CHAR(ROUND(cpu_time/executions/1e6,6), '999,990.000000') cpu_secs_per_exec
, executions
, TO_CHAR(ROUND(elapsed_time/1e6,6), '999,999,999,990') et_secs_tot
, TO_CHAR(ROUND(cpu_time/1e6,6), '999,999,999,990') cpu_secs_tot
, TO_CHAR(last_active_time, 'YYYY-MM-DD"T"HH24:MI:SS') last_active_time
, ROUND(buffer_gets/executions) buffers_per_exec
, TO_CHAR(ROUND(rows_processed/executions, 3), '999,999,999,990.000') rows_per_exec
FROM gv$sql
WHERE sql_id = :sql_id
AND executions > 0
ORDER BY inst_id
, SUBSTR(object_status, 1, 7) DESC
, is_obsolete
, is_shareable DESC
, last_active_time DESC
, child_number DESC
/
CLEAR BREAKS;
BREAK ON inst_id SKIP PAGE ON obj_sta SKIP PAGE ON obsl SKIP PAGE ON shar SKIP PAGE;
PRO
PRO GV$SQL (ordered by inst_id, object_status, is_obsolete, is_shareable, last_active_time and child_number)
PRO ~~~~~~
SELECT inst_id
, SUBSTR(object_status, 1, 7) obj_sta
, is_obsolete obsl
, is_shareable shar
, LPAD(TO_CHAR(last_active_time, 'YYYY-MM-DD"T"HH24:MI:SS'), 20) last_active_time_ff
, child_number
, plan_hash_value
&&is_10g., sql_plan_baseline
, sql_profile
&&is_10g., sql_patch
FROM gv$sql
WHERE sql_id = :sql_id
AND executions > 0
ORDER BY inst_id
, SUBSTR(object_status, 1, 7) DESC
, is_obsolete
, is_shareable DESC
, last_active_time DESC
, child_number DESC
/
CLEAR BREAKS;
PRO
--PRO GV$SQL_PLAN_STATISTICS_ALL LAST (ordered by inst_id and child_number)
PRO GV$SQL_PLAN_STATISTICS_ALL LAST (ordered by child_number)
PRO ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
PRO
--BREAK ON inst_child_ff SKIP 2;
SET PAGES 0;
SPO planx_&&x_db_name.-&&x_instname.-&&x_container-&&sql_id._&¤t_time..txt APP;
/*
WITH v AS (
SELECT /*+ MATERIALIZE * /
DISTINCT sql_id, inst_id, child_number
FROM gv$sql
WHERE sql_id = :sql_id
AND loaded_versions > 0
ORDER BY 1, 2, 3 )
SELECT /*+ ORDERED USE_NL(t) * /
RPAD('Inst: '||v.inst_id, 9)||' '||RPAD('Child: '||v.child_number, 11) inst_child_ff,
t.plan_table_output
FROM v, TABLE(DBMS_XPLAN.DISPLAY('gv$sql_plan_statistics_all', NULL, 'ADVANCED ALLSTATS LAST',
'inst_id = '||v.inst_id||' AND sql_id = '''||v.sql_id||''' AND child_number = '||v.child_number)) t
/
*/
SELECT plan_table_output FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR(:sql_id, NULL, 'ADVANCED ALLSTATS LAST &&format_adaptive'));
PRO
PRO DBA_HIST_SQLSTAT DELTA (ordered by snap_id DESC, instance_number and plan_hash_value)
PRO ~~~~~~~~~~~~~~~~~~~~~~
SET PAGES 50;
SPO planx_&&x_db_name.-&&x_instname.-&&x_container-&&sql_id._&¤t_time..txt APP;
SELECT s.snap_id
, TO_CHAR(s.begin_interval_time, 'YYYY-MM-DD"T"HH24:MI:SS') begin_interval_time_ff
, TO_CHAR(s.end_interval_time, 'YYYY-MM-DD"T"HH24:MI:SS') end_interval_time_ff
, s.instance_number
, h.plan_hash_value
, DECODE(h.loaded_versions, 1, 'Y', 'N') loaded_ff
, LPAD(TO_CHAR(h.version_count, '999,990'), 8) version_count_ff
, LPAD(TO_CHAR(h.parse_calls_delta, '999,999,999,999,990'), 20) parse_calls_ff
, LPAD(TO_CHAR(h.executions_delta, '999,999,999,999,990'), 20) executions_ff
, LPAD(TO_CHAR(h.rows_processed_delta, '999,999,999,999,990'), 20) rows_processed_ff
, LPAD(TO_CHAR(h.loads_delta, '999,990'), 8) loads_ff
, LPAD(TO_CHAR(h.invalidations_delta, '999,990'), 8) invalidations_ff
, LPAD(TO_CHAR(h.buffer_gets_delta, '999,999,999,999,990'), 20) buffer_gets_ff
, LPAD(TO_CHAR(h.disk_reads_delta, '999,999,999,999,990'), 20) disk_reads_ff
, LPAD(TO_CHAR(h.direct_writes_delta, '999,999,999,999,990'), 20) direct_writes_ff
, LPAD(TO_CHAR(ROUND(h.elapsed_time_delta/1e6, 3), '999,999,990.000'), 18) elsapsed_secs_ff
, LPAD(TO_CHAR(ROUND(h.cpu_time_delta/1e6, 3), '999,999,990.000'), 18) cpu_secs_ff
, LPAD(TO_CHAR(ROUND(h.iowait_delta/1e6, 3), '999,999,990.000'), 18) user_io_wait_secs_ff
, LPAD(TO_CHAR(ROUND(h.clwait_delta/1e6, 3), '999,999,990.000'), 18) cluster_wait_secs_ff
, LPAD(TO_CHAR(ROUND(h.apwait_delta/1e6, 3), '999,999,990.000'), 18) appl_wait_secs_ff
, LPAD(TO_CHAR(ROUND(h.ccwait_delta/1e6, 3), '999,999,990.000'), 18) conc_wait_secs_ff
, LPAD(TO_CHAR(ROUND(h.plsexec_time_delta/1e6, 3), '999,999,990.000'), 18) plsql_exec_secs_ff
, LPAD(TO_CHAR(ROUND(h.javexec_time_delta/1e6, 3), '999,999,990.000'), 18) java_exec_secs_ff
, LPAD(TO_CHAR(h.sorts_delta, '999,999,999,999,990'), 20) sorts_ff
, LPAD(TO_CHAR(h.sharable_mem, '999,999,999,999,990'), 20) sharable_mem_ff
, h.optimizer_cost
, h.optimizer_env_hash_value
, h.parsing_schema_name
, h.module module_ff
, h.action action_ff
, h.sql_profile sql_profile_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(h.io_offload_elig_bytes_delta, '999,999,999,999,999,999,990'), 30) io_cell_offload_eligible_b_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(h.io_interconnect_bytes_delta, '999,999,999,999,999,999,990'), 30) io_interconnect_bytes_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(h.cell_uncompressed_bytes_delta, '999,999,999,999,999,999,990'), 30) io_cell_uncompressed_bytes_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(h.io_offload_return_bytes_delta, '999,999,999,999,999,999,990'), 30) io_cell_offload_returned_b_ff
&&is_10g.&&is_11r1., LPAD(CASE WHEN h.io_offload_elig_bytes_delta > h.io_offload_return_bytes_delta AND h.io_offload_elig_bytes_delta > 0 THEN LPAD(TO_CHAR(ROUND((h.io_offload_elig_bytes_delta - h.io_offload_return_bytes_delta) * 100 / h.io_offload_elig_bytes_delta, 2), '990.00')||' %', 9) END, 10) io_saved_ff
FROM dba_hist_sqlstat h,
dba_hist_snapshot s
WHERE :license = 'Y'
AND h.dbid = :dbid
AND h.sql_id = :sql_id
AND s.snap_id = h.snap_id
AND s.dbid = h.dbid
AND s.instance_number = h.instance_number
ORDER BY 1 DESC, 4, 5
/
PRO
PRO DBA_HIST_SQLSTAT TOTAL (ordered by snap_id DESC, instance_number and plan_hash_value)
PRO ~~~~~~~~~~~~~~~~~~~~~~
SPO planx_&&x_db_name.-&&x_instname.-&&x_container-&&sql_id._&¤t_time..txt APP;
SELECT s.snap_id
, TO_CHAR(s.begin_interval_time, 'YYYY-MM-DD"T"HH24:MI:SS') begin_interval_time_ff
, TO_CHAR(s.end_interval_time, 'YYYY-MM-DD"T"HH24:MI:SS') end_interval_time_ff
, s.instance_number
, h.plan_hash_value
, DECODE(h.loaded_versions, 1, 'Y', 'N') loaded_ff
, LPAD(TO_CHAR(h.version_count, '999,990'), 8) version_count_ff
, LPAD(TO_CHAR(h.parse_calls_total, '999,999,999,999,990'), 20) parse_calls_ff
, LPAD(TO_CHAR(h.executions_total, '999,999,999,999,990'), 20) executions_ff
, LPAD(TO_CHAR(h.rows_processed_total, '999,999,999,999,990'), 20) rows_processed_ff
, LPAD(TO_CHAR(h.loads_total, '999,990'), 8) loads_ff
, LPAD(TO_CHAR(h.invalidations_total, '999,990'), 8) invalidations_ff
, LPAD(TO_CHAR(h.buffer_gets_total, '999,999,999,999,990'), 20) buffer_gets_ff
, LPAD(TO_CHAR(h.disk_reads_total, '999,999,999,999,990'), 20) disk_reads_ff
, LPAD(TO_CHAR(h.direct_writes_total, '999,999,999,999,990'), 20) direct_writes_ff
, LPAD(TO_CHAR(ROUND(h.elapsed_time_total/1e6, 3), '999,999,990.000'), 18) elsapsed_secs_ff
, LPAD(TO_CHAR(ROUND(h.cpu_time_total/1e6, 3), '999,999,990.000'), 18) cpu_secs_ff
, LPAD(TO_CHAR(ROUND(h.iowait_total/1e6, 3), '999,999,990.000'), 18) user_io_wait_secs_ff
, LPAD(TO_CHAR(ROUND(h.clwait_total/1e6, 3), '999,999,990.000'), 18) cluster_wait_secs_ff
, LPAD(TO_CHAR(ROUND(h.apwait_total/1e6, 3), '999,999,990.000'), 18) appl_wait_secs_ff
, LPAD(TO_CHAR(ROUND(h.ccwait_total/1e6, 3), '999,999,990.000'), 18) conc_wait_secs_ff
, LPAD(TO_CHAR(ROUND(h.plsexec_time_total/1e6, 3), '999,999,990.000'), 18) plsql_exec_secs_ff
, LPAD(TO_CHAR(ROUND(h.javexec_time_total/1e6, 3), '999,999,990.000'), 18) java_exec_secs_ff
, LPAD(TO_CHAR(h.sorts_total, '999,999,999,999,990'), 20) sorts_ff
, LPAD(TO_CHAR(h.sharable_mem, '999,999,999,999,990'), 20) sharable_mem_ff
, h.optimizer_cost
, h.optimizer_env_hash_value
, h.parsing_schema_name
, h.module module_ff
, h.action action_ff
, h.sql_profile sql_profile_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(h.io_offload_elig_bytes_total, '999,999,999,999,999,999,990'), 30) io_cell_offload_eligible_b_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(h.io_interconnect_bytes_total, '999,999,999,999,999,999,990'), 30) io_interconnect_bytes_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(h.cell_uncompressed_bytes_total, '999,999,999,999,999,999,990'), 30) io_cell_uncompressed_bytes_ff
&&is_10g.&&is_11r1., LPAD(TO_CHAR(h.io_offload_return_bytes_total, '999,999,999,999,999,999,990'), 30) io_cell_offload_returned_b_ff
&&is_10g.&&is_11r1., LPAD(CASE WHEN h.io_offload_elig_bytes_total > h.io_offload_return_bytes_total AND h.io_offload_elig_bytes_total > 0 THEN LPAD(TO_CHAR(ROUND((h.io_offload_elig_bytes_total - h.io_offload_return_bytes_total) * 100 / h.io_offload_elig_bytes_total, 2), '990.00')||' %', 9) END, 10) io_saved_ff
FROM dba_hist_sqlstat h,
dba_hist_snapshot s
WHERE :license = 'Y'
AND h.dbid = :dbid
AND h.sql_id = :sql_id
AND s.snap_id = h.snap_id
AND s.dbid = h.dbid
AND s.instance_number = h.instance_number
ORDER BY 1 DESC, 4, 5
/
PRO
PRO DBA_HIST_SQLSTAT DELTA (ordered by et_secs_per_exec)
PRO ~~~~~~~~~~~~~~~~~~~~~~
SELECT plan_hash_value
, TO_CHAR(ROUND(SUM(elapsed_time_delta)/SUM(executions_delta)/1e6,6), '999,990.000000') et_secs_per_exec
, TO_CHAR(ROUND(SUM(cpu_time_delta)/SUM(executions_delta)/1e6,6), '999,990.000000') cpu_secs_per_exec
, SUM(executions_delta) executions
, TO_CHAR(ROUND(SUM(elapsed_time_delta)/1e6,6), '999,999,999,990') et_secs_tot
, TO_CHAR(ROUND(SUM(cpu_time_delta)/1e6,6), '999,999,999,990') cpu_secs_tot
, ROUND(SUM(buffer_gets_delta)/SUM(executions_delta)) buffers_per_exec
, TO_CHAR(ROUND(SUM(rows_processed_delta)/SUM(executions_delta), 3), '999,999,999,990.000') rows_per_exec
FROM dba_hist_sqlstat
WHERE :license = 'Y'
AND sql_id = :sql_id
AND executions_delta > 0
GROUP BY
plan_hash_value
ORDER BY
2
/
PRO
PRO AWR_PLAN_CHANGE
PRO ~~~~~~~~~~~~~~~~~~~~~~
col execs for 999,999,999
col avg_etime for 999,999.999
col avg_lio for 999,999,999.9
col begin_interval_time for a30
col node for 99999
select ss.snap_id, ss.instance_number node, begin_interval_time, sql_id, plan_hash_value,
nvl(executions_delta,0) execs,
(elapsed_time_delta/decode(nvl(executions_delta,0),0,1,executions_delta))/1000000 avg_etime,
(buffer_gets_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta)) avg_lio,
(io_offload_elig_bytes_delta/decode(nvl(buffer_gets_delta,0),0,1,executions_delta)) avg_offload,
s.parsing_schema_name
from DBA_HIST_SQLSTAT S, DBA_HIST_SNAPSHOT SS
where S.sql_id = '&&sql_id.'
and ss.dbid = :dbid
and ss.dbid = S.dbid
and ss.snap_id = S.snap_id
and ss.instance_number = S.instance_number
and executions_delta > 0
order by 1, 2, 3
/
PRO
PRO DBA_HIST_SQL_PLAN (ordered by plan_hash_value)
PRO ~~~~~~~~~~~~~~~~~
BREAK ON plan_timestamp_ff SKIP 2;
SET PAGES 0;
SPO planx_&&x_db_name.-&&x_instname.-&&x_container-&&sql_id._&¤t_time..txt APP;
WITH v AS (
SELECT /*+ MATERIALIZE */
DISTINCT sql_id, plan_hash_value, dbid, timestamp
FROM dba_hist_sql_plan
WHERE :license = 'Y'
AND dbid = :dbid
AND sql_id = :sql_id
ORDER BY 1, 2, 3 )
SELECT /*+ ORDERED USE_NL(t) */
TO_CHAR(v.timestamp, 'YYYY-MM-DD"T"HH24:MI:SS') plan_timestamp_ff,
t.plan_table_output
FROM v, TABLE(DBMS_XPLAN.DISPLAY_AWR(v.sql_id, v.plan_hash_value, v.dbid, 'ADVANCED &&format_adaptive')) t
/
CLEAR BREAK;
PRO
PRO GV$ACTIVE_SESSION_HISTORY - ash_elap by exec (recent)
PRO ~~~~~~~~~~~~~~~~~~~~~~~~~
set lines 300
SET PAGES 50000
col sql_exec_start format a30
col run_time_timestamp format a30
select 'realtime' source, sql_id,
sql_exec_id,
sql_plan_hash_value,
CAST(sql_exec_start AS TIMESTAMP) sql_exec_start,
run_time run_time_timestamp,
(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)) run_time_sec,
round(temp/1024/1024,2) temp_mb,
round(pga/1024/1024,2) pga_mb,
round(rbytes/1024/1024,2) read_mb,
round(wbytes/1024/1024,2) write_mb,
riops,
wiops
from (
select
sql_id,
sql_exec_id,
sql_plan_hash_value,
max(sql_exec_start) sql_exec_start,
max(sample_time - sql_exec_start) run_time,
max(TEMP_SPACE_ALLOCATED) temp,
max(PGA_ALLOCATED) pga,
max(DELTA_READ_IO_BYTES) rbytes,
max(DELTA_READ_IO_REQUESTS) riops,
max(DELTA_WRITE_IO_BYTES) wbytes,
max(DELTA_WRITE_IO_REQUESTS) wiops
from
v$active_session_history
where sql_id = '&&sql_id.'
and sql_exec_start is not null
group by sql_id,sql_exec_id,sql_plan_hash_value
order by sql_exec_start desc
)
where rownum < 21
order by 1, sql_exec_start asc
/
select 'historical' source, sql_id,
sql_exec_id,
sql_plan_hash_value,
CAST(sql_exec_start AS TIMESTAMP) sql_exec_start,
run_time run_time_timestamp,
(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)) run_time_sec,
round(temp/1024/1024,2) temp_mb,
round(pga/1024/1024,2) pga_mb,
round(rbytes/1024/1024,2) read_mb,
round(wbytes/1024/1024,2) write_mb,
riops,
wiops
from (
select
sql_id,
sql_exec_id,
sql_plan_hash_value,
max(sql_exec_start) sql_exec_start,
max(sample_time - sql_exec_start) run_time,
max(TEMP_SPACE_ALLOCATED) temp,
max(PGA_ALLOCATED) pga,
max(DELTA_READ_IO_BYTES) rbytes,
max(DELTA_READ_IO_REQUESTS) riops,
max(DELTA_WRITE_IO_BYTES) wbytes,
max(DELTA_WRITE_IO_REQUESTS) wiops
from
dba_hist_active_sess_history
where sql_id = '&&sql_id.'
and sql_exec_start is not null
group by sql_id,sql_exec_id,sql_plan_hash_value
order by sql_exec_start desc
)
where rownum < 21
order by 1, sql_exec_start asc
/
PRO
PRO GV$ACTIVE_SESSION_HISTORY - ash_elap exec avg min max
PRO ~~~~~~~~~~~~~~~~~~~~~~~~~
select 'realtime' source, sql_plan_hash_value,
count(*),
round(avg(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) avg ,
round(min(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) min ,
round(max(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) max
from (
select
sql_id,
sql_exec_id,
sql_plan_hash_value,
max(sql_exec_start) sql_exec_start,
max(sample_time - sql_exec_start) run_time
from
gv$active_session_history
where
sql_exec_start is not null
and sql_id = '&&sql_id.'
group by sql_id,sql_exec_id,sql_plan_hash_value
)
group by sql_plan_hash_value
union all
select null, null,
count(*),
round(avg(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) avg ,
round(min(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) min ,
round(max(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) max
from (
select
sql_id,
sql_exec_id,
sql_plan_hash_value,
max(sql_exec_start) sql_exec_start,
max(sample_time - sql_exec_start) run_time
from
gv$active_session_history
where
sql_exec_start is not null
and sql_id = '&&sql_id.'
group by sql_id,sql_exec_id,sql_plan_hash_value
)
/
select 'historical' source, sql_plan_hash_value,
count(*),
round(avg(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) avg ,
round(min(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) min ,
round(max(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) max
from (
select
sql_id,
sql_exec_id,
sql_plan_hash_value,
max(sql_exec_start) sql_exec_start,
max(sample_time - sql_exec_start) run_time
from
dba_hist_active_sess_history
where
sql_exec_start is not null
and sql_id = '&&sql_id.'
group by sql_id,sql_exec_id,sql_plan_hash_value
)
group by sql_plan_hash_value
union all
select null, null,
count(*),
round(avg(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) avg ,
round(min(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) min ,
round(max(EXTRACT(HOUR FROM run_time) * 3600
+ EXTRACT(MINUTE FROM run_time) * 60
+ EXTRACT(SECOND FROM run_time)),2) max
from (
select
sql_id,
sql_exec_id,
sql_plan_hash_value,
max(sql_exec_start) sql_exec_start,
max(sample_time - sql_exec_start) run_time
from
dba_hist_active_sess_history
where
sql_exec_start is not null
and sql_id = '&&sql_id.'
group by sql_id,sql_exec_id,sql_plan_hash_value
)
/
PRO
PRO GV$ACTIVE_SESSION_HISTORY
PRO ~~~~~~~~~~~~~~~~~~~~~~~~~
DEF x_slices = '10';
SET PAGES 50000;
COL samples FOR 999,999,999,999
COL percent FOR 9,990.0;
COL timed_event FOR A70;
WITH
events AS (
SELECT /*+ MATERIALIZE */
CASE h.session_state WHEN 'ON CPU' THEN h.session_state ELSE h.wait_class||' "'||h.event||'"' END timed_event,
COUNT(*) samples
FROM gv$active_session_history h
WHERE :license = 'Y'
AND sql_id = '&&sql_id.'
GROUP BY
CASE h.session_state WHEN 'ON CPU' THEN h.session_state ELSE h.wait_class||' "'||h.event||'"' END
ORDER BY
2 DESC
),
total AS (
SELECT SUM(samples) samples,
SUM(CASE WHEN ROWNUM > &&x_slices. THEN samples ELSE 0 END) others
FROM events
)
SELECT 'realtime' source, e.samples,
ROUND(100 * e.samples / t.samples, 1) percent,
e.timed_event
FROM events e,
total t
WHERE ROWNUM <= &&x_slices.
AND ROUND(100 * e.samples / t.samples, 1) > 0.1
UNION ALL
SELECT null, others samples,
ROUND(100 * others / samples, 1) percent,
'Others' timed_event
FROM total
WHERE others > 0
AND ROUND(100 * others / samples, 1) > 0.1
order by 2 desc
/
WITH
events AS (
SELECT /*+ MATERIALIZE */
CASE h.session_state WHEN 'ON CPU' THEN h.session_state ELSE h.wait_class||' "'||h.event||'"' END timed_event,
COUNT(*) samples
FROM dba_hist_active_sess_history h
WHERE :license = 'Y'
AND sql_id = '1g10r6kwgmv30'
GROUP BY
CASE h.session_state WHEN 'ON CPU' THEN h.session_state ELSE h.wait_class||' "'||h.event||'"' END
ORDER BY