-
Notifications
You must be signed in to change notification settings - Fork 27
/
Copy pathTrcExtProf.sql
1768 lines (1547 loc) · 64 KB
/
TrcExtProf.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
/*
# TrcExtProf.sql
#
# TrcExtProf is a sql script for analyzing raw trace file(10046) and generating a formatted output.
#
# You can customize the code as you want (add new sections,metrics,join with other views ,etc) and all you need is SQL you don't need to know any other
# programing language (perl,D,etc) and that's one of the primary goal of this script. The combination of external tables + sql give us a powerful tools, special thanks goes
# to nikolay savvinov for inspiring me after reading his blog post on http://savvinov.com/2014/09/08/querying-trace-files/
#
# The analyzis done by the script are based on this key metrics :
#
# Response time = Idle wait time + non-idle Waits time + CPU time
# Self Response time = Response time - recursive statement Response time
#
#
# Usage: @TrcExtProf.sql tracefile.trc -options
# Options :
#
# t(threshold) : Statement which contribute less than this threshold to the total response time will not be diplayed in the TOP SQL section . Default : 10
# r(threshold) : Statement which contribute less than this threshold to the parent statement response time will not be diplayed in the RECURSIVE STATEMENT section. Default : 20
# w : Display wait event histograms.
# b : Display bind variables.
# d : Display I/O stats.
# g : Display SQL genealogy
#
# Example :
# @TrcExtProf.sql tracefile.trc -t(20)r(20)wbg
# This will display : - All statements which contribute more than 20% of total response time
# - For every statements displayed list all recursive statements which contribute more than 20% of parent statement response time
# - Display wait event histograms
# - Display bind variables
# - Does not display I/O stats because 'd' option is not specified
# - Display SQL genealogy
#
#
#
#
# Author : Hatem Mahmoud <h.mahmoud87@gmail.com>
# BLOG : https://mahmoudhatem.wordpress.com
#
# Version TrcExtProf 1.1 BETA
# Note: this is an experimental script, use at your own risk
#
#
# Instalation script to run before execution :
prompt External table creation
CREATE OR REPLACE DIRECTORY TRACEDIR AS 'Trace_file_path';
CREATE TABLE RAWTRACEFILE
(
row_num number,
TEXT VARCHAR2(4000 BYTE) NULL
)
ORGANIZATION EXTERNAL
( TYPE ORACLE_LOADER
DEFAULT DIRECTORY TRACEDIR
ACCESS PARAMETERS
( RECORDS DELIMITED BY '\n' fields
( row_num RECNUM ,TEXT position(1:4000) )
)
LOCATION (TRACEDIR:'ORCL_2_ora_3541.trc')
)
REJECT LIMIT 0
/
prompt Temporary table and indexes for wait events
CREATE GLOBAL TEMPORARY TABLE TRCEXTPROF_WAITS
(
ROW_NUM NUMBER NULL,
CURNUM VARCHAR2(4000 BYTE) NULL,
EVENT VARCHAR2(4000 BYTE) NULL,
ELA_S NUMBER NULL
)
ON COMMIT PRESERVE ROWS
RESULT_CACHE (MODE DEFAULT)
NOCACHE;
CREATE UNIQUE INDEX TRCEXTPROF_WAITS_IDX ON TRCEXTPROF_WAITS(ROW_NUM);
prompt Temporary table and indexes for sql geanology (PARSE,EXEC,FETCH,CLOSE)
CREATE GLOBAL TEMPORARY TABLE TRCEXTPROF_SQLGEANOLOGY
(
ROW_NUM NUMBER NULL,
TIM VARCHAR2(4000 BYTE) NULL,
CALL_NAME VARCHAR2(5 BYTE) NULL,
MISS NUMBER NULL,
CURNUM VARCHAR2(4000 BYTE) NULL,
DEP NUMBER NULL,
DEP_PRE NUMBER NULL,
CALL_BEGIN NUMBER NULL,
CPU_TIME NUMBER NULL,
ELA_TIME NUMBER NULL,
PIO NUMBER NULL,
CR NUMBER NULL,
CUR NUMBER NULL,
NB_ROWS NUMBER NULL,
SELF_PIO NUMBER NULL,
SELF_CR NUMBER NULL,
SELF_CUR NUMBER NULL,
SELF_CPU_TIME NUMBER NULL,
SELF_ELA_TIME NUMBER NULL,
SELF_WAIT_ELA_S NUMBER NULL
)
ON COMMIT PRESERVE ROWS
RESULT_CACHE (MODE DEFAULT)
NOCACHE;
CREATE UNIQUE INDEX TRCEXTPROF_SQLGEANOLOGY_IDX ON TRCEXTPROF_SQLGEANOLOGY (DEP,ROW_NUM) compress 1;
CREATE GLOBAL TEMPORARY TABLE TRCEXTPROF_GEANOLGY_TEXT
(
ROW_NUM NUMBER NULL,
TIM VARCHAR2(4000 BYTE) NULL,
CALL_NAME VARCHAR2(5 BYTE) NULL,
MISS NUMBER NULL,
CURNUM VARCHAR2(4000 BYTE) NULL,
DEP NUMBER NULL,
DEP_PRE NUMBER NULL,
CALL_BEGIN NUMBER NULL,
CPU_TIME NUMBER NULL,
ELA_TIME NUMBER NULL,
PIO NUMBER NULL,
CR NUMBER NULL,
CUR NUMBER NULL,
NB_ROWS NUMBER NULL,
SELF_PIO NUMBER NULL,
SELF_CR NUMBER NULL,
SELF_CUR NUMBER NULL,
SELF_CPU_TIME NUMBER NULL,
SELF_ELA_TIME NUMBER NULL,
SELF_WAIT_ELA_S NUMBER NULL,
ALL_WAIT_TIME NUMBER NULL,
SQLID VARCHAR2(13 BYTE) NULL,
TEXT VARCHAR2(4000 BYTE) NULL,
U_ID VARCHAR2(4000 BYTE) NULL,
HV VARCHAR2(10 BYTE) NULL
)
ON COMMIT PRESERVE ROWS
RESULT_CACHE (MODE DEFAULT)
NOCACHE;
prompt Temporary table and indexes for base cursors
CREATE GLOBAL TEMPORARY TABLE TRCEXTPROF_BASE_CURSOR_TEXT
(
ROW_NUM NUMBER NULL,
TEXT VARCHAR2(4000 BYTE) NULL
)
ON COMMIT PRESERVE ROWS
RESULT_CACHE (MODE DEFAULT)
NOCACHE;
CREATE UNIQUE INDEX TRCEXTPROF_BASE_CURSOR_T_IDX ON TRCEXTPROF_BASE_CURSOR_TEXT (ROW_NUM);
CREATE GLOBAL TEMPORARY TABLE TRCEXTPROF_BASE_CURSOR_INTER
(
ROW_NUM NUMBER NULL,
CALL_NAME VARCHAR2(17 BYTE) NULL,
CURNUM VARCHAR2(4000 BYTE) NULL,
SQLID VARCHAR2(13 BYTE) NULL,
DEP NUMBER NULL,
U_ID VARCHAR2(4000 BYTE) NULL,
HV VARCHAR2(10 BYTE) NULL,
END_TEXT NUMBER NULL,
CURS_NUM_BEGIN NUMBER NULL,
PARSEIN_CURS_NEXT NUMBER NULL,
CURS_NUM_END NUMBER NULL,
TEXT VARCHAR2(4000 BYTE) NULL
)
ON COMMIT PRESERVE ROWS
RESULT_CACHE (MODE DEFAULT)
NOCACHE;
CREATE UNIQUE INDEX TRCEXTPROF_BASE_CURSOR_I_IDX ON TRCEXTPROF_BASE_CURSOR_INTER (call_name,curnum,ROW_NUM) compress 2;
CREATE GLOBAL TEMPORARY TABLE TRCEXTPROF_BASE_CURSOR
(
ROW_NUM NUMBER NULL,
CALL_NAME VARCHAR2(17 BYTE) NULL,
CURNUM VARCHAR2(4000 BYTE) NULL,
SQLID VARCHAR2(13 BYTE) NULL,
DEP NUMBER NULL,
U_ID VARCHAR2(4000 BYTE) NULL,
HV VARCHAR2(10 BYTE) NULL,
END_TEXT NUMBER NULL,
CURS_NUM_BEGIN NUMBER NULL,
PARSEIN_CURS_NEXT NUMBER NULL,
CURS_NUM_END NUMBER NULL,
TEXT VARCHAR2(4000 BYTE) NULL
)
ON COMMIT PRESERVE ROWS
RESULT_CACHE (MODE DEFAULT)
NOCACHE;
CREATE UNIQUE INDEX TRCEXTPROF_BASE_CURSOR_IDX ON TRCEXTPROF_BASE_CURSOR (ROW_NUM);
prompt Temporary table and indexes for plan stat
CREATE GLOBAL TEMPORARY TABLE TRCEXTPROF_STATS
(
ROW_NUM NUMBER NULL,
CURNUM VARCHAR2(4000 BYTE) NULL,
CNT NUMBER NULL,
OBJN NUMBER NULL,
O_ID NUMBER NULL,
O_PID NUMBER NULL,
OPERA VARCHAR2(4000 BYTE) NULL
)
ON COMMIT PRESERVE ROWS
RESULT_CACHE (MODE DEFAULT)
NOCACHE;
CREATE UNIQUE INDEX TRCEXTPROF_STATS_IDX ON TRCEXTPROF_STATS(ROW_NUM);
prompt Temporary table and indexes for bindes
CREATE GLOBAL TEMPORARY TABLE TRCEXTPROF_BINDS
(
ROW_NUM NUMBER NULL,
TEXT VARCHAR2(4000 BYTE) NULL,
CUR_NUM VARCHAR2(4000 BYTE) NULL,
BIND_END NUMBER NULL
)
ON COMMIT PRESERVE ROWS
RESULT_CACHE (MODE DEFAULT)
NOCACHE;
CREATE UNIQUE INDEX TRCEXTPROF_BINDS_IDX ON TRCEXTPROF_BINDS (ROW_NUM);
prompt Temporary table and indexes for sql_text
CREATE GLOBAL TEMPORARY TABLE TRCEXTPROF_TEXT
(
ROW_NUM NUMBER NULL,
TEXT VARCHAR2(4000 BYTE) NULL
)
ON COMMIT PRESERVE ROWS
RESULT_CACHE (MODE DEFAULT)
NOCACHE;
CREATE UNIQUE INDEX TRCEXTPROF_TEXT_IDX ON TRCEXTPROF_TEXT (ROW_NUM);
*/
WHENEVER SQLERROR EXIT SQL.SQLCODE
SET SERVEROUTPUT ON FORMAT WRAPPED
set linesize 2000;
set echo off;
set define on;
set verify off;
set feed off;
--Threshold
-- Minimum statement response time %
var l_min_response_time number ;
-- Minimum recursive statement response time %
var l_min_recusive_response_time number ;
var l_max_time number;
var l_show_bind number;
var l_show_wait_hist number;
var l_show_io_stat number;
var l_show_sql_gea number;
var l_min_time number;
var last_call_time number;
var l_total_response_time number;
var l_total_wait_time number;
var l_total_cpu_time number;
var l_total_unaccounted_for number;
var nb_recursive_stat number;
var NB_INTERNAL_STAT number;
var nb_total_stat number;
var nb_distinct_stat number;
var l_prev_sql varchar2( 4000 BYTE);
var l_prev_plan varchar2(4000 BYTE);
var l_sum_wait_time number;
var l_final_line number;
PROMPT
PROMPT ===================================================================================;
PROMPT =============================TrcExtProf V1.1 BETA==================================;
PROMPT ===================================================================================;
PROMPT ===================================================================================;
PROMPT
PROMPT
PROMPT ----> Initializing
PROMPT
BEGIN
:l_prev_plan := 0;
:l_prev_sql :='null';
:l_total_wait_time := 0.0;
:l_total_cpu_time := 0.0;
:l_min_response_time := 20;
:l_min_recusive_response_time := 10;
:l_show_wait_hist := 0;
:l_show_bind := 0;
:l_show_io_stat := 0;
:l_show_sql_gea := 0;
:l_final_line := 9999999999999999;
if ('&2' like '-%w%' ) then
:l_show_wait_hist := 1;
dbms_output.put_line('Display wait events histograms : Y ');
else
dbms_output.put_line('Display wait events histograms : N ');
end if;
if ('&2' like '-%b%' ) then
:l_show_bind := 1;
dbms_output.put_line('Display bind variables : Y ');
else
dbms_output.put_line('Display bind variables : N ');
end if;
if ('&2' like '-%g%' ) then
:l_show_sql_gea := 1;
dbms_output.put_line('Display sql geanology : Y ');
else
dbms_output.put_line('Display sql geanology : N ');
end if;
if ('&2' like '-%d%' ) then
:l_show_io_stat := 1;
dbms_output.put_line('Display I/O stats : Y ');
else
dbms_output.put_line('Display I/O stats : N ');
end if;
if ('&2' like '-%t(%' ) then
:l_min_response_time := SUBSTR ('&2',INSTR ('&2', 't(') + 2,INSTR ('&2', ')',INSTR ('&2', 't(')) - INSTR ('&2', 't(') - 2);
end if;
if ('&2' like '-%r(%' ) then
:l_min_recusive_response_time := SUBSTR ('&2',INSTR ('&2', 'r(') + 2,INSTR ('&2', ')',INSTR ('&2', 'r(')) - INSTR ('&2', 'r(') - 2);
end if;
dbms_output.put_line('Top SQL min response time : ' || :l_min_response_time || '%');
dbms_output.put_line('Recursive SQL min response time : ' || :l_min_recusive_response_time || '%');
execute immediate 'truncate table TRCEXTPROF_BINDS';
execute immediate 'truncate table TRCEXTPROF_STATS';
execute immediate 'truncate table TRCEXTPROF_BASE_CURSOR';
execute immediate 'truncate table TRCEXTPROF_SQLGEANOLOGY';
execute immediate 'truncate table TRCEXTPROF_WAITS';
execute immediate 'TRUNCATE TABLE TRCEXTPROF_BASE_CURSOR_INTER';
execute immediate 'TRUNCATE TABLE TRCEXTPROF_BASE_CURSOR_TEXT';
execute immediate 'TRUNCATE TABLE TRCEXTPROF_BASE_CURSOR';
execute immediate 'TRUNCATE TABLE TRCEXTPROF_GEANOLGY_TEXT';
execute immediate 'ALTER TABLE RAWTRACEFILE LOCATION(''&1'') ';
end;
/
PROMPT
PROMPT <---- Initializing
PROMPT
PROMPT ----> LOADING DATA
PROMPT
PROMPT
PROMPT -- LOADING trcextprof_waits
PROMPT
set timing off;
begin
INSERT /*+ append */ INTO trcextprof_waits
SELECT row_num,
SUBSTR (text,
INSTR (text, '#') + 1,
INSTR (text, ':') - INSTR (text, '#') - 1)
AS curnum,
SUBSTR (text,
INSTR (text, 'nam=') + 5,
INSTR (text, 'ela=') - INSTR (text, 'nam=') - 7)
event,
TO_NUMBER (
SUBSTR (
text,
INSTR (text, 'ela=') + 5,
INSTR (text, ' ', INSTR (text, 'ela=') + 5)
- INSTR (text, 'ela=')
- 4))
/ 10E5
ela_s
FROM RAWTRACEFILE
WHERE text LIKE 'WAIT%';
commit;
end ;
/
PROMPT
PROMPT -- LOADING trcextprof_base_cursor
PROMPT
begin
INSERT /*+ append */
INTO trcextprof_base_cursor_inter (row_num,
call_name,
curnum,
sqlid,
dep,
u_id,
hv,
end_text)
SELECT row_num,
CASE
WHEN text LIKE 'CLOSE%' THEN 'CLOSE'
WHEN text LIKE 'PARSING IN CURSOR%' THEN 'PARSING IN CURSOR'
WHEN text LIKE 'PARSE ERROR%' THEN 'PARSE ERROR'
WHEN text LIKE 'END OF STMT%' THEN 'END OF STMT'
END
AS call_name,
CASE
WHEN text LIKE 'PARSING IN CURSOR %'
THEN
SUBSTR (
text,
INSTR (text, '#') + 1,
INSTR (text, ' ', INSTR (text, 'len=') - 2)
- INSTR (text, '#')
- 1)
WHEN text LIKE 'CLOSE %'
THEN
SUBSTR (text,
INSTR (text, '#') + 1,
INSTR (text, ':') - INSTR (text, '#') - 1)
WHEN text LIKE 'PARSE ERROR %'
THEN
SUBSTR (text,
INSTR (text, '#') + 1,
INSTR (text, ':') - INSTR (text, '#') - 1)
END
AS curnum,
CASE
WHEN text LIKE 'PARSING IN CURSOR %'
THEN
SUBSTR (text, INSTR (text, 'sqlid=') + 7, 13)
WHEN text LIKE 'PARSE ERROR %'
THEN
SUBSTR (text, INSTR (text, 'err='))
END
AS sqlid,
CASE
WHEN text LIKE 'PARSING IN CURSOR %'
THEN
to_number(SUBSTR (text, INSTR (text, 'dep=') + 4, 1))
END
AS dep,
CASE
WHEN text LIKE 'PARSING IN CURSOR %'
THEN
SUBSTR (text,
INSTR (text, 'uid=') + 4,
INSTR (text, 'oct=') - INSTR (text, 'uid=') - 5)
END
AS u_id,
CASE
WHEN text LIKE 'PARSING IN CURSOR %'
THEN
SUBSTR (text, INSTR (text, 'hv=') + 3, 10)
END
AS hv,
CASE
WHEN text LIKE 'PARSING IN CURSOR %'
THEN
LEAD (row_num) OVER (ORDER BY ROW_NUM)
WHEN text LIKE 'PARSE ERROR %'
THEN
row_num + 2
END
AS end_text
FROM RAWTRACEFILE
WHERE text LIKE 'PARSING IN CURSOR %'
OR text LIKE 'CLOSE%'
OR text LIKE 'PARSE ERROR%'
OR text LIKE 'END OF STMT%';
COMMIT;
UPDATE trcextprof_base_cursor_inter b
SET curs_num_begin =
CASE
WHEN call_name = 'PARSING IN CURSOR'
THEN
(SELECT /*+ index(i TRCEXTPROF_BASE_CURSOR_I_IDX) */
MAX (i.row_num)
FROM trcextprof_base_cursor_inter i
WHERE i.curnum = b.curnum
AND i.row_num < b.row_num
AND i.call_name = 'CLOSE')
WHEN call_name = 'PARSE ERROR'
THEN
(SELECT /*+ index(i TRCEXTPROF_BASE_CURSOR_I_IDX) */
MAX (i.row_num)
FROM trcextprof_base_cursor_inter i
WHERE i.curnum = b.curnum
AND i.row_num < b.row_num
AND i.call_name = 'CLOSE')
END,
parsein_curs_next =
CASE
WHEN call_name = 'PARSING IN CURSOR'
THEN
(SELECT /*+ index(i TRCEXTPROF_BASE_CURSOR_I_IDX) */
MIN (i.row_num)
FROM trcextprof_base_cursor_inter i
WHERE i.curnum = b.curnum
AND i.row_num > b.row_num
AND ( i.call_name = 'PARSING IN CURSOR' OR i.call_name = 'PARSE ERROR') )
WHEN call_name = 'PARSE ERROR'
THEN
(SELECT /*+ index(i TRCEXTPROF_BASE_CURSOR_I_IDX) */
MIN (i.row_num)
FROM trcextprof_base_cursor_inter i
WHERE i.curnum = b.curnum
AND i.row_num > b.row_num
AND ( i.call_name = 'PARSING IN CURSOR' OR i.call_name = 'PARSE ERROR') )
END;
UPDATE trcextprof_base_cursor_inter b
SET curs_num_end =
CASE
WHEN call_name = 'PARSING IN CURSOR'
THEN
(SELECT /*+ index(i TRCEXTPROF_BASE_CURSOR_I_IDX) */
MAX (i.row_num)
FROM trcextprof_base_cursor_inter i
WHERE i.curnum = b.curnum
AND i.row_num >
NVL2 (b.curs_num_begin, b.curs_num_begin, 0)
AND i.row_num <
NVL2 (b.parsein_curs_next,
b.parsein_curs_next,
:l_final_line)
AND i.call_name = 'CLOSE')
WHEN call_name = 'PARSE ERROR'
THEN
(SELECT /*+ index(i TRCEXTPROF_BASE_CURSOR_I_IDX) */
MAX (i.row_num)
FROM trcextprof_base_cursor_inter i
WHERE i.curnum = b.curnum
AND i.row_num >
NVL2 (b.curs_num_begin, b.curs_num_begin, 0)
AND i.row_num <
NVL2 (b.parsein_curs_next,
b.parsein_curs_next,
:l_final_line)
AND i.call_name = 'CLOSE')
END;
COMMIT;
INSERT /*+ append */
INTO TRCEXTPROF_BASE_CURSOR_TEXT
SELECT row_num, text
FROM RAWTRACEFILE r
WHERE r.text NOT LIKE 'PARS%'
AND r.text NOT LIKE 'CLOSE%'
AND r.text NOT LIKE 'WAIT%'
AND r.text NOT LIKE 'FETCH%'
AND r.text NOT LIKE 'EXEC%'
AND r.text NOT LIKE 'STAT%'
AND r.text NOT LIKE 'END OF STMT%'
AND r.text NOT LIKE '========%'
AND r.text NOT LIKE '***%';
COMMIT;
INSERT /*+ append */ INTO TRCEXTPROF_BASE_CURSOR (row_num,
call_name,
curnum,
sqlid,
dep,
u_id,
hv,
end_text,
curs_num_begin,
parsein_curs_next,
curs_num_end,
text)
SELECT /*+
USE_CONCAT(@"SEL$1" 8 OR_PREDICATES(1) PREDICATE_REORDERS((4 3) (5 4) (3 5)))
OUTLINE_LEAF(@"SEL$1_2")
OUTLINE(@"SEL$1")
FULL(@"INS$1" "TRCEXTPROF_BASE_CURSOR"@"INS$1")
INDEX_RS_ASC(@"SEL$1_1" "B"@"SEL$1" ("TRCEXTPROF_BASE_CURSOR_INTER"."CALL_NAME" "TRCEXTPROF_BASE_CURSOR_INTER"."CURNUM"
"TRCEXTPROF_BASE_CURSOR_INTER"."ROW_NUM"))
INDEX_RS_ASC(@"SEL$1_1" "R"@"SEL$1" ("TRCEXTPROF_BASE_CURSOR_TEXT"."ROW_NUM"))
FULL(@"SEL$1_2" "B"@"SEL$1_2")
FULL(@"SEL$1_2" "R"@"SEL$1_2")
LEADING(@"SEL$1_1" "B"@"SEL$1" "R"@"SEL$1")
LEADING(@"SEL$1_2" "B"@"SEL$1_2" "R"@"SEL$1_2")
USE_NL(@"SEL$1_1" "R"@"SEL$1")
USE_NL(@"SEL$1_2" "R"@"SEL$1_2")
*/
b.row_num,
b.call_name,
b.curnum,
b.sqlid,
b.dep,
b.u_id,
b.hv,
b.end_text,
b.curs_num_begin,
b.parsein_curs_next,
b.curs_num_end,
LISTAGG (text, ' ') WITHIN GROUP (ORDER BY pos ASC) as text
FROM (SELECT b.row_num,
b.call_name,
b.curnum,
b.sqlid,
b.dep,
b.u_id,
b.hv,
b.end_text,
b.curs_num_begin,
b.parsein_curs_next,
b.curs_num_end,
r.text,
r.row_num AS pos
FROM trcextprof_base_cursor_inter b, TRCEXTPROF_BASE_CURSOR_TEXT r
WHERE ( b.row_num != b.end_text - 2
AND r.row_num < b.end_text
AND r.row_num > b.row_num)
OR ( b.row_num = b.end_text - 2
AND r.row_num = b.end_text - 1)
AND ( b.call_name = 'PARSING IN CURSOR'
OR b.call_name = 'PARSE ERROR')) b
GROUP BY b.row_num,
b.call_name,
b.curnum,
b.sqlid,
b.dep,
b.u_id,
b.hv,
b.end_text,
b.curs_num_begin,
b.parsein_curs_next,
b.curs_num_end;
COMMIT;
execute immediate 'TRUNCATE TABLE TRCEXTPROF_BASE_CURSOR_INTER';
execute immediate 'TRUNCATE TABLE TRCEXTPROF_BASE_CURSOR_TEXT';
end ;
/
PROMPT
PROMPT -- LOADING trcextprof_sqlgeanology
PROMPT
begin
INSERT /*+ append */
INTO trcextprof_sqlgeanology (row_num,
tim,
call_name,
miss,
curnum,
dep,
dep_pre,
call_begin,
cpu_time,
ela_time,
pio,
cr,
cur,
nb_rows)
WITH sql_geanolgy
AS ( SELECT row_num,
SUBSTR (text, INSTR (text, 'tim=') + 4) tim,
CASE
WHEN text LIKE ('FETCH #%') THEN 'FETCH'
WHEN text LIKE ('PARSE #%') THEN 'PARSE'
WHEN text LIKE ('EXEC #%') THEN 'EXEC'
WHEN text LIKE ('CLOSE #%') THEN 'CLOSE'
END
call_name,
TO_NUMBER (
NVL (
SUBSTR (
text,
INSTR (text, 'mis=') + 4,
INSTR (text, ',r=') - INSTR (text, 'mis=') - 4),
0))
AS miss,
SUBSTR (text,
INSTR (text, '#') + 1,
INSTR (text, ':') - INSTR (text, '#') - 1)
AS curnum,
to_number(SUBSTR (
text,
INSTR (text, 'dep=') + 4,
INSTR (text, ',', (INSTR (text, 'dep=')))
- INSTR (text, 'dep=')
- 4))
AS dep,
to_number(LAG (
SUBSTR (
text,
INSTR (text, 'dep=') + 4,
INSTR (text, ',', (INSTR (text, 'dep=')))
- INSTR (text, 'dep=')
- 4))
OVER (ORDER BY ROW_NUM))
AS dep_pre,
CASE
WHEN (SUBSTR (
text,
INSTR (text, 'dep=') + 4,
INSTR (text, ',', (INSTR (text, 'dep=')))
- INSTR (text, 'dep=')
- 4) <
(LAG (
SUBSTR (
text,
INSTR (text, 'dep=') + 4,
INSTR (text,
',',
(INSTR (text, 'dep=')))
- INSTR (text, 'dep=')
- 4))
OVER (ORDER BY ROW_NUM)))
THEN
NVL (
MAX (
row_num)
OVER (
PARTITION BY (SUBSTR (
text,
INSTR (text, 'dep=') + 4,
INSTR (
text,
',',
(INSTR (text, 'dep=')))
- INSTR (text, 'dep=')
- 4))
ORDER BY ROWNUM
ROWS BETWEEN UNBOUNDED PRECEDING
AND 1 PRECEDING),
0)
ELSE
NVL (
MAX (
row_num)
OVER (
PARTITION BY (SUBSTR (
text,
INSTR (text, '#') + 1,
INSTR (text, ':')
- INSTR (text, '#')
- 1))
ORDER BY ROWNUM
ROWS BETWEEN UNBOUNDED PRECEDING
AND 1 PRECEDING),
0)
END
AS call_begin,
TO_NUMBER (
SUBSTR (text,
INSTR (text, 'c=') + 2,
INSTR (text, ',e=') - INSTR (text, 'c=') - 2))
/ 10E5
cpu_time,
TO_NUMBER (
SUBSTR (
text,
INSTR (text, 'e=') + 2,
INSTR (text, ',', INSTR (text, 'e='))
- INSTR (text, 'e=')
- 2))
/ 10E5
ela_time,
TO_NUMBER (
NVL (
SUBSTR (
text,
INSTR (text, 'p=') + 2,
INSTR (text, ',cr') - INSTR (text, 'p=') - 2),
0))
pio,
TO_NUMBER (
NVL (
SUBSTR (
text,
INSTR (text, 'cr=') + 3,
INSTR (text, ',cu') - INSTR (text, 'cr=') - 3),
0))
Cr,
TO_NUMBER (
NVL (
SUBSTR (
text,
INSTR (text, 'cu=') + 3,
INSTR (text, ',mis=') - INSTR (text, 'cu=') - 3),
0))
Cur,
TO_NUMBER (
CASE
WHEN text NOT LIKE 'CLOSE %'
THEN
NVL (
SUBSTR (
text,
INSTR (text, ',r=') + 3,
INSTR (text, ',dep=')
- INSTR (text, ',r=')
- 3),
0)
ELSE
'0'
END)
nb_rows
FROM RAWTRACEFILE
WHERE text LIKE 'PARSE #%'
OR text LIKE 'EXEC #%'
OR text LIKE 'FETCH #%'
OR text LIKE 'CLOSE #%'
ORDER BY row_num)
SELECT row_num,
tim,
call_name,
miss,
curnum,
dep,
dep_pre,
call_begin,
cpu_time,
ela_time,
pio,
cr,
cur,
nb_rows
FROM sql_geanolgy;
COMMIT;
UPDATE trcextprof_sqlgeanology g
SET self_wait_ela_s = CASE
WHEN NVL (g.call_begin, 0) < g.row_num - 1
THEN
(SELECT NVL (SUM (ela_s), 0)
FROM trcextprof_waits w
WHERE w.row_num < g.row_num
AND w.row_num > NVL (g.call_begin, 0)
AND g.curnum = w.curnum)
ELSE
0
END;
COMMIT;
INSERT /*+ append */ INTO TRCEXTPROF_GEANOLGY_TEXT
WITH wait_events AS (SELECT * FROM trcextprof_waits)
SELECT g.row_num,
g.tim,
g.call_name,
miss,
g.curnum,
g.dep,
g.dep_pre,
call_begin,
cpu_time,
ela_time,
pio,
cr,
cur,
nb_rows,
CASE
WHEN g.dep < g.dep_pre and g.call_name != 'CLOSE'
THEN
g.pio
- (SELECT SUM (pio)
FROM trcextprof_sqlgeanology self
WHERE self.row_num < g.row_num
AND self.row_num > g.call_begin
AND self.dep = g.dep + 1)
ELSE
g.pio
END as self_pio,
CASE
WHEN g.dep < g.dep_pre and g.call_name != 'CLOSE'
THEN
g.cr
- (SELECT SUM (cr)
FROM trcextprof_sqlgeanology self
WHERE self.row_num < g.row_num
AND self.row_num > g.call_begin
AND self.dep = g.dep + 1)
ELSE
g.cr
END as self_cr,
CASE
WHEN g.dep < g.dep_pre and g.call_name != 'CLOSE'
THEN
g.cur
- (SELECT SUM (cur)
FROM trcextprof_sqlgeanology self
WHERE self.row_num < g.row_num
AND self.row_num > g.call_begin
AND self.dep = g.dep + 1)
ELSE
g.cur
END as self_cur,
CASE
WHEN g.dep < g.dep_pre
THEN
g.cpu_time
- (SELECT SUM (cpu_time)
FROM trcextprof_sqlgeanology self
WHERE self.row_num < g.row_num
AND self.row_num > g.call_begin
AND self.dep = g.dep + 1)
ELSE
g.cpu_time
END as self_cpu_time,
CASE
WHEN g.dep < g.dep_pre
THEN
g.ela_time
- (SELECT SUM (ela_time)
FROM trcextprof_sqlgeanology self
WHERE self.row_num < g.row_num
AND self.row_num > g.call_begin
AND self.dep = g.dep + 1)
ELSE
g.ela_time
END as self_ela_time,
g.self_wait_ela_s,
CASE
WHEN g.dep < g.dep_pre
THEN
(SELECT SUM (self_wait_ela_s)
FROM trcextprof_sqlgeanology s
WHERE s.row_num < g.row_num
AND s.row_num > g.call_begin
AND s.dep > g.dep ) + self_wait_ela_s
ELSE
self_wait_ela_s
END as ALL_WAIT_TIME,
ct.sqlid,
ct.text,
ct.u_id,
ct.hv
FROM trcextprof_sqlgeanology g
LEFT OUTER JOIN
trcextprof_base_cursor ct
ON g.row_num >
NVL2 (ct.curs_num_begin, ct.curs_num_begin, 0)
AND g.row_num <=
NVL2 (ct.curs_num_end,
ct.curs_num_end,
:l_final_line)
AND g.curnum = ct.curnum;
commit;
execute immediate 'truncate table trcextprof_sqlgeanology';
end ;
/
PROMPT
PROMPT -- LOADING trcextprof_stats