|
| 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 | + |
0 commit comments