Skip to content

Commit 8178374

Browse files
Alexey MoseyevAlexey Moseyev
Alexey Moseyev
authored and
Alexey Moseyev
committed
Inital commit. Added oramonitor__xxx.sql files
1 parent 0cbaa56 commit 8178374

8 files changed

+672
-0
lines changed

oramonitor__1_DB_ash.sql

+87
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,87 @@
1+
-- Copyright (c) 2017 AVM Consulting inc. All Rights Reserved.
2+
-- Licensed under the GNU General Public License v3 or any later version
3+
-- See license text at http://www.gnu.org/licenses/gpl.txt
4+
5+
set lines 1000
6+
set verify off
7+
set feedback off
8+
define inst_clause='and inst_id in (1,2,3,4,5,6)'
9+
---how long wait between sampels
10+
define seconds_to_monitor=&1
11+
--prompt
12+
--prompt &&inst_clause
13+
prompt
14+
15+
prompt REPORT DESCRIPTION: The Report Shows ASH for last hour from gv$active_session_history and gv$sysmetric_history. (ash based)
16+
prompt
17+
prompt columns CPU+BCPU - Total Cpu (background+user) what oracle asked for.
18+
prompt column CPU_ORA_WAIT - is how much was not satisfied from what oracle askef for..
19+
20+
---remove delay if needed.
21+
exec dbms_lock.sleep(&&seconds_to_monitor);
22+
23+
COLUMN time1 HEADING 'TIME' format a10
24+
COLUMN cpu HEADING 'CPU' format 999.9
25+
COLUMN bcpu HEADING 'BCPU' format 999.9
26+
COLUMN cpu_ora_wait HEADING 'CPU|ORA|WAIT' format 999.9
27+
COLUMN scheduler HEADING 'SCHE|DUL|ER' format 999.9
28+
COLUMN uio HEADING 'UIO' format 999.9
29+
COLUMN sio HEADING 'SIO' format 999.9
30+
COLUMN concurrency HEADING 'CON|CURR|ENCY' format 999.9
31+
COLUMN application HEADING 'APP|LICA|TION' format 999.9
32+
COLUMN COMMIT HEADING 'COMM|IT' format 999.9
33+
COLUMN configuration HEADING 'CONFI|GURA|TION' format 999.9
34+
COLUMN administrative HEADING 'ADMI|NISTR|ATIVE' format 999.9
35+
COLUMN network HEADING 'NETW|ORK' format 999.9
36+
COLUMN queueing HEADING 'QUEU|EING' format 999.9
37+
COLUMN clust HEADING 'CLUS|TER' format 999.9
38+
COLUMN other HEADING 'OTHER' format 999.9
39+
select * from
40+
(
41+
select * from
42+
(
43+
SELECT to_char(sysmetric_history.sample_time,'hh24:mi:ss') time1,
44+
round(cpu/60,1) AS cpu,
45+
round(bcpu/60,1) AS bcpu,
46+
round(DECODE(SIGN((cpu+bcpu)/60-cpu_ora_consumed), -1, 0, ((cpu+bcpu)/60-cpu_ora_consumed)),1) AS cpu_ora_wait,
47+
round(scheduler/60,1) AS scheduler,
48+
round(uio/60,1) AS uio,
49+
round(sio/60,1) AS sio,
50+
round(concurrency/60,1) AS concurrency,
51+
round(application/60,1) AS application,
52+
round(COMMIT/60,2) AS COMMIT,
53+
round(configuration/60,1) AS configuration,
54+
round(administrative/60,1) AS administrative,
55+
round(network/60,1) AS network,
56+
round(queueing/60,1) AS queueing,
57+
round(clust/60,1) AS clust,
58+
round(other/60,1) AS other
59+
FROM
60+
(SELECT
61+
TRUNC(sample_time,'MI') AS sample_time,
62+
DECODE(session_state,'ON CPU',DECODE(session_type,'BACKGROUND','BCPU','ON CPU'), wait_class) AS wait_class
63+
FROM gv$active_session_history
64+
WHERE sample_time>sysdate-INTERVAL '1' HOUR
65+
AND sample_time<=TRUNC(SYSDATE,'MI')
66+
&&inst_clause
67+
) ash
68+
PIVOT (COUNT(*) FOR wait_class IN ('ON CPU' AS cpu,'BCPU' AS bcpu,'Scheduler' AS scheduler,'User I/O' AS uio,'System I/O' AS sio,
69+
'Concurrency' AS concurrency,'Application' AS application,'Commit' AS COMMIT,'Configuration' AS configuration,
70+
'Administrative' AS administrative,'Network' AS network,'Queueing' AS queueing,'Cluster' AS clust,'Other' AS other)) ash,
71+
(SELECT
72+
TRUNC(begin_time,'MI') AS sample_time,
73+
sum(VALUE/100) AS cpu_ora_consumed
74+
FROM gv$sysmetric_history
75+
WHERE GROUP_ID=2
76+
AND metric_name='CPU Usage Per Sec'
77+
&&inst_clause
78+
group by TRUNC(begin_time,'MI')) sysmetric_history
79+
WHERE ash.sample_time (+)=sysmetric_history.sample_time
80+
ORDER BY sysmetric_history.sample_time desc
81+
)
82+
where rownum<28
83+
)
84+
order by time1
85+
;
86+
exit
87+

oramonitor__2_DB_top_events.sql

+70
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,70 @@
1+
-- Copyright (c) 2017 AVM Consulting inc. All Rights Reserved.
2+
-- Licensed under the GNU General Public License v3 or any later version
3+
-- See license text at http://www.gnu.org/licenses/gpl.txt
4+
5+
set lines 1000
6+
set pages 30
7+
set verify off
8+
set feedback off
9+
define inst_clause='and inst_id in (1,2,3,4,5,6) '
10+
---how long wait between sampels
11+
define seconds_to_monitor=&1
12+
prompt
13+
--prompt &&inst_clause
14+
--prompt
15+
16+
prompt REPORT DESCRIPTION: The Report Shows Top EVENTS for last &&seconds_to_monitor seconds (from gv$active_session_history). (ash based)
17+
prompt
18+
prompt only "ACT_SESS_CNT" are per event. all other metrics are GLOBAL.
19+
prompt "ON CPU" is what oracle asked for (not what it got)
20+
21+
---remove delay if needed.
22+
exec dbms_lock.sleep(&&seconds_to_monitor);
23+
24+
COLUMN event1 HEADING 'EVENT' format a45 trunc
25+
COLUMN active_sess HEADING 'ACTV|SESS|CNT' format 999.9
26+
COLUMN sql_cnt HEADING 'ON|SQL|CNT' format 999.9
27+
COLUMN plsql_cnt HEADING 'ON|PLSQL|CNT' format 999.9
28+
COLUMN java_cnt HEADING 'ON|JAVA|CNT' format 999.9
29+
COLUMN parse_cnt HEADING 'ON|PARSE|CNT' format 999.9
30+
COLUMN seq_load_cnt HEADING 'SEQ|LOAD|CNT' format 999.9
31+
COLUMN blocked_cnt HEADING 'BLCKD|CNT' format 999.9
32+
COLUMN fts_cnt HEADING 'FTS|CNT' format 999.9
33+
COLUMN act_tot_cnt HEADING 'TOT|ACTV|SESS' format 999.9
34+
35+
select * from
36+
(
37+
select * from
38+
(
39+
select case when event is null then session_state else event end event1,
40+
round(count(1)/max(samples_cnt),1) active_sess,
41+
round(max(sql_cnt)/max(samples_cnt),1) sql_cnt,
42+
round(max(plsql_cnt)/max(samples_cnt),1) plsql_cnt,
43+
round(max(java_cnt)/max(samples_cnt),1) java_cnt,
44+
round(max(parse_cnt)/max(samples_cnt),1) parse_cnt,
45+
round(max(seq_load_cnt)/max(samples_cnt),1) seq_load_cnt,
46+
round(max(blocked_cnt)/max(samples_cnt),1) blocked_cnt,
47+
round(max(fts_cnt)/max(samples_cnt),1) fts_cnt,
48+
round(max(act_sess_cnt)/max(samples_cnt),1) act_tot_cnt
49+
from (
50+
select SESSION_STATE,event,
51+
&&seconds_to_monitor samples_cnt, ---how many samples total should be done. (should be every seconds. but if acvitity is low some can be skiped. this counts even for skipped samples)
52+
count(1) over (PARTITION by null) act_sess_cnt,
53+
sum(case when s.in_sql_execution='Y' then 1 else 0 end) over (PARTITION by null) sql_cnt,
54+
sum(case when s.in_plsql_execution='Y' or s.in_plsql_rpc='Y' or s.in_plsql_compilation='Y' then 1 else 0 end) over (PARTITION by null) plsql_cnt,
55+
sum(case when s.in_java_execution='Y' then 1 else 0 end) over (PARTITION by null) java_cnt,
56+
sum(case when s.in_hard_parse='Y' then 1 else 0 end) over (PARTITION by null) parse_cnt,
57+
sum(case when s.in_sequence_load='Y' then 1 else 0 end) over (PARTITION by null) seq_load_cnt,
58+
sum(case when s.blocking_inst_id is not null then 1 else 0 end) over (PARTITION by null) blocked_cnt,
59+
sum(case when s.sql_plan_operation='TABLE ACCESS' and s.sql_plan_options='FULL' then 1 else 0 end) over (PARTITION by null) fts_cnt
60+
from gV$ACTIVE_SESSION_HISTORY s
61+
where SAMPLE_TIME>sysdate-(&&seconds_to_monitor/24/60/60) ---for last X seconds.
62+
&&inst_clause
63+
)
64+
group by SESSION_STATE,event
65+
order by active_sess desc
66+
)
67+
where rownum<7
68+
)
69+
;
70+
exit
+57
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,57 @@
1+
-- Copyright (c) 2017 AVM Consulting inc. All Rights Reserved.
2+
-- Licensed under the GNU General Public License v3 or any later version
3+
-- See license text at http://www.gnu.org/licenses/gpl.txt
4+
5+
set lines 200
6+
set verify off
7+
set feedback off
8+
---set list of RAC instances to look at.
9+
define inst_clause='and inst_id in (1,2,3,4,5,6)'
10+
---how long wait between sampels
11+
define seconds_to_monitor=&1
12+
prompt
13+
--prompt &&inst_clause
14+
--prompt
15+
16+
prompt REPORT DESCRIPTION: The Report Shows latencines/counts for last &&seconds_to_monitor seconds for major events. (stats based)
17+
prompt
18+
19+
set serveroutput on
20+
declare
21+
wait_sec number:=&&seconds_to_monitor;
22+
type num_list_type is table of number index by pls_integer;
23+
type varchar_list_type is table of varchar2(100) index by pls_integer;
24+
totw1 num_list_type;
25+
totw2 num_list_type;
26+
wtt1 num_list_type;
27+
wtt2 num_list_type;
28+
p_event_name varchar_list_type;
29+
begin
30+
p_event_name(1) :='db file sequential read';
31+
p_event_name(2) :='db file scattered read';
32+
p_event_name(3) :='direct path read';
33+
p_event_name(4) :='log file sync';
34+
p_event_name(5) :='log file parallel write';
35+
p_event_name(6) :='Disk file operations I/O';
36+
p_event_name(7) :='gc current grant busy';
37+
p_event_name(8) :='gc current block 2-way';
38+
p_event_name(9) :='gc cr block 2-way';
39+
for i in 1..p_event_name.count loop
40+
select sum(total_waits),sum(time_waited_micro) into totw1(i),wtt1(i) from gv$system_event where event=p_event_name(i) &&inst_clause;
41+
end loop;
42+
dbms_lock.sleep(wait_sec);
43+
for i in 1..p_event_name.count loop
44+
select sum(total_waits),sum(time_waited_micro) into totw2(i),wtt2(i) from gv$system_event where event=p_event_name(i) &&inst_clause;
45+
end loop;
46+
47+
for i in 1..p_event_name.count loop
48+
dbms_output.put_line
49+
(
50+
rpad(p_event_name(i), 35,' ')||' = '
51+
||rpad(round((wtt2(i)-wtt1(i))/(case totw2(i)-totw1(i) when 0 then 1 else totw2(i)-totw1(i) end)/1000,1),10,' ')||' ms. Waits: '
52+
||rpad(totw2(i)-totw1(i),6,' ')||' Waits/sec: '||(round(totw2(i)-totw1(i))/wait_sec)
53+
);
54+
end loop;
55+
end;
56+
/
57+
exit

oramonitor__4_DB_main_sys_stats.sql

+54
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,54 @@
1+
-- Copyright (c) 2017 AVM Consulting inc. All Rights Reserved.
2+
-- Licensed under the GNU General Public License v3 or any later version
3+
-- See license text at http://www.gnu.org/licenses/gpl.txt
4+
5+
set lines 200
6+
set verify off
7+
set feedback off
8+
---set list of RAC instances to look at.
9+
define inst_clause='and inst_id in (1,2,3,4,5,6)'
10+
---how long wait between sampels
11+
define seconds_to_monitor=&1
12+
prompt
13+
--prompt &&inst_clause
14+
--prompt
15+
16+
prompt REPORT DESCRIPTION: The Report Shows major stats for last &&seconds_to_monitor seconds (stats based)
17+
prompt
18+
19+
set serveroutput on
20+
declare
21+
wait_sec number:=&&seconds_to_monitor;
22+
type num_list_type is table of number index by pls_integer;
23+
type varchar_list_type is table of varchar2(100) index by pls_integer;
24+
totw1 num_list_type;
25+
totw2 num_list_type;
26+
wtt1 num_list_type;
27+
wtt2 num_list_type;
28+
p_event_name varchar_list_type;
29+
begin
30+
p_event_name(1) :='redo size';
31+
p_event_name(2) :='user commits';
32+
p_event_name(3) :='physical read bytes';
33+
p_event_name(4) :='physical read total bytes';
34+
p_event_name(5) :='physical write total bytes';
35+
p_event_name(6) :='physical read total IO requests';
36+
p_event_name(7) :='physical write total IO requests';
37+
p_event_name(8) :='gc cr blocks received';
38+
p_event_name(9) :='gc current blocks received';
39+
40+
for i in 1..p_event_name.count loop
41+
select sum(value) into totw1(i) from gv$sysstat where name=p_event_name(i) &&inst_clause;
42+
end loop;
43+
dbms_lock.sleep(wait_sec);
44+
for i in 1..p_event_name.count loop
45+
select sum(value) into totw2(i) from gv$sysstat where name=p_event_name(i) &&inst_clause;
46+
end loop;
47+
48+
for i in 1..p_event_name.count loop
49+
dbms_output.put_line(rpad(p_event_name(i), 35,' ')||' = '||rpad(round((totw2(i)-totw1(i))/(wait_sec),1),14,' ')||' /sec.');
50+
end loop;
51+
dbms_output.put_line('--');
52+
end;
53+
/
54+
exit

0 commit comments

Comments
 (0)