-
Notifications
You must be signed in to change notification settings - Fork 9
/
run_awr_miner.sql
1401 lines (1149 loc) · 47.7 KB
/
run_awr_miner.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
define SQL_TOP_N = 100
define CAPTURE_HOST_NAMES = 'YES'
-- Last n days of data to capture.
define NUM_DAYS = 30
-- Only change the DATE_BEGIN | END parameters to filter to a certain range.
-- For 99% of the use-cases, just leave these parameters alone.
-- If DATE_BEGIN is changed, NUM_DAYS is ignored
-- Date Format YYYY-MM-DD
define DATE_BEGIN = '2000-01-01'
define DATE_END = '2040-01-01'
set define '&'
set concat '~'
set colsep " "
SET UNDERLINE '-'
set pagesize 50000
SET ARRAYSIZE 5000
REPHEADER OFF
REPFOOTER OFF
define AWR_MINER_VER = 5.0.8
set termout off
alter session set optimizer_dynamic_sampling=4;
alter session set workarea_size_policy = manual;
alter session set sort_area_size = 268435456;
alter session set NLS_LENGTH_SEMANTICS=BYTE;
alter session set cursor_sharing = exact;
alter session set NLS_DATE_FORMAT = 'yyyy-mm-dd HH24:mi:ss';
alter session set NLS_TIMESTAMP_FORMAT = 'yyyy-mm-dd HH24:mi:ss';
set termout on
set timing off
set serveroutput on
set verify off
prompt
prompt AWR-Miner Version &AWR_MINER_VER
prompt This script queries views in the AWR Repository that require
prompt a license for the Diagnostic Pack. These are the same views used
prompt to generate an AWR report.
prompt If you are licensed for the Diagnostic Pack please type YES.
prompt Otherwise please type NO and this script will exit.
-- define DIAG_PACK_LICENSE = 'NO'
prompt
-- accept DIAG_PACK_LICENSE CHAR prompt 'Are you licensed for the Diagnostic Pack? [NO|YES] '
-- whenever sqlerror exit
-- set serveroutput on
-- begin
-- if upper('&DIAG_PACK_LICENSE') = 'YES' then
-- null;
-- else
-- dbms_output.put_line('This script will now exit.');
-- execute immediate 'bogus statement to force exit';
-- end if;
-- end;
-- /
whenever sqlerror continue
column cnt_dbid_1 new_value CNT_DBID noprint
SELECT count(DISTINCT dbid) cnt_dbid_1
FROM dba_hist_database_instance;
--where rownum = 1;
define DBID = ' '
column :DBID_1 new_value DBID noprint
variable DBID_1 varchar2(30)
define DB_VERSION = 0
column :DB_VERSION_1 new_value DB_VERSION noprint
variable DB_VERSION_1 number
set feedback off
declare
version_gte_11_2 varchar2(30);
l_sql varchar2(32767);
l_variables varchar2(1000) := ' ';
l_block_size number;
begin
:DB_VERSION_1 := dbms_db_version.version + (dbms_db_version.release / 10);
dbms_output.put_line('Database IDs in this Repository:');
for c1 in (select distinct dbid,db_name FROM dba_hist_database_instance order by db_name)
loop
dbms_output.put_line(rpad(c1.dbid,35)||c1.db_name);
end loop; --c1
if to_number(&CNT_DBID) > 1 then
:DBID_1 := ' ';
else
SELECT DISTINCT dbid into :DBID_1
FROM dba_hist_database_instance
where rownum = 1;
end if;
--l_variables := l_variables||'ver_gte_11_2:TRUE';
if :DB_VERSION_1 >= 11.2 then
l_variables := l_variables||'ver_gte_11_2:TRUE';
else
l_variables := l_variables||'ver_gte_11_2:FALSE';
end if;
if :DB_VERSION_1 >= 11.1 then
l_variables := l_variables||',ver_gte_11_1:TRUE';
else
l_variables := l_variables||',ver_gte_11_1:FALSE';
end if;
--alter session set plsql_ccflags = 'debug_flag:true';
l_sql := q'[alter session set plsql_ccflags =']'||l_variables||q'[']';
execute immediate l_sql;
end;
/
select :DBID_1 from dual;
select :DB_VERSION_1 from dual;
-- accept DBID2 CHAR prompt 'Which dbid would you like to use? [&DBID] '
-- column DBID_2 new_value DBID noprint
-- select case when length('&DBID2') > 3 then '&DBID2' else '&DBID' end DBID_2 from dual;
-- whenever sqlerror exit
-- set serveroutput on
-- begin
-- if length('&DBID') > 4 then
-- null;
-- else
-- dbms_output.put_line('!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!');
-- dbms_output.put_line('You must choose a database ID.');
-- dbms_output.put_line('This script will now exit.');
-- dbms_output.put_line('!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!');
-- execute immediate 'bogus statement to force exit';
-- end if;
-- end;
-- /
COL ecr_dbid NEW_V DBID;
SELECT 'get_dbid', TO_CHAR(dbid) ecr_dbid FROM v$database;
whenever sqlerror continue
declare
l_stat_rows number := 1;
l_last_analyzed_days number:= 0;
l_last_analyzed_threshold constant number:= 60;
l_actual_rows number;
l_pct_change number := 0;
begin
select nvl(NUM_ROWS,1) nrows,round(sysdate - S.LAST_ANALYZED) last_analyzed_days
into l_stat_rows,l_last_analyzed_days from sys.DBA_TAB_STATISTICS s where owner = 'SYS' and table_name = 'WRM$_SNAPSHOT';
select count(*) num_rows into l_actual_rows from sys.dba_hist_snapshot;
if l_stat_rows is null or l_stat_rows < 1 then
l_stat_rows := 1;
end if;
--dbms_output.put_line('Stats: '||l_stat_rows);
--dbms_output.put_line('Actual: '||l_actual_rows);
l_pct_change := abs(round((l_actual_rows-l_stat_rows)/l_stat_rows,3))*100;
--dbms_output.put_line('% Change: '||l_pct_change);
if l_pct_change >= 30 or l_last_analyzed_days > l_last_analyzed_threshold then
dbms_output.put_line(' ');
dbms_output.put_line('*******************************************************************************');
dbms_output.put_line('****************************** WARNING !!! ************************************');
dbms_output.put_line('It appears that statistics on the SYS schema may be invalid.');
if l_last_analyzed_days > l_last_analyzed_threshold then
dbms_output.put_line(q'!Statistics haven't been collect for !'||l_last_analyzed_days||q'! days!');
end if;
dbms_output.put_line('This can have serious, negative performance implications for this script ');
dbms_output.put_line('as well as AWR, ASH, and ADDM. Please review My Oracle Support Doc ID 457926.1');
dbms_output.put_line('for details on gathering stats on SYS objects.');
dbms_output.put_line('****************************** WARNING !!! ************************************');
dbms_output.put_line('*******************************************************************************');
end if;
end;
/
prompt
prompt
prompt Do NOT change the file name of the .out file generated by this script!
prompt Do NOT edit the output file in any way!
prompt Either type of change will cause the analysis engine to fail to parse the output later.
-- prompt Press Enter to run AWR-Miner now
-- pause
REM set heading off
select '&DBID' a from dual;
column db_name1 new_value DBNAME
prompt Will export AWR data for the following Database:
SELECT dbid,db_name db_name1
FROM dba_hist_database_instance
where dbid = '&DBID'
and rownum = 1;
define T_WAITED_MICRO_COL = 'TIME_WAITED_MICRO'
column :T_WAITED_MICRO_COL_1 new_value T_WAITED_MICRO_COL noprint
variable T_WAITED_MICRO_COL_1 varchar2(30)
begin
if :DB_VERSION_1 >= 11.1 then
:T_WAITED_MICRO_COL_1 := 'TIME_WAITED_MICRO_FG';
else
:T_WAITED_MICRO_COL_1 := 'TIME_WAITED_MICRO';
end if;
end;
/
select :T_WAITED_MICRO_COL_1 from dual;
define DB_BLOCK_SIZE = 0
column :DB_BLOCK_SIZE_1 new_value DB_BLOCK_SIZE noprint
variable DB_BLOCK_SIZE_1 number
set feedback off
begin
:DB_BLOCK_SIZE_1 := 0;
for c1 in (
with inst as (
select min(instance_number) inst_num
from dba_hist_snapshot
where dbid = &DBID
)
SELECT VALUE the_block_size
FROM DBA_HIST_PARAMETER
WHERE dbid = &DBID
and PARAMETER_NAME = 'db_block_size'
AND snap_id = (SELECT MAX(snap_id) FROM dba_hist_osstat WHERE dbid = &DBID AND instance_number = (select inst_num from inst))
AND instance_number = (select inst_num from inst))
loop
:DB_BLOCK_SIZE_1 := c1.the_block_size;
end loop; --c1
if :DB_BLOCK_SIZE_1 = 0 then
:DB_BLOCK_SIZE_1 := 8192;
end if;
end;
/
select :DB_BLOCK_SIZE_1 from dual;
--column snap_min1 new_value SNAP_ID_MIN noprint
column snap_min1 new_value SNAP_ID_MIN
--SELECT min(snap_id) - 1 snap_min1
-- FROM dba_hist_snapshot
-- WHERE dbid = &DBID
-- and begin_interval_time > (
-- SELECT max(begin_interval_time) - &NUM_DAYS
-- FROM dba_hist_snapshot
-- where dbid = &DBID);
SELECT min(snap_id) - 1 snap_min1
FROM dba_hist_snapshot
WHERE dbid = &DBID
and (
(
'&DATE_BEGIN' = '2000-01-01'
and
begin_interval_time > (
SELECT max(begin_interval_time) - &NUM_DAYS
FROM dba_hist_snapshot
where dbid = &DBID)
)
or
('&DATE_BEGIN' != '2000-01-01'
and
begin_interval_time >= trunc(to_date('&DATE_BEGIN','YYYY-MM-DD'))
)
)
;
select 'foo' from dual where '&DATE_BEGIN' = '2000-01-01';
column snap_max1 new_value SNAP_ID_MAX noprint
SELECT max(snap_id) snap_max1
FROM dba_hist_snapshot
WHERE dbid = &DBID
and begin_interval_time < trunc(to_date('&DATE_END','YYYY-MM-DD'))+1
and ('&DATE_BEGIN' = '2000-01-01'
or
(
'&DATE_BEGIN' != '2000-01-01'
and
begin_interval_time >= trunc(to_date('&DATE_BEGIN','YYYY-MM-DD'))
)
);
prompt
rem prompt &SNAP_ID_MIN
rem prompt &SNAP_ID_MAX
rem prompt &NUM_DAYS
whenever sqlerror exit
set serveroutput on
begin
if length('&DBID') > 4 then
null;
else
dbms_output.put_line('!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!');
dbms_output.put_line('You must choose a database ID.');
dbms_output.put_line('This script will now exit.');
dbms_output.put_line('!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!');
execute immediate 'bogus statement to force exit';
end if;
end;
/
whenever sqlerror continue
whenever sqlerror exit
set serveroutput on
declare
l_snapshot_count number := 0;
begin
for c1 in (SELECT count(*) cnt
FROM dba_hist_snapshot
WHERE dbid = &DBID)
loop
l_snapshot_count := c1.cnt;
end loop; --c1
if l_snapshot_count > 2 then
null;
else
dbms_output.put_line('!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!');
dbms_output.put_line('There is no AWR data for this DBID');
dbms_output.put_line('This script will now exit.');
dbms_output.put_line('!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!');
execute immediate 'bogus statement to force exit';
end if;
end;
/
whenever sqlerror continue
whenever sqlerror exit
set serveroutput on
begin
--if length(&SNAP_ID_MIN) > 0 and length(&SNAP_ID_MAX) > 0 then
--dbms_output.put_line('foo'|| REGEXP_REPLACE('&SNAP_ID_MIN','[[:space:]]','')||'bar');
--if ('&SNAP_ID_MIN') != '' then
if length(REGEXP_REPLACE('&SNAP_ID_MIN','[[:space:]]','')) > 0 and
length(REGEXP_REPLACE('&SNAP_ID_MAX','[[:space:]]','')) > 0 then
null;
else
dbms_output.put_line('!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!');
dbms_output.put_line('The chosen date range doesn''t contain any data.');
dbms_output.put_line('This script will now exit.');
dbms_output.put_line('!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!!');
execute immediate 'bogus statement to force exit';
end if;
end;
/
whenever sqlerror continue
column FILE_NAME new_value SPOOL_FILE_NAME noprint
select 'awr-hist-'||'&DBID'||'-'||'&DBNAME'||'-'||ltrim('&SNAP_ID_MIN')||'-'||ltrim('&SNAP_ID_MAX')||'.out' FILE_NAME from dual;
set timing on
TIMING START full_capture_script
spool &SPOOL_FILE_NAME
-- ##############################################################################################
REPHEADER ON
REPFOOTER ON
set linesize 1000
set numwidth 10
set wrap off
set heading on
set trimspool on
set feedback off
set serveroutput on
DECLARE
l_pad_length number :=60;
l_hosts varchar2(4000);
l_dbid number;
BEGIN
dbms_output.put_line('~~BEGIN-OS-INFORMATION~~');
dbms_output.put_line(rpad('STAT_NAME',l_pad_length)||' '||'STAT_VALUE');
dbms_output.put_line(rpad('-',l_pad_length,'-')||' '||rpad('-',l_pad_length,'-'));
FOR c1 IN (
with inst as (
select min(instance_number) inst_num
from dba_hist_snapshot
where dbid = &DBID
and snap_id BETWEEN to_number(&SNAP_ID_MIN) and to_number(&SNAP_ID_MAX))
SELECT
CASE WHEN stat_name = 'PHYSICAL_MEMORY_BYTES' THEN 'PHYSICAL_MEMORY_GB' ELSE stat_name END stat_name,
CASE WHEN stat_name IN ('PHYSICAL_MEMORY_BYTES') THEN round(VALUE/1024/1024/1024,2) ELSE VALUE END stat_value
FROM dba_hist_osstat
WHERE dbid = &DBID
AND snap_id = (SELECT MAX(snap_id) FROM dba_hist_osstat WHERE dbid = &DBID AND instance_number = (select inst_num from inst))
AND instance_number = (select inst_num from inst)
AND (stat_name LIKE 'NUM_CPU%'
OR stat_name IN ('PHYSICAL_MEMORY_BYTES')))
loop
dbms_output.put_line(rpad(c1.stat_name,l_pad_length)||' '||c1.stat_value);
end loop; --c1
for c1 in (SELECT CPU_COUNT,CPU_CORE_COUNT,CPU_SOCKET_COUNT
FROM DBA_CPU_USAGE_STATISTICS
where dbid = &DBID
and TIMESTAMP = (select max(TIMESTAMP) from DBA_CPU_USAGE_STATISTICS where dbid = &DBID )
AND ROWNUM = 1)
loop
dbms_output.put_line(rpad('!CPU_COUNT',l_pad_length)||' '||c1.CPU_COUNT);
dbms_output.put_line(rpad('!CPU_CORE_COUNT',l_pad_length)||' '||c1.CPU_CORE_COUNT);
dbms_output.put_line(rpad('!CPU_SOCKET_COUNT',l_pad_length)||' '||c1.CPU_SOCKET_COUNT);
end loop;
for c1 in (SELECT distinct platform_name FROM sys.GV_$DATABASE
where dbid = &DBID
and rownum = 1)
loop
dbms_output.put_line(rpad('!PLATFORM_NAME',l_pad_length)||' '||c1.platform_name);
end loop;
FOR c2 IN (SELECT
$IF $$VER_GTE_11_2 $THEN
REPLACE(platform_name,' ','_') platform_name,
$ELSE
'None' platform_name,
$END
VERSION,db_name,DBID FROM dba_hist_database_instance
WHERE dbid = &DBID
and startup_time = (select max(startup_time) from dba_hist_database_instance WHERE dbid = &DBID )
AND ROWNUM = 1)
loop
dbms_output.put_line(rpad('PLATFORM_NAME',l_pad_length)||' '||c2.platform_name);
dbms_output.put_line(rpad('VERSION',l_pad_length)||' '||c2.VERSION);
dbms_output.put_line(rpad('DB_NAME',l_pad_length)||' '||c2.db_name);
dbms_output.put_line(rpad('DBID',l_pad_length)||' '||c2.DBID);
end loop; --c2
FOR c3 IN (SELECT count(distinct s.instance_number) instances
FROM dba_hist_database_instance i,dba_hist_snapshot s
WHERE i.dbid = s.dbid
and i.dbid = &DBID
AND s.snap_id BETWEEN &SNAP_ID_MIN AND &SNAP_ID_MAX)
loop
dbms_output.put_line(rpad('INSTANCES',l_pad_length)||' '||c3.instances);
end loop; --c3
FOR c4 IN (SELECT distinct regexp_replace(host_name,'^([[:alnum:]]+)\..*$','\1') host_name
FROM dba_hist_database_instance i,dba_hist_snapshot s
WHERE i.dbid = s.dbid
and i.dbid = &DBID
and s.startup_time = i.startup_time
AND s.snap_id BETWEEN &SNAP_ID_MIN AND &SNAP_ID_MAX
order by 1)
loop
if '&CAPTURE_HOST_NAMES' = 'YES' then
l_hosts := l_hosts || c4.host_name ||',';
end if;
end loop; --c4
l_hosts := rtrim(l_hosts,',');
dbms_output.put_line(rpad('HOSTS',l_pad_length)||' '||l_hosts);
FOR c5 IN (SELECT REGEXP_REPLACE(sys_context('USERENV', 'MODULE'),'^(.+?)@.+$','\1') module FROM DUAL)
loop
dbms_output.put_line(rpad('MODULE',l_pad_length)||' '||c5.module);
end loop; --c5
dbms_output.put_line(rpad('AWR_MINER_VER',l_pad_length)||' &AWR_MINER_VER');
dbms_output.put_line('~~END-OS-INFORMATION~~');
END;
/
prompt
prompt
-- ##############################################################################################
REPHEADER PAGE LEFT '~~BEGIN-PATCH-HISTORY~~'
REPFOOTER PAGE LEFT '~~END-PATCH-HISTORY~~'
column ACTION_TIME format a24
column comments format a80
select * from (
select rownum rnum, h.* from DBA_REGISTRY_HISTORY h order by action_time desc)
where rownum <= 10;
prompt
prompt
REPHEADER PAGE LEFT '~~BEGIN-MODULE~~'
REPFOOTER PAGE LEFT '~~END-MODULE~~'
SELECT REGEXP_REPLACE(sys_context('USERENV', 'MODULE'),'^(.+?)@.+$','\1') module FROM DUAL;
REPHEADER PAGE LEFT '~~BEGIN-SNAP-HISTORY~~'
REPFOOTER PAGE LEFT '~~END-SNAP-HISTORY~~'
SELECT min(snap_id) snap_min, max(snap_id) snap_max,count(*) cnt,count(distinct INSTANCE_NUMBER) inst_count,
sum(ERROR_COUNT) ERROR_COUNT
FROM dba_hist_snapshot
WHERE dbid = &DBID;
-- ##############################################################################################
REPHEADER PAGE LEFT '~~BEGIN-MEMORY~~'
REPFOOTER PAGE LEFT '~~END-MEMORY~~'
SELECT snap_id,
instance_number,
MAX (DECODE (stat_name, 'SGA', stat_value, NULL)) "SGA",
MAX (DECODE (stat_name, 'PGA', stat_value, NULL)) "PGA",
MAX (DECODE (stat_name, 'SGA', stat_value, NULL)) + MAX (DECODE (stat_name, 'PGA', stat_value,
NULL)) "TOTAL"
FROM
(SELECT snap_id,
instance_number,
ROUND (SUM (bytes) / 1024 / 1024 / 1024, 1) stat_value,
MAX ('SGA') stat_name
FROM dba_hist_sgastat
WHERE dbid = &DBID
AND snap_id BETWEEN &SNAP_ID_MIN AND &SNAP_ID_MAX
GROUP BY snap_id,
instance_number
UNION ALL
SELECT snap_id,
instance_number,
ROUND (value / 1024 / 1024 / 1024, 1) stat_value,
'PGA' stat_name
FROM dba_hist_pgastat
WHERE dbid = &DBID
AND snap_id BETWEEN &SNAP_ID_MIN AND &SNAP_ID_MAX
AND NAME = 'total PGA allocated'
)
GROUP BY snap_id,
instance_number
ORDER BY snap_id,
instance_number;
prompt
prompt
-- ##############################################################################################
REPHEADER PAGE LEFT '~~BEGIN-MEMORY-SGA-ADVICE~~'
REPFOOTER PAGE LEFT '~~END-MEMORY-SGA-ADVICE~~'
select snap_id,instance_number,sga_target_gb,size_factor,ESTD_PHYSICAL_READS,lead_read_diff
from(
with top_n_dbtime as(
select snap_id from(
select snap_id, sum(average) dbtime_p_s,
dense_rank() over (order by sum(average) desc nulls last) rnk
from dba_hist_sysmetric_summary
where dbid = &DBID
and snap_id between &SNAP_ID_MIN and &SNAP_ID_MAX
and metric_name = 'Database Time Per Sec'
group by snap_id)
where rnk <= 10)
SELECT a.SNAP_ID,
INSTANCE_NUMBER,
ROUND(sga_size/1024,1) sga_target_gb,
sga_size_FACTOR size_factor,
ESTD_PHYSICAL_READS,
round((ESTD_PHYSICAL_READS - lead(ESTD_PHYSICAL_READS,1,ESTD_PHYSICAL_READS) over (partition by a.snap_id,instance_number order by sga_size_FACTOR asc nulls last)),1) lead_read_diff,
min(sga_size_FACTOR) over (partition by a.snap_id,instance_number) min_factor,
max(sga_size_FACTOR) over (partition by a.snap_id,instance_number) max_factor
FROM DBA_HIST_SGA_TARGET_ADVICE a,top_n_dbtime tn
WHERE dbid = &DBID
AND a.snap_id = tn.snap_id)
where (size_factor = 1
or size_factor = min_factor
or size_factor = max_factor
or lead_read_diff > 1)
order by snap_id asc,instance_number, size_factor asc nulls last;
prompt
prompt
-- ##############################################################################################
REPHEADER PAGE LEFT '~~BEGIN-MEMORY-PGA-ADVICE~~'
REPFOOTER PAGE LEFT '~~END-MEMORY-PGA-ADVICE~~'
SELECT SNAP_ID,
INSTANCE_NUMBER,
PGA_TARGET_GB,
SIZE_FACTOR,
ESTD_EXTRA_MB_RW,
LEAD_SIZE_DIFF_MB,
ESTD_PGA_CACHE_HIT_PERCENTAGE
FROM
( WITH top_n_dbtime AS
(SELECT snap_id
FROM
(SELECT snap_id,
SUM(average) dbtime_p_s,
dense_rank() over (order by SUM(average) DESC nulls last) rnk
FROM dba_hist_sysmetric_summary
where dbid = &DBID
and snap_id between &SNAP_ID_MIN and &SNAP_ID_MAX
AND metric_name = 'Database Time Per Sec'
GROUP BY snap_id
)
WHERE rnk <= 10
)
SELECT a.SNAP_ID,
INSTANCE_NUMBER,
ROUND(PGA_TARGET_FOR_ESTIMATE/1024/1024/1024,1) pga_target_gb,
PGA_TARGET_FACTOR size_factor,
ROUND(ESTD_EXTRA_BYTES_RW /1024/1024,1) ESTD_EXTRA_MB_RW,
ROUND((ESTD_EXTRA_BYTES_RW - lead(ESTD_EXTRA_BYTES_RW,1,ESTD_EXTRA_BYTES_RW) over (partition BY a.snap_id,instance_number order by PGA_TARGET_FACTOR ASC nulls last))/1024/1024,1) lead_size_diff_mb,
ESTD_PGA_CACHE_HIT_PERCENTAGE,
MIN(PGA_TARGET_FACTOR) over (partition BY a.snap_id,instance_number) min_factor,
MAX(PGA_TARGET_FACTOR) over (partition BY a.snap_id,instance_number) max_factor
FROM DBA_HIST_PGA_TARGET_ADVICE a,
top_n_dbtime tn
WHERE dbid = &DBID
AND a.snap_id = tn.snap_id
)
WHERE (size_factor = 1
OR size_factor = min_factor
OR size_factor = max_factor
OR lead_size_diff_mb > 1)
ORDER BY snap_id ASC,
instance_number,
size_factor ASC nulls last;
prompt
prompt
-- ##############################################################################################
REPHEADER PAGE LEFT '~~BEGIN-SIZE-ON-DISK~~'
REPFOOTER PAGE LEFT '~~END-SIZE-ON-DISK~~'
WITH ts_info as (
select dbid, ts#, tsname, max(block_size) block_size
from dba_hist_datafile
where dbid = &DBID
group by dbid, ts#, tsname),
-- Get the maximum snaphsot id for each day from dba_hist_snapshot
snap_info as (
select dbid,to_char(trunc(end_interval_time,'DD'),'MM/DD/YY') dd, max(s.snap_id) snap_id
FROM dba_hist_snapshot s
where s.snap_id between &SNAP_ID_MIN and &SNAP_ID_MAX
and dbid = &DBID
--where s.end_interval_time > to_date(:start_time,'MMDDYYYY')
--and s.end_interval_time < to_date(:end_time,'MMDDYYYY')
group by dbid,trunc(end_interval_time,'DD'))
-- Sum up the sizes of all the tablespaces for the last snapshot of each day
select s.snap_id, round(sum(tablespace_size*f.block_size)/1024/1024/1024,2) size_gb
from dba_hist_tbspc_space_usage sp,
ts_info f,
snap_info s
WHERE s.dbid = sp.dbid
AND s.dbid = &DBID
and s.snap_id between &SNAP_ID_MIN and &SNAP_ID_MAX
and s.snap_id = sp.snap_id
and sp.dbid = f.dbid
AND sp.tablespace_id = f.ts#
GROUP BY s.snap_id,s.dd, s.dbid
order by s.snap_id;
prompt
prompt
-- ##############################################################################################
REPHEADER PAGE LEFT '~~BEGIN-OSSTAT~~'
REPFOOTER PAGE LEFT '~~END-OSSTAT~~'
SELECT snap_id,
INSTANCE_NUMBER,
MAX(DECODE(STAT_NAME,'LOAD', round(value,1),NULL)) "load",
MAX(DECODE(STAT_NAME,'NUM_CPUS', value,NULL)) "cpus",
MAX(DECODE(STAT_NAME,'NUM_CPU_CORES', value,NULL)) "cores",
MAX(DECODE(STAT_NAME,'NUM_CPU_SOCKETS', value,NULL)) "sockets",
MAX(DECODE(STAT_NAME,'PHYSICAL_MEMORY_BYTES', ROUND(value/1024/1024),NULL)) "mem_gb",
MAX(DECODE(STAT_NAME,'FREE_MEMORY_BYTES', ROUND(value /1024/1024),NULL)) "mem_free_gb",
MAX(DECODE(STAT_NAME,'IDLE_TIME', value,NULL)) "idle",
MAX(DECODE(STAT_NAME,'BUSY_TIME', value,NULL)) "busy",
MAX(DECODE(STAT_NAME,'USER_TIME', value,NULL)) "user",
MAX(DECODE(STAT_NAME,'SYS_TIME', value,NULL)) "sys",
MAX(DECODE(STAT_NAME,'IOWAIT_TIME', value,NULL)) "iowait",
MAX(DECODE(STAT_NAME,'NICE_TIME', value,NULL)) "nice",
MAX(DECODE(STAT_NAME,'OS_CPU_WAIT_TIME', value,NULL)) "cpu_wait",
MAX(DECODE(STAT_NAME,'RSRC_MGR_CPU_WAIT_TIME', value,NULL)) "rsrc_mgr_wait",
MAX(DECODE(STAT_NAME,'VM_IN_BYTES', value,NULL)) "vm_in",
MAX(DECODE(STAT_NAME,'VM_OUT_BYTES', value,NULL)) "vm_out",
MAX(DECODE(STAT_NAME,'cpu_count', value,NULL)) "cpu_count"
FROM
(SELECT snap_id,
INSTANCE_NUMBER,
STAT_NAME,
value
FROM DBA_HIST_OSSTAT
where dbid = &DBID
and snap_id between &SNAP_ID_MIN and &SNAP_ID_MAX
union all
SELECT SNAP_ID,
INSTANCE_NUMBER,
PARAMETER_NAME STAT_NAME,
to_number(VALUE) value
FROM DBA_HIST_PARAMETER
where dbid = &DBID
and snap_id between &SNAP_ID_MIN and &SNAP_ID_MAX
and PARAMETER_NAME = 'cpu_count'
)
GROUP BY snap_id,
INSTANCE_NUMBER
ORDER BY snap_id,
INSTANCE_NUMBER;
prompt
prompt
-- ##############################################################################################
REPHEADER PAGE LEFT '~~BEGIN-MAIN-METRICS~~'
REPFOOTER PAGE LEFT '~~END-MAIN-METRICS~~'
select snap_id "snap",num_interval "dur_m", end_time "end",inst "inst",
max(decode(metric_name,'Host CPU Utilization (%)', average,null)) "os_cpu",
max(decode(metric_name,'Host CPU Utilization (%)', maxval,null)) "os_cpu_max",
max(decode(metric_name,'Host CPU Utilization (%)', STANDARD_DEVIATION,null)) "os_cpu_sd",
max(decode(metric_name,'Database Wait Time Ratio', round(average,1),null)) "db_wait_ratio",
max(decode(metric_name,'Database CPU Time Ratio', round(average,1),null)) "db_cpu_ratio",
max(decode(metric_name,'CPU Usage Per Sec', round(average/100,3),null)) "cpu_per_s",
max(decode(metric_name,'CPU Usage Per Sec', round(STANDARD_DEVIATION/100,3),null)) "cpu_per_s_sd",
max(decode(metric_name,'Host CPU Usage Per Sec', round(average/100,3),null)) "h_cpu_per_s",
max(decode(metric_name,'Host CPU Usage Per Sec', round(STANDARD_DEVIATION/100,3),null)) "h_cpu_per_s_sd",
max(decode(metric_name,'Average Active Sessions', average,null)) "aas",
max(decode(metric_name,'Average Active Sessions', STANDARD_DEVIATION,null)) "aas_sd",
max(decode(metric_name,'Average Active Sessions', maxval,null)) "aas_max",
max(decode(metric_name,'Database Time Per Sec', average,null)) "db_time",
max(decode(metric_name,'Database Time Per Sec', STANDARD_DEVIATION,null)) "db_time_sd",
max(decode(metric_name,'SQL Service Response Time', average,null)) "sql_res_t_cs",
max(decode(metric_name,'Background Time Per Sec', average,null)) "bkgd_t_per_s",
max(decode(metric_name,'Logons Per Sec', average,null)) "logons_s",
max(decode(metric_name,'Current Logons Count', average,null)) "logons_total",
max(decode(metric_name,'Executions Per Sec', average,null)) "exec_s",
max(decode(metric_name,'Hard Parse Count Per Sec', average,null)) "hard_p_s",
max(decode(metric_name,'Logical Reads Per Sec', average,null)) "l_reads_s",
max(decode(metric_name,'User Commits Per Sec', average,null)) "commits_s",
max(decode(metric_name,'Physical Read Total Bytes Per Sec', round((average)/1024/1024,1),null)) "read_mb_s",
max(decode(metric_name,'Physical Read Total Bytes Per Sec', round((maxval)/1024/1024,1),null)) "read_mb_s_max",
max(decode(metric_name,'Physical Read Total IO Requests Per Sec', average,null)) "read_iops",
max(decode(metric_name,'Physical Read Total IO Requests Per Sec', maxval,null)) "read_iops_max",
max(decode(metric_name,'Physical Reads Per Sec', average,null)) "read_bks",
max(decode(metric_name,'Physical Reads Direct Per Sec', average,null)) "read_bks_direct",
max(decode(metric_name,'Physical Write Total Bytes Per Sec', round((average)/1024/1024,1),null)) "write_mb_s",
max(decode(metric_name,'Physical Write Total Bytes Per Sec', round((maxval)/1024/1024,1),null)) "write_mb_s_max",
max(decode(metric_name,'Physical Write Total IO Requests Per Sec', average,null)) "write_iops",
max(decode(metric_name,'Physical Write Total IO Requests Per Sec', maxval,null)) "write_iops_max",
max(decode(metric_name,'Physical Writes Per Sec', average,null)) "write_bks",
max(decode(metric_name,'Physical Writes Direct Per Sec', average,null)) "write_bks_direct",
max(decode(metric_name,'Redo Generated Per Sec', round((average)/1024/1024,1),null)) "redo_mb_s",
max(decode(metric_name,'DB Block Gets Per Sec', average,null)) "db_block_gets_s",
max(decode(metric_name,'DB Block Changes Per Sec', average,null)) "db_block_changes_s",
max(decode(metric_name,'GC CR Block Received Per Second', average,null)) "gc_cr_rec_s",
max(decode(metric_name,'GC Current Block Received Per Second', average,null)) "gc_cu_rec_s",
max(decode(metric_name,'Global Cache Average CR Get Time', average,null)) "gc_cr_get_cs",
max(decode(metric_name,'Global Cache Average Current Get Time', average,null)) "gc_cu_get_cs",
max(decode(metric_name,'Global Cache Blocks Corrupted', average,null)) "gc_bk_corrupted",
max(decode(metric_name,'Global Cache Blocks Lost', average,null)) "gc_bk_lost",
max(decode(metric_name,'Active Parallel Sessions', average,null)) "px_sess",
max(decode(metric_name,'Active Serial Sessions', average,null)) "se_sess",
max(decode(metric_name,'Average Synchronous Single-Block Read Latency', average,null)) "s_blk_r_lat",
max(decode(metric_name,'Cell Physical IO Interconnect Bytes', round((average)/1024/1024,1),null)) "cell_io_int_mb",
max(decode(metric_name,'Cell Physical IO Interconnect Bytes', round((maxval)/1024/1024,1),null)) "cell_io_int_mb_max"
from(
select snap_id,num_interval,to_char(end_time,'YY/MM/DD HH24:MI') end_time,instance_number inst,metric_name,round(average,1) average,
round(maxval,1) maxval,round(standard_deviation,1) standard_deviation
from dba_hist_sysmetric_summary
where dbid = &DBID
and snap_id between &SNAP_ID_MIN and &SNAP_ID_MAX
--and snap_id = 920
--and instance_number = 4
and metric_name in ('Host CPU Utilization (%)','CPU Usage Per Sec','Host CPU Usage Per Sec','Average Active Sessions','Database Time Per Sec',
'Executions Per Sec','Hard Parse Count Per Sec','Logical Reads Per Sec','Logons Per Sec',
'Physical Read Total Bytes Per Sec','Physical Read Total IO Requests Per Sec','Physical Reads Per Sec','Physical Write Total Bytes Per Sec',
'Redo Generated Per Sec','User Commits Per Sec','Current Logons Count','DB Block Gets Per Sec','DB Block Changes Per Sec',
'Database Wait Time Ratio','Database CPU Time Ratio','SQL Service Response Time','Background Time Per Sec',
'Physical Write Total IO Requests Per Sec','Physical Writes Per Sec','Physical Writes Direct Per Sec','Physical Writes Direct Lobs Per Sec',
'Physical Reads Direct Per Sec','Physical Reads Direct Lobs Per Sec',
'GC CR Block Received Per Second','GC Current Block Received Per Second','Global Cache Average CR Get Time','Global Cache Average Current Get Time',
'Global Cache Blocks Corrupted','Global Cache Blocks Lost',
'Active Parallel Sessions','Active Serial Sessions','Average Synchronous Single-Block Read Latency','Cell Physical IO Interconnect Bytes'
)
)
group by snap_id,num_interval, end_time,inst
order by snap_id, end_time,inst;
prompt
prompt
-- ##############################################################################################
column display_value format a50
set wrap off
REPHEADER PAGE LEFT '~~BEGIN-DATABASE-PARAMETERS~~'
REPFOOTER PAGE LEFT '~~END-DATABASE-PARAMETERS~~'
with inst as (
select min(instance_number) inst_num
from dba_hist_snapshot
where dbid = &DBID
and snap_id BETWEEN to_number(&SNAP_ID_MIN) and to_number(&SNAP_ID_MAX))
SELECT PARAMETER_NAME,VALUE
FROM DBA_HIST_PARAMETER
WHERE dbid = &DBID
AND snap_id = (SELECT MAX(snap_id) FROM dba_hist_osstat WHERE dbid = &DBID AND instance_number = (select inst_num from inst))
AND instance_number = (select inst_num from inst)
and PARAMETER_NAME not in ('local_listener','service_names','remote_listener','db_domain','cluster_interconnects')
ORDER BY 1;
prompt
prompt
-- ##############################################################################################
REPHEADER PAGE LEFT '~~BEGIN-AVERAGE-ACTIVE-SESSIONS~~'
REPFOOTER PAGE LEFT '~~END-AVERAGE-ACTIVE-SESSIONS~~'
column wait_class format a20
SELECT snap_id,
wait_class,
ROUND (SUM (pSec), 2) avg_sess
FROM
(SELECT snap_id,
wait_class,
p_tmfg / 1000000 / ela pSec
FROM
(SELECT (CAST (s.end_interval_time AS DATE) - CAST (s.begin_interval_time AS DATE)) * 24 *
3600 ela,
s.snap_id,
wait_class,
e.event_name,
CASE WHEN s.begin_interval_time = s.startup_time
-- compare to e.time_waited_micro_fg for 10.2?
THEN e.&T_WAITED_MICRO_COL
ELSE e.&T_WAITED_MICRO_COL - lag (e.&T_WAITED_MICRO_COL) over (partition BY
event_id, e.dbid, e.instance_number, s.startup_time order by e.snap_id)
END p_tmfg
FROM dba_hist_snapshot s,
dba_hist_system_event e
WHERE s.dbid = e.dbid
AND s.dbid = to_number(&DBID)
AND e.dbid = to_number(&DBID)
AND s.instance_number = e.instance_number
AND s.snap_id = e.snap_id
AND s.snap_id BETWEEN to_number(&SNAP_ID_MIN) and to_number(&SNAP_ID_MAX)
AND e.snap_id BETWEEN to_number(&SNAP_ID_MIN) and to_number(&SNAP_ID_MAX)
AND e.wait_class != 'Idle'
UNION ALL
SELECT (CAST (s.end_interval_time AS DATE) - CAST (s.begin_interval_time AS DATE)) * 24 *
3600 ela,
s.snap_id,
t.stat_name wait_class,
t.stat_name event_name,
CASE WHEN s.begin_interval_time = s.startup_time
THEN t.value
ELSE t.value - lag (value) over (partition BY stat_id, t.dbid, t.instance_number,
s.startup_time order by t.snap_id)
END p_tmfg
FROM dba_hist_snapshot s,
dba_hist_sys_time_model t
WHERE s.dbid = t.dbid
AND s.dbid = to_number(&DBID)
AND s.instance_number = t.instance_number
AND s.snap_id = t.snap_id
AND s.snap_id BETWEEN to_number(&SNAP_ID_MIN) and to_number(&SNAP_ID_MAX)
AND t.snap_id BETWEEN to_number(&SNAP_ID_MIN) and to_number(&SNAP_ID_MAX)
AND t.stat_name = 'DB CPU'
)
where p_tmfg is not null
)
GROUP BY snap_id,
wait_class
ORDER BY snap_id,
wait_class;
prompt
prompt
-- ##############################################################################################
REPHEADER OFF
REPFOOTER OFF
define HISTOGRAM_QUERY = ' '
column :HISTOGRAM_QUERY_1 new_value HISTOGRAM_QUERY noprint
variable HISTOGRAM_QUERY_1 varchar2(4000)
begin
if :DB_VERSION_1 >= 11.1 then
:HISTOGRAM_QUERY_1 := q'! snap_id,wait_class,event_name,wait_time_milli,sum(wait_count) wait_count
from(
SELECT s.snap_id,
wait_class,
h.event_name,
wait_time_milli,
CASE WHEN s.begin_interval_time = s.startup_time
THEN h.wait_count
ELSE h.wait_count - lag (h.wait_count) over (partition BY
event_id,wait_time_milli, h.dbid, h.instance_number, s.startup_time order by h.snap_id)
END wait_count
FROM dba_hist_snapshot s,
DBA_HIST_event_histogram h
WHERE s.dbid = h.dbid
AND s.dbid = &DBID
AND s.instance_number = h.instance_number