08. Statspack / AWR
(1) Statspack / AWR 기본 사용법
SQL>@?/rdbms/admin/awrrpt <--- ? AWR SQL>@?/rdbms/admin/spreport <--- ? Statspack |
select to_char(min(s.begin_interval_time), 'hh24:mi') begin , to_char(min(s.end_interval_time),'hh24:mi') end , sum(b.value-a.value) "execute count" from dba_hist_sysstat a, dba_hist_sysstat b, dba_hist_snapshot s where s.instance_number = &instance_number and s.snap_id between &gegin_snap and &end_snap and a.stat_name = 'execute count' and b.stat_id = a.stat_id and b.snap_id = s.snap_id and a.snap_id = b.snap_id - 1 and a.instance_number = s.instance_number group by s.snap_id order by s.snap_id; |
(2) Statspack / AWR 리포트 분석
Loar Profile | Per Second | Per Transaction |
Redo size : | 140,839.60 | 5,345.24 |
Logical reads : | 47,768.26 | 1,812.93 |
Block changes : | 711.34 | 27.00 |
Physical reads : | 736.69 | 27.96 |
Physical writes : | 84.69 | 3.21 |
User calls : | 2,401.63 | 91.15 |
Parses : | 412.66 | 15.66 |
Hard parses : | 1.49 | 0.06 |
Sorts : | 138.94 | 5.27 |
Logons : | 0.79 | 0.03 |
Executes : | 1,187.18 | 45.06 |
Transactions : | 26.35 |
select value rsiz from v$sysstat where name = 'redo size'; select value gets from v$sysstat where name = 'session logical reads'; select value chng from v$sysstat where name = 'db block changes'; select value phyr from v$sysstat where name = 'physical reads'; select value phyw from v$sysstat where name = 'physical writes'; select value ucal from v$sysstat where name = 'user calls'; select value prse from v$sysstat where name = 'parse count (total)'; select value hprse from v$sysstat where name = 'parse count (hard)'; select srtm + srtd from (select value srtm from v$sysstat where name = 'sorts (memory)' ), (select value srtd from v$sysstat where name = 'sorts (disk)' ); select value logc from v$sysstat where name = 'logons cumulative'; select value exe from v$sysstat where name = 'execute count'; select ucom + urol from (select value ucom from v$sysstat where name = 'user calls'), (select value urol from v$sysstat where name = 'user rollbacks'); |
% Blocks changed per Read : 1.49 | Recursive Call % : 35.33 |
Rollback per transaction % : 3.81 | Rows per Sort : 274.24 |
select round(100*chng/gets, 2) "% Blocks changed per Read" from (select value chng from v$sysstat where name = 'db block changes'), (select value gets from v$sysstat where name = 'session logical reads'); |
select round(100*urol/(ucom+urol), 2) "Rollback per transaction %" from (select value ucom from v$sysstat where name = 'user calls'), (select value urol from v$sysstat where name = 'user rollbaks'); |
select round(100*recr/(recr+ucal), 2) "Recursive Call %" from (select value recr from v$sysstat where name = 'recursive calls'), (select value ucal from v$sysstat where name = 'user calls'); |
select decode((srtm+srtd), 0, to_number(null), round(srtr/(srtm+srtd),2)) from (select value srtm from v$sysstat where name = 'sorts (memory)'), (select value srtd from v$sysstat where name = 'sorts (disk)'), (select value srtr from v$sysstat where name = 'sorts (rows)'); |
Instance Efficiency Percentages (Target 100%) | |||
Buffer Nowait % : | 99.99 | Redo NoWait % : | 100.00 |
Buffer Hit % : | 98.71 | In-memory Sort % : | 100.00 |
Library Hit % : | 99.67 | Soft Parse % : | 99.64 |
Execute to Parse % : | 65.24 | Latch Hit % : | 99.89 |
Parse CPU to Parse Elapsd % : | 0.85 | % Non-Parse CPU : | 97.96 |
Shared Pool Statistics | Begin | End |
Memory Usage % : | 69.20 | 93.96 |
% SQL with executions > 1 : | 93.40 | 98.29 |
% Memory for SQL w/exec > 1 | 73.36 | 98.99 |
Top 5 Timed Events | Avg Wait (ms) | %Total Call Time | |||
~~~~~~~~~~~~~~~~ | |||||
Event | Waits | Time(s) | Wait Class | ||
Latch free | 2,169,850 | 596,104 | 275 | 70.2 | Other |
Latch: shared pool | 1,050,870 | 262,298 | 250 | 30.9 | Concurrenc |
Latch: library cache | 868,920 | 219,076 | 252 | 25.8 | Concurrenc |
Db file sequential read | 18,869,172 | 108,189 | 6 | 12.7 | User I/O |
CPU time | 48,991 | 5.8 |