행위

"ORACLE 모니터링"의 두 판 사이의 차이

DB CAFE

(오래 걸리는 세션 정보)
4번째 줄: 4번째 줄:
 
----
 
----
 
== 세션 정보 ==
 
== 세션 정보 ==
 +
=== User 별 Session 정보 조회 ===
 +
* V$SESSION
 +
* V$PROCESS
 +
<source lang="sql">
 +
SELECT S.USERNAME
 +
    , S.SID
 +
    , S.SERIAL#
 +
    , P.SPID
 +
    , S.OSUSER
 +
    , S.MACHINE
 +
    , S.PROGRAM
 +
    , TO_CHAR(S.LOGON_TIME, 'MM/DD HH24:MI') "LOGON_TIME"
 +
    , ROUND(S.LAST_CALL_ET / 60) "IDLE"
 +
  FROM V$SESSION S
 +
    , V$PROCESS P
 +
WHERE S.PADDR = P.ADDR
 +
  AND S.USERNAME LIKE UPPER('&DBUSER%')
 +
ORDER BY 9;
 +
</source>
  
 
=== 세션 죽이기(SID,SERAIL#) ===
 
=== 세션 죽이기(SID,SERAIL#) ===
12번째 줄: 31번째 줄:
 
</source>
 
</source>
  
=== 오라클 세션과 관련된 테이블 ===
+
==== 현재 TOP  세션 gv$session ====
* v$session
+
<source lang=sql>
<source lang="sql">
+
select inst_id||'_'||sid||' '||serial# inst_sid_ser,
  select count(*)  
+
    username||case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username,
  from v$session  
+
    sql_id sql_id,
  where machine ='머신이름'  
+
    round((sysdate-sql_exec_start)*24*3600,1) sql_dT,
    and schemaname ='스키마이름'
+
        last_call_et call_dT,
 +
    case state when 'WAITING' then round(wait_time_micro/1000000,2) else round(time_since_last_wait_micro/1000000,2) end W_dT,
 +
        decode(state,'WAITING',event,'CPU') event,
 +
    service_name||' '||substr(module,1,20)||' '||ACTION serv_mod_action, 
 +
          nullif(row_wait_obj#,-1) obj#,decode(taddr,null,null,'NN') tr
 +
from gv$session
 +
where ((state='WAITING' and wait_class<>'Idle') or (state<>'WAITING' and status='ACTIVE'))
 +
      --and audsid != to_number(sys_context('USERENV','SESSIONID')) -- this is clean but does not work on ADG so replaced by following line
 +
      and (machine,port) <> (select machine,port from v$session where sid=sys_context('USERENV','SID')) --workaround for ADG
 +
order by inst_id,sql_id
 
</source>
 
</source>
  
=== 현재 커서 수 확인 ===
+
=== 오래 걸리는  세션 정보 ===
* V$OPEN_CURSOR
 
* v$session_wait
 
* v$transaction
 
  
 +
==== 현재 작업중인 세션 정보 V$SESSION_LONGOPS ====
 +
* V$SESSION_LONGOPS
 +
* V$SESSION
 +
<source lang=sql>
 +
SELECT B.USERNAME, A.SID, B.OPNAME, B.TARGET
 +
    , ROUND(B.SOFAR*100/B.TOTALWORK,0) || '%' AS "%DONE", B.TIME_REMAINING
 +
    , TO_CHAR(B.START_TIME,'YYYY/MM/DD HH24:MI:SS') START_TIME
 +
  FROM V$SESSION_LONGOPS B
 +
    , V$SESSION A
 +
WHERE A.SID = B.SID     
 +
ORDER BY 6 DESC;
 +
</source>
 +
 +
=== 세션당 리소스 사용률 gv$sessmetric ===
 +
* gv$sessmetric
 +
<source lang=sql>
 +
select * from (
 +
  select inst_id, session_id sid, to_char(begin_time,'hh24:mi:ss') begTime, round(intsize_csec/100,0) D_sec,  cpu,         
 +
        physical_reads PhyReads, logical_reads LogicalReads, pga_memory, hard_parses, soft_parses
 +
  from gv$sessmetric
 +
  order by cpu+physical_reads desc
 +
)
 +
where rownum<20
 +
</source>
  
==== sid별 열린커셔 ====
+
=== 대기중인 세션 ===
 +
* v$session_wait
 
<source lang="sql">
 
<source lang="sql">
SELECT sid, count(sid) cursor
+
select *  
  FROM V$OPEN_CURSOR
+
   from v$session_wait;
WHERE user_name = 'ilips'
 
GROUP BY sid
 
ORDER BY cursor DESC;
 
</source>
 
==== sql 별 열린 커서 ====
 
<source lang="sql">
 
SELECT sql_text, count(sid) cnt
 
  FROM v$OPEN_CURSOR
 
GROUP BY sql_text
 
ORDER BY cnt DESC
 
</source>
 
==== 대기 세션 ====
 
* v$session_wait
 
<source lang="sql">
 
select *  
 
   from v$session_wait;
 
 
</source>
 
</source>
  
==== 트랜젝션  중인 세션 ====
+
==== 1시간 이상 idle 상태인 세션 ====
* v$transaction
+
* V$SESSION
* gv$fast_start_transactions
 
  
* USED_UBLK
+
<source lang="sql">
** Number of undo blocks used 사용된 언두 블럭 수
+
SELECT SID
* USED_UREC
+
    , SERIAL#
** Number of undo records used , 사용된 언두 레코드 수
+
    , USERNAME
 +
    , TRUNC(LAST_CALL_ET / 3600, 2) || ' HR' LAST_CALL_ET
 +
  FROM V$SESSION
 +
  WHERE LAST_CALL_ET > 3600
 +
  AND USERNAME IS NOT NULL;
 +
</source>
  
 +
==== Active Session 중 Idle Time이 긴 작업 ====
 +
* V$SESSION
 +
* V$PROCESS
 
<source lang="sql">
 
<source lang="sql">
select sid, serial#, username, taddr, used_ublk, used_urec
+
SELECT VS.SID || ',' || VS.SERIAL# " SID"
   from v$transaction t
+
    , VP.SPID
     , v$session s
+
    , VS.MACHINE
where t.addr = s.taddr;
+
    , VS.PROGRAM
 +
    , VS.MODULE
 +
    , VS.STATUS
 +
    , TO_CHAR(VS.LOGON_TIME, 'MM/DD HH24:MI') LOGIN_TIME
 +
    , ROUND(VS.LAST_CALL_ET / 60) "IDLE"
 +
   FROM V$SESSION VS
 +
     , V$PROCESS VP
 +
WHERE VS.STATUS = 'ACTIVE'
 +
  AND VS.SID NOT IN (1, 2, 3, 4, 5, 6, 7)
 +
  AND VS.PADDR = VP.ADDR ORDER BY 8;  
 
</source>
 
</source>
<source lang="sql">
+
 
select inst_id,addr,start_time,used_ublk,xid
+
==== 사용자 세션 중에서 2시간 이상 idle 상태가 지속되는 세션 kill ====
  from gv$transaction;
+
* V$SESSION
 +
* V$PROCESS
 +
<source lang="sql"> SET PAGESIZE 0 SPOOL KILLIDLE3.SQL
 +
SELECT DISTINCT '!KILL -9 ' || B.SPID, 'ALTER SYSTEM KILL SESSION '''|| A.SID || ',' || A.SERIAL# || ''';'
 +
  FROM V$SESSION A
 +
    , V$PROCESS B
 +
WHERE A.PADDR IN (SELECT S.PADDR
 +
                    FROM V$SESSION S
 +
                    WHERE STATUS = 'INACTIVE'
 +
                    GROUP BY  S.PADDR
 +
                  HAVING MIN(ROUND(LAST_CALL_ET / 60)) > 120)
 +
  AND A.PADDR = B.ADDR AND A.STATUS = 'INACTIVE';
 +
SPOOL OFF
 
</source>
 
</source>
 +
 +
==== 트랜젝션 중인 세션 ====
 +
* v$transaction
 +
* gv$fast_start_transactions
 +
 +
* USED_UBLK
 +
**  Number of undo blocks used ,  사용된 언두 블럭 수
 +
* USED_UREC
 +
**  Number of undo records used , 사용된 언두 레코드 수
 +
 +
<source lang="sql">
 +
select sid, serial#, username, taddr, used_ublk, used_urec
 +
  from v$transaction t
 +
    , v$session s
 +
where t.addr = s.taddr;
 +
</source>
 +
 +
<source lang="sql">
 +
select inst_id,addr,start_time,used_ublk,xid
 +
  from gv$transaction;
 +
</source>
 +
 
<source lang="sql">
 
<source lang="sql">
 
select inst_id,state,undoblocksdone,undoblockstotal,xid  
 
select inst_id,state,undoblocksdone,undoblockstotal,xid  
 
  from gv$fast_start_transactions;
 
  from gv$fast_start_transactions;
 
</source>
 
</source>
 +
 
<source lang="sql">
 
<source lang="sql">
 
SELECT sess.sid, sess.status, sess.username, machine, sql_id, prev_sql_id, trans.USED_UBLK, trans.start_date
 
SELECT sess.sid, sess.status, sess.username, machine, sql_id, prev_sql_id, trans.USED_UBLK, trans.start_date
79번째 줄: 164번째 줄:
 
</source>
 
</source>
  
=== 연결되어 있는 OS 사용자 및 프로그램 조회 ===
+
==== 연결되어 있는 OS 사용자 및 프로그램 조회 ====
 
* V$SESSION  
 
* V$SESSION  
  
94번째 줄: 179번째 줄:
 
</source>
 
</source>
  
=== 락 모니터링 ===
+
==== Session별 사용 명령어 ====
==== V$LOCK 을 사용한 잠금 경합 모니터링 ====
+
* V$SESSION SESS
<source lang="sql">
+
* V$SESSTAT STAT
SELECT S.USERNAME, S.SID, S.SERIAL#, S.LOGON_TIME,
+
* V$STATNAME NAME
    DECODE(L.TYPE, 'TM', 'TABLE LOCK',
+
* V$PROCESS PROC
                  'TX', 'ROW LOCK',
 
            NULL) "LOCK LEVEL",
 
    O.OWNER, O.OBJECT_NAME, O.OBJECT_TYPE
 
FROM V$SESSION S, V$LOCK L, DBA_OBJECTS O
 
WHERE S.SID = L.SID
 
AND O.OBJECT_ID = L.ID1
 
AND S.USERNAME IS NOT NULL
 
</source>
 
 
  
==== 락이 걸린 세션 상세 보기 ====
 
 
<source lang="sql">
 
<source lang="sql">
SELECT A.SID, A.SERIAL#,A.USERNAME,A.PROCESS,B.OBJECT_NAME
+
SELECT SESS.SID
     , DECODE(C.LMODE,2,'RS',3,'RX',4,'S',5,'SRX',8,'X','NO') "TABLE LOCK"
+
    , SESS.SERIAL#
    , DECODE (A.COMMAND,2,'INSERT',3,'SELECT',6,'UPDATE',7,'DELETE',12,'DROP TABLE',26,'LOCK TABLE','UNKNOWN') "SQL"
+
    , SUBSTR(SESS.USERNAME, 1, 10) "USER NAME"
    , DECODE(A.LOCKWAIT, NULL,'NO WAIT','WAIT') "STATUS"
+
    , SUBSTR(OSUSER, 1, 11) "OS USER"
  FROM V$SESSION A,DBA_OBJECTS B, V$LOCK C
+
    , SUBSTR(SESS.MACHINE, 1, 15) "MACHINE NAME"
WHERE A.SID=C.SID
+
    , STATUS
  AND B.OBJECT_ID=C.ID1
+
     , UPPER(
  AND C.TYPE='TM'
+
            DECODE(NVL(COMMAND, 0)
</source>
+
              , 0, '---'
+
              , 1, 'CREATE TABLE'
 
+
              , 2, 'INSERT -'
==== 락이 걸린 세션 간단히 알아보기 ====
+
              , 3, 'SELECT -'
<source lang="sql">
+
              , 4, 'CREATE CLUST'
SELECT A.SID, A.SERIAL#, B.TYPE, C.OBJECT_NAME, A.PROGRAM, A.LOCKWAIT,
+
              , 5, 'ALTER CLUST'
      A.LOGON_TIME, A.PROCESS, A.OSUSER, A.TERMINAL
+
              , 6, 'UPDATE -'
  FROM V$SESSION  A
+
              , 7, 'DELETE -'
    , V$LOCK     B
+
              , 8, 'DROP -'
    , DBA_OBJECTS C
+
              , 9, 'CREATE INDEX'
WHERE A.SID = B.SID
+
              , 10, 'DROP INDEX'
  AND B.ID1 = C.OBJECT_ID
+
              , 11, 'ALTER INDEX'
  AND B.TYPE = 'TM';
+
              , 12, 'DROP TABLE'
</source>
+
              , 13, 'CREATE SEQ'
<source lang="sql">
+
              , 14, 'ALTER SEQ'
SELECT A.SID, A.SERIAL#, A.USERNAME, A.PROCESS, B.OBJECT_NAME
+
              , 15, 'ALTER TABLE'
  FROM V$SESSION A
+
              , 16, 'DROP SEQ'
    , DBA_OBJECTS B, V$LOCK C
+
              , 17, 'GRANT'
  WHERE A.SID=C.SID
+
              , 18, 'REVOKE'
    AND B.OBJECT_ID = C.ID1
+
              , 19, 'CREATE SYN'
    AND C.TYPE = 'TM'
+
              , 20, 'DROP SYN'
</source>
+
              , 21, 'CREATE VIEW'
+
              , 22, 'DROP VIEW'
* 락이 걸린 세션을 찾아 내어 세션을 죽이려고 해도 죽지 않는 경우
+
              , 23, 'VALIDATE IX'
* 아래 쿼리문으로 OS단의 PROCESS ID를 찾아내어 OS에서 죽인다
+
              , 24, 'CREATE PROC'
* kill -9 프로세스아이디
+
              , 25, 'ALTER PROC'
 
+
              , 26, 'LOCK TABLE'
<source lang="sql">
+
              , 27, 'NO OPERATION'
SELECT SUBSTR(S.USERNAME,1,11) "ORACLE USER", P.PID "PROCESS ID"
+
              , 28, 'RENAME'
    , S.SID "SESSION ID", S.SERIAL#, OSUSER "OS USER"
+
              , 29, 'COMMENT'
    , P.SPID "PROC SPID",S.PROCESS "SESS SPID", S.LOCKWAIT "LOCK WAIT"
+
              , 30, 'AUDIT'
  FROM V$PROCESS P
+
              , 31, 'NOAUDIT'
    , V$SESSION S
+
              , 32, 'CREATE DBLINK'
    , V$ACCESS  A
+
              , 33, 'DROP DB LINK'
WHERE A.SID=S.SID
+
              , 34, 'CREATE DATABASE'
  AND P.ADDR=S.PADDR
+
              , 35, 'ALTER DATABASE'
  AND S.USERNAME != 'SYS'
+
              , 36, 'CREATE RBS'
</source>
+
              , 37, 'ALTER RBS'
 
+
              , 38, 'DROP RBS'
* 위 쿼리문의 결과가 있다면 락이 걸린 세션이 있다는것이므로 아래의 쿼리문으로 세션을 죽인다
+
              , 39, 'CREATE TABLESPACE'
<source lang="sql">
+
              , 40, 'ALTER TABLESPACE'
ALTER SYSTEM KILL SESSION '11,39061'
+
              , 41, 'DROP TABLESPACE'
</source>
+
              , 42, 'ALTER SESSION'
+
              , 43, 'ALTER USER'
* alter session으로 죽지않는 프로세스 죽이기
+
              , 44, 'COMMIT'
<source lang="sql">
+
              , 45, 'ROLLBACK'
1.oracle이 설치된 서버에 텔넷으로 root로 접속한다
+
              , 47, 'PL/SQL EXEC'
2.su -오라클계정
+
              , 48, 'SET TRANSACTION'
3.sqlplus '/as sysdba''
+
              , 49, 'SWITCH LOG'
4.connect system/sys
+
              , 50, 'EXPLAIN'
5.ALTER SYSTEM KILL SESSION '137,1723'
+
              , 51, 'CREATE USER'
</source>
+
              , 52, 'CREATE ROLE'
 
+
              , 53, 'DROP USER'
== 오래 걸리는  세션 정보 ==
+
              , 54, 'DROP ROLE'
=== 현재 TOP  세션 gv$session ===
+
              , 55, 'SET ROLE'
<source lang=sql>
+
              , 56, 'CREATE SCHEMA'
select inst_id||'_'||sid||' '||serial# inst_sid_ser,
+
              , 58, 'ALTER TRACING'
username||case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username,
+
              , 59, 'CREATE TRIGGER'
sql_id sql_id,  
+
              , 61, 'DROP TRIGGER'
round((sysdate-sql_exec_start)*24*3600,1) sql_dT,
+
              , 62, 'ANALYZE TABLE'
        last_call_et call_dT,
+
              , 63, 'ANALYZE INDEX'
case state when 'WAITING' then round(wait_time_micro/1000000,2) else round(time_since_last_wait_micro/1000000,2) end W_dT,
+
              , 69, 'DROP PROCEDURE'
        decode(state,'WAITING',event,'CPU') event,  
+
              , 71, 'CREATE SNAP LOG'
service_name||' '||substr(module,1,20)||' '||ACTION serv_mod_action, 
+
              , 72, 'ALTER SNAP LOG'
          nullif(row_wait_obj#,-1) obj#,decode(taddr,null,null,'NN') tr
+
              , 73, 'DROP SNAP LOG'
from gv$session
+
              , 74, 'CREATE SNAPSHOT'
where ((state='WAITING' and wait_class<>'Idle') or (state<>'WAITING' and status='ACTIVE'))
+
              , 75, 'ALTER SNAPSHOT'
      --and audsid != to_number(sys_context('USERENV','SESSIONID')) -- this is clean but does not work on ADG so replaced by following line
+
              , 76, 'DROP SNAPSHOT'
      and (machine,port) <> (select machine,port from v$session where sid=sys_context('USERENV','SID')) --workaround for ADG
+
              , 85, 'TRUNCATE TABLE'
order by inst_id,sql_id
+
              , 88, 'ALTER VIEW'
</source>
+
              , 91, 'CREATE FUNCTION'
 
+
              , 92, 'ALTER FUNCTION'
=== 현재 작업중인 세션 정보 V$SESSION_LONGOPS ===
+
              , 93, 'DROP FUNCTION'
<source lang=sql>
+
              , 94, 'CREATE PACKAGE'
SELECT B.USERNAME, A.SID, B.OPNAME, B.TARGET
+
              , 95, 'ALTER PACKAGE'
     , ROUND(B.SOFAR*100/B.TOTALWORK,0) || '%' AS "%DONE", B.TIME_REMAINING
+
              , 96, 'DROP PACKAGE'
     , TO_CHAR(B.START_TIME,'YYYY/MM/DD HH24:MI:SS') START_TIME
+
              , 46, 'SAVEPOINT'
   FROM V$SESSION_LONGOPS B
+
                  )
     , V$SESSION A
+
          )
  WHERE A.SID = B.SID    
+
            COMMAND
ORDER BY 6 DESC;
+
    , SESS.PROCESS "C.PROC"
</source>
+
     , PROC.SPID "S.PROC"
 
+
     , TO_CHAR(SESS.LOGON_TIME, 'YYYY-MM-DD HH24:MI')
=== 세션당 리소스 사용률 gv$sessmetric ===
+
   FROM V$SESSION SESS
<source lang=sql>
+
     , V$SESSTAT STAT
select * from (
+
    , V$STATNAME NAME
  select inst_id, session_id sid, to_char(begin_time,'hh24:mi:ss') begTime, round(intsize_csec/100,0) D_sec, cpu,        
+
    , V$PROCESS PROC
        physical_reads PhyReads, logical_reads LogicalReads, pga_memory, hard_parses, soft_parses
+
  WHERE SESS.SID = STAT.SID  
  from gv$sessmetric
+
  AND STAT.STATISTIC# = NAME.STATISTIC#
  order by cpu+physical_reads desc
+
  AND SESS.USERNAME IS NOT NULL
)
+
  AND NAME.NAME = 'RECURSIVE CALLS'
where rownum<20
+
  AND SESS.PADDR = PROC.ADDR
 +
  ORDER BY 3, 1, 2;
 
</source>
 
</source>
 +
----
 +
 +
== SQL 찾기 ==
 +
=== SQL 통계 정보확인하기 ===
  
=== 1일 이상 존재 하는 조회 / kill / AWS_KILL_CMD ===
+
==== Module LEVEL 통계 ====
<source lang=sql>
 
-- DROP VIEW RTIS_DBA.V_DBA_KILL_SESS_OVER_1DAY;
 
 
 
CREATE OR REPLACE FORCE VIEW V_DBA_KILL_SESS_OVER_1DAY
 
(
 
    STATUS
 
  , USERNAME
 
  , OSUSER
 
  , MACHINE
 
  , EXEC_TIME
 
  , SID
 
  , SERIAL#
 
  , CMD_KILL
 
)
 
BEQUEATH DEFINER
 
AS
 
      SELECT STATUS
 
          , USERNAME
 
          , OSUSER
 
          , MACHINE
 
          , NVL (A.SQL_EXEC_START, A.PREV_EXEC_START)    EXEC_TIME
 
          , SID
 
          , SERIAL#
 
          ,    'EXEC RDSADMIN.RDSADMIN_UTIL.KILL('
 
            || TO_CHAR (SID)
 
            || ','
 
            || TO_CHAR (SERIAL#)
 
            || ');'                                      CMD_KILL
 
        FROM V$SESSION A
 
      WHERE    STATUS = 'INACTIVE'
 
            AND TYPE = 'USER'
 
            AND MACHINE NOT LIKE 'ip%'
 
            AND (SYSDATE - NVL (A.SQL_EXEC_START, A.PREV_EXEC_START)) * 24 > 1
 
    ORDER BY EXEC_TIME DESC;
 
</source>
 
 
 
=== 1시간 이상 유휴 상태인 세션 ===
 
* V$SESSION
 
  
 
<source lang="sql">  
 
<source lang="sql">  
SELECT SID
+
    SELECT *
    , SERIAL#
+
    FROM
    , USERNAME
+
        (SELECT module ,
    , TRUNC(LAST_CALL_ET / 3600, 2) || ' HR' LAST_CALL_ET
+
                count(*) sql_cnt ,
  FROM V$SESSION
+
                sum(executions) executions ,
WHERE LAST_CALL_ET > 3600
+
                round(avg(buffer_gets/executions)) "lio(avg)" ,
  AND USERNAME IS NOT NULL;  
+
                round(avg(disk_reads/executions)) "pio(avg)" ,
</source>
+
                round(avg(rows_processed/executions)) "rows(avg)" ,
 +
                round(avg(elapsed_time/executions/1000000),2) "elapsed(avg)" ,
 +
                count(CASE WHEN elapsed_time/executions/1000000>=3 THEN 1 END) bad_sql ,
 +
                round(max(elapsed_time/executions/1000000),2) "elapsed(max)"
 +
        FROM v$sql
 +
        WHERE executions > 0
 +
        GROUP BY module)
 +
ORDER BY "lio(avg)" * executions DESC ;
 +
</source>
 +
 
 +
 
 +
==== SCHEMA LEVEL 통계 ====
 +
<source lang="sql">
 +
SELECT * --9i
 +
FROM
 +
    ( SELECT
 +
        (SELECT username
 +
          FROM dba_users
 +
          WHERE user_id = parsing_schema_id) AS SCHEMA_NAME ,
 +
            count(*) sql_cnt ,
 +
            sum(executions) executions ,
 +
            round(avg(buffer_gets/executions)) "lio(avg)" ,
 +
            round(avg(disk_reads/executions)) "pio(avg)" ,
 +
            round(avg(rows_processed/executions)) "rows(avg)" ,
 +
            round(avg(elapsed_time/executions/1000000),2) "elapsed(avg)" ,
 +
            count(CASE WHEN elapsed_time/executions/1000000>=10 THEN 1 END) bad_sql ,
 +
            round(max(elapsed_time/executions/1000000),2) "elapsed(max)"
 +
    FROM v$sqlarea
 +
    WHERE executions > 0
 +
    GROUP BY parsing_schema_id)
 +
ORDER BY "lio(avg)" * executions DESC ;
 +
</source>  
  
=== 프로세스 아이디를 이용하여 쿼리문 알아내기 ===
+
<source lang="sql">  
* v$process
+
SELECT * --10g
* v$session
+
FROM
* v$sqltext
+
    (SELECT parsing_schema_name ,
<source lang="sql">
+
            count(*) sql_cnt ,
select c.sql_text
+
            sum(executions) executions ,
    , b.SID
+
            round(avg(buffer_gets/executions)) "lio(avg)" ,
    , b.SERIAL#
+
            round(avg(disk_reads/executions)) "pio(avg)" ,
    , b.machine
+
            round(avg(rows_processed/executions)) "rows(avg)" ,
    , b.OSUSER
+
            round(avg(elapsed_time/executions/1000000),2) "elapsed(avg)" ,
    , b.logon_time --이 쿼리를 호출한 시간
+
            count(CASE WHEN elapsed_time/executions/1000000>=10 THEN 1 END) bad_sql ,
  from v$process a, v$session b, v$sqltext c
+
            round(max(elapsed_time/executions/1000000),2) "elapsed(max)"
where a.addr = b.paddr
+
    FROM v$sqlarea
  and b.sql_hash_value = c.hash_value
+
    WHERE executions > 0
  and a.spid = '1708032' --1912870/
+
    GROUP BY parsing_schema_name)
order by c.PIECE
+
ORDER BY "lio(avg)" * executions DESC ;
</source>
+
</source>  
  
  
=== Active Session 중 Idle Time이 긴 작업 ===
+
==== DB Time 분석하기 ====
* V$SESSION
+
<source lang="sql">  
* V$PROCESS
+
SELECT STAT_NAME ,
<source lang="sql">
+
      VALUE,
SELECT VS.SID || ',' || VS.SERIAL# " SID"
+
      ROUND(VALUE/
    , VP.SPID
+
                ( SELECT VALUE
    , VS.MACHINE
+
                  FROM V$SYS_TIME_MODEL
    , VS.PROGRAM
+
                  WHERE STAT_NAME='DB TIME' ) *100 , 2) TIME_RATIO
    , VS.MODULE
+
FROM V$SYS_TIME_MODEL
    , VS.STATUS
+
WHERE STAT_NAME NOT IN ( 'BACKGROUND ELAPSED TIME' ,
    , TO_CHAR(VS.LOGON_TIME, 'MM/DD HH24:MI') LOGIN_TIME
+
                        'BACKGROUND CPU TIME' ,
    , ROUND(VS.LAST_CALL_ET / 60) "IDLE"
+
                        'RMAN CPU TIME (BACKUP/RESTORE)' ,
  FROM V$SESSION VS
+
                        'HARD PARSE ELAPSED TIME' ,
    , V$PROCESS VP
+
                        'HARD PARSE (SHARING CRITERIA) ELAPSED TIME' ,
WHERE VS.STATUS = 'ACTIVE'  
+
                        'HARD PARSE (BIND MISMATCH) ELAPSED TIME' ,
  AND VS.SID NOT IN (1, 2, 3, 4, 5, 6, 7)  
+
                        'FAILED PARSE ELAPSED TIME' ,
  AND VS.PADDR = VP.ADDR ORDER BY 8;  
+
                        'FAILED PARSE (OUT OF SHARED MEMORY) ELAPSED TIME' ,
</source>
+
                        'DB CPU')
 +
ORDER BY TIME_RATIO DESC ;
 +
</source>  
  
=== DBUser 별로 Session 정보를 조회 ===
+
=== SQL 추출하기 (10g) ===
* V$SESSION
+
<source lang="sql">  
* V$PROCESS
+
    SELECT *
<source lang="sql">
+
    FROM
SELECT S.USERNAME
+
        ( SELECT rownum cnt,
    , S.SID
+
                t1.*
    , S.SERIAL#
+
        FROM
    , P.SPID
+
            ( SELECT parsing_schema_name SCHEMA,   --> 1
    , S.OSUSER
+
                                          module,   --> 2
    , S.MACHINE
+
                                          sql_id,   --> 3
    , S.PROGRAM
+
                                          hash_value,--> 4
    , TO_CHAR(S.LOGON_TIME, 'MM/DD HH24:MI') "LOGON_TIME"
+
                                          substr(sql_text,1,100) substr_sqltext, --> 5
    , ROUND(S.LAST_CALL_ET / 60) "IDLE"
+
                                          executions--> 6
  FROM V$SESSION S
+
                                          buffer_gets, --> 7 (전체 I/O 처리량)
    , V$PROCESS P
+
                                          disk_reads, --> 8
  WHERE S.PADDR = P.ADDR
+
                                          rows_processed, --> 9
  AND S.USERNAME LIKE UPPER('&DBUSER%')  
+
                                          round(buffer_gets/executions,1) lio, --> 10 (1회 수행 당 I/O)
  ORDER BY 9;
+
                                          round(elapsed_time/executions/1000000,1) elapsed_sec, --> 11 (1회 수행 당 Elapsed)
</source>
+
                                          round(cpu_time/executions/1000000,1) cpu_sec, --> 12 (1회 수행 당 CPU)
 
+
                                          round(elapsed_time/tot_elapsed*100,1) ratio_elapsed, --> 13 (전체 대비 Elapsed )
=== Session별 사용 명령어 ===
+
                                          round(cpu_time/tot_cpu*100,1) ratio_cpu --> 14 (전체 대비 CPU 사용률)
* V$SESSION SESS
+
                            FROM v$sqlarea s,
* V$SESSTAT STAT
+
                  (SELECT sum(elapsed_time) tot_elapsed,
* V$STATNAME NAME
+
                          sum(cpu_time) tot_cpu
* V$PROCESS PROC
+
                  FROM v$sqlarea) t
 
+
               WHERE s.executions > 0
<source lang="sql">
+
                  AND parsing_schema_name NOT IN ('SYS','SYSTEM')
SELECT SESS.SID
+
                  AND ((module NOT LIKE 'TOAD%'
    , SESS.SERIAL#
+
                        AND module NOT LIKE 'SQL De%'
    , SUBSTR(SESS.USERNAME, 1, 10) "USER NAME"
+
                        AND module NOT LIKE 'Orange%'
    , SUBSTR(OSUSER, 1, 11) "OS USER"
+
                        AND module NOT LIKE 'PL/SQL%'
    , SUBSTR(SESS.MACHINE, 1, 15) "MACHINE NAME"
+
                        AND module NOT LIKE 'plsqldev.exe')
    , STATUS
+
                      OR (module IS NULL))
    , UPPER(
+
               ORDER BY 14 DESC ) t1
            DECODE(NVL(COMMAND, 0)
+
        WHERE rownum <= 50) WHERE cnt >= 1
              , 0, '---'
+
;
              , 1, 'CREATE TABLE'
+
</source>
              , 2, 'INSERT -'
+
 
              , 3, 'SELECT -'
+
=== 엑사 DB ===
              , 4, 'CREATE CLUST'
+
==== Exa . Smart Scan으로 수행되지 않고,Interconnect Bytes가 높은 SQL ====
               , 5, 'ALTER CLUST'
+
 
              , 6, 'UPDATE -'
+
<source lang="sql">
              , 7, 'DELETE -'
+
WITH Cell_Mon_SQL AS
              , 8, 'DROP -'
+
        ( SELECT sql_id,
              , 9, 'CREATE INDEX'
+
                io_cell_offload_eligible_bytes AS coeb,
              , 10, 'DROP INDEX'
+
                io_interconnect_bytes AS ib,
              , 11, 'ALTER INDEX'
+
                io_cell_offload_returned_bytes AS corb,
              , 12, 'DROP TABLE'
+
                io_cell_uncompressed_bytes AS cub,
              , 13, 'CREATE SEQ'
+
                optimized_phy_read_requests AS oprr,
               , 14, 'ALTER SEQ'
+
                physical_read_requests AS prr,
              , 15, 'ALTER TABLE'
+
                physical_read_bytes AS prb,
              , 16, 'DROP SEQ'
+
                sql_text
              , 17, 'GRANT'
+
        FROM v$sqlarea)
              , 18, 'REVOKE'
+
    SELECT /*** Smart Scan이 되지 않으면서, Interconnect Bytes가 높은 SQL ***/ *
              , 19, 'CREATE SYN'
+
    FROM
              , 20, 'DROP SYN'
+
        ( SELECT sql_id ,
              , 21, 'CREATE VIEW'
+
                decode(coeb,0,'No','Yes') AS "Offload",
              , 22, 'DROP VIEW'
+
                round(prb/1024/1024/1024,3) AS "Physical_Bytes(GB)",
              , 23, 'VALIDATE IX'
+
                round(coeb/1024/1024/1024,3) AS "Offload_Bytes(GB)",
              , 24, 'CREATE PROC'
+
                round(ib/1024/1024/1024,3) AS "Interconnect_Bytes(GB)",
              , 25, 'ALTER PROC'
+
                round(oprr*8192/1024/1024/1024,3) AS "Cell_Flash_Cache(GB)",
              , 26, 'LOCK TABLE'
+
                round(corb/1024/1024/1024,3) AS "Returned_Bytes(GB)",
              , 27, 'NO OPERATION'
+
                round(decode(coeb,0,0,100*(coeb-ib)/coeb),2) AS "Saved_IO(%)",
              , 28, 'RENAME'
+
                sql_text
              , 29, 'COMMENT'
+
        FROM Cell_Mon_SQL
              , 30, 'AUDIT'
+
        WHERE coeb = 0
              , 31, 'NOAUDIT'
+
        ORDER BY ib DESC) WHERE rownum <= 10 ;
              , 32, 'CREATE DBLINK'
+
</source>
              , 33, 'DROP DB LINK'
+
 
              , 34, 'CREATE DATABASE'
+
==== Smart Scan으로 수행되지 않고,Offload Returned Bytes가 높은 SQL  ====
              , 35, 'ALTER DATABASE'
+
* Reverting TO Block Shipping으로 수행된 SQL로 Smart Scan으로 동작할 수 있는 SQL이지만,Direct I/O로 동작하지 않는 경우 (FULL TABLE Scan도 cell single block physical read로 수행됨.)
              , 36, 'CREATE RBS'
+
 
              , 37, 'ALTER RBS'
+
* Chained Row가 있는 블록들을 읽을 때 발생. : Smart Scan을 통해서 Chained Row가 있는 블록을 읽을 때 각 블록이 다른 STORAGE Cell에 있는 경우 STORAGE Cell 간 통신할 수 없기 때문에 Buffer Cache로 전체 블록을 전송한 후 처리하도록 Block Shipping Mode로 변경
              , 38, 'DROP RBS'
+
 
              , 39, 'CREATE TABLESPACE'
+
* 읽기 일관성 모드로 변경 중인 데이터를 가진 Block에 대해서 Smart Scan을 중지하고,     Single Block Read를 수행하는 Block Shipping Mode로 변경
              , 40, 'ALTER TABLESPACE'
+
 
              , 41, 'DROP TABLESPACE'
+
<source lang="sql">
              , 42, 'ALTER SESSION'
+
WITH Cell_Mon_SQL AS
              , 43, 'ALTER USER'
+
    ( SELECT sql_id,
              , 44, 'COMMIT'
+
            io_cell_offload_eligible_bytes AS coeb,
              , 45, 'ROLLBACK'
+
            io_interconnect_bytes AS ib,
              , 47, 'PL/SQL EXEC'
+
            io_cell_offload_returned_bytes AS corb,
              , 48, 'SET TRANSACTION'
+
            io_cell_uncompressed_bytes AS cub,
              , 49, 'SWITCH LOG'
+
            optimized_phy_read_requests AS oprr,
              , 50, 'EXPLAIN'
+
            physical_read_requests AS prr,
              , 51, 'CREATE USER'
+
            physical_read_bytes AS prb,
              , 52, 'CREATE ROLE'
+
            sql_text
              , 53, 'DROP USER'
+
    FROM v$sqlarea)
              , 54, 'DROP ROLE'
+
SELECT *
              , 55, 'SET ROLE'
+
FROM
              , 56, 'CREATE SCHEMA'
+
    ( SELECT sql_id ,
              , 58, 'ALTER TRACING'
+
            decode(coeb,0,'No','Yes') AS "Offload",
              , 59, 'CREATE TRIGGER'
+
            round(prb/1024/1024/1024,3) AS "Physical_Bytes(GB)",
              , 61, 'DROP TRIGGER'
+
            round(coeb/1024/1024/1024,3) AS "Offload_Bytes(GB)",
              , 62, 'ANALYZE TABLE'
+
            round(ib/1024/1024/1024,3) AS "Interconnect_Bytes(GB)",
              , 63, 'ANALYZE INDEX'
+
            round(oprr*8192/1024/1024/1024,3) AS "Cell_Flash_Cache(GB)",
              , 69, 'DROP PROCEDURE'
+
            round(corb/1024/1024/1024,3) AS "Returned_Bytes(GB)",
              , 71, 'CREATE SNAP LOG'
+
            round(decode(coeb,0,0,100*(coeb-ib)/coeb),2) AS "Saved_IO(%)",
              , 72, 'ALTER SNAP LOG'
+
            sql_text
              , 73, 'DROP SNAP LOG'
+
     FROM Cell_Mon_SQL
              , 74, 'CREATE SNAPSHOT'
+
     WHERE coeb = 0
              , 75, 'ALTER SNAPSHOT'
+
     ORDER BY corb DESC)
              , 76, 'DROP SNAPSHOT'
+
WHERE rownum <= 10 ;
              , 85, 'TRUNCATE TABLE'
+
</source>
              , 88, 'ALTER VIEW'
+
 
              , 91, 'CREATE FUNCTION'
+
=== Full Table Scan 처리가 있는 SQL문 정보 추출하기(10g) ===
              , 92, 'ALTER FUNCTION'
+
<source lang="sql">
              , 93, 'DROP FUNCTION'
+
SELECT *
              , 94, 'CREATE PACKAGE'
+
FROM
              , 95, 'ALTER PACKAGE'
+
    (SELECT rownum cnt,
              , 96, 'DROP PACKAGE'
+
            t1.*
              , 46, 'SAVEPOINT'
+
    FROM
                  )
+
        (SELECT parsing_schema_name,
          )
+
                --> 1
            COMMAND
+
 
    , SESS.PROCESS "C.PROC"
+
                module,
    , PROC.SPID "S.PROC"
+
                --> 2
    , TO_CHAR(SESS.LOGON_TIME, 'YYYY-MM-DD HH24:MI')
 
  FROM V$SESSION SESS
 
     , V$SESSTAT STAT
 
     , V$STATNAME NAME
 
     , V$PROCESS PROC
 
WHERE SESS.SID = STAT.SID
 
  AND STAT.STATISTIC# = NAME.STATISTIC#
 
  AND SESS.USERNAME IS NOT NULL
 
  AND NAME.NAME = 'RECURSIVE CALLS'
 
  AND SESS.PADDR = PROC.ADDR
 
ORDER BY 3, 1, 2;
 
</source>
 
  
=== 사용자 session 중에서 2시간 이상 idle 상태가 지속되는 session을 kill  ===
+
                sql_id,
* V$SESSION
+
                --> 3
* V$PROCESS
+
 
<source lang="sql"> SET PAGESIZE 0 SPOOL KILLIDLE3.SQL
+
                hash_value,
SELECT DISTINCT '!KILL -9 ' || B.SPID, 'ALTER SYSTEM KILL SESSION '''|| A.SID || ',' || A.SERIAL# || ''';'
+
                --> 4
  FROM V$SESSION A
 
    , V$PROCESS B
 
WHERE A.PADDR IN (SELECT S.PADDR
 
                    FROM V$SESSION S
 
                    WHERE STATUS = 'INACTIVE'
 
                    GROUP BY  S.PADDR
 
                  HAVING MIN(ROUND(LAST_CALL_ET / 60)) > 120)
 
  AND A.PADDR = B.ADDR AND A.STATUS = 'INACTIVE';
 
SPOOL OFF
 
</source>
 
----
 
  
== 프로세스 정보 ==
+
                substr(sql_text,1,100) substr_sqltext,
=== Oracle Process의 정보 ===
+
                --> 5
* V$SESSION
 
* V$PROCESS
 
* SYS.V_$SESS_IO
 
  
<source lang="sql">
+
                executions,
SELECT S.STATUS "STATUS"
+
                --> 6
    , S.SERIAL# "SERIAL#"
 
    , S.TYPE "TYPE"
 
    , S.USERNAME "DB USER"
 
    , S.OSUSER "CLIENT USER"
 
    , S.SERVER "SERVER"
 
    , S.MACHINE "MACHINE"
 
    , S.MODULE "MODULE"
 
    , S.TERMINAL "TERMINAL"
 
    , S.PROGRAM "PROGRAM"
 
    , P.PROGRAM "O.S. PROGRAM"
 
    , S.LOGON_TIME "CONNECT TIME"
 
    , LOCKWAIT "LOCK WAIT"
 
    , SI.PHYSICAL_READS "PHYSICAL READS"
 
    , SI.BLOCK_GETS "BLOCK GETS"
 
    , SI.CONSISTENT_GETS "CONSISTENT GETS"
 
    , SI.BLOCK_CHANGES "BLOCK CHANGES"
 
    , SI.CONSISTENT_CHANGES "CONSISTENT CHANGES"
 
    , S.PROCESS "PROCESS"
 
    , P.SPID
 
    , P.PID
 
    , S.SERIAL#
 
    , SI.SID
 
    , S.SQL_ADDRESS "ADDRESS"
 
    , S.SQL_HASH_VALUE "SQL HASH"
 
    , S.ACTION
 
  FROM V$SESSION S
 
    , V$PROCESS P
 
    , SYS.V_$SESS_IO SI
 
WHERE S.PADDR = P.ADDR(+)
 
  AND SI.SID(+) = S.SID
 
  AND S.USERNAME IS NOT NULL
 
  AND NVL(S.OSUSER, 'X') <> 'SYSTEM'
 
  AND S.TYPE <> 'BACKGROUND'
 
ORDER BY 3;
 
</source>
 
  
=== 오브젝트에 접속되어 있는 프로그램 조회  ===
+
                buffer_gets,
* V$SESSION
+
                --> 7 (전체 I/O 처리량)
* V$ACCESS
+
 
<source lang="sql">
+
                disk_reads,
SELECT SUBSTR(B.OBJECT, 1, 15) AS OBJECT, SUBSTR(A.PROGRAM, 1, 15) AS PROGRAM, COUNT(*) AS CNT
+
                --> 8
  FROM V$SESSION A
 
    , V$ACCESS B
 
WHERE A.SID = B.SID
 
  AND B.OWNER NOT IN ('SYS')
 
  AND A.TYPE!= 'BACKGROUND'
 
  AND B.OBJECT LIKE UPPER('&OBJECT_NAME') || '%'
 
GROUP BY B.OBJECT, SUBSTR(A.PROGRAM, 1, 15);
 
</source>
 
  
----
+
                rows_processed,
 +
                --> 9
  
== 부하 발생 모니터링 ==
+
                round(buffer_gets/executions,1) lio,
=== cpu를 많이 사용하는 쿼리문과 프로세스아이디,시리얼번호,머신 알아내기 ===
+
                --> 10 (1회 수행 당 I/O)
* V$PROCESS 
 
* V$SESSION 
 
* V$SQLTEXT
 
  
<source lang="sql">
+
                round(elapsed_time/executions/1000000,1) elapsed_sec,
SELECT C.SQL_TEXT
+
                --> 11 (1회 수행 당 Elapsed)
    , B.SID
 
    , B.SERIAL#
 
    , B.MACHINE
 
    , B.OSUSER
 
    , B.LOGON_TIME --이 쿼리를 호출한 시간
 
  FROM V$PROCESS A
 
    , V$SESSION B
 
    , V$SQLTEXT C
 
WHERE A.ADDR = B.PADDR
 
  AND B.SQL_HASH_VALUE = C.HASH_VALUE
 
--AND A.SPID = '675958'
 
ORDER BY C.PIECE
 
</source>
 
 
=== 롤백 세그먼트 경합 조회  ===
 
* V$ROLLSTAT
 
* V$ROLLNAME
 
  
<source lang="sql">
+
                round(cpu_time/executions/1000000,1) cpu_sec,
SELECT NAME T0
+
                --> 12 (1회 수행 당 CPU)
    , GETS T1
 
    , WAITS T2
 
    , TO_CHAR(TRUNC(WAITS / GETS * 100, 2), 099.99) || '%' T3
 
    , TO_CHAR(ROUND(RSSIZE / 1024)) T4
 
    , SHRINKS T5
 
    , EXTENDS T6
 
  FROM V$ROLLSTAT
 
    , V$ROLLNAME
 
WHERE V$ROLLSTAT.USN = V$ROLLNAME.USN;
 
</source>
 
  
=== Buffer Cache Hit Ratio ===
+
                round(elapsed_time/tot_elapsed*100,1) ratio_elapsed,
* V$SYSSTAT
+
                --> 13 (전체 대비 Elapsed )
<source lang="sql">
 
SELECT ROUND(((1-(SUM(DECODE(name, 'physical reads', value,0))/(SUM(DECODE(name, 'db block gets', value,0))+ (SUM(DECODE(name, 'consistent gets', value, 0))))))*100),2) || '%' "Buffer Cache Hit Ratio"
 
  FROM V$SYSSTAT;
 
</source>
 
  
=== Library Cache Hit Ratio ===
+
                round(cpu_time/tot_cpu*100,1) ratio_cpu --> 14 (전체 대비 CPU 사용률)
* V$LIBRARYCACHE
 
<source lang="sql">
 
SELECT (1-SUM (reloads)/SUM(pins))*100 "Library Cache Hit Ratio"
 
From V$LIBRARYCACHE;
 
</source>
 
  
=== Data Dictionary Cache Hit Ratio ===
+
          FROM
* V$ROWCACHE
+
              (SELECT /*+ leading(x) no_merge(x) use_hash(x s) */ s.*
<source lang="sql">
+
              FROM v$sqlarea s,
SELECT (1-SUM(getmisses)/SUM(gets))*100 "Data Dictionary Hit Ratio"
+
                  ( SELECT DISTINCT hash_value
  FROM V$ROWCACHE;
+
                    FROM v$sql_plan
</source>
+
                    WHERE OPERATION = 'TABLE ACCESS'
+
                        AND OPTIONS = 'FULL' --and object_owner like :b1||'%'
----
+
) x
 
+
              WHERE x.hash_value = s.hash_value) s,
== DISK I/O ==
+
              (SELECT sum(elapsed_time) tot_elapsed,
* V$IOFUNCMETRIC
+
                      sum(cpu_time) tot_cpu
<source lang=sql>
+
              FROM v$sqlarea) t
-- iometric values in 11g
+
          WHERE executions > 0
 
+
              AND parsing_schema_name NOT IN ('SYS',
select min(begin_time) b_time, min(end_time) e_time, function_name,
+
                                              'SYSTEM')
      round(sum(small_read_iops+large_read_iops)) read_TOT_iops, round(sum(small_write_iops+large_write_iops)) write_TOT_iops, round(sum(large_read_mbps+small_read_mbps)) read_TOT_mbps, round(sum(large_write_mbps+small_write_mbps)) write_TOT_mbps
+
              AND ((module NOT LIKE 'TOAD%'
      from GV$IOFUNCMETRIC
+
                    AND module NOT LIKE 'SQL De%'
      group by rollup(function_name)
+
                    AND module NOT LIKE 'Orange%'
      having round(sum(small_read_iops+large_read_iops)) + round(sum(large_read_mbps+small_read_mbps)) + round(sum(small_write_iops+large_write_iops)) + round(sum(large_write_mbps+small_write_mbps))  >0
+
                    AND module NOT LIKE 'PL/SQL%'
      order by function_name;
+
                    AND module NOT LIKE 'plsqldev.exe')
 +
                  OR (module IS NULL))
 +
          ORDER BY 10 DESC ) t1
 +
    WHERE rownum <= 50)
 +
WHERE cnt >= 1
 
</source>
 
</source>
  
<source lang=sql>
+
=== 하드 파싱(leteral,리터럴) SQL 찾기 ===
-- query to iofuncmetric view in 11g
 
  
select inst_id,begin_time,function_name,
+
<source lang="sql">
      round(small_read_iops) RD_IOPS_sm, round(large_read_iops) RD_IOPS_lg,
+
    SELECT *
      round(small_read_mbps) RD_MBPS_sm, round(large_read_mbps) RD_MBPS_lg,
+
    FROM
      round(small_write_iops) WT_IOPS_sm, round(large_write_iops) WT_IOPS_lg,  
+
        ( SELECT
      round(small_write_mbps) WT_MBPS_sm, round(large_write_mbps) WT_MBPS_lg
+
            ( SELECT parsing_schema_name
from GV$IOFUNCMETRIC
+
              FROM v$sqlarea
--where function_name in ('Buffer Cache Reads','LGWR','DBWR','Direct Reads','Direct Writes','RMAN')
+
              WHERE sql_id=a.max_sql_id ) SCHEMA,
--where round(small_read_iops+large_read_iops+small_write_iops+large_write_iops) >0
+
            ( SELECT MODULE
order by function_name,inst_id;
+
              FROM v$sqlarea
</source>
+
              WHERE sql_id=a.max_sql_id ) MODULE, a.literal_sql_cnt, a.execution_cnt, a.plan_cnt, a.max_sql_id,
<source lang=sql>
+
            ( SELECT sql_fulltext
select min(begin_time) b_time, min(end_time) e_time, round(sum(small_read_iops+large_read_iops)) read_TOT_iops, round(sum(large_read_mbps+small_read_mbps)) read_TOT_mbps, round(sum(small_write_iops+large_write_iops)) write_TOT_iops, round(sum(large_write_mbps+small_write_mbps)) write_TOT_mbps from GV$IOFUNCMETRIC;
+
              FROM v$sqlarea
 +
              WHERE sql_id = a.max_sql_id ) sql_text
 +
        FROM
 +
            ( SELECT s.force_matching_signature,
 +
                      COUNT(s.exact_matching_signature) literal_sql_cnt,
 +
                      SUM(s.executions) execution_cnt,
 +
                      MAX(s.sql_id) max_sql_id,
 +
                      COUNT(DISTINCT s.plan_hash_value) plan_cnt
 +
              FROM v$sql s
 +
              GROUP BY s.force_matching_signature HAVING COUNT(s.exact_matching_signature) >= 2 ) a
 +
        ORDER BY 3 DESC ) WHERE ROWNUM <= 50
 +
;
 
</source>
 
</source>
  
 +
또는
  
== DB 용량 관리 ==
+
<source lang="sql">  
=== 테이블 스페이스 사용량 ===
+
SELECT /*+ leading(h) no_merge(h) use_nl(h s) */
* dba_data_files
+
      s.parsing_schema_name        SCHEMA                  , --> 1
* dba_free_space
+
      s.module                                            , --> 2
<source lang="sql">
+
      s.sql_id                                            , --> 3
SELECT A.TABLESPACE_NAME,
+
      s.hash_value                                        , --> 4
            A.TOTAL "TOTAL(MB)",
+
      SUBSTR (s.sql_text, 1, 100)       substr_sqltext    , --> 5
            A.TOTAL - B.FREE "USED(MB)",
+
      s.executions                                        , --> 6
            NVL(B.FREE,0) "FREE(MB)",
+
      s.buffer_gets                                        , --> 7 (전체 I/O 처리량)
            ROUND((A.TOTAL - NVL(B.FREE,0))*100/TOTAL,0) "USED(%)"
+
      s.disk_reads                                        , --> 8
   FROM ( SELECT TABLESPACE_NAME
+
      s.rows_processed                                    , --> 9
                , ROUND((SUM(BYTES)/1024/1024),0) AS TOTAL
+
      ROUND (s.buffer_gets / s.executions, 1)               lio    , --> 10 (1회 수행 당 I/O)
            FROM DBA_DATA_FILES
+
      ROUND (s.elapsed_time / s.executions / 1000000, 1)     elapsed_sec    , --> 11 (1회 수행 당 Elapsed)
            GROUP BY TABLESPACE_NAME
+
      ROUND (s.cpu_time / s.executions / 1000000, 1)         cpu_sec --> 12 (1회 수행 당 CPU)
      ) A
+
   FROM v$sqlarea  s
    , ( SELECT TABLESPACE_NAME
+
    , (SELECT *
              , ROUND((SUM(BYTES)/1024/1024),0) AS FREE
+
          FROM ( SELECT *
          FROM DBA_FREE_SPACE
+
                    FROM (  SELECT s.force_matching_signature
          GROUP BY TABLESPACE_NAME
+
                                , COUNT (s.exact_matching_signature)    literal_sql_cnt
      ) B
+
                                , SUM (s.executions)                   execution_cnt
WHERE A.TABLESPACE_NAME = B.TABLESPACE_NAME(+)
+
                                , MAX (s.sql_id)                       max_sql_id
  ORDER BY A.TABLESPACE_NAME;
+
                                , COUNT (DISTINCT s.plan_hash_value)   plan_cnt
 +
                              FROM v$sql s
 +
                            WHERE s.executions > 0
 +
                                  AND parsing_schema_name NOT IN
 +
                                          ('SYS', 'SYSTEM')
 +
                                  AND (   (   module NOT LIKE 'TOAD%'
 +
                                            AND module NOT LIKE 'SQL De%'
 +
                                            AND module NOT LIKE 'Orange%'
 +
                                            AND module NOT LIKE 'PL/SQL%'
 +
                                            AND module NOT LIKE 'plsqldev.exe')
 +
                                        OR (module IS NULL))
 +
                          GROUP BY s.force_matching_signature
 +
                            HAVING COUNT (s.exact_matching_signature) >= 2) a
 +
                ORDER BY 3 DESC)
 +
        WHERE ROWNUM <= 50) h
 +
  WHERE h.max_sql_id = s.sql_id;
 
</source>
 
</source>
  
== 오라클 서버 스펙  ==
+
{{틀:고지상자
=== 오라클서버의 메모리 ===
+
|제목= SQL 수행 이력 추출하기
* v$sgastat
+
|내용=* DBA_HIST_SQLTEXT : SQL TEXT가 CLOB으로 저장
<source lang="sql">
+
* DBA_HIST_SQL_PLAN : SQL문의 수행 PLAN이 저장되어 있으므로 플랜 변경등의 이력을 조회해 볼때 용이하다.
SELECT * FROM V$SGASTAT;
+
* DBA_HIST_SQLBIND : SQL문을 수행한 BIND VALUE를 저장하고 있는데 시간정보가 같이 있으므로 조회패턴을 분석하기 용이하다. DBA_HIST_SQLSTAT : V$SQL 정보와 같은 SQL 수행이력이 있는 VIEW로 각 SNAP_ID 마다의 Snap Shot 정보를 담고 있으므로 수행이력 패턴을 조회할 수 있다.
 +
}}
  
SELECT POOL, SUM(BYTES) "SIZE"
+
=== 특정 SQL 수행내역 확인하기 ===
  FROM V$SGASTAT
+
-- SQL TEXT
WHERE POOL = 'SHARED POOL'
+
<source lang="sql">
GROUP BY POOL
+
SELECT module,
</source>
+
      sql_fulltext
 +
FROM v$sqlarea
 +
WHERE hash_value = :hash_value -- 수행내역
 +
;
 +
</source>  
  
== 테이블 스페이스 ==
+
* v$sqlarea
=== System 테이블스페이스에 비시스템 세그먼트 조회 ===
 
* DBA_SEGMENTS
 
 
<source lang="sql">  
 
<source lang="sql">  
SELECT OWNER
+
    SELECT EXECUTIONS "Executions(total)",
    , SEGMENT_NAME
+
          round(DISK_READS/executions,2) "Disk_reads(one)",
    , SEGMENT_TYPE
+
          round(BUFFER_GETS/executions,0) "Buffer_gets(one)",
    , TABLESPACE_NAME
+
          round(ROWS_PROCESSED/EXECUTIONS,0) "Rows(one)",
   FROM DBA_SEGMENTS
+
          round((ELAPSED_TIME/EXECUTIONS)/1000000,2) "Elapsed_time(one)",
  WHERE OWNER NOT IN ('SYS', 'SYSTEM')
+
          round((CPU_TIME/EXECUTIONS)/1000000,2) "Cpu_time(one)"
  AND TABLESPACE_NAME = 'SYSTEM';  
+
   FROM v$sqlarea sa
</source>
+
  WHERE hash_value = :hash_value -- 바인드 변수값
 +
;
 +
</source>  
  
== DB Time 분석하기 ==
+
=== SQL_ID를 이용하여 SQL TEXT 추출하기 ===
 +
* DBA_HIST_SQLTEXT
 
<source lang="sql">  
 
<source lang="sql">  
SELECT STAT_NAME ,
+
SELECT *
      VALUE,
+
  FROM DBA_HIST_SQLTEXT
      ROUND(VALUE/
+
WHERE sql_id = :sql_id
                ( SELECT VALUE
+
;
                  FROM V$SYS_TIME_MODEL
 
                  WHERE STAT_NAME='DB TIME' ) *100 , 2) TIME_RATIO
 
FROM V$SYS_TIME_MODEL
 
WHERE STAT_NAME NOT IN ( 'BACKGROUND ELAPSED TIME' ,
 
                        'BACKGROUND CPU TIME' ,
 
                        'RMAN CPU TIME (BACKUP/RESTORE)' ,
 
                        'HARD PARSE ELAPSED TIME' ,
 
                        'HARD PARSE (SHARING CRITERIA) ELAPSED TIME' ,
 
                        'HARD PARSE (BIND MISMATCH) ELAPSED TIME' ,
 
                        'FAILED PARSE ELAPSED TIME' ,
 
                        'FAILED PARSE (OUT OF SHARED MEMORY) ELAPSED TIME' ,
 
                        'DB CPU')
 
ORDER BY TIME_RATIO DESC ;
 
 
</source>  
 
</source>  
  
=== 총 CPU Time 대비 SQL Parsing Time ===
+
=== SQL_ID를 이용하여 SQL문의 수행내역 추출하기 ===
 +
* dba_hist_sqlstat
 
<source lang="sql">  
 
<source lang="sql">  
SELECT MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'CPU USED BY THIS SESSION',X.VALUE))) AS "CPU USED BY THIS SESSION" ,
+
    SELECT snap_id,
      MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'PARSE TIME CPU',X.VALUE))) AS "PARSE TIME CPU" ,
+
          EXECUTIONS_TOTAL "Executions(total)",
      ROUND((MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'PARSE TIME CPU',X.VALUE)))/MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'CPU USED BY THIS SESSION',X.VALUE))) * 100),1)||'%' AS "PARSETIME/CPU(%)"
+
          round(DISK_READS_TOTAL/executions_total,2) "Disk_reads(one)",
FROM
+
          round(BUFFER_GETS_TOTAL/executions_total,0) "Buffer_gets(one)",
    ( SELECT NAME,
+
          round(ROWS_PROCESSED_TOTAL/EXECUTIONS_TOTAL,0) "Rows(one)",
            VALUE
+
          round((ELAPSED_TIME_TOTAL/EXECUTIONS_TOTAL)/1000000,2) "Elapsed_time(one)",
    FROM V$SYSSTAT
+
          round((CPU_TIME_TOTAL/EXECUTIONS_TOTAL)/1000000,2) "Cpu_time(one)"
    WHERE NAME IN ('CPU USED BY THIS SESSION',
+
     FROM dba_hist_sqlstat WHERE sql_id = :sql_id
                    'PARSE TIME CPU') ) X,
+
ORDER BY snap_id DESC
    (SELECT LEVEL AS RNO
+
;
    FROM DUAL CONNECT BY LEVEL<=2) Y ;
 
 
 
=== 총 Parsing Time 대비 Hard Parsing Time ===
 
<source lang="sql">
 
SELECT MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'PARSE TIME ELAPSED',X.VALUE))) AS "PARSE TIME ELAPSED" ,
 
      MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'HARD PARSE ELAPSED TIME',X.VALUE))) AS "HARD PARSE ELAPSED TIME" ,
 
      ROUND((MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'HARD PARSE ELAPSED TIME',X.VALUE)))/MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'PARSE TIME ELAPSED',X.VALUE))) * 100),1)||'%' AS "HARD/PARSETORAL(%)"
 
FROM
 
     ( SELECT STAT_NAME AS NAME,
 
            VALUE
 
    FROM V$SYS_TIME_MODEL
 
    WHERE STAT_NAME IN ('PARSE TIME ELAPSED',
 
                        'HARD PARSE ELAPSED TIME') ) X,
 
    (SELECT LEVEL AS RNO
 
    FROM DUAL CONNECT BY LEVEL<=2) Y ;
 
 
</source>  
 
</source>  
  
=== Log file sync 관련 대기현상 Sync Writes Time ===
+
=== 프로세스 ID 를 이용하여 SQL 찾기 ===
- redo synch time의 단위는 centisecond이다. => v$sysstat의 stat 중 time 정보를 담고 있는 stat의 value 단위는 centisecond이다.
+
* v$process
<source lang="sql">  
+
* v$session
SELECT MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'USER COMMITS',X.VALUE))) AS "USER COMMITS" ,
+
* v$sqltext
      MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'REDO SYNCH WRITES',X.VALUE))) AS "REDO SYNCH WRITES" ,
+
<source lang="sql">
      MAX(DECODE(Y.RNO,3,DECODE(X.NAME,
+
select c.sql_text
        'REDO SYNCH TIME',X.VALUE/100))) AS "REDO SYNCH TIME" ,
+
    , b.SID
      ROUND((MAX(DECODE(Y.RNO,3,DECODE(X.NAME,'REDO SYNCH TIME',X.VALUE/100)))/MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'REDO SYNCH WRITES',X.VALUE)))),3)||'초' AS "SYNCTIME/SYNCWRITES(초)"
+
    , b.SERIAL#
FROM
+
    , b.machine
    ( SELECT NAME,
+
    , b.OSUSER
            VALUE
+
    , b.logon_time --이 쿼리를 호출한 시간
    FROM V$SYSSTAT
+
  from v$process a, v$session b, v$sqltext c
    WHERE NAME IN ('USER COMMITS' ,
+
where a.addr = b.paddr
                    'REDO SYNCH TIME' ,
+
  and b.sql_hash_value = c.hash_value
                    'REDO SYNCH WRITES') ) X,
+
  and a.spid = '1708032' --1912870/
    (SELECT LEVEL AS RNO
+
order by c.PIECE
    FROM DUAL CONNECT BY LEVEL<=3) Y
+
</source>
;
+
 
</source>  
+
==== 바인드 변수 값 ====
=== 인스턴스 기동 이후 I/O 관련 대기현상 누적 값 ===
+
* 바인드 변수 값의 이력을 가지고 있는 뷰 조회로 SQL문의 조회 패턴 분석 가능
- v$system_event의 time_waited는 centisecond이다.
+
* v$sql_bind_capture
 
<source lang="sql">  
 
<source lang="sql">  
SELECT EVENT ,
+
    SELECT name,
      TOTAL_WAITS ,
+
          sql_id,
      TIME_WAITED / 100 AS "TIME_WAITED(SEC)" ,
+
          to_char(LAST_CAPTURED,'yyyymmdd hh24:mi:ss') LAST_CAPTURED,
      AVERAGE_WAIT
+
          datatype,
FROM V$SYSTEM_EVENT
+
          VALUE_STRING
WHERE EVENT IN ('DB FILE SEQUENTIAL READ' ,
+
    FROM v$sql_bind_capture
                'LOG FILE SYNC' ,
+
  WHERE hash_value = :hash_value -- or sql_id=:sql_id;
                'DB FILE SCATTERED READ')
+
 
;
+
</source>  
</source>
 
  
== SQL 통계 정보확인하기 ==
 
  
=== Module LEVEL 통계 ===
+
==== 바인드 변수 값2 ====
 +
* gv$sql_monitor
 
<source lang="sql">  
 
<source lang="sql">  
    SELECT *
+
select BINDS_XML from
    FROM
+
* gv$sql_monitor
        (SELECT module ,
+
where sql_id='&1';
                count(*) sql_cnt ,
 
                sum(executions) executions ,
 
                round(avg(buffer_gets/executions)) "lio(avg)" ,
 
                round(avg(disk_reads/executions)) "pio(avg)" ,
 
                round(avg(rows_processed/executions)) "rows(avg)" ,
 
                round(avg(elapsed_time/executions/1000000),2) "elapsed(avg)" ,
 
                count(CASE WHEN elapsed_time/executions/1000000>=3 THEN 1 END) bad_sql ,
 
                round(max(elapsed_time/executions/1000000),2) "elapsed(max)"
 
        FROM v$sql
 
        WHERE executions > 0
 
        GROUP BY module)
 
ORDER BY "lio(avg)" * executions DESC ;
 
 
</source>  
 
</source>  
  
 
+
==== 바인드 변수 값3 ====
=== SCHEMA LEVEL 통계 ===
+
* dba_hist_sqlbind
 
<source lang="sql">  
 
<source lang="sql">  
SELECT * --9i
+
     SELECT name,
FROM
+
          to_char(LAST_CAPTURED,'yyyymmdd hh24:mi:ss') LAST_CAPTURED,
     ( SELECT
+
          datatype,
        (SELECT username
+
          VALUE_STRING
          FROM dba_users
+
    FROM dba_hist_sqlbind
          WHERE user_id = parsing_schema_id) AS SCHEMA_NAME ,
+
  WHERE sql_id = :sql_id -- PLAN
            count(*) sql_cnt ,
+
;
            sum(executions) executions ,
 
            round(avg(buffer_gets/executions)) "lio(avg)" ,
 
            round(avg(disk_reads/executions)) "pio(avg)" ,
 
            round(avg(rows_processed/executions)) "rows(avg)" ,
 
            round(avg(elapsed_time/executions/1000000),2) "elapsed(avg)" ,
 
            count(CASE WHEN elapsed_time/executions/1000000>=10 THEN 1 END) bad_sql ,
 
            round(max(elapsed_time/executions/1000000),2) "elapsed(max)"
 
    FROM v$sqlarea
 
    WHERE executions > 0
 
    GROUP BY parsing_schema_id)
 
ORDER BY "lio(avg)" * executions DESC ;
 
 
</source>  
 
</source>  
  
 +
=== 플랜 정보 조회 ===
 +
* V$SQL_PLAN
 
<source lang="sql">  
 
<source lang="sql">  
SELECT * --10g
+
    SELECT --cardinality , cost,
FROM
+
LPAD('.', 1*(LEVEL-1),'.')|| OPERATION || decode(OPTIONS,NULL,NULL,' (') || OPTIONS || decode(OPTIONS,NULL,NULL,')') || decode(object_owner,NULL,NULL,' :')||object_owner || decode(object_name,NULL,NULL,'.') || OBJECT_NAME || decode(other_tag,NULL,NULL,'(')||other_tag||decode(other_tag,NULL,NULL,')') || DECODE(ACCESS_PREDICATES,NULL,NULL,' [AP] '||ACCESS_PREDICATES) ||DECODE(FILTER_PREDICATES,NULL,NULL,' [FP] '||FILTER_PREDICATES) "operation"
    (SELECT parsing_schema_name ,
+
    FROM
            count(*) sql_cnt ,
+
        (SELECT /*+ NO_MERGE */ *
            sum(executions) executions ,
+
        FROM V$SQL_PLAN
            round(avg(buffer_gets/executions)) "lio(avg)" ,
+
        WHERE HASH_VALUE = :hash_value
            round(avg(disk_reads/executions)) "pio(avg)" ,
+
            AND CHILD_NUMBER = 0) CONNECT BY
            round(avg(rows_processed/executions)) "rows(avg)" ,
+
    PRIOR id = parent_id START WITH id=0
            round(avg(elapsed_time/executions/1000000),2) "elapsed(avg)" ,
+
ORDER BY ID
            count(CASE WHEN elapsed_time/executions/1000000>=10 THEN 1 END) bad_sql ,
+
;
            round(max(elapsed_time/executions/1000000),2) "elapsed(max)"
 
    FROM v$sqlarea
 
    WHERE executions > 0
 
    GROUP BY parsing_schema_name)
 
ORDER BY "lio(avg)" * executions DESC ;
 
 
</source>  
 
</source>  
  
 
+
==== SQL_ID를 이용하여 SQL문의 PLAN 추출하기 ====
=== SQL LEVEL 통계 -- SQL 추출하기 (9i) ===
+
* DBA_HIST_SQL_PLAN
 
 
 
<source lang="sql">  
 
<source lang="sql">  
SELECT * --9i
+
    SELECT LPAD(' ',4*(depth-1))||OPERATION||DECODE(OTHER_TAG,NULL,'','*')|| DECODE(OPTIONS,NULL,'',' ('||OPTIONS||')')|| DECODE(OBJECT_NAME,NULL,'',' OF '|| OBJECT_NAME||'')|| DECODE(OBJECT_TYPE,NULL,'',' ('||OBJECT_TYPE||')')|| DECODE(ID,0,DECODE(OPTIMIZER,NULL,'',' Optimizer='||OPTIMIZER))|| DECODE(COST,NULL,'',' (Cost='||COST|| DECODE(CARDINALITY,NULL,'',' Card='||CARDINALITY)|| DECODE(BYTES,NULL,'',' Bytes='||BYTES)||')')|| DECODE(ACCESS_PREDICATES,NULL,' ',' [AP] = '||ACCESS_PREDICATES)|| DECODE(ACCESS_PREDICATES,NULL,' ',' [FP] = '||FILTER_PREDICATES) AS PLAN_OUTPUT
FROM
+
    FROM DBA_HIST_SQL_PLAN WHERE sql_id = :sql_id
    ( SELECT rownum cnt,
+
ORDER BY ID,
            t1.*
+
        POSITION
    FROM
 
        ( SELECT
 
              (SELECT username
 
              FROM dba_users
 
              WHERE user_id=parsing_schema_id) AS SCHEMA,
 
                  module,
 
                  hash_value,
 
                  substr(sql_text,1,100) substr_sqltext,
 
                  executions,
 
                  buffer_gets,
 
                  disk_reads,
 
                  rows_processed,
 
                  round(buffer_gets/executions,1) lio,
 
                  round(elapsed_time/executions/1000000,1) elapsed_sec,
 
                  round(cpu_time/executions/1000000,1) cpu_sec,
 
                  round(elapsed_time/tot_elapsed*100,1) ratio_elapsed,
 
                  round(cpu_time/tot_cpu*100,1) ratio_cpu
 
          FROM v$sqlarea s,
 
              (SELECT sum(elapsed_time) tot_elapsed,
 
                      sum(cpu_time) tot_cpu
 
              FROM v$sqlarea) t
 
          WHERE s.executions > 0
 
          ORDER BY 13 DESC ) t1
 
    WHERE rownum <= 50)
 
WHERE cnt >= 1
 
 
;
 
;
 
</source>  
 
</source>  
  
<source lang="sql">
+
----
    SELECT * --9i
+
 
      FROM
+
== SQL 과 커서 조회 ==
        ( SELECT rownum cnt,
+
 
                t1.*
+
=== 현재 커서 수 확인 ===
        FROM
+
* V$OPEN_CURSOR
            ( SELECT
+
* v$session_wait
                  (SELECT username
+
* v$transaction
                  FROM dba_users
 
                  WHERE user_id=parsing_schema_id) AS SCHEMA,
 
                      module,
 
                      hash_value,
 
                      substr(sql_text,1,100) substr_sqltext,
 
                      executions,
 
                      buffer_gets,
 
                      disk_reads,
 
                      rows_processed,
 
                      round(buffer_gets/executions,1) lio,
 
                      round(elapsed_time/executions/1000000,1) elapsed_sec,
 
                      round(cpu_time/executions/1000000,1) cpu_sec,
 
                      round(elapsed_time/tot_elapsed*100,1) ratio_elapsed,
 
                      round(cpu_time/tot_cpu*100,1) ratio_cpu
 
              FROM v$sqlarea s,
 
                  (SELECT sum(elapsed_time) tot_elapsed,
 
                          sum(cpu_time) tot_cpu
 
                  FROM v$sqlarea) t
 
              WHERE s.executions > 0
 
                  AND (s.sql_text NOT LIKE 'BEGIN'||'%'
 
                      AND s.sql_text NOT LIKE 'begin'||'%'
 
                      AND s.sql_text NOT LIKE 'DECLARE'||'%'
 
                      AND s.sql_text NOT LIKE 'declare'||'%' )
 
              ORDER BY 13 DESC ) t1
 
        WHERE rownum <= 50) WHERE cnt >= 1
 
;
 
</source>
 
  
=== SQL 추출하기 (10g) ===
+
==== sid별 열린커셔 ====
<source lang="sql">  
+
<source lang="sql">
    SELECT *
+
SELECT sid, count(sid) cursor
    FROM
+
  FROM V$OPEN_CURSOR
        ( SELECT rownum cnt,
+
WHERE user_name = 'dbcafe'
                t1.*
+
GROUP BY sid
        FROM
+
ORDER BY cursor DESC;
            ( SELECT parsing_schema_name SCHEMA,    --> 1
+
</source>
                                          module,    --> 2
 
                                          sql_id,    --> 3
 
                                          hash_value,--> 4
 
                                          substr(sql_text,1,100) substr_sqltext, --> 5
 
                                          executions,  --> 6
 
                                          buffer_gets, --> 7 (전체 I/O 처리량)
 
                                          disk_reads,  --> 8
 
                                          rows_processed, --> 9
 
                                          round(buffer_gets/executions,1) lio, --> 10 (1회 수행 당 I/O)
 
                                          round(elapsed_time/executions/1000000,1) elapsed_sec, --> 11 (1회 수행 당 Elapsed)
 
                                          round(cpu_time/executions/1000000,1) cpu_sec, --> 12 (1회 수행 당 CPU)
 
                                          round(elapsed_time/tot_elapsed*100,1) ratio_elapsed, --> 13 (전체 대비 Elapsed )
 
                                          round(cpu_time/tot_cpu*100,1) ratio_cpu --> 14 (전체 대비 CPU 사용률)
 
                            FROM v$sqlarea s,
 
                  (SELECT sum(elapsed_time) tot_elapsed,
 
                          sum(cpu_time) tot_cpu
 
                  FROM v$sqlarea) t
 
              WHERE s.executions > 0
 
                  AND parsing_schema_name NOT IN ('SYS','SYSTEM')
 
                  AND ((module NOT LIKE 'TOAD%'
 
                        AND module NOT LIKE 'SQL De%'
 
                        AND module NOT LIKE 'Orange%'
 
                        AND module NOT LIKE 'PL/SQL%'
 
                        AND module NOT LIKE 'plsqldev.exe')
 
                      OR (module IS NULL))
 
              ORDER BY 14 DESC ) t1
 
        WHERE rownum <= 50) WHERE cnt >= 1
 
;
 
</source>  
 
  
 
+
==== sql 별 열린 커서 ====
=== Exa SQL[1]. Smart Scan으로 수행되지 않고,Interconnect Bytes가 높은 SQL ===  
+
<source lang="sql">
 
+
SELECT sql_text, count(sid) cnt
<source lang="sql">  
+
  FROM v$OPEN_CURSOR
WITH Cell_Mon_SQL AS
+
GROUP BY sql_text
        ( SELECT sql_id,
+
ORDER BY cnt DESC
                io_cell_offload_eligible_bytes AS coeb,
 
                io_interconnect_bytes AS ib,
 
                io_cell_offload_returned_bytes AS corb,
 
                io_cell_uncompressed_bytes AS cub,
 
                optimized_phy_read_requests AS oprr,
 
                physical_read_requests AS prr,
 
                physical_read_bytes AS prb,
 
                sql_text
 
        FROM v$sqlarea)
 
    SELECT /*** Smart Scan이 되지 않으면서, Interconnect Bytes가 높은 SQL ***/ *
 
    FROM
 
        ( SELECT sql_id ,
 
                decode(coeb,0,'No','Yes') AS "Offload",
 
                round(prb/1024/1024/1024,3) AS "Physical_Bytes(GB)",
 
                round(coeb/1024/1024/1024,3) AS "Offload_Bytes(GB)",
 
                round(ib/1024/1024/1024,3) AS "Interconnect_Bytes(GB)",
 
                round(oprr*8192/1024/1024/1024,3) AS "Cell_Flash_Cache(GB)",
 
                round(corb/1024/1024/1024,3) AS "Returned_Bytes(GB)",
 
                round(decode(coeb,0,0,100*(coeb-ib)/coeb),2) AS "Saved_IO(%)",
 
                sql_text
 
        FROM Cell_Mon_SQL
 
        WHERE coeb = 0
 
        ORDER BY ib DESC) WHERE rownum <= 10 ;
 
 
</source>
 
</source>
=== SQL[2]. Smart Scan으로 수행되지 않고,Offload Returned Bytes가 높은 SQL : ===
 
Reverting TO Block Shipping으로 수행된 SQL로 Smart Scan으로 동작할 수 있는 SQL이지만,                                                                                                          Direct I/O로 동작하지 않는 경우 (FULL TABLE Scan도 cell single block physical read로 수행됨.)
 
- Chained Row가 있는 블록들을 읽을 때 발생. : Smart Scan을 통해서 Chained Row가 있는 블록을 읽을 때 각 블록이 다른
 
STORAGE Cell에 있는 경우 STORAGE Cell 간 통신할 수 없기 때문에 Buffer Cache로 전체 블록을 전송한 후 처리하도록 Block Shipping Mode로 변경
 
- 읽기 일관성 모드로 변경 중인 데이터를 가진 Block에 대해서 Smart Scan을 중지하고,                                                                                                                                Single Block Read를 수행하는 Block Shipping Mode로 변경
 
  
<source lang="sql">  
+
----
WITH Cell_Mon_SQL AS
+
== 락 모니터링 ==
    ( SELECT sql_id,
+
=== V$LOCK 을 사용한 잠금 경합 모니터링 ===
            io_cell_offload_eligible_bytes AS coeb,
+
* V$SESSION
            io_interconnect_bytes AS ib,
+
* DBA_OBJECTS
            io_cell_offload_returned_bytes AS corb,
+
* V$LOCK
            io_cell_uncompressed_bytes AS cub,
+
<source lang="sql">
            optimized_phy_read_requests AS oprr,
+
SELECT S.USERNAME, S.SID, S.SERIAL#, S.LOGON_TIME,
            physical_read_requests AS prr,
+
     DECODE(L.TYPE, 'TM', 'TABLE LOCK',
            physical_read_bytes AS prb,
+
                  'TX', 'ROW LOCK',
            sql_text
+
             NULL) "LOCK LEVEL",
    FROM v$sqlarea)
+
    O.OWNER, O.OBJECT_NAME, O.OBJECT_TYPE
SELECT *
+
FROM V$SESSION S, V$LOCK L, DBA_OBJECTS O
FROM
+
WHERE S.SID = L.SID
     ( SELECT sql_id ,
+
AND O.OBJECT_ID = L.ID1
            decode(coeb,0,'No','Yes') AS "Offload",
+
AND S.USERNAME IS NOT NULL
             round(prb/1024/1024/1024,3) AS "Physical_Bytes(GB)",
+
</source>
            round(coeb/1024/1024/1024,3) AS "Offload_Bytes(GB)",
+
            round(ib/1024/1024/1024,3) AS "Interconnect_Bytes(GB)",
+
=== 락이 걸린 세션 간단히 보기 ===
            round(oprr*8192/1024/1024/1024,3) AS "Cell_Flash_Cache(GB)",
+
<source lang="sql">
            round(corb/1024/1024/1024,3) AS "Returned_Bytes(GB)",
+
SELECT A.SID, A.SERIAL#, B.TYPE, C.OBJECT_NAME, A.PROGRAM, A.LOCKWAIT,
            round(decode(coeb,0,0,100*(coeb-ib)/coeb),2) AS "Saved_IO(%)",
+
      A.LOGON_TIME, A.PROCESS, A.OSUSER, A.TERMINAL
            sql_text
+
  FROM V$SESSION  A
     FROM Cell_Mon_SQL
+
     , V$LOCK      B
     WHERE coeb = 0
+
     , DBA_OBJECTS C
    ORDER BY corb DESC)
+
WHERE A.SID = B.SID
WHERE rownum <= 10 ;
+
  AND B.ID1 = C.OBJECT_ID
 +
  AND B.TYPE = 'TM';
 
</source>
 
</source>
  
=== Full Table Scan 처리가 있는 SQL문 정보 추출하기(10g) ===
+
=== 락이 걸린 세션 상세 보기 ===
<source lang="sql">  
+
* V$SESSION
SELECT *
+
* DBA_OBJECTS
FROM
+
* V$LOCK
    (SELECT rownum cnt,
+
<source lang="sql">
            t1.*
+
SELECT A.SID, A.SERIAL#,A.USERNAME,A.PROCESS,B.OBJECT_NAME
     FROM
+
    , DECODE(C.LMODE,2,'RS',3,'RX',4,'S',5,'SRX',8,'X','NO') "TABLE LOCK"
        (SELECT parsing_schema_name,
+
    , DECODE (A.COMMAND,2,'INSERT',3,'SELECT',6,'UPDATE',7,'DELETE',12,'DROP TABLE',26,'LOCK TABLE','UNKNOWN') "SQL"
                --> 1
+
    , DECODE(A.LOCKWAIT, NULL,'NO WAIT','WAIT') "STATUS"
 +
  FROM V$SESSION A
 +
     , DBA_OBJECTS B
 +
    , V$LOCK C
 +
WHERE A.SID=C.SID
 +
  AND B.OBJECT_ID=C.ID1
 +
  AND C.TYPE='TM'
 +
</source>
 +
  
                module,
+
* 락이 걸린 세션을 찾아 내어 세션을 죽이려고 해도 죽지 않는 경우
                --> 2
+
* 아래 쿼리문으로 OS단의 PROCESS ID를 찾아내어 OS에서 죽인다
 +
* kill -9 프로세스아이디
  
                sql_id,
+
<source lang="sql">
                --> 3
+
SELECT SUBSTR(S.USERNAME,1,11) "ORACLE USER", P.PID "PROCESS ID"
 +
    , S.SID "SESSION ID", S.SERIAL#, OSUSER "OS USER"
 +
    , P.SPID "PROC SPID",S.PROCESS "SESS SPID", S.LOCKWAIT "LOCK WAIT"
 +
  FROM V$PROCESS P
 +
    , V$SESSION S
 +
    , V$ACCESS  A
 +
WHERE A.SID=S.SID
 +
  AND P.ADDR=S.PADDR
 +
  AND S.USERNAME != 'SYS'
 +
</source>
  
                hash_value,
+
* 위 쿼리문의 결과가 있다면 락이 걸린 세션이 있다는것이므로 아래의 쿼리문으로 세션을 죽인다
                --> 4
+
<source lang="sql">
 
+
ALTER SYSTEM KILL SESSION '11,39061'
                substr(sql_text,1,100) substr_sqltext,
+
</source>
                --> 5
+
 +
* alter session으로 죽지않는 프로세스 죽이기
 +
<source lang="sql">
 +
1.oracle이 설치된 서버에 텔넷으로 root로 접속한다
 +
2.su -오라클계정
 +
3.sqlplus '/as sysdba''
 +
4.connect system/sys
 +
5.ALTER SYSTEM KILL SESSION '137,1723'
 +
</source>
  
                executions,
 
                --> 6
 
  
                buffer_gets,
+
=== 1일 이상 존재 하는 조회 / kill / AWS_KILL_CMD ===
                --> 7 (전체 I/O 처리량)
+
<source lang=sql>
 +
-- DROP VIEW RTIS_DBA.V_DBA_KILL_SESS_OVER_1DAY;
  
                disk_reads,
+
CREATE OR REPLACE FORCE VIEW V_DBA_KILL_SESS_OVER_1DAY
                --> 8
+
(
 
+
    STATUS
                rows_processed,
+
  , USERNAME
                --> 9
+
  , OSUSER
 
+
  , MACHINE
                round(buffer_gets/executions,1) lio,
+
  , EXEC_TIME
                --> 10 (1회 수행 당 I/O)
+
  , SID
 +
  , SERIAL#
 +
  , CMD_KILL
 +
)
 +
BEQUEATH DEFINER
 +
AS
 +
      SELECT STATUS
 +
          , USERNAME
 +
          , OSUSER
 +
          , MACHINE
 +
          , NVL (A.SQL_EXEC_START, A.PREV_EXEC_START)    EXEC_TIME
 +
          , SID
 +
          , SERIAL#
 +
          ,   'EXEC RDSADMIN.RDSADMIN_UTIL.KILL('
 +
            || TO_CHAR (SID)
 +
            || ','
 +
            || TO_CHAR (SERIAL#)
 +
            || ');'                                      CMD_KILL
 +
        FROM V$SESSION A
 +
      WHERE    STATUS = 'INACTIVE'
 +
            AND TYPE = 'USER'
 +
            AND MACHINE NOT LIKE 'ip%'
 +
            AND (SYSDATE - NVL (A.SQL_EXEC_START, A.PREV_EXEC_START)) * 24 > 1
 +
    ORDER BY EXEC_TIME DESC;
 +
</source>
  
                round(elapsed_time/executions/1000000,1) elapsed_sec,
 
                --> 11 (1회 수행 당 Elapsed)
 
  
                round(cpu_time/executions/1000000,1) cpu_sec,
 
                --> 12 (1회 수행 당 CPU)
 
  
                round(elapsed_time/tot_elapsed*100,1) ratio_elapsed,
+
----
                --> 13 (전체 대비 Elapsed )
 
  
                round(cpu_time/tot_cpu*100,1) ratio_cpu --> 14 (전체 대비 CPU 사용률)
+
== 프로세스 정보 ==
 +
=== Oracle Process의 정보 ===
 +
* V$SESSION
 +
* V$PROCESS
 +
* SYS.V_$SESS_IO
  
          FROM
+
<source lang="sql">
              (SELECT /*+ leading(x) no_merge(x) use_hash(x s) */ s.*
+
SELECT S.STATUS "STATUS"
              FROM v$sqlarea s,
+
    , S.SERIAL# "SERIAL#"
                  ( SELECT DISTINCT hash_value
+
    , S.TYPE "TYPE"
                    FROM v$sql_plan
+
    , S.USERNAME "DB USER"
                    WHERE OPERATION = 'TABLE ACCESS'
+
    , S.OSUSER "CLIENT USER"
                        AND OPTIONS = 'FULL' --and object_owner like :b1||'%'
+
    , S.SERVER "SERVER"
) x
+
    , S.MACHINE "MACHINE"
              WHERE x.hash_value = s.hash_value) s,
+
    , S.MODULE "MODULE"
              (SELECT sum(elapsed_time) tot_elapsed,
+
    , S.TERMINAL "TERMINAL"
                      sum(cpu_time) tot_cpu
+
    , S.PROGRAM "PROGRAM"
              FROM v$sqlarea) t
+
    , P.PROGRAM "O.S. PROGRAM"
          WHERE executions > 0
+
    , S.LOGON_TIME "CONNECT TIME"
              AND parsing_schema_name NOT IN ('SYS',
+
    , LOCKWAIT "LOCK WAIT"
                                              'SYSTEM')
+
    , SI.PHYSICAL_READS "PHYSICAL READS"
              AND ((module NOT LIKE 'TOAD%'
+
    , SI.BLOCK_GETS "BLOCK GETS"
                    AND module NOT LIKE 'SQL De%'
+
    , SI.CONSISTENT_GETS "CONSISTENT GETS"
                    AND module NOT LIKE 'Orange%'
+
    , SI.BLOCK_CHANGES "BLOCK CHANGES"
                    AND module NOT LIKE 'PL/SQL%'
+
    , SI.CONSISTENT_CHANGES "CONSISTENT CHANGES"
                    AND module NOT LIKE 'plsqldev.exe')
+
    , S.PROCESS "PROCESS"
                  OR (module IS NULL))
+
    , P.SPID
          ORDER BY 10 DESC ) t1
+
    , P.PID
     WHERE rownum <= 50)
+
    , S.SERIAL#
WHERE cnt >= 1
+
    , SI.SID
</source>
+
     , S.SQL_ADDRESS "ADDRESS"
=== 하드파싱(leteral,리터럴) 찾기 ===
+
    , S.SQL_HASH_VALUE "SQL HASH"
 
+
    , S.ACTION
<source lang="sql">
+
  FROM V$SESSION S
    SELECT *
+
    , V$PROCESS P
    FROM
+
    , SYS.V_$SESS_IO SI
        ( SELECT
+
WHERE S.PADDR = P.ADDR(+)  
            ( SELECT parsing_schema_name
+
  AND SI.SID(+) = S.SID
              FROM v$sqlarea
+
  AND S.USERNAME IS NOT NULL
              WHERE sql_id=a.max_sql_id ) SCHEMA,
+
  AND NVL(S.OSUSER, 'X') <> 'SYSTEM'
            ( SELECT MODULE
+
  AND S.TYPE <> 'BACKGROUND'
              FROM v$sqlarea
+
ORDER BY 3;  
              WHERE sql_id=a.max_sql_id ) MODULE, a.literal_sql_cnt, a.execution_cnt, a.plan_cnt, a.max_sql_id,
 
            ( SELECT sql_fulltext
 
              FROM v$sqlarea
 
              WHERE sql_id = a.max_sql_id ) sql_text
 
        FROM
 
            ( SELECT s.force_matching_signature,
 
                      COUNT(s.exact_matching_signature) literal_sql_cnt,
 
                      SUM(s.executions) execution_cnt,
 
                      MAX(s.sql_id) max_sql_id,
 
                      COUNT(DISTINCT s.plan_hash_value) plan_cnt
 
              FROM v$sql s
 
              GROUP BY s.force_matching_signature HAVING COUNT(s.exact_matching_signature) >= 2 ) a
 
        ORDER BY 3 DESC ) WHERE ROWNUM <= 50
 
;
 
 
</source>
 
</source>
또는
 
  
<source lang="sql">  
+
=== 오브젝트에 접속되어 있는 프로그램 조회  ===
/* Formatted on 2020/01/13 오전 11:21:11 (QP5 v5.336) */
+
* V$SESSION
SELECT /*+ leading(h) no_merge(h) use_nl(h s) */
+
* V$ACCESS
      s.parsing_schema_name        SCHEMA                  , --> 1
+
<source lang="sql">
      s.module                                            , --> 2
+
SELECT SUBSTR(B.OBJECT, 1, 15) AS OBJECT, SUBSTR(A.PROGRAM, 1, 15) AS PROGRAM, COUNT(*) AS CNT
      s.sql_id                                            , --> 3
+
   FROM V$SESSION A
      s.hash_value                                        , --> 4
+
     , V$ACCESS B
      SUBSTR (s.sql_text, 1, 100)       substr_sqltext    , --> 5
+
  WHERE A.SID = B.SID
      s.executions                                        , --> 6
+
   AND B.OWNER NOT IN ('SYS')  
      s.buffer_gets                                        , --> 7 (전체 I/O 처리량)
+
   AND A.TYPE!= 'BACKGROUND'  
      s.disk_reads                                        , --> 8
+
  AND B.OBJECT LIKE UPPER('&OBJECT_NAME') || '%'  
      s.rows_processed                                    , --> 9
+
GROUP BY B.OBJECT, SUBSTR(A.PROGRAM, 1, 15);
      ROUND (s.buffer_gets / s.executions, 1)                lio    , --> 10 (1회 수행 당 I/O)
+
</source>
      ROUND (s.elapsed_time / s.executions / 1000000, 1)    elapsed_sec    , --> 11 (1회 수행 당 Elapsed)
+
 
      ROUND (s.cpu_time / s.executions / 1000000, 1)        cpu_sec --> 12 (1회 수행 당 CPU)
+
----
   FROM v$sqlarea  s
+
 
     , (SELECT *
+
== 부하 발생 모니터링 ==
          FROM ( SELECT *
+
=== cpu를 많이 사용하는 쿼리문과 프로세스아이디,시리얼번호,머신 알아내기 ===
                    FROM (  SELECT s.force_matching_signature
+
* V$PROCESS 
                                , COUNT (s.exact_matching_signature)    literal_sql_cnt
+
* V$SESSION  
                                , SUM (s.executions)                    execution_cnt
+
* V$SQLTEXT
                                , MAX (s.sql_id)                        max_sql_id
 
                                , COUNT (DISTINCT s.plan_hash_value)   plan_cnt
 
                              FROM v$sql s
 
                            WHERE s.executions > 0
 
                                  AND parsing_schema_name NOT IN
 
                                          ('SYS', 'SYSTEM')
 
                                  AND (  (   module NOT LIKE 'TOAD%'
 
                                            AND module NOT LIKE 'SQL De%'
 
                                            AND module NOT LIKE 'Orange%'
 
                                            AND module NOT LIKE 'PL/SQL%'
 
                                            AND module NOT LIKE 'plsqldev.exe')
 
                                        OR (module IS NULL))
 
                          GROUP BY s.force_matching_signature
 
                            HAVING COUNT (s.exact_matching_signature) >= 2) a
 
                ORDER BY 3 DESC)
 
        WHERE ROWNUM <= 50) h
 
  WHERE h.max_sql_id = s.sql_id;
 
</source>
 
  
=== 특정 SQL 수행내역 확인하기 ===
+
<source lang="sql">
-- SQL TEXT
+
SELECT C.SQL_TEXT
<source lang="sql">  
+
    , B.SID
SELECT module,
+
    , B.SERIAL#
      sql_fulltext
+
    , B.MACHINE
FROM v$sqlarea
+
    , B.OSUSER
WHERE hash_value = :hash_value -- 수행내역
+
    , B.LOGON_TIME --이 쿼리를 호출한 시간
;
+
  FROM V$PROCESS A
</source>  
+
    , V$SESSION B
 +
    , V$SQLTEXT C
 +
WHERE A.ADDR = B.PADDR
 +
  AND B.SQL_HASH_VALUE = C.HASH_VALUE
 +
--AND A.SPID = '675958'
 +
ORDER BY C.PIECE
 +
</source>
 +
 +
=== 롤백 세그먼트 경합 조회  ===
 +
* V$ROLLSTAT
 +
* V$ROLLNAME
  
<source lang="sql">  
+
<source lang="sql">
    SELECT EXECUTIONS "Executions(total)",
+
SELECT NAME T0
          round(DISK_READS/executions,2) "Disk_reads(one)",
+
    , GETS T1
          round(BUFFER_GETS/executions,0) "Buffer_gets(one)",
+
    , WAITS T2
          round(ROWS_PROCESSED/EXECUTIONS,0) "Rows(one)",
+
    , TO_CHAR(TRUNC(WAITS / GETS * 100, 2), 099.99) || '%' T3
          round((ELAPSED_TIME/EXECUTIONS)/1000000,2) "Elapsed_time(one)",
+
    , TO_CHAR(ROUND(RSSIZE / 1024)) T4
          round((CPU_TIME/EXECUTIONS)/1000000,2) "Cpu_time(one)"
+
    , SHRINKS T5
   FROM v$sqlarea sa
+
    , EXTENDS T6
  WHERE hash_value = :hash_value -- 바인드 변수값
+
   FROM V$ROLLSTAT
;
+
    , V$ROLLNAME
</source>  
+
  WHERE V$ROLLSTAT.USN = V$ROLLNAME.USN;  
 +
</source>
  
* 바인드 변수 값
+
=== 버퍼 캐시 히트율(Buffer Cache Hit Ratio) ===
<source lang="sql">  
+
* V$SYSSTAT
    SELECT name,
+
<source lang="sql">
          sql_id,
+
SELECT ROUND(((1-(SUM(DECODE(name, 'physical reads', value,0))/(SUM(DECODE(name, 'db block gets', value,0))+ (SUM(DECODE(name, 'consistent gets', value, 0))))))*100),2) || '%' "Buffer Cache Hit Ratio"
          to_char(LAST_CAPTURED,'yyyymmdd hh24:mi:ss') LAST_CAPTURED,
+
  FROM V$SYSSTAT;
          datatype,
+
</source>
          VALUE_STRING
 
    FROM v$sql_bind_capture
 
  WHERE hash_value = :hash_value -- or sql_id=:sql_id;
 
-- 바인드 변수 값의 이력을 가지고 있는 뷰 조회로 SQL문의 조회 패턴을 분석할 수 있다.
 
;
 
</source>
 
* 바인드 변수 값2
 
<source lang="sql">
 
select BINDS_XML from gv$sql_monitor
 
where sql_id='&1';
 
</source>  
 
  
* 바인드 변수 값3
+
=== 라이브러리 캐시 히트율(Library Cache Hit Ratio) ===
<source lang="sql">  
+
* V$LIBRARYCACHE
    SELECT name,
+
<source lang="sql">
          to_char(LAST_CAPTURED,'yyyymmdd hh24:mi:ss') LAST_CAPTURED,
+
SELECT (1-SUM (reloads)/SUM(pins))*100 "Library Cache Hit Ratio"
          datatype,
+
From V$LIBRARYCACHE;
          VALUE_STRING
+
</source>
    FROM dba_hist_sqlbind
 
  WHERE sql_id = :sql_id -- PLAN
 
;
 
;
 
</source>  
 
  
<source lang="sql">  
+
=== 데이터 딕셔너리 캐시 히트율(Data Dictionary Cache Hit Ratio) ===
    SELECT --cardinality , cost,
+
* V$ROWCACHE
LPAD('.', 1*(LEVEL-1),'.')|| OPERATION || decode(OPTIONS,NULL,NULL,' (') || OPTIONS || decode(OPTIONS,NULL,NULL,')') || decode(object_owner,NULL,NULL,' :')||object_owner || decode(object_name,NULL,NULL,'.') || OBJECT_NAME || decode(other_tag,NULL,NULL,'(')||other_tag||decode(other_tag,NULL,NULL,')') || DECODE(ACCESS_PREDICATES,NULL,NULL,' [AP] '||ACCESS_PREDICATES) ||DECODE(FILTER_PREDICATES,NULL,NULL,' [FP] '||FILTER_PREDICATES) "operation"
+
<source lang="sql">
    FROM
+
SELECT (1-SUM(getmisses)/SUM(gets))*100 "Data Dictionary Hit Ratio"
        (SELECT /*+ NO_MERGE */ *
+
  FROM V$ROWCACHE;
        FROM V$SQL_PLAN
+
</source>
        WHERE HASH_VALUE = :hash_value
+
            AND CHILD_NUMBER = 0) CONNECT BY
+
----
    PRIOR id = parent_id START WITH id=0
 
ORDER BY ID
 
;
 
</source>  
 
  
--SQL 수행 이력 추출하기
+
== I/O 부하 찾기 ==
DBA_HIST_SQLTEXT : SQL TEXT가 CLOB으로 저장
+
* V$IOFUNCMETRIC
DBA_HIST_SQL_PLAN : SQL문의 수행 PLAN이 저장되어 있으므로 플랜 변경등의 이력을 조회해 볼때 용이하다.
+
<source lang=sql>
DBA_HIST_SQLBIND : SQL문을 수행한 BIND VALUE를 저장하고 있는데 시간정보가 같이 있으므로 조회패턴을 분석하기 용이하다. DBA_HIST_SQLSTAT : V$SQL 정보와 같은 SQL 수행이력이 있는 VIEW로 각 SNAP_ID 마다의 Snap Shot 정보를 담고 있으므로 수행이력 패턴을 조회할 수 있다.
+
-- iometric values in 11g
  
=== SQL_ID를 이용하여 SQL TEXT 추출하기 ===
+
select min(begin_time) b_time, min(end_time) e_time, function_name,
 +
      round(sum(small_read_iops+large_read_iops)) read_TOT_iops, round(sum(small_write_iops+large_write_iops)) write_TOT_iops, round(sum(large_read_mbps+small_read_mbps)) read_TOT_mbps, round(sum(large_write_mbps+small_write_mbps)) write_TOT_mbps
 +
      from GV$IOFUNCMETRIC
 +
      group by rollup(function_name)
 +
      having round(sum(small_read_iops+large_read_iops)) + round(sum(large_read_mbps+small_read_mbps)) + round(sum(small_write_iops+large_write_iops)) + round(sum(large_write_mbps+small_write_mbps))  >0
 +
      order by function_name;
 +
</source>
  
<source lang="sql">  
+
<source lang=sql>
SELECT *
+
-- query to iofuncmetric view in 11g
  FROM DBA_HIST_SQLTEXT
 
WHERE sql_id = :sql_id
 
;
 
</source>
 
  
=== SQL_ID를 이용하여 SQL문의 수행내역 추출하기 ===
+
select inst_id,begin_time,function_name,
<source lang="sql">
+
      round(small_read_iops) RD_IOPS_sm, round(large_read_iops) RD_IOPS_lg,  
    SELECT snap_id,
+
      round(small_read_mbps) RD_MBPS_sm, round(large_read_mbps) RD_MBPS_lg,  
          EXECUTIONS_TOTAL "Executions(total)",
+
      round(small_write_iops) WT_IOPS_sm, round(large_write_iops) WT_IOPS_lg,  
          round(DISK_READS_TOTAL/executions_total,2) "Disk_reads(one)",
+
      round(small_write_mbps) WT_MBPS_sm, round(large_write_mbps) WT_MBPS_lg
          round(BUFFER_GETS_TOTAL/executions_total,0) "Buffer_gets(one)",
+
from GV$IOFUNCMETRIC
          round(ROWS_PROCESSED_TOTAL/EXECUTIONS_TOTAL,0) "Rows(one)",
+
--where function_name in ('Buffer Cache Reads','LGWR','DBWR','Direct Reads','Direct Writes','RMAN')  
          round((ELAPSED_TIME_TOTAL/EXECUTIONS_TOTAL)/1000000,2) "Elapsed_time(one)",
+
--where round(small_read_iops+large_read_iops+small_write_iops+large_write_iops) >0
          round((CPU_TIME_TOTAL/EXECUTIONS_TOTAL)/1000000,2) "Cpu_time(one)"
+
order by function_name,inst_id;
    FROM dba_hist_sqlstat WHERE sql_id = :sql_id
+
</source>
ORDER BY snap_id DESC
+
<source lang=sql>
;
+
select min(begin_time) b_time, min(end_time) e_time, round(sum(small_read_iops+large_read_iops)) read_TOT_iops, round(sum(large_read_mbps+small_read_mbps)) read_TOT_mbps, round(sum(small_write_iops+large_write_iops)) write_TOT_iops, round(sum(large_write_mbps+small_write_mbps)) write_TOT_mbps from GV$IOFUNCMETRIC;
</source>  
+
</source>
  
=== SQL_ID를 이용하여 바인드 변수 값을 추출하기 ===
+
=== 인스턴스 기동 이후 I/O 관련 대기현상 누적 값 ===
 +
- v$system_event의 time_waited는 centisecond (1/100 초)
 
<source lang="sql">  
 
<source lang="sql">  
SELECT name,
+
SELECT EVENT ,
       to_char(LAST_CAPTURED,'yyyymmdd hh24:mi:ss') LAST_CAPTURED,
+
       TOTAL_WAITS ,
       datatype,
+
       TIME_WAITED / 100 AS "TIME_WAITED(SEC)" ,
       VALUE_STRING
+
       AVERAGE_WAIT
FROM dba_hist_sqlbind
+
FROM V$SYSTEM_EVENT
WHERE sql_id = :sql_id
+
WHERE EVENT IN ('DB FILE SEQUENTIAL READ' ,
-- dba_hist_sqlbind를 이용하면 바인드 변수 값의 이력을 가지고 있는 뷰이므로 SQL문의 조회 패턴을 분석할 수 있다.
+
                'LOG FILE SYNC' ,
 +
                'DB FILE SCATTERED READ')
 
;
 
;
</source>  
+
</source>
 +
 
 +
==== 전체 IO량(100%) 대비 사용자별 IO량  ====
  
== SQL_ID를 이용하여 SQL문의 PLAN 추출하기 ==
 
 
<source lang="sql">  
 
<source lang="sql">  
    SELECT LPAD(' ',4*(depth-1))||OPERATION||DECODE(OTHER_TAG,NULL,'','*')|| DECODE(OPTIONS,NULL,'',' ('||OPTIONS||')')|| DECODE(OBJECT_NAME,NULL,'',' OF '|| OBJECT_NAME||'')|| DECODE(OBJECT_TYPE,NULL,'',' ('||OBJECT_TYPE||')')|| DECODE(ID,0,DECODE(OPTIMIZER,NULL,'',' Optimizer='||OPTIMIZER))|| DECODE(COST,NULL,'',' (Cost='||COST|| DECODE(CARDINALITY,NULL,'',' Card='||CARDINALITY)|| DECODE(BYTES,NULL,'',' Bytes='||BYTES)||')')|| DECODE(ACCESS_PREDICATES,NULL,' ',' [AP] = '||ACCESS_PREDICATES)|| DECODE(ACCESS_PREDICATES,NULL,' ',' [FP] = '||FILTER_PREDICATES) AS PLAN_OUTPUT
+
WITH io AS (
    FROM DBA_HIST_SQL_PLAN WHERE sql_id = :sql_id
+
  SELECT /*+ materialize */ decode(statistic_name,'logical reads', 'lio','pio') io_type
ORDER BY ID,
+
      , sum(value) io_value
        POSITION
+
  FROM v$segment_statistics
;
+
WHERE statistic_name IN ( 'logical reads' ,
</source>
+
                          'physical reads' ,
 
+
                          'physical reads direct' )
== INDEX 정보 추출하기 ==
+
GROUP BY decode(statistic_name,'logical reads', 'lio','pio')),
 
+
per_io AS
===  Function-based Index 컬럼 찾기 ===
+
( SELECT OWNER,
 
+
        object_name,
<source lang="sql">
+
        object_type,
SELECT table_owner,
+
        seg_io,
      TABLE_NAME,
+
        seg_value,
      index_name,
+
        round(seg_value / decode(seg_io,'lio',
      column_expression
+
                                      (SELECT io_value
FROM dba_ind_expressions
+
                                      FROM io
WHERE table_owner LIKE upper(ltrim(rtrim(:owner)))
+
                                      WHERE io_type='lio'),
    AND TABLE_NAME LIKE upper(ltrim(rtrim(:table))) ;
+
                                      (SELECT io_value
;
+
                                      FROM io
</source>
+
                                      WHERE io_type='pio') )*100,5) per_seg_io
 
+
FROM
=== 중복 인덱스 찾기(불필요 인덱스) ===
+
    ( SELECT ss.OWNER,
<source lang="sql">
+
                ss.object_name,
SELECT di.table_owner "OWNER" ,
+
                ss.object_type,
      di.TABLE_NAME ,
+
                decode(ss.statistic_name,'logical reads', 'lio','pio') seg_io,
          dic1.index_name || chr(10) || ' (' || replace(dic1.index_cols,' ',',') || decode(sign(dic1.cnt-6),1,'...') || ')' "삭제대상 INDEX" ,
+
                                                                        sum(ss.value) seg_value
                                                                                                                            dic2.index_name || chr(10) || ' (' || replace(dic2.index_cols,' ',',') || decode(sign(dic1.cnt-7),1,'...') || ')' "삭제원인 INDEX"
+
      FROM v$segment_statistics ss
FROM dba_indexes di ,
+
      WHERE ss.statistic_name IN ( 'logical reads' ,
    ( SELECT table_owner,
+
                                  'physical reads' ,
            TABLE_NAME,
+
                                  'physical reads direct' )
            index_owner,
+
      GROUP BY ss.OWNER,
            index_name,
+
                  ss.object_name,
            TRIM(MAX(DECODE(column_position, 1, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 2, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 3, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 4, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 5, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 6, COLUMN_NAME))) INDEX_COLS,
+
                  ss.object_type,
            count(*) cnt
+
                  decode(ss.statistic_name,'logical reads', 'lio','pio') ))
    FROM dba_ind_columns dic
+
SELECT *
    WHERE table_owner NOT IN ('SYS',
+
FROM
                              'SYSTEM')
+
( SELECT OWNER,
    GROUP BY table_owner,
+
        sum(decode(seg_io,'lio',per_seg_io)) AS lio,
              TABLE_NAME,
+
        sum(decode(seg_io,'pio',per_seg_io)) AS pio
              index_owner,
+
FROM per_io
              index_name ) dic1 ,
+
GROUP BY OWNER
    ( SELECT table_owner,
+
ORDER BY sum(decode(seg_io,'lio',per_seg_io)) DESC)
            TABLE_NAME,
+
WHERE rownum <= 50 - Segment별 전체 IO량(100%) 대비 IO량 (TABLE/INDEX 분리) WITH io AS
            index_owner,
+
( SELECT /*+ materialize */ decode(statistic_name,'logical reads', 'lio','pio') io_type,
            index_name,
+
                                                                                sum(value) io_value
            TRIM(MAX(DECODE(column_position, 1, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 2, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 3, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 4, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 5, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 6, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 7, COLUMN_NAME))) INDEX_COLS,
+
FROM v$segment_statistics
            count(*) cnt
+
WHERE statistic_name IN ( 'logical reads' ,
    FROM dba_ind_columns dic
+
                          'physical reads' ,
    WHERE table_owner NOT IN ('SYS',
+
                          'physical reads direct' )
                              'SYSTEM')
+
GROUP BY decode(statistic_name,'logical reads', 'lio','pio')),
     GROUP BY table_owner,
+
                                                                        per_io AS
              TABLE_NAME,
+
( SELECT OWNER,
              index_owner,
+
        object_name,
              index_name ) dic2
+
        object_type,
WHERE di.table_owner NOT IN ('SYS','SYSTEM')
+
        seg_io,
    AND di.owner=dic1.index_owner
+
        seg_value,
    AND di.index_name=dic1.index_name
+
        round(seg_value / decode(seg_io,'lio',
    AND di.table_owner=dic1.table_owner
+
                                      (SELECT io_value
    AND di.TABLE_NAME=dic1.TABLE_NAME
+
                                      FROM io
    AND dic1.table_owner=dic2.table_owner
+
                                      WHERE io_type='lio'),
    AND dic1.TABLE_NAME=dic2.TABLE_NAME
+
                                      (SELECT io_value
    AND dic1.index_name<>dic2.index_name
+
                                      FROM io
    AND dic2.index_cols LIKE dic1.index_cols || '%'
+
                                      WHERE io_type='pio') )*100,5) per_seg_io
    AND dic2.cnt>dic1.cnt
+
FROM
;
+
     ( SELECT ss.OWNER,
</source>
+
                ss.object_name,
 
+
                ss.object_type,
=== CONSTRAINTS 확인하기 ===
+
                decode(ss.statistic_name,'logical reads', 'lio','pio') seg_io,
-- 해당 테이블에 걸린 Constraints 확인하기
+
                                                                        sum(ss.value) seg_value
<source lang="sql">
+
      FROM v$segment_statistics ss
    SELECT t.owner ,
+
      WHERE ss.statistic_name IN ( 'logical reads' ,
          t.constraint_name ,
+
                                  'physical reads' ,
          t.constraint_type ,
+
                                  'physical reads direct' )
          t.TABLE_NAME ,
+
      GROUP BY ss.OWNER,
            c.COLUMN_NAME ,
+
                  ss.object_name,
              c.position ,
+
                  ss.object_type,
              t.r_owner ,
+
                  decode(ss.statistic_name,'logical reads', 'lio','pio') ))
              t.r_constraint_name ,
+
 
              t.status ,
+
SELECT *
              t.last_change ,
+
  FROM per_io
              t.index_owner ,
+
ORDER BY per_seg_io DESC  
              t.index_name
+
;
    FROM dba_constraints t ,
+
</source>  
        dba_cons_columns c WHERE t.TABLE_NAME = :table_name
+
 
    AND t.TABLE_NAME = c.TABLE_NAME
 
    AND t.constraint_name = c.constraint_name
 
    AND t.constraint_type <> 'C'
 
ORDER BY TABLE_NAME ASC, constraint_type DESC,
 
                        CONSTRAINT_NAME ASC, POSITION ASC
 
;
 
</source>
 
  
=== 해당 테이블을 참조하는 테이블(자식) Constraints 확인하기 ===
 
<source lang="sql">
 
SELECT t.owner ,
 
      t.CONSTRAINT_NAME ,
 
        t.constraint_type ,
 
        t.TABLE_NAME ,
 
          c.COLUMN_NAME ,
 
            c.POSITION ,
 
              t.r_owner ,
 
              t.r_constraint_name ,
 
              t.status ,
 
              t.last_change ,
 
              t.index_owner ,
 
              t.index_name
 
FROM dba_constraints t ,
 
    dba_cons_columns c
 
WHERE t.R_CONSTRAINT_NAME = '%'|| :table_name ||'%'
 
    AND t.TABLE_NAME = c.TABLE_NAME
 
    AND t.CONSTRAINT_NAME = c.CONSTRAINT_NAME
 
    AND t.constraint_type <> 'C'
 
ORDER BY TABLE_NAME ASC, constraint_type DESC,
 
                        CONSTRAINT_NAME ASC, POSITION ASC
 
;
 
</source>
 
  
  
=== v$segment_statistics 활용하기 ===
 
  
-- User별 전체 IO량(100%) 대비 IO량
 
<source lang="sql">
 
  
WITH io AS (
+
== 오라클 서버 스펙  ==
  SELECT /*+ materialize */ decode(statistic_name,'logical reads', 'lio','pio') io_type
+
=== 테이블 스페이스 사용량 ===
      , sum(value) io_value
+
* dba_data_files
   FROM v$segment_statistics
+
* dba_free_space
WHERE statistic_name IN ( 'logical reads' ,
+
<source lang="sql">
                          'physical reads' ,
+
SELECT A.TABLESPACE_NAME,
                          'physical reads direct' )
+
            A.TOTAL "TOTAL(MB)",
GROUP BY decode(statistic_name,'logical reads', 'lio','pio')),
+
            A.TOTAL - B.FREE "USED(MB)",
per_io AS
+
            NVL(B.FREE,0) "FREE(MB)",
( SELECT OWNER,
+
            ROUND((A.TOTAL - NVL(B.FREE,0))*100/TOTAL,0)  "USED(%)"
        object_name,
+
   FROM ( SELECT TABLESPACE_NAME
        object_type,
+
                , ROUND((SUM(BYTES)/1024/1024),0) AS TOTAL
        seg_io,
+
            FROM DBA_DATA_FILES
        seg_value,
+
            GROUP BY TABLESPACE_NAME
        round(seg_value / decode(seg_io,'lio',
+
      ) A
                                      (SELECT io_value
+
    , ( SELECT TABLESPACE_NAME
                                      FROM io
+
              , ROUND((SUM(BYTES)/1024/1024),0) AS FREE
                                      WHERE io_type='lio'),
+
          FROM DBA_FREE_SPACE
                                      (SELECT io_value
+
          GROUP BY  TABLESPACE_NAME
                                      FROM io
+
      ) B
                                      WHERE io_type='pio') )*100,5) per_seg_io
+
WHERE A.TABLESPACE_NAME = B.TABLESPACE_NAME(+)
FROM
+
ORDER BY A.TABLESPACE_NAME;
    ( SELECT ss.OWNER,
+
</source>
                ss.object_name,
+
 
                ss.object_type,
+
=== System 테이블스페이스에 비시스템 세그먼트 조회 ===
                decode(ss.statistic_name,'logical reads', 'lio','pio') seg_io,
+
* DBA_SEGMENTS
                                                                        sum(ss.value) seg_value
+
<source lang="sql">
      FROM v$segment_statistics ss
+
SELECT OWNER
      WHERE ss.statistic_name IN ( 'logical reads' ,
+
    , SEGMENT_NAME
                                  'physical reads' ,
+
    , SEGMENT_TYPE
                                  'physical reads direct' )
+
    , TABLESPACE_NAME
      GROUP BY ss.OWNER,
+
  FROM DBA_SEGMENTS
                  ss.object_name,
+
WHERE OWNER NOT IN ('SYS', 'SYSTEM')
                  ss.object_type,
+
  AND TABLESPACE_NAME = 'SYSTEM';
                  decode(ss.statistic_name,'logical reads', 'lio','pio') ))
+
</source>
SELECT *
+
 
 +
=== 오라클서버의 메모리 ===
 +
* v$sgastat
 +
<source lang="sql">
 +
SELECT * FROM V$SGASTAT;
 +
 
 +
SELECT POOL, SUM(BYTES) "SIZE"
 +
  FROM V$SGASTAT
 +
WHERE POOL = 'SHARED POOL'
 +
GROUP BY POOL
 +
</source>
 +
 
 +
=== 총 CPU Time 대비 SQL Parsing Time ===
 +
* V$SYSSTAT
 +
<source lang="sql">
 +
SELECT MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'CPU USED BY THIS SESSION',X.VALUE))) AS "CPU USED BY THIS SESSION" ,
 +
      MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'PARSE TIME CPU',X.VALUE))) AS "PARSE TIME CPU" ,
 +
      ROUND((MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'PARSE TIME CPU',X.VALUE)))/MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'CPU USED BY THIS SESSION',X.VALUE))) * 100),1)||'%' AS "PARSETIME/CPU(%)"
 
FROM
 
FROM
( SELECT OWNER,
+
    ( SELECT NAME,
        sum(decode(seg_io,'lio',per_seg_io)) AS lio,
+
            VALUE
        sum(decode(seg_io,'pio',per_seg_io)) AS pio
+
    FROM V$SYSSTAT
FROM per_io
+
    WHERE NAME IN ('CPU USED BY THIS SESSION',
GROUP BY OWNER
+
                    'PARSE TIME CPU') ) X,
ORDER BY sum(decode(seg_io,'lio',per_seg_io)) DESC)
+
    (SELECT LEVEL AS RNO
WHERE rownum <= 50 - Segment별 전체 IO량(100%) 대비 IO량 (TABLE/INDEX 분리) WITH io AS
+
    FROM DUAL CONNECT BY LEVEL<=2) Y ;
( SELECT /*+ materialize */ decode(statistic_name,'logical reads', 'lio','pio') io_type,
+
 
                                                                                sum(value) io_value
+
=== 총 Parsing Time 대비 Hard Parsing Time ===
FROM v$segment_statistics
+
* V$SYS_TIME_MODEL
WHERE statistic_name IN ( 'logical reads' ,
+
<source lang="sql">
                          'physical reads' ,
+
SELECT MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'PARSE TIME ELAPSED',X.VALUE))) AS "PARSE TIME ELAPSED" ,
                          'physical reads direct' )
+
      MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'HARD PARSE ELAPSED TIME',X.VALUE))) AS "HARD PARSE ELAPSED TIME" ,
GROUP BY decode(statistic_name,'logical reads', 'lio','pio')),
+
      ROUND((MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'HARD PARSE ELAPSED TIME',X.VALUE)))/MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'PARSE TIME ELAPSED',X.VALUE))) * 100),1)||'%' AS "HARD/PARSETORAL(%)"
                                                                        per_io AS
+
FROM
( SELECT OWNER,
+
    ( SELECT STAT_NAME AS NAME,
        object_name,
+
            VALUE
        object_type,
+
    FROM V$SYS_TIME_MODEL
        seg_io,
+
    WHERE STAT_NAME IN ('PARSE TIME ELAPSED',
        seg_value,
+
                        'HARD PARSE ELAPSED TIME') ) X,
        round(seg_value / decode(seg_io,'lio',
+
    (SELECT LEVEL AS RNO
                                      (SELECT io_value
+
    FROM DUAL CONNECT BY LEVEL<=2) Y ;
                                      FROM io
 
                                      WHERE io_type='lio'),
 
                                      (SELECT io_value
 
                                      FROM io
 
                                      WHERE io_type='pio') )*100,5) per_seg_io
 
FROM
 
    ( SELECT ss.OWNER,
 
                ss.object_name,
 
                ss.object_type,
 
                decode(ss.statistic_name,'logical reads', 'lio','pio') seg_io,
 
                                                                        sum(ss.value) seg_value
 
      FROM v$segment_statistics ss
 
      WHERE ss.statistic_name IN ( 'logical reads' ,
 
                                  'physical reads' ,
 
                                  'physical reads direct' )
 
      GROUP BY ss.OWNER,
 
                  ss.object_name,
 
                  ss.object_type,
 
                  decode(ss.statistic_name,'logical reads', 'lio','pio') ))
 
 
 
SELECT *
 
  FROM per_io
 
ORDER BY per_seg_io DESC
 
;
 
 
</source>  
 
</source>  
  
 +
=== Log file sync 관련 대기현상 Sync Writes Time ===
 +
* redo synch time의 단위는 centisecond (1/100 초)
 +
* v$sysstat의 stat 중 time 정보를 담고 있는 stat의 value 단위는 centisecond이다.
  
 +
<source lang="sql">
 +
SELECT MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'USER COMMITS',X.VALUE))) AS "USER COMMITS" ,
 +
      MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'REDO SYNCH WRITES',X.VALUE))) AS "REDO SYNCH WRITES" ,
 +
      MAX(DECODE(Y.RNO,3,DECODE(X.NAME,
 +
        'REDO SYNCH TIME',X.VALUE/100))) AS "REDO SYNCH TIME" ,
 +
      ROUND((MAX(DECODE(Y.RNO,3,DECODE(X.NAME,'REDO SYNCH TIME',X.VALUE/100)))/MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'REDO SYNCH WRITES',X.VALUE)))),3)||'초' AS "SYNCTIME/SYNCWRITES(초)"
 +
FROM
 +
    ( SELECT NAME,
 +
            VALUE
 +
    FROM V$SYSSTAT
 +
    WHERE NAME IN ('USER COMMITS' ,
 +
                    'REDO SYNCH TIME' ,
 +
                    'REDO SYNCH WRITES') ) X,
 +
    (SELECT LEVEL AS RNO
 +
    FROM DUAL CONNECT BY LEVEL<=3) Y
 +
;
 +
</source>
  
=== Parameter 확인하기 ===
+
----
 +
== INDEX 정보 추출하기 ==
 +
===  Function-based Index 컬럼 찾기 ===
  
 
<source lang="sql">  
 
<source lang="sql">  
 +
SELECT table_owner,
 +
      TABLE_NAME,
 +
      index_name,
 +
      column_expression
 +
FROM dba_ind_expressions
 +
WHERE table_owner LIKE upper(ltrim(rtrim(:owner)))
 +
    AND TABLE_NAME LIKE upper(ltrim(rtrim(:table))) ;
 +
;
 +
</source>
  
SET linesize 200
+
=== 중복 인덱스 찾기(불필요 인덱스) ===
SET pagesize 100 col name
+
<source lang="sql">
FOR a30 col value
+
SELECT di.table_owner "OWNER" ,
FOR a10 col display_value
+
       di.TABLE_NAME ,
FOR a10 col isdefault
+
          dic1.index_name || chr(10) || ' (' || replace(dic1.index_cols,' ',',') || decode(sign(dic1.cnt-6),1,'...') || ')' "삭제대상 INDEX" , dic2.index_name || chr(10) || ' (' || replace(dic2.index_cols,' ',',') || decode(sign(dic1.cnt-7),1,'...') || ')' "삭제원인 INDEX"
FOR a10 col ismodified
+
FROM dba_indexes di ,
FOR a10
+
    ( SELECT table_owner,
 
+
            TABLE_NAME,
SELECT name,
+
            index_owner,
       value,
+
            index_name,
      isdefault,
+
            TRIM(MAX(DECODE(column_position, 1, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 2, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 3, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 4, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 5, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 6, COLUMN_NAME))) INDEX_COLS,
      ismodified
+
            count(*) cnt
FROM v$parameter
+
    FROM dba_ind_columns dic
WHERE name IN ( 'lock_sga' ,
+
    WHERE table_owner NOT IN ('SYS',
                'db_cache_advice' ,
+
                              'SYSTEM')
                'optimizer_dynamic_sampling' ,
+
    GROUP BY table_owner,
                'session_cached_cursors' ,
+
              TABLE_NAME,
                'sga_max_size' ,
+
              index_owner,
                'sga_target' ,
+
              index_name ) dic1 ,
                'db_cache_size' ,
+
    ( SELECT table_owner,
                'shared_pool_size' ,
+
            TABLE_NAME,
                'shared_pool_reserved_size' ,
+
            index_owner,
                'log_buffer' ,
+
            index_name,
                'skip_unusable_indexes' ,
+
            TRIM(MAX(DECODE(column_position, 1, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 2, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 3, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 4, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 5, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 6, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 7, COLUMN_NAME))) INDEX_COLS,
                'pga_aggregate_target' ,
+
            count(*) cnt
                'workarea_size_policy' ,
+
    FROM dba_ind_columns dic
                'cpu_count' ,
+
     WHERE table_owner NOT IN ('SYS',
                'statistics_level') ;
+
                              'SYSTEM')
</source>
+
     GROUP BY table_owner,
 
+
              TABLE_NAME,
<source lang="sql">
+
              index_owner,
SELECT ksppinm AS name,
+
              index_name ) dic2
      ksppstvl AS value
+
WHERE di.table_owner NOT IN ('SYS','SYSTEM')
FROM sys.x$ksppi x
+
    AND di.owner=dic1.index_owner
  , sys.x$ksppcv y
+
    AND di.index_name=dic1.index_name
WHERE (x.indx = y.indx)
+
    AND di.table_owner=dic1.table_owner
AND (translate(ksppinm,'_','#') LIKE '%_optim_peek_user_binds%'
+
    AND di.TABLE_NAME=dic1.TABLE_NAME
    OR translate(ksppinm,'_','#') LIKE '%_kks_use_mutex_pin%'
+
    AND dic1.table_owner=dic2.table_owner
    OR translate(ksppinm,'_','#') LIKE '%_gby_hash_aggregation_enabled%'
+
    AND dic1.TABLE_NAME=dic2.TABLE_NAME
    OR translate(ksppinm,'_','#') LIKE '%_gc_affinity_time%'
+
    AND dic1.index_name<>dic2.index_name
    OR translate(ksppinm,'_','#') LIKE '%_optimizer_skip_scan_enabled%'
+
    AND dic2.index_cols LIKE dic1.index_cols || '%'
    OR translate(ksppinm,'_','#') LIKE '%_pga_max_size%'
+
    AND dic2.cnt>dic1.cnt
     OR translate(ksppinm,'_','#') LIKE '%_smm_max_size%'
+
;
     OR translate(ksppinm,'_','#') LIKE '%_b_tree_bitmap_plans%'
 
    OR translate(ksppinm,'_','#') LIKE '%_undo_autotune%' ) ;
 
 
</source>  
 
</source>  
  
=== Bind Peeked 확인하기 ===
+
=== CONSTRAINTS 확인하기 ===
 
+
-- 해당 테이블에 걸린 Constraints 확인하기
 
<source lang="sql">  
 
<source lang="sql">  
SELECT p.plan_table_output
+
    SELECT t.owner ,
  FROM
+
          t.constraint_name ,
( SELECT sql_id ,
+
          t.constraint_type ,
        child_number
+
          t.TABLE_NAME ,
FROM v$sql
+
            c.COLUMN_NAME ,
WHERE hash_value=:hash_value ) s
+
              c.position ,
    , TABLE(dbms_xplan.display_cursor(s.sql_id , s.child_number , 'typical +peeked_binds')) p
+
              t.r_owner ,
 +
              t.r_constraint_name ,
 +
              t.status ,
 +
              t.last_change ,
 +
              t.index_owner ,
 +
              t.index_name
 +
    FROM dba_constraints t ,
 +
        dba_cons_columns c WHERE t.TABLE_NAME = :table_name
 +
    AND t.TABLE_NAME = c.TABLE_NAME
 +
    AND t.constraint_name = c.constraint_name
 +
    AND t.constraint_type <> 'C'
 +
ORDER BY TABLE_NAME ASC, constraint_type DESC,
 +
                        CONSTRAINT_NAME ASC, POSITION ASC
 
;
 
;
</source>
 
 
 
-- Group By 처리하는 방식 변경
 
<source lang="sql">
 
파라미터 : _gby_hash_aggregation_enabled VERSION : 10g에서 신규 추가된 파라미터 해석방법 : FALSE
 
-
 
GROUP BY +
 
ORDER BY TRUE -
 
GROUP BY 주의사항 : 9i에서 10g로 업그레이드 수행 시 해당 파라미터가 True이면 기존
 
GROUP BY 절이 있는 SQL문의 정렬이 되지 않기 때문에 도출되는 결과가 바뀔 수 있다. 이럴 경우에는 해당 프로그램들에
 
ORDER by를 추가하여야 한다. _b_tree_bitmap_plans=TRUE
 
 
</source>
 
</source>
  
=== JOB 확인하기 ===
+
=== 해당 테이블을 참조하는 테이블(자식) Constraints 확인하기 ===
 
 
 
<source lang="sql">  
 
<source lang="sql">  
SELECT *
+
SELECT t.owner ,
  FROM dba_jobs
+
      t.CONSTRAINT_NAME ,
WHERE last_date >= to_date('20110906 14:00:00' , 'yyyymmdd hh24:mi:ss')
+
        t.constraint_type ,
ORDER BY last_date
+
        t.TABLE_NAME ,
</source>
+
          c.COLUMN_NAME ,
<source lang="sql">  
+
            c.POSITION ,
SELECT *
+
              t.r_owner ,
  FROM dba_objects
+
              t.r_constraint_name ,
WHERE object_name = upper('proc_olap_summ_measure_run_02')
+
              t.status ,
</source>  
+
              t.last_change ,
 +
              t.index_owner ,
 +
              t.index_name
 +
FROM dba_constraints t ,
 +
    dba_cons_columns c
 +
WHERE t.R_CONSTRAINT_NAME = '%'|| :table_name ||'%'
 +
    AND t.TABLE_NAME = c.TABLE_NAME
 +
    AND t.CONSTRAINT_NAME = c.CONSTRAINT_NAME
 +
    AND t.constraint_type <> 'C'
 +
ORDER BY TABLE_NAME ASC, constraint_type DESC,
 +
                        CONSTRAINT_NAME ASC, POSITION ASC
 +
;
 +
</source>
  
<source lang="sql">
 
SELECT *
 
FROM v$sqlarea WHERE program_id = 100286
 
;
 
</source>
 
  
<source lang="sql">
+
=== v$segment_statistics 활용하기 ===
SELECT *
 
FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR(NULL,NULL,’ALLSTATS COST LAST’));
 
</source>
 
  
=== DB Link SQL CURSOR 확인하기 ===
 
<source lang="sql">
 
SELECT inst_id ,
 
      kglnaown ,
 
      kglnaobj ,
 
      kglnadlk , -- DB Link
 
      decode(kglhdnsp , 0 , 'CURSOR' , 1 , 'TABLE/PROCEDURE' , 2 , 'BODY' , 3 , 'TRIGGER' , 4 , 'INDEX' , 5 , 'CLUSTER' , 6 , 'OBJECT' , 13 , 'JAVA SOURCE' , 14 , 'JAVA RESOURCE' , 15 , 'REPLICATED TABLE OBJECT' , 16 , 'REPLICATION INTERNAL PACKAGE' , 17 , 'CONTEXT POLICY' , 18 , 'PUB_SUB' , 19 , 'SUMMARY' , 20 , 'DIMENSION' , 21 , 'APP CONTEXT' , 22 , 'STORED OUTLINE' , 23 , 'RULESET' , 24 , 'RSRC PLAN' , 25 , 'RSRC CONSUMER GROUP' , 26 , 'PENDING RSRC PLAN' , 27 , 'PENDING RSRC CONSUMER GROUP' , 28 , 'SUBSCRIPTION' , 29 , 'LOCATION' , 30 , 'REMOTE OBJECT' , 31 , 'SNAPSHOT METADATA' , 32 , 'JAVA SHARED DATA' , 33 , 'SECURITY PROFILE' , 'INVALID NAMESPACE') ,
 
      decode(bitand(kglobflg , 3) , 0 , 'NOT LOADED' , 2 , 'NON-EXISTENT' , 3 , 'INVALID STATUS' , decode(kglobtyp , 0 , 'CURSOR' , 1 , 'INDEX' , 2 , 'TABLE' , 3 , 'CLUSTER' , 4 , 'VIEW' , 5 , 'SYNONYM' , 6 , 'SEQUENCE' , 7 , 'PROCEDURE' , 8 , 'FUNCTION' , 9 , 'PACKAGE' , 10 , 'NON-EXISTENT' , 11 , 'PACKAGE BODY' , 12 , 'TRIGGER' , 13 , 'TYPE' , 14 , 'TYPE BODY' , 15 , 'OBJECT' , 16 , 'USER' , 17 , 'DBLINK' , 18 , 'PIPE' , 19 , 'TABLE PARTITION' , 20 , 'INDEX PARTITION' , 21 , 'LOB' , 22 , 'LIBRARY' , 23 , 'DIRECTORY' , 24 , 'QUEUE' , 25 , 'INDEX-ORGANIZED TABLE' , 26 , 'REPLICATION OBJECT GROUP' , 27 , 'REPLICATION PROPAGATOR' , 28 , 'JAVA SOURCE' , 29 , 'JAVA CLASS' , 30 , 'JAVA RESOURCE' , 31 , 'JAVA JAR' , 32 , 'INDEX TYPE' , 33 , 'OPERATOR' , 34 , 'TABLE SUBPARTITION' , 35 , 'INDEX SUBPARTITION' , 36 , 'REPLICATED TABLE OBJECT' , 37 , 'REPLICATION INTERNAL PACKAGE' , 38 , 'CONTEXT POLICY' , 39 , 'PUB_SUB' , 40 , 'LOB PARTITION' , 41 , 'LOB SUBPARTITION' , 42 , 'SUMMARY' , 43 , 'DIMENSION' , 44 , 'APP CONTEXT' , 45 , 'STORED OUTLINE' , 46 , 'RULESET' , 47 , 'RSRC PLAN' , 48 , 'RSRC CONSUMER GROUP' , 49 , 'PENDING RSRC PLAN' , 50 , 'PENDING RSRC CONSUMER GROUP' , 51 , 'SUBSCRIPTION' , 52 , 'LOCATION' , 53 , 'REMOTE OBJECT' , 54 , 'SNAPSHOT METADATA' , 55 , 'IFS' , 56 , 'JAVA SHARED DATA' , 57 , 'SECURITY PROFILE' , 'INVALID TYPE')) ,
 
      kglobhs0+kglobhs1+kglobhs2+kglobhs3+kglobhs4+kglobhs5+kglobhs6 ,
 
      kglhdldc ,
 
      kglhdexc ,
 
      kglhdlkc ,
 
      kglobpc0 ,
 
      decode(kglhdkmk , 0 , 'NO' , 'YES') ,
 
      kglhdclt ,
 
      kglhdivc ,
 
      kglhdpar AS paddress,
 
      ------->>> 추가한 부분
 
  
      kglhdadr AS address,
 
      ------->>> 추가한 부분
 
  
      kglnahsh AS hash_value,
 
      ------->>> 추가한 부분
 
  
      kglobt03 AS sql_id ------->>> 추가한 부분
+
=== Parameter 확인하기 ===
FROM x$kglob
 
WHERE kglhdnsp = 0 -- NAMESPACE='CURSOR'
 
AND kglnadlk IS NOT NULL ;
 
</source>
 
  
 +
<source lang="sql">
  
=== INDEX Deleted ROWS CHECK [1] ===
 
- Validate + index_stats
 
<source lang="sql">
 
SET serveroutput ON
 
SET pagesize 0
 
 
SET linesize 200
 
SET linesize 200
SET feedback OFF
+
SET pagesize 100 col name
SET timing OFF
+
FOR a30 col value
 +
FOR a10 col display_value
 +
FOR a10 col isdefault
 +
FOR a10 col ismodified
 +
FOR a10
  
--------------------------------------------------------------------------------
+
SELECT name,
-- Work Time
+
      value,
--------------------------------------------------------------------------------
+
      isdefault,
 
+
      ismodified
COLUMN the_date new_value run_date
+
FROM v$parameter
SELECT to_char(sysdate,'yyyymmddhh24mi') the_date
+
WHERE name IN ( 'lock_sga' ,
FROM dual;
+
                'db_cache_advice' ,
 +
                'optimizer_dynamic_sampling' ,
 +
                'session_cached_cursors' ,
 +
                'sga_max_size' ,
 +
                'sga_target' ,
 +
                'db_cache_size' ,
 +
                'shared_pool_size' ,
 +
                'shared_pool_reserved_size' ,
 +
                'log_buffer' ,
 +
                'skip_unusable_indexes' ,
 +
                'pga_aggregate_target' ,
 +
                'workarea_size_policy' ,
 +
                'cpu_count' ,
 +
                'statistics_level') ;
 +
</source>
  
--------------------------------------------------------------------------------
+
<source lang="sql">
-- File Creation - Index Size Check Script
+
SELECT ksppinm AS name,
--------------------------------------------------------------------------------
+
       ksppstvl AS value
spool index_validate_check.SQL DECLARE
+
FROM sys.x$ksppi x
CURSOR cur_index_name IS
+
  , sys.x$ksppcv y
SELECT OWNER,
+
WHERE (x.indx = y.indx)
       index_name
+
AND (translate(ksppinm,'_','#') LIKE '%_optim_peek_user_binds%'
FROM dba_indexes
+
    OR translate(ksppinm,'_','#') LIKE '%_kks_use_mutex_pin%'
WHERE OWNER = 'SYSTEM' ;
+
    OR translate(ksppinm,'_','#') LIKE '%_gby_hash_aggregation_enabled%'
 
+
    OR translate(ksppinm,'_','#') LIKE '%_gc_affinity_time%'
BEGIN dbms_output.enable(buffer_size=>2000000);
+
    OR translate(ksppinm,'_','#') LIKE '%_optimizer_skip_scan_enabled%'
FOR index_rec IN cur_index_name LOOP dbms_output.put_line('Validate index '||index_rec.OWNER||'.'||index_rec.index_name||';');
+
    OR translate(ksppinm,'_','#') LIKE '%_pga_max_size%'
dbms_output.put_line(' ');
+
    OR translate(ksppinm,'_','#') LIKE '%_smm_max_size%'
dbms_output.put_line('select  '''||index_rec.OWNER||''',');
+
    OR translate(ksppinm,'_','#') LIKE '%_b_tree_bitmap_plans%'
dbms_output.put_line('       name index_name,');
+
    OR translate(ksppinm,'_','#') LIKE '%_undo_autotune%' ) ;
dbms_output.put_line('        lf_rows Tot_rows,');
 
dbms_output.put_line('       del_lf_rows Deleted_Rows,');
 
dbms_output.put_line('       (del_lf_rows * 100)/decode(lf_rows,0,0.1,lf_rows) "deleted(%)",');
 
dbms_output.put_line('        round(btree_space/1024/1024/1024,3) "tot_space(GB)",');
 
dbms_output.put_line('       round(used_space/1024/1024/1024,3) "used_space(GB)",');
 
dbms_output.put_line('       pct_used "used_pct(%)",');
 
dbms_output.put_line('       100 - pct_used "empty_pct(%)",');
 
dbms_output.put_line('       decode( sign((del_lf_rows * 100)/decode(lf_rows,0,0.1,lf_rows) - 20),1,');
 
dbms_output.put_line('               ''--->> Rebuild required'',');
 
dbms_output.put_line('               ''--->> Good'') Check_Result');
 
dbms_output.put_line(' from index_stats ;');
 
END LOOP;
 
END;
 
/
 
 
</source>  
 
</source>  
  
 +
=== Bind Peeked 확인하기 ===
  
 
<source lang="sql">  
 
<source lang="sql">  
--------------------------------------------------------------------------------
+
SELECT p.plan_table_output
-- Run - Index Size Check Script
+
  FROM
--------------------------------------------------------------------------------
+
( SELECT sql_id ,
col OWNER format a10;
+
        child_number
col index_name format a33;
+
FROM v$sql
col tot_rows format 99999999 col deleted_rows format 99999999 spool c:\total_index_size_check_&run_date..txt prompt OWNER INDEX name total ROWS deleted ROWS deleted(%) tot_space used_space used_pct(%) empty_pct(%) prompt
+
WHERE hash_value=:hash_value ) s
---------------------------------------------------------------------------------------------------------------------------------
+
    , TABLE(dbms_xplan.display_cursor(s.sql_id , s.child_number , 'typical +peeked_binds')) p
@index_validate_check spool OFF
+
;
SET feedback ON
+
</source>
SET serveroutput OFF
+
 
################################################################################
+
 
## INDEX Deleted ROWS CHECK [2] - INDEX STATISTICS
+
-- Group By 처리하는 방식 변경
################################################################################
+
<source lang="sql">
col blevel heading "INDEX|BLEVEL"
+
파라미터 : _gby_hash_aggregation_enabled VERSION : 10g에서 신규 추가된 파라미터 해석방법 : FALSE
col leaf_blocks heading "LEAF|BLOCKS"  
+
-
col num_rows heading "NUM|ROWS"
+
GROUP BY +
col usable_key_count_per_block heading "USABLE_KEY|COUNT|PER_BLOCK"
+
ORDER BY TRUE -
col current_key_count_per_block heading "CURRENT_KEY|COUNT|PER_BLOCK"
+
GROUP BY 주의사항 : 9i에서 10g로 업그레이드 수행 시 해당 파라미터가 True이면 기존
col used_percent heading "USED|PERCENT|(%)"
+
GROUP BY 절이 있는 SQL문의 정렬이 되지 않기 때문에 도출되는 결과가 바뀔 수 있다. 이럴 경우에는 해당 프로그램들에
col empty_percent heading "EMPTY|PERCENT|(%)"
+
ORDER by를 추가하여야 한다. _b_tree_bitmap_plans=TRUE
 +
</source>
 +
 
 +
=== JOB 확인하기 ===
 +
 
 +
<source lang="sql">
 +
SELECT *
 +
  FROM dba_jobs
 +
WHERE last_date >= to_date('20110906 14:00:00' , 'yyyymmdd hh24:mi:ss')
 +
ORDER BY last_date
 +
</source>
 +
<source lang="sql">
 
SELECT *
 
SELECT *
FROM
+
  FROM dba_objects
( SELECT /*+ leading(i) use_hash(i s) */ i.index_name,
+
WHERE object_name = upper('proc_olap_summ_measure_run_02')
                                        max(i.blevel) AS blevel,
+
</source>
                                        max(i.leaf_blocks) AS leaf_blocks,
+
 
                                        max(i.num_rows) AS num_rows,
+
<source lang="sql">
                                        sum(s.blocks) AS "BLOCKS",
+
SELECT *
                                        sum(s.bytes)/1024/1024 AS "SIZE(MB)",
+
FROM v$sqlarea WHERE program_id = 100286
                                        max(i.usable_key_count_per_block) AS usable_key_count_per_block,
+
;
                                        max(i.current_key_count_per_block) AS current_key_count_per_block,
+
</source>
                                        max(i.used_percent) AS used_percent,
 
                                        max(i.empty_percent) AS empty_percent
 
FROM
 
    ( SELECT i.index_name,
 
              i.blevel,
 
              i.leaf_blocks,
 
              i.num_rows,
 
              round(i.usable_block_size / (i.avg_key_length),0) AS usable_key_count_per_block,
 
              round(i.num_rows / i.leaf_blocks,0) AS current_key_count_per_block,
 
              round((i.num_rows / i.leaf_blocks) / (i.usable_block_size / i.avg_key_length) * 100,0) AS used_percent,
 
              round(100 -((i.num_rows / i.leaf_blocks) / (i.usable_block_size / i.avg_key_length) * 100)) AS empty_percent
 
      FROM
 
          ( SELECT i.index_name,
 
                  sum(c1.avg_col_len)+9 AS avg_key_length,
 
                  max(t.block_size*0.98) usable_block_size,
 
                  max(i.blevel) blevel,
 
                  max(i.leaf_blocks) leaf_blocks,
 
                  max(i.num_rows) num_rows
 
          FROM dba_indexes i,
 
                dba_tab_columns c1,
 
                dba_ind_columns c2,
 
                dba_tablespaces t
 
          WHERE i.OWNER=upper('GCKDPROD') --and    i.table_name = upper('TSD_PTSEQ_I')
 
--and    i.index_name LIKE '%'
 
  
              AND i.OWNER=c1.OWNER
+
<source lang="sql">
              AND i.TABLE_NAME=c1.TABLE_NAME
+
SELECT *
              AND c1.OWNER=c2.table_owner
+
FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR(NULL,NULL,’ALLSTATS COST LAST’));
              AND c1.TABLE_NAME=c2.TABLE_NAME
+
</source>
              AND c1.COLUMN_NAME=c2.COLUMN_NAME
 
              AND i.OWNER=c2.index_owner
 
              AND i.index_name=c2.index_name
 
              AND i.tablespace_name=t.tablespace_name
 
          GROUP BY i.index_name HAVING max(i.leaf_blocks) >= 10000 ) i ) i,
 
                                                                          dba_segments s
 
WHERE s.OWNER = 'GCKDPROD'
 
    AND i.index_name = s.segment_name
 
GROUP BY i.index_name
 
ORDER BY max(i.empty_percent) DESC)
 
WHERE rownum <= 50 ;
 
</source>  
 
  
 +
=== DB Link SQL CURSOR 확인하기 ===
 
<source lang="sql">  
 
<source lang="sql">  
################################################################################
+
SELECT inst_id ,
## Locking Contention Query
+
       kglnaown ,
################################################################################
+
       kglnaobj ,
SELECT OS_USER_NAME AS OSUSER,
+
       kglnadlk , -- DB Link
       s.serial# AS "SERIAL NO.",
+
       decode(kglhdnsp , 0 , 'CURSOR' , 1 , 'TABLE/PROCEDURE' , 2 , 'BODY' , 3 , 'TRIGGER' , 4 , 'INDEX' , 5 , 'CLUSTER' , 6 , 'OBJECT' , 13 , 'JAVA SOURCE' , 14 , 'JAVA RESOURCE' , 15 , 'REPLICATED TABLE OBJECT' , 16 , 'REPLICATION INTERNAL PACKAGE' , 17 , 'CONTEXT POLICY' , 18 , 'PUB_SUB' , 19 , 'SUMMARY' , 20 , 'DIMENSION' , 21 , 'APP CONTEXT' , 22 , 'STORED OUTLINE' , 23 , 'RULESET' , 24 , 'RSRC PLAN' , 25 , 'RSRC CONSUMER GROUP' , 26 , 'PENDING RSRC PLAN' , 27 , 'PENDING RSRC CONSUMER GROUP' , 28 , 'SUBSCRIPTION' , 29 , 'LOCATION' , 30 , 'REMOTE OBJECT' , 31 , 'SNAPSHOT METADATA' , 32 , 'JAVA SHARED DATA' , 33 , 'SECURITY PROFILE' , 'INVALID NAMESPACE') ,
       PROCESS AS "PID",
+
      decode(bitand(kglobflg , 3) , 0 , 'NOT LOADED' , 2 , 'NON-EXISTENT' , 3 , 'INVALID STATUS' , decode(kglobtyp , 0 , 'CURSOR' , 1 , 'INDEX' , 2 , 'TABLE' , 3 , 'CLUSTER' , 4 , 'VIEW' , 5 , 'SYNONYM' , 6 , 'SEQUENCE' , 7 , 'PROCEDURE' , 8 , 'FUNCTION' , 9 , 'PACKAGE' , 10 , 'NON-EXISTENT' , 11 , 'PACKAGE BODY' , 12 , 'TRIGGER' , 13 , 'TYPE' , 14 , 'TYPE BODY' , 15 , 'OBJECT' , 16 , 'USER' , 17 , 'DBLINK' , 18 , 'PIPE' , 19 , 'TABLE PARTITION' , 20 , 'INDEX PARTITION' , 21 , 'LOB' , 22 , 'LIBRARY' , 23 , 'DIRECTORY' , 24 , 'QUEUE' , 25 , 'INDEX-ORGANIZED TABLE' , 26 , 'REPLICATION OBJECT GROUP' , 27 , 'REPLICATION PROPAGATOR' , 28 , 'JAVA SOURCE' , 29 , 'JAVA CLASS' , 30 , 'JAVA RESOURCE' , 31 , 'JAVA JAR' , 32 , 'INDEX TYPE' , 33 , 'OPERATOR' , 34 , 'TABLE SUBPARTITION' , 35 , 'INDEX SUBPARTITION' , 36 , 'REPLICATED TABLE OBJECT' , 37 , 'REPLICATION INTERNAL PACKAGE' , 38 , 'CONTEXT POLICY' , 39 , 'PUB_SUB' , 40 , 'LOB PARTITION' , 41 , 'LOB SUBPARTITION' , 42 , 'SUMMARY' , 43 , 'DIMENSION' , 44 , 'APP CONTEXT' , 45 , 'STORED OUTLINE' , 46 , 'RULESET' , 47 , 'RSRC PLAN' , 48 , 'RSRC CONSUMER GROUP' , 49 , 'PENDING RSRC PLAN' , 50 , 'PENDING RSRC CONSUMER GROUP' , 51 , 'SUBSCRIPTION' , 52 , 'LOCATION' , 53 , 'REMOTE OBJECT' , 54 , 'SNAPSHOT METADATA' , 55 , 'IFS' , 56 , 'JAVA SHARED DATA' , 57 , 'SECURITY PROFILE' , 'INVALID TYPE')) ,
       ORACLE_USERNAME AS "USERNAME",
+
      kglobhs0+kglobhs1+kglobhs2+kglobhs3+kglobhs4+kglobhs5+kglobhs6 ,
       l.SID AS "SID",
+
      kglhdldc ,
      DECODE(l.TYPE -- Long locks, 'TM', 'dml/data enq (TM)', 'TX', 'transac enq (TX) ', 'UL', 'pls usr lock (UL)'
+
      kglhdexc ,
-- Short locks, 'BL', 'buf hash tbl (BL)', 'CF', 'control file (CF)', 'CI', 'cross inst f (CI)', 'CU', 'cursor bind (CU) ', 'DF', 'data file (CF) ', 'DL', 'direct load (DL) ', 'DM', 'mount/strtup (DM)', 'DR', 'reco lock (DR) ', 'DX', 'distrib tran (DX)', 'FI', 'sga opn file (FI)', 'FS', 'file set (FS) ', 'IN', 'instance num (IN)', 'IR', 'instce recvr (IR)', 'IS', 'get state (IS) ', 'IV', 'libcache inv (IV)', 'JQ', 'job queue (JQ) ', 'KK', 'log sw kick (KK) ', 'LS', 'log switch (LS) ', 'MM', 'mount def (MM) ', 'MR', 'media recvry (MR)', 'PF', 'pwfile enq (PF) ', 'PR', 'process strt (PR)', 'RW', 'row wait (RW) ', 'RT', 'redo thread (RT) ', 'SC', 'scn enq (SC) ', 'SM', 'smon lock (SM) ', 'SN', 'seqno instce (SN)', 'SQ', 'seqno enq (SQ) ', 'ST', 'space transc (ST)', 'SV', 'seqno value (SV) ', 'TA', 'generic enq (TA) ', 'TD', 'dll enq (TD) ', 'TE', 'extend seg (TE) ', 'TS', 'temp segment (TS)', 'TT', 'temp table (TT) ', 'UN', 'user name (UN) ', 'WL', 'write redo (WL) ', 'TYPE = ' || l.TYPE) AS type,
+
      kglhdlkc ,
decode(l.lmode, 0, 'none', 1, 'null', 2, 'RS', 3, 'RX', 4, 'S', 5, 'SRX', 6, 'Exclusive', TO_CHAR(l.lmode)) AS lmode,
+
      kglobpc0 ,
decode(l.request, 0, 'none', 1, 'null', 2, 'RS', 3, 'RX', 4, 'S', 5, 'SRX', 6, 'X', TO_CHAR(l.request)) AS lrequest,
+
      decode(kglhdkmk , 0 , 'NO' , 'YES') ,
decode(BLOCK, 0, 'Not Blocking', 1, 'Blocking', 2, 'Global', block) AS "DETAIL",
+
      kglhdclt ,
OWNER,
+
      kglhdivc ,
object_name
+
      kglhdpar AS paddress,
FROM sys.v_$locked_object lo,
+
      ------->>> 추가한 부분
                          dba_objects DO,
+
 
                                      sys.v_$lock l,
+
      kglhdadr AS address,
(SELECT a.sid,
+
      ------->>> 추가한 부분
        a.serial#
 
FROM v$session a,
 
                v$bgprocess b
 
WHERE a.paddr = b.paddr(+)) s
 
WHERE lo.object_id = DO.object_id
 
AND l.sid = lo.session_id
 
AND s.sid = l.sid
 
;
 
</source>  
 
  
== ASH를 이용한 모니터링 ==
+
      kglnahsh AS hash_value,
* 최근 가장 많이 수행 된 SQL과 수행 점유율(수행 횟수)
+
      ------->>> 추가한 부분
* v$active_session_history
+
 
<source lang="sql">  
+
       kglobt03 AS sql_id ------->>> 추가한 부분
SELECT sql_id ,
+
FROM x$kglob
       COUNT(*) ,
+
WHERE kglhdnsp = 0 -- NAMESPACE='CURSOR'
      COUNT(*) *100/sum(COUNT(*)) over() pctload
+
AND kglnadlk IS NOT NULL ;
  FROM v$active_session_history
 
WHERE sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
 
AND sample_time < to_date(:to_time,'yyyymmdd hh24miss')
 
GROUP BY sql_id
 
ORDER BY COUNT(*) DESC ;
 
 
</source>  
 
</source>  
  
=== 특정 Session이 가장 많이 수행 된 SQL과 수행 점유율(수행 횟수) ===
+
 
* v$active_session_history
+
=== INDEX Deleted ROWS CHECK [1] ===  
 +
- Validate + index_stats
 
<source lang="sql">  
 
<source lang="sql">  
SELECT sql_id ,
+
SET serveroutput ON
      COUNT(*) ,
+
SET pagesize 0
      COUNT(*) *100/sum(COUNT(*)) over() pctload
+
SET linesize 200
FROM v$active_session_history
+
SET feedback OFF
WHERE sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
+
SET timing OFF
AND sample_time < to_date(:to_time,'yyyymmdd hh24miss')
 
AND session_id = :b1
 
GROUP BY sql_id
 
ORDER BY COUNT(*) DESC ;
 
</source>
 
  
=== 주요한 이벤트 메트릭 표시 gv$eventmetric v$event_name ===
+
--------------------------------------------------------------------------------
* sqlplus 스크립트
+
-- Work Time
<source lang="sql">
+
--------------------------------------------------------------------------------
/*
 
  eventmetric.sql - sqlplus script - displays significant event metrics
 
*/
 
  
col "Time /Delta" for a14
+
COLUMN the_date new_value run_date
col name for a40
+
SELECT to_char(sysdate,'yyyymmddhh24mi') the_date
col INST_ID for 999
+
FROM dual;
set linesize 140
 
set pagesize 1000
 
  
set wrap off
+
--------------------------------------------------------------------------------
select "Time /Delta",inst_id,name,
+
-- File Creation - Index Size Check Script
        T_per_wait_fg*10 "Avg_FG_wait_ms", round(T_waited_fg/100,1) "Waited_FG_sec", W_count_fg "W_count_FG",
+
--------------------------------------------------------------------------------
        round(T_waited/100,1) "Waited_tot_sec", W_count "W_count_tot"     
+
spool index_validate_check.SQL DECLARE
from (
+
CURSOR cur_index_name IS
  select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time /Delta",
+
SELECT OWNER,
      em.inst_id,en.name,
+
       index_name
      sum(em.time_waited_fg) T_waited_fg, sum(em.time_waited) T_waited,sum(wait_count) W_count, sum(wait_count_fg) W_count_fg,
+
FROM dba_indexes
      sum(decode(em.wait_count, 0,0,round(em.time_waited/em.wait_count,2))) T_per_wait,
+
WHERE OWNER = 'SYSTEM' ;
       sum(decode(em.wait_count_fg, 0,0,round(em.time_waited_fg/em.wait_count_fg,2))) T_per_wait_fg
 
  from gv$eventmetric em
 
    , v$event_name en
 
  where em.event#=en.event#
 
      and en.wait_class <>'Idle'
 
  group by em.inst_id,en.name,em.event_id
 
  order by T_waited_fg desc
 
  )
 
where rownum<=20;
 
set wrap on
 
  
</source>
+
BEGIN dbms_output.enable(buffer_size=>2000000);
 
+
FOR index_rec IN cur_index_name LOOP dbms_output.put_line('Validate index '||index_rec.OWNER||'.'||index_rec.index_name||';');
=== 중요한 시스템 메트릭 표시 gv$sysmetric ===
+
dbms_output.put_line(' ');
<source lang="sql">  
+
dbms_output.put_line('select '''||index_rec.OWNER||''',');
select "Time+Delta", "Metric",
+
dbms_output.put_line('        name index_name,');
      case when "Total" >10000000 then '* '||round("Total"/1024/1024,0)||' M'
+
dbms_output.put_line('        lf_rows Tot_rows,');
            when "Total" between 10000 and 10000000 then '+ '||round("Total"/1024,0)||' K'
+
dbms_output.put_line('        del_lf_rows Deleted_Rows,');
            when "Total" between 10 and 1024 then '  '||to_char(round("Total",0))
+
dbms_output.put_line('       (del_lf_rows * 100)/decode(lf_rows,0,0.1,lf_rows) "deleted(%)",');
            else ' '||to_char("Total")  
+
dbms_output.put_line('       round(btree_space/1024/1024/1024,3) "tot_space(GB)",');
      end "Total"
+
dbms_output.put_line('       round(used_space/1024/1024/1024,3) "used_space(GB)",');
from (
+
dbms_output.put_line('       pct_used "used_pct(%)",');
  select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time+Delta",
+
dbms_output.put_line('       100 - pct_used "empty_pct(%)",');
      metric_name||' - '||metric_unit "Metric",
+
dbms_output.put_line('       decode( sign((del_lf_rows * 100)/decode(lf_rows,0,0.1,lf_rows) - 20),1,');
       nvl(sum(value_inst1),0)+nvl(sum(value_inst2),0)+nvl(sum(value_inst3),0)+nvl(sum(value_inst4),0)+
+
dbms_output.put_line('               ''--->> Rebuild required'',');
       nvl(sum(value_inst5),0)+nvl(sum(value_inst6),0)+nvl(sum(value_inst7),0)+nvl(sum(value_inst8),0) "Total",
+
dbms_output.put_line('               ''--->> Good'') Check_Result');
      sum(value_inst1) inst1, sum(value_inst2) inst2, sum(value_inst3) inst3, sum(value_inst4) inst4,
+
dbms_output.put_line(' from index_stats ;');
       sum(value_inst5) inst5, sum(value_inst6) inst6, sum(value_inst7) inst7, sum(value_inst8) inst8
+
END LOOP;
from
+
END;
  ( select begin_time,intsize_csec,metric_name,metric_unit,metric_id,group_id,
+
/
       case inst_id when 1 then round(value,1) end value_inst1,
+
</source>  
      case inst_id when 2 then round(value,1) end value_inst2,
+
 
       case inst_id when 3 then round(value,1) end value_inst3,
+
 
      case inst_id when 4 then round(value,1) end value_inst4,
+
<source lang="sql">  
       case inst_id when 5 then round(value,1) end value_inst5,
+
--------------------------------------------------------------------------------
      case inst_id when 6 then round(value,1) end value_inst6,
+
-- Run - Index Size Check Script
      case inst_id when 7 then round(value,1) end value_inst7,
+
--------------------------------------------------------------------------------
       case inst_id when 8 then round(value,1) end value_inst8
+
col OWNER format a10;
  from gv$sysmetric
+
col index_name format a33;
  where metric_name in ('Host CPU Utilization (%)','Current OS Load', 'Physical Write Total IO Requests Per Sec',  
+
col tot_rows format 99999999 col deleted_rows format 99999999 spool c:\total_index_size_check_&run_date..txt prompt OWNER INDEX name total ROWS deleted ROWS deleted(%) tot_space used_space used_pct(%) empty_pct(%) prompt
        'Physical Write Total Bytes Per Sec', 'Physical Write IO Requests Per Sec', 'Physical Write Bytes Per Sec',
+
---------------------------------------------------------------------------------------------------------------------------------
        'I/O Requests per Second', 'I/O Megabytes per Second',
+
@index_validate_check spool OFF
        'Physical Read Total Bytes Per Sec', 'Physical Read Total IO Requests Per Sec', 'Physical Read IO Requests Per Sec',
+
SET feedback ON
        'CPU Usage Per Sec','Network Traffic Volume Per Sec','Logons Per Sec','Redo Generated Per Sec','Redo Writes Per Sec',
+
SET serveroutput OFF
        'User Transaction Per Sec','Average Active Sessions','Average Synchronous Single-Block Read Latency',
+
################################################################################
        'Logical Reads Per Sec','DB Block Changes Per Sec')
+
## INDEX Deleted ROWS CHECK [2] - INDEX STATISTICS
  )
+
################################################################################
group by metric_id,group_id,metric_name,metric_unit
+
col blevel heading "INDEX|BLEVEL"
order by metric_name
+
col leaf_blocks heading "LEAF|BLOCKS"
);
+
col num_rows heading "NUM|ROWS"
</source>
+
col usable_key_count_per_block heading "USABLE_KEY|COUNT|PER_BLOCK"
 
+
col current_key_count_per_block heading "CURRENT_KEY|COUNT|PER_BLOCK"  
=== RAC 인스턴스별로 상세한 중요한 시스템 메트릭 gv$sysmetric ===
+
col used_percent heading "USED|PERCENT|(%)"
<source lang="sql">  
+
col empty_percent heading "EMPTY|PERCENT|(%)"
select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time+Delta",
+
SELECT *
      metric_name||' - '||metric_unit "Metric",  
+
FROM
      sum(value_inst1) inst1, sum(value_inst2) inst2, sum(value_inst3) inst3, sum(value_inst4) inst4,
+
( SELECT /*+ leading(i) use_hash(i s) */ i.index_name,
      sum(value_inst5) inst5, sum(value_inst6) inst6
+
                                        max(i.blevel) AS blevel,
  from
+
                                        max(i.leaf_blocks) AS leaf_blocks,
  ( select begin_time,intsize_csec,metric_name,metric_unit,metric_id,group_id,
+
                                        max(i.num_rows) AS num_rows,
      case inst_id when 1 then round(value,1) end value_inst1,
+
                                        sum(s.blocks) AS "BLOCKS",
      case inst_id when 2 then round(value,1) end value_inst2,
+
                                        sum(s.bytes)/1024/1024 AS "SIZE(MB)",
      case inst_id when 3 then round(value,1) end value_inst3,
+
                                        max(i.usable_key_count_per_block) AS usable_key_count_per_block,
      case inst_id when 4 then round(value,1) end value_inst4,
+
                                        max(i.current_key_count_per_block) AS current_key_count_per_block,
      case inst_id when 5 then round(value,1) end value_inst5,
+
                                        max(i.used_percent) AS used_percent,
      case inst_id when 6 then round(value,1) end value_inst6
+
                                        max(i.empty_percent) AS empty_percent
  from gv$sysmetric
+
  FROM
  where metric_name in ('Host CPU Utilization (%)','Current OS Load', 'Physical Write Total IO Requests Per Sec',
+
    ( SELECT i.index_name,
        'Physical Write Total Bytes Per Sec', 'Physical Write IO Requests Per Sec', 'Physical Write Bytes Per Sec',
+
              i.blevel,
        'I/O Requests per Second', 'I/O Megabytes per Second',
+
              i.leaf_blocks,
        'Physical Read Total Bytes Per Sec', 'Physical Read Total IO Requests Per Sec', 'Physical Read IO Requests Per Sec',
+
              i.num_rows,
        'CPU Usage Per Sec','Network Traffic Volume Per Sec','Logons Per Sec','Redo Generated Per Sec',
+
              round(i.usable_block_size / (i.avg_key_length),0) AS usable_key_count_per_block,
        'User Transaction Per Sec','Average Active Sessions','Average Synchronous Single-Block Read Latency',
+
              round(i.num_rows / i.leaf_blocks,0) AS current_key_count_per_block,
        'Logical Reads Per Sec','DB Block Changes Per Sec')
+
              round((i.num_rows / i.leaf_blocks) / (i.usable_block_size / i.avg_key_length) * 100,0) AS used_percent,
  )
+
              round(100 -((i.num_rows / i.leaf_blocks) / (i.usable_block_size / i.avg_key_length) * 100)) AS empty_percent
  group by metric_id,group_id,metric_name,metric_unit
+
      FROM
order by metric_name;
+
          ( SELECT i.index_name,
</source>
+
                  sum(c1.avg_col_len)+9 AS avg_key_length,
 
+
                  max(t.block_size*0.98) usable_block_size,
=== 특정 구간 이벤트 별 대기 시간 v$active_session_history ===
+
                  max(i.blevel) blevel,
<source lang="sql">
+
                  max(i.leaf_blocks) leaf_blocks,
SELECT NVL(a.event, 'ON CPU') AS event,
+
                  max(i.num_rows) num_rows
      COUNT(*) AS total_wait_time
+
          FROM dba_indexes i,
FROM v$active_session_history a
+
                dba_tab_columns c1,
WHERE sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
+
                dba_ind_columns c2,
AND sample_time < to_date(:to_time,'yyyymmdd hh24miss')
+
                dba_tablespaces t
GROUP BY a.event
+
          WHERE i.OWNER=upper('GCKDPROD') --and    i.table_name = upper('TSD_PTSEQ_I')
ORDER BY total_wait_time DESC;
+
  --and    i.index_name LIKE '%'
</source>
+
 
 +
              AND i.OWNER=c1.OWNER
 +
              AND i.TABLE_NAME=c1.TABLE_NAME
 +
              AND c1.OWNER=c2.table_owner
 +
              AND c1.TABLE_NAME=c2.TABLE_NAME
 +
              AND c1.COLUMN_NAME=c2.COLUMN_NAME
 +
              AND i.OWNER=c2.index_owner
 +
              AND i.index_name=c2.index_name
 +
              AND i.tablespace_name=t.tablespace_name
 +
          GROUP BY i.index_name HAVING max(i.leaf_blocks) >= 10000 ) i ) i,
 +
                                                                          dba_segments s
 +
WHERE s.OWNER = 'GCKDPROD'
 +
    AND i.index_name = s.segment_name
 +
GROUP BY i.index_name
 +
ORDER BY max(i.empty_percent) DESC)
 +
WHERE rownum <= 50 ;
 +
</source>  
  
=== 특정 구간 CPU 점유율 순 - TOP SQL ===
 
 
<source lang="sql">  
 
<source lang="sql">  
SELECT ash.session_id ,
+
################################################################################
       ash.session_serial# ,
+
## Locking Contention Query
       ash.user_id ,
+
################################################################################
       ash.program ,
+
SELECT OS_USER_NAME AS OSUSER,
       MAX(en.name) event_name ,
+
       s.serial# AS "SERIAL NO.",
      SUM(decode(ash.session_state , 'ON CPU' , 1 , 0)) "CPU" ,
+
       PROCESS AS "PID",
      SUM(decode(ash.session_state , 'WAITING' , 1 , 0)) - SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "WAITING" ,
+
      ORACLE_USERNAME AS "USERNAME",
      SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "IO" ,
+
       l.SID AS "SID",
      SUM(decode(session_state , 'ON CPU' , 1 , 1)) "TOTAL"
+
       DECODE(l.TYPE -- Long locks, 'TM', 'dml/data enq (TM)', 'TX', 'transac enq (TX) ', 'UL', 'pls usr lock (UL)'
FROM v$active_session_history ash
+
-- Short locks, 'BL', 'buf hash tbl (BL)', 'CF', 'control file (CF)', 'CI', 'cross inst f (CI)', 'CU', 'cursor bind (CU) ', 'DF', 'data file (CF) ', 'DL', 'direct load (DL) ', 'DM', 'mount/strtup (DM)', 'DR', 'reco lock (DR) ', 'DX', 'distrib tran (DX)', 'FI', 'sga opn file (FI)', 'FS', 'file set (FS) ', 'IN', 'instance num (IN)', 'IR', 'instce recvr (IR)', 'IS', 'get state (IS) ', 'IV', 'libcache inv (IV)', 'JQ', 'job queue (JQ) ', 'KK', 'log sw kick (KK) ', 'LS', 'log switch (LS) ', 'MM', 'mount def (MM) ', 'MR', 'media recvry (MR)', 'PF', 'pwfile enq (PF) ', 'PR', 'process strt (PR)', 'RW', 'row wait (RW) ', 'RT', 'redo thread (RT) ', 'SC', 'scn enq (SC) ', 'SM', 'smon lock (SM) ', 'SN', 'seqno instce (SN)', 'SQ', 'seqno enq (SQ) ', 'ST', 'space transc (ST)', 'SV', 'seqno value (SV) ', 'TA', 'generic enq (TA) ', 'TD', 'dll enq (TD) ', 'TE', 'extend seg (TE) ', 'TS', 'temp segment (TS)', 'TT', 'temp table (TT) ', 'UN', 'user name (UN) ', 'WL', 'write redo (WL) ', 'TYPE = ' || l.TYPE) AS type,
  , v$event_name en
+
decode(l.lmode, 0, 'none', 1, 'null', 2, 'RS', 3, 'RX', 4, 'S', 5, 'SRX', 6, 'Exclusive', TO_CHAR(l.lmode)) AS lmode,
WHERE en.event# = ash.event#
+
decode(l.request, 0, 'none', 1, 'null', 2, 'RS', 3, 'RX', 4, 'S', 5, 'SRX', 6, 'X', TO_CHAR(l.request)) AS lrequest,
AND ash.sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
+
decode(BLOCK, 0, 'Not Blocking', 1, 'Blocking', 2, 'Global', block) AS "DETAIL",
AND ash.sample_time < to_date(:to_time,'yyyymmdd hh24miss')
+
OWNER,
GROUP BY session_id ,
+
object_name
        user_id ,
+
FROM sys.v_$locked_object lo,
        session_serial# ,
+
                          dba_objects DO,
        program
+
                                      sys.v_$lock l,
ORDER BY SUM(decode(session_state , 'ON CPU' , 1 , 1))  
+
(SELECT a.sid,
 +
        a.serial#
 +
FROM v$session a,
 +
                v$bgprocess b
 +
WHERE a.paddr = b.paddr(+)) s
 +
WHERE lo.object_id = DO.object_id
 +
AND l.sid = lo.session_id
 +
AND s.sid = l.sid
 
;
 
;
</source>
+
</source>  
  
=== 특정 구간 CPU 점유율 순 - TOP SESSION v$active_session_history ===
+
== ASH를 이용한 모니터링 ==
 +
* 최근 가장 많이 수행 된 SQL과 수행 점유율(수행 횟수)
 +
* v$active_session_history  
 
<source lang="sql">  
 
<source lang="sql">  
SELECT ash.session_id ,
+
SELECT sql_id ,
       ash.session_serial# ,
+
       COUNT(*) ,
      ash.user_id ,
+
       COUNT(*) *100/sum(COUNT(*)) over() pctload
      ash.program ,
+
  FROM v$active_session_history
       SUM(decode(ash.session_state , 'ON CPU' , 1 , 0)) "CPU" ,
+
WHERE sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
      SUM(decode(ash.session_state , 'WAITING' , 1 , 0)) - SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "WAITING" ,
+
AND sample_time < to_date(:to_time,'yyyymmdd hh24miss')
       SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "IO" ,
+
GROUP BY sql_id
       SUM(decode(session_state , 'ON CPU' , 1 , 1)) "TOTAL"
+
ORDER BY COUNT(*) DESC ;
FROM v$active_session_history ash
+
</source>
  , v$event_name en
+
 
WHERE en.event# = ash.event#
+
=== 특정 Session이 가장 많이 수행 된 SQL과 수행 점유율(수행 횟수) ===
AND ash.sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
+
* v$active_session_history
AND ash.sample_time < to_date(:to_time,'yyyymmdd hh24miss')
+
<source lang="sql">
GROUP BY session_id ,
+
SELECT sql_id ,
        user_id ,
+
       COUNT(*) ,
        session_serial# ,
+
       COUNT(*) *100/sum(COUNT(*)) over() pctload
        program
+
FROM v$active_session_history
ORDER BY SUM(decode(session_state , 'ON CPU' , 1 , 1))  
+
WHERE sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
;
+
AND sample_time < to_date(:to_time,'yyyymmdd hh24miss')
 +
AND session_id = :b1
 +
GROUP BY sql_id
 +
ORDER BY COUNT(*) DESC ;
 
</source>
 
</source>
  
=== 특정 구간 수행 이력 v$active_session_history ===
+
=== 주요한 이벤트 메트릭 표시 gv$eventmetric v$event_name ===
 +
* sqlplus 스크립트
 
<source lang="sql">  
 
<source lang="sql">  
SELECT ash.sample_time TIME ,
+
/*
      ash.session_id ,
+
  eventmetric.sql - sqlplus script - displays significant event metrics
      ash.session_serial# ,
+
*/
      ash.user_id ,
 
      ash.program ,
 
      ash.module ,
 
      ash.client_id ,
 
      ash.machine ,
 
      ash.session_state ,
 
      ash.event ,
 
      ash.sql_id ,
 
      ash.blocking_session ,
 
      ash.current_obj# ,
 
      ash.current_file# ,
 
      ash.pga_allocated ,
 
      ash.temp_space_allocated
 
FROM v$active_session_history ash
 
WHERE ash.sample_time >= TO_DATE(:from_time , 'yyyymmdd hh24miss')
 
AND ash.sample_time < TO_DATE(:to_time , 'yyyymmdd hh24miss')
 
ORDER BY ash.sample_time DESC
 
;
 
</source>
 
  
== AWR을 이용한 모니터링 ==
+
col "Time /Delta" for a14
----
+
col name for a40
=== AWR을 이용한 literal SQL 추출 방법 ===
+
col INST_ID for 999
* get_literal_sql.SQL
+
set linesize 140
<source lang="sql">
+
set pagesize 1000
SET linesize 120 col SCHEMA_NAME
 
FOR a8 col module_name
 
FOR a15 col sql_text
 
FOR a35 col SCHEMA_NAME heading "SCHEMA|NAME" col module_name heading "MODULE|NAME" col literal_sql_cnt heading "LITERAL|CNT"
 
FOR 99999 col execution_cnt heading "EXECUTION|CNT"
 
FOR 99999 col plan_cnt heading "PLAN|CNT"
 
FOR 999 col literal_sql_ratio heading "LITERAL|RATIO(%)"
 
FOR 999 accept i_begin_time prompt 'Enter begin time[YYYYMMDDHH24]: ' accept i_end_time prompt 'Enter end  time[YYYYMMDDHH24]: ' VARIABLE v_begin_time char(10) VARIABLE v_end_time char(10) EXEC :v_begin_time:=&i_begin_time EXEC :v_end_time :=&i_end_time
 
  
SELECT a.SCHEMA_NAME , a.module_name , a.literal_sql_cnt , a.execution_cnt , round(a.literal_sql_cnt/a.execution_cnt*100,1) literal_sql_ratio, a.plan_cnt,
+
set wrap off
    ( SELECT sql_text
+
select "Time /Delta",inst_id,name,  
    FROM dba_hist_sqltext
+
        T_per_wait_fg*10 "Avg_FG_wait_ms", round(T_waited_fg/100,1) "Waited_FG_sec", W_count_fg "W_count_FG",
    WHERE dbid = a.dbid
+
        round(T_waited/100,1) "Waited_tot_sec", W_count "W_count_tot"     
        AND sql_id = a.max_sql_id ) sql_text
+
from (
FROM
+
  select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time /Delta",
    ( SELECT s.force_matching_signature,
+
      em.inst_id,en.name,
            s.dbid ,
+
      sum(em.time_waited_fg) T_waited_fg, sum(em.time_waited) T_waited,sum(wait_count) W_count, sum(wait_count_fg) W_count_fg,
            s.parsing_schema_name SCHEMA_NAME ,
+
      sum(decode(em.wait_count, 0,0,round(em.time_waited/em.wait_count,2))) T_per_wait,
                                  s.module module_name ,
+
      sum(decode(em.wait_count_fg, 0,0,round(em.time_waited_fg/em.wait_count_fg,2))) T_per_wait_fg
                                  count(*) literal_sql_cnt ,
+
  from gv$eventmetric em
                                  sum(s.executions_total) execution_cnt ,
+
    , v$event_name en
                                  max(s.sql_id) max_sql_id,
+
  where em.event#=en.event#
                                  count(DISTINCT s.plan_hash_value) plan_cnt
+
      and en.wait_class <>'Idle'
    FROM sys.wrm$_snapshot w ,
+
  group by em.inst_id,en.name,em.event_id
                            dba_hist_sqlstat s
+
  order by T_waited_fg desc
    WHERE w.begin_interval_time >= to_timestamp(:v_begin_time , 'yyyymmddhh24')
+
  )  
        AND w.end_interval_time <= to_timestamp(:v_end_time , 'yyyymmddhh24')
+
where rownum<=20;
        AND w.snap_id = s.snap_id
+
set wrap on
        AND w.dbid = s.dbid
 
        AND w.instance_number = s.instance_number
 
        AND s.parsing_schema_name <> 'SYS'
 
    GROUP BY s.dbid ,
 
              s.force_matching_signature ,
 
              s.parsing_schema_name ,
 
              s.module
 
    ORDER BY count(*) DESC ) a
 
WHERE rownum<=10;
 
</source>
 
  
 +
</source>
  
=== AWR SQL ordered BY Elapsed Time ===
+
=== 중요한 시스템 메트릭 표시 gv$sysmetric ===
 
<source lang="sql">  
 
<source lang="sql">  
 +
select "Time+Delta", "Metric",
 +
      case when "Total" >10000000 then '* '||round("Total"/1024/1024,0)||' M'
 +
            when "Total" between 10000 and 10000000 then '+ '||round("Total"/1024,0)||' K'
 +
            when "Total" between 10 and 1024 then '  '||to_char(round("Total",0))
 +
            else '  '||to_char("Total")
 +
      end "Total"
 +
from (
 +
select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time+Delta",
 +
      metric_name||' - '||metric_unit "Metric",
 +
      nvl(sum(value_inst1),0)+nvl(sum(value_inst2),0)+nvl(sum(value_inst3),0)+nvl(sum(value_inst4),0)+
 +
      nvl(sum(value_inst5),0)+nvl(sum(value_inst6),0)+nvl(sum(value_inst7),0)+nvl(sum(value_inst8),0) "Total",
 +
      sum(value_inst1) inst1, sum(value_inst2) inst2, sum(value_inst3) inst3, sum(value_inst4) inst4,
 +
      sum(value_inst5) inst5, sum(value_inst6) inst6, sum(value_inst7) inst7, sum(value_inst8) inst8
 +
from
 +
  ( select begin_time,intsize_csec,metric_name,metric_unit,metric_id,group_id,
 +
      case inst_id when 1 then round(value,1) end value_inst1,
 +
      case inst_id when 2 then round(value,1) end value_inst2,
 +
      case inst_id when 3 then round(value,1) end value_inst3,
 +
      case inst_id when 4 then round(value,1) end value_inst4,
 +
      case inst_id when 5 then round(value,1) end value_inst5,
 +
      case inst_id when 6 then round(value,1) end value_inst6,
 +
      case inst_id when 7 then round(value,1) end value_inst7,
 +
      case inst_id when 8 then round(value,1) end value_inst8
 +
  from gv$sysmetric
 +
  where metric_name in ('Host CPU Utilization (%)','Current OS Load', 'Physical Write Total IO Requests Per Sec',
 +
        'Physical Write Total Bytes Per Sec', 'Physical Write IO Requests Per Sec', 'Physical Write Bytes Per Sec',
 +
        'I/O Requests per Second', 'I/O Megabytes per Second',
 +
        'Physical Read Total Bytes Per Sec', 'Physical Read Total IO Requests Per Sec', 'Physical Read IO Requests Per Sec',
 +
        'CPU Usage Per Sec','Network Traffic Volume Per Sec','Logons Per Sec','Redo Generated Per Sec','Redo Writes Per Sec',
 +
        'User Transaction Per Sec','Average Active Sessions','Average Synchronous Single-Block Read Latency',
 +
        'Logical Reads Per Sec','DB Block Changes Per Sec')
 +
  )
 +
group by metric_id,group_id,metric_name,metric_unit
 +
order by metric_name
 +
);
 +
</source>
  
def dbid="&1"
+
=== RAC 인스턴스별로 상세한 중요한 시스템 메트릭 gv$sysmetric ===
def inst_num="&2"
 
def snap_start="&3"
 
def snap_end="&4"
 
def top_num="&5"
 
col ela_Time format 999990.00 heading "ElaTime|(s)"
 
col EXEC format 9999990 heading "Exec"
 
col elapexec format 999990.00 heading "ElaTimeperexec (s)"
 
--col Total              format 9999990.00        heading "DBTime%"
 
col CPU format 999990.00 heading "CPU%"
 
col IO format 999990.00 heading "IO%"
 
col SQLId format a15 heading "SQL_ID"
 
col SQLModule format a50 heading "SQL_Module"
 
col SQLText format a50 heading "SQL_Text"
 
 
 
WITH sqt AS
 
(SELECT elap,
 
        cput,
 
        EXEC,
 
        norm_val,
 
        iowt,
 
        sql_id,
 
        module,
 
        rnum
 
FROM
 
    (SELECT sql_id,
 
            module,
 
            elap,
 
            norm_val,
 
            cput,
 
            EXEC,
 
            iowt,
 
            rownum rnum
 
      FROM
 
          (SELECT sql_id,
 
                  MAX(module) module,
 
                              SUM(elapsed_time_delta) elap, (100 * (SUM(elapsed_time_delta) / NULLIF(
 
                                                                                                        (SELECT (SUM(e.VALUE) - SUM(b.VALUE)) / 1000000 / 60
 
                                                                                                          FROM DBA_HIST_SYS_TIME_MODEL e, DBA_HIST_SYS_TIME_MODEL b
 
                                                                                                          WHERE e.SNAP_ID = &snap_end
 
                                                                                                              AND e.DBID = &dbid
 
                                                                                                              AND e.INSTANCE_NUMBER = &inst_num
 
                                                                                                              AND e.STAT_NAME = 'DB time'
 
                                                                                                              AND b.SNAP_ID = &snap_start
 
                                                                                                              AND b.DBID = &dbid
 
                                                                                                              AND b.INSTANCE_NUMBER = &inst_num
 
                                                                                                              AND b.STAT_NAME = 'DB time'), 0))) norm_val,
 
                                                                                                                                                SUM(cpu_time_delta) cput,
 
                                                                                                                                                                    SUM(executions_delta) EXEC,
 
                                                                                                                                                                                          SUM(iowait_delta) iowt
 
          FROM dba_hist_sqlstat
 
          WHERE dbid = &dbid
 
              AND instance_number = &inst_num
 
              AND &snap_start < snap_id
 
              AND snap_id <= &snap_end
 
          GROUP BY sql_id
 
          ORDER BY nvl(SUM(elapsed_time_delta), -1) DESC, sql_id))
 
WHERE rnum < &top_num --  and (rnum <= :tsql_min or norm_val > :top_pct_sql)
 
)
 
;
 
</source>
 
 
 
 
 
 
<source lang="sql">  
 
<source lang="sql">  
SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.elap / 1000000), to_number(NULL)) ela_Time,
+
select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time+Delta",
                            sqt.EXEC EXEC,
+
      metric_name||' - '||metric_unit "Metric",
                                    decode(sqt.EXEC, 0, to_number(NULL), (sqt.elap / sqt.EXEC / 1000000)) elapexec,
+
      sum(value_inst1) inst1, sum(value_inst2) inst2, sum(value_inst3) inst3, sum(value_inst4) inst4,
                                    sqt.norm_val Total ,
+
      sum(value_inst5) inst5, sum(value_inst6) inst6
                                    --(100 * (sum(elap) /nullif(dbtime.dbtime,0))) norm_val
+
from
  --null Total,
+
  ( select begin_time,intsize_csec,metric_name,metric_unit,metric_id,group_id,
 +
      case inst_id when 1 then round(value,1) end value_inst1,
 +
      case inst_id when 2 then round(value,1) end value_inst2,
 +
      case inst_id when 3 then round(value,1) end value_inst3,
 +
      case inst_id when 4 then round(value,1) end value_inst4,
 +
      case inst_id when 5 then round(value,1) end value_inst5,
 +
      case inst_id when 6 then round(value,1) end value_inst6
 +
  from gv$sysmetric
 +
  where metric_name in ('Host CPU Utilization (%)','Current OS Load', 'Physical Write Total IO Requests Per Sec',
 +
        'Physical Write Total Bytes Per Sec', 'Physical Write IO Requests Per Sec', 'Physical Write Bytes Per Sec',
 +
        'I/O Requests per Second', 'I/O Megabytes per Second',
 +
        'Physical Read Total Bytes Per Sec', 'Physical Read Total IO Requests Per Sec', 'Physical Read IO Requests Per Sec',
 +
        'CPU Usage Per Sec','Network Traffic Volume Per Sec','Logons Per Sec','Redo Generated Per Sec',
 +
        'User Transaction Per Sec','Average Active Sessions','Average Synchronous Single-Block Read Latency',
 +
        'Logical Reads Per Sec','DB Block Changes Per Sec')
 +
  )
 +
  group by metric_id,group_id,metric_name,metric_unit
 +
order by metric_name;
 +
</source>
  
                                    decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))) CPU,
+
=== 특정 구간 이벤트 별 대기 시간 v$active_session_history ===
                                    decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.iowt / sqt.elap))) IO,
+
<source lang="sql">
                                    sqt.sql_id SQLId,
+
SELECT NVL(a.event, 'ON CPU') AS event,
                                    to_clob(decode(sqt.module, NULL, NULL, 'Module: ' || sqt.module)) SQLModule,
+
      COUNT(*) AS total_wait_time
                                    nvl(substr(st.sql_text, 0, 50), to_clob('** SQL Text Not Available **')) SQLText
+
FROM v$active_session_history a
FROM sqt,
+
WHERE sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
    dba_hist_sqltext st
+
AND sample_time < to_date(:to_time,'yyyymmdd hh24miss')
WHERE st.sql_id(+) = sqt.sql_id
+
GROUP BY a.event
AND st.dbid(+) = &dbid
+
ORDER BY total_wait_time DESC;
ORDER BY sqt.rnum
 
/
 
 
</source>
 
</source>
  
=== AWR SQL ordered BY Elapsed Time ===
+
=== 특정 구간 CPU 점유율 순 - TOP SQL ===
 
<source lang="sql">  
 
<source lang="sql">  
undef dbid
+
SELECT ash.session_id ,
undef inst_num
+
      ash.session_serial# ,
undef snap_start
+
      ash.user_id ,
undef snap_end
+
      ash.program ,
undef sql_id
+
      MAX(en.name) event_name ,
undef top_num
+
      SUM(decode(ash.session_state , 'ON CPU' , 1 , 0)) "CPU" ,
 +
      SUM(decode(ash.session_state , 'WAITING' , 1 , 0)) - SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "WAITING" ,
 +
      SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "IO" ,
 +
      SUM(decode(session_state , 'ON CPU' , 1 , 1)) "TOTAL"
 +
FROM v$active_session_history ash
 +
  , v$event_name en
 +
WHERE en.event# = ash.event#
 +
AND ash.sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
 +
AND ash.sample_time < to_date(:to_time,'yyyymmdd hh24miss')
 +
GROUP BY session_id ,
 +
        user_id ,
 +
        session_serial# ,
 +
        program
 +
ORDER BY SUM(decode(session_state , 'ON CPU' , 1 , 1))
 +
;
 +
</source>
  
WITH sqt AS
+
=== 특정 구간 CPU 점유율 순 - TOP SESSION v$active_session_history ===
(SELECT elap,
+
<source lang="sql">
        cput,
+
SELECT ash.session_id ,
        EXEC,
+
      ash.session_serial# ,
        iowt,
+
      ash.user_id ,
        norm_val,
+
      ash.program ,
        sql_id,
+
      SUM(decode(ash.session_state , 'ON CPU' , 1 , 0)) "CPU" ,
        module,
+
      SUM(decode(ash.session_state , 'WAITING' , 1 , 0)) - SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "WAITING" ,
        rnum
+
      SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "IO" ,
FROM
+
      SUM(decode(session_state , 'ON CPU' , 1 , 1)) "TOTAL"
    (SELECT sql_id,
+
FROM v$active_session_history ash
            module,
+
  , v$event_name en
            elap,
+
WHERE en.event# = ash.event#
            norm_val,
+
AND ash.sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
            cput,
+
AND ash.sample_time < to_date(:to_time,'yyyymmdd hh24miss')
            EXEC,
+
GROUP BY session_id ,
            iowt,
+
        user_id ,
            rownum rnum
+
        session_serial# ,
      FROM
+
        program
          (SELECT sql_id ,
+
ORDER BY SUM(decode(session_state , 'ON CPU' , 1 , 1))  
                  MAX(module) module ,
+
;
                              SUM(elapsed_time_delta) elap , (100 * (SUM(elapsed_time_delta) / NULLIF(:dbtime,0))) norm_val ,
+
</source>
                                                                                                                  SUM(cpu_time_delta) cput ,                                                                                                                                       SUM(executions_delta) EXEC ,                                                                                                                                                            SUM(iowait_delta) iowt
+
 
          FROM dba_hist_sqlstat
+
=== 특정 구간 수행 이력 v$active_session_history ===
          WHERE dbid = :dbid
+
<source lang="sql">
              AND instance_number = :inst_num
+
SELECT ash.sample_time TIME ,
              AND :bid < snap_id
+
      ash.session_id ,
              AND snap_id <= :eid
+
      ash.session_serial# ,
          GROUP BY sql_id
+
      ash.user_id ,
          ORDER BY nvl(SUM(elapsed_time_delta), -1) DESC, sql_id))
+
      ash.program ,
WHERE rnum < :tsql_max
+
      ash.module ,
    AND (rnum <= :tsql_min
+
      ash.client_id ,
          OR norm_val > :top_pct_sql))
+
      ash.machine ,
 +
      ash.session_state ,
 +
      ash.event ,
 +
      ash.sql_id ,
 +
      ash.blocking_session ,
 +
      ash.current_obj# ,
 +
      ash.current_file# ,
 +
      ash.pga_allocated ,
 +
      ash.temp_space_allocated
 +
FROM v$active_session_history ash
 +
WHERE ash.sample_time >= TO_DATE(:from_time , 'yyyymmdd hh24miss')
 +
AND ash.sample_time < TO_DATE(:to_time , 'yyyymmdd hh24miss')
 +
ORDER BY ash.sample_time DESC
 
;
 
;
 
</source>
 
</source>
  
 +
== AWR을 이용한 모니터링 ==
 +
----
 +
=== AWR을 이용한 literal SQL 추출 방법 ===
 +
* get_literal_sql.SQL
 
<source lang="sql">  
 
<source lang="sql">  
SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.elap/1000000), to_number(NULL)),
+
SET linesize 120 col SCHEMA_NAME
                            sqt.EXEC,
+
FOR a8 col module_name
                                decode(sqt.EXEC, 0, to_number(NULL),(sqt.elap / sqt.EXEC / 1000000)),
+
FOR a15 col sql_text
                                sqt.norm_val,
+
FOR a35 col SCHEMA_NAME heading "SCHEMA|NAME" col module_name heading "MODULE|NAME" col literal_sql_cnt heading "LITERAL|CNT"
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
+
FOR 99999 col execution_cnt heading "EXECUTION|CNT"
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.iowt / sqt.elap))),
+
FOR 99999 col plan_cnt heading "PLAN|CNT"
                                sqt.sql_id,
+
FOR 999 col literal_sql_ratio heading "LITERAL|RATIO(%)"
                                to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
+
FOR 999 accept i_begin_time prompt 'Enter begin time[YYYYMMDDHH24]: ' accept i_end_time prompt 'Enter end  time[YYYYMMDDHH24]: ' VARIABLE v_begin_time char(10) VARIABLE v_end_time char(10) EXEC :v_begin_time:=&i_begin_time EXEC :v_end_time :=&i_end_time
                                nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
 
FROM sqt,
 
    dba_hist_sqltext st
 
WHERE st.sql_id(+) = sqt.sql_id
 
AND st.dbid(+) = :dbid
 
ORDER BY sqt.rnum
 
;
 
</source>
 
 
 
=== AWR SQL ordered BY CPU Time ===
 
 
 
<source lang="sql">
 
WITH sqt AS
 
(SELECT elap,
 
        cput,
 
        EXEC,
 
        uiot,
 
        norm_val,
 
        sql_id,
 
        module,
 
        rnum
 
FROM
 
    (SELECT sql_id,
 
            module,
 
            elap,
 
            norm_val,
 
            cput,
 
            EXEC,
 
            uiot,
 
            rownum rnum
 
      FROM
 
          (SELECT sql_id ,
 
                  MAX(module) module ,
 
                              SUM(elapsed_time_delta) elap , (100 * (SUM(cpu_time_delta) / NULLIF(:tcpu,0))) norm_val ,
 
                                                                                                            SUM(cpu_time_delta) cput ,                                                                                                                                SUM(executions_delta) EXEC ,                                                                                                                                                      SUM(iowait_delta) uiot
 
          FROM dba_hist_sqlstat
 
          WHERE dbid = :dbid
 
              AND instance_number = :inst_num
 
              AND :bid < snap_id
 
              AND snap_id <= :eid
 
          GROUP BY sql_id
 
          ORDER BY nvl(SUM(cpu_time_delta), -1) DESC, sql_id))
 
WHERE rnum < :tsql_max
 
    AND (rnum <= :tsql_min
 
          OR norm_val > :top_pct_sql))
 
;
 
</source>
 
  
 +
SELECT a.SCHEMA_NAME , a.module_name , a.literal_sql_cnt , a.execution_cnt , round(a.literal_sql_cnt/a.execution_cnt*100,1) literal_sql_ratio, a.plan_cnt,
 +
    ( SELECT sql_text
 +
    FROM dba_hist_sqltext
 +
    WHERE dbid = a.dbid
 +
        AND sql_id = a.max_sql_id ) sql_text
 +
FROM
 +
    ( SELECT s.force_matching_signature,
 +
            s.dbid ,
 +
            s.parsing_schema_name SCHEMA_NAME ,
 +
                                  s.module module_name ,
 +
                                  count(*) literal_sql_cnt ,
 +
                                  sum(s.executions_total) execution_cnt ,
 +
                                  max(s.sql_id) max_sql_id,
 +
                                  count(DISTINCT s.plan_hash_value) plan_cnt
 +
    FROM sys.wrm$_snapshot w ,
 +
                            dba_hist_sqlstat s
 +
    WHERE w.begin_interval_time >= to_timestamp(:v_begin_time , 'yyyymmddhh24')
 +
        AND w.end_interval_time <= to_timestamp(:v_end_time , 'yyyymmddhh24')
 +
        AND w.snap_id = s.snap_id
 +
        AND w.dbid = s.dbid
 +
        AND w.instance_number = s.instance_number
 +
        AND s.parsing_schema_name <> 'SYS'
 +
    GROUP BY s.dbid ,
 +
              s.force_matching_signature ,
 +
              s.parsing_schema_name ,
 +
              s.module
 +
    ORDER BY count(*) DESC ) a
 +
WHERE rownum<=10;
 +
</source>
 +
 +
 +
=== AWR SQL ordered BY Elapsed Time ===
 
<source lang="sql">  
 
<source lang="sql">  
SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.cput/1000000), to_number(NULL)),
 
                            sqt.EXEC,
 
                                decode(sqt.EXEC, 0, to_number(NULL), (sqt.cput / sqt.EXEC /1000000)),
 
                                sqt.norm_val,
 
                                nvl((sqt.elap/1000000), to_number(NULL)),
 
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
 
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.uiot / sqt.elap))),
 
                                sqt.sql_id,
 
                                to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
 
                                nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
 
FROM sqt,
 
    dba_hist_sqltext st
 
WHERE st.sql_id(+) = sqt.sql_id
 
AND st.dbid(+) = :dbid
 
ORDER BY sqt.rnum
 
;
 
</source>
 
  
=== AWR SQL ordered BY USER I/O Wait Time ===
+
def dbid="&1"
<source lang="sql">  
+
def inst_num="&2"
WITH sqt AS
+
def snap_start="&3"
(SELECT elap,
+
def snap_end="&4"
         cput,
+
def top_num="&5"
         EXEC,
+
col ela_Time format 999990.00 heading "ElaTime|(s)"
         uiot,
+
col EXEC format 9999990 heading "Exec"
         norm_val,
+
col elapexec format 999990.00 heading "ElaTimeperexec (s)"
         sql_id,
+
--col Total              format 9999990.00        heading "DBTime%"
         module,
+
col CPU format 999990.00 heading "CPU%"
         rnum
+
col IO format 999990.00 heading "IO%"
  FROM
+
col SQLId format a15 heading "SQL_ID"
     (SELECT sql_id,
+
col SQLModule format a50 heading "SQL_Module"
             module,
+
col SQLText format a50 heading "SQL_Text"
             elap,
+
 
             norm_val,
+
WITH sqt AS
             cput,
+
(SELECT elap,
             EXEC,
+
        cput,
             uiot,
+
        EXEC,
             rownum rnum
+
        norm_val,
       FROM
+
        iowt,
           (SELECT sql_id ,
+
        sql_id,
                   MAX(module) module ,
+
        module,
                               SUM(elapsed_time_delta) elap , (100 * (SUM(iowait_delta) / NULLIF(:uiowt,0))) norm_val ,
+
        rnum
                                                                                                            SUM(cpu_time_delta) cput ,                                                                                                                                SUM(executions_delta) EXEC ,                                                                                                                                                      SUM(iowait_delta) uiot
+
FROM
           FROM dba_hist_sqlstat
+
    (SELECT sql_id,
           WHERE dbid = :dbid
+
            module,
               AND instance_number = :inst_num
+
            elap,
               AND :bid < snap_id
+
            norm_val,
               AND snap_id <= :eid
+
            cput,
           GROUP BY sql_id
+
            EXEC,
           ORDER BY nvl(SUM(iowait_delta), -1) DESC, sql_id))
+
            iowt,
  WHERE rnum < :tsql_max
+
            rownum rnum
     AND (rnum <= :tsql_min
+
      FROM
           OR norm_val > :top_pct_sql))
+
          (SELECT sql_id,
;
+
                  MAX(module) module,
</source>
+
                              SUM(elapsed_time_delta) elap, (100 * (SUM(elapsed_time_delta) / NULLIF(
 
+
                                                                                                        (SELECT (SUM(e.VALUE) - SUM(b.VALUE)) / 1000000 / 60
<source lang="sql">  
+
                                                                                                          FROM DBA_HIST_SYS_TIME_MODEL e, DBA_HIST_SYS_TIME_MODEL b
SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.uiot/1000000), to_number(NULL)),
+
                                                                                                          WHERE e.SNAP_ID = &snap_end
                             sqt.EXEC,
+
                                                                                                              AND e.DBID = &dbid
                                 decode(sqt.EXEC, 0, to_number(NULL), (sqt.uiot / sqt.EXEC /1000000)),
+
                                                                                                              AND e.INSTANCE_NUMBER = &inst_num
                                 sqt.norm_val,
+
                                                                                                              AND e.STAT_NAME = 'DB time'
                                 nvl((sqt.elap/1000000), to_number(NULL)),
+
                                                                                                              AND b.SNAP_ID = &snap_start
                                 decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
+
                                                                                                              AND b.DBID = &dbid
                                 decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.uiot / sqt.elap))),
+
                                                                                                              AND b.INSTANCE_NUMBER = &inst_num
                                 sqt.sql_id,
+
                                                                                                              AND b.STAT_NAME = 'DB time'), 0))) norm_val,
                                 to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
+
                                                                                                                                                SUM(cpu_time_delta) cput,
 +
                                                                                                                                                                    SUM(executions_delta) EXEC,
 +
                                                                                                                                                                                          SUM(iowait_delta) iowt
 +
          FROM dba_hist_sqlstat
 +
          WHERE dbid = &dbid
 +
              AND instance_number = &inst_num
 +
              AND &snap_start < snap_id
 +
              AND snap_id <= &snap_end
 +
          GROUP BY sql_id
 +
          ORDER BY nvl(SUM(elapsed_time_delta), -1) DESC, sql_id))
 +
WHERE rnum < &top_num --  and (rnum <= :tsql_min or norm_val > :top_pct_sql)
 +
)
 +
;
 +
</source>
 +
 
 +
 
 +
<source lang="sql">
 +
SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.elap / 1000000), to_number(NULL)) ela_Time,
 +
                            sqt.EXEC EXEC,
 +
                                    decode(sqt.EXEC, 0, to_number(NULL), (sqt.elap / sqt.EXEC / 1000000)) elapexec,
 +
                                    sqt.norm_val Total ,
 +
                                    --(100 * (sum(elap) /nullif(dbtime.dbtime,0))) norm_val
 +
--null Total,
 +
 
 +
                                    decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))) CPU,
 +
                                    decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.iowt / sqt.elap))) IO,
 +
                                    sqt.sql_id SQLId,
 +
                                    to_clob(decode(sqt.module, NULL, NULL, 'Module: ' || sqt.module)) SQLModule,
 +
                                    nvl(substr(st.sql_text, 0, 50), to_clob('** SQL Text Not Available **')) SQLText
 +
FROM sqt,
 +
    dba_hist_sqltext st
 +
WHERE st.sql_id(+) = sqt.sql_id
 +
AND st.dbid(+) = &dbid
 +
ORDER BY sqt.rnum
 +
/
 +
</source>
 +
 
 +
=== AWR SQL ordered BY Elapsed Time ===
 +
<source lang="sql">
 +
undef dbid
 +
undef inst_num
 +
undef snap_start
 +
undef snap_end
 +
undef sql_id
 +
undef top_num
 +
 
 +
WITH sqt AS
 +
(SELECT elap,
 +
        cput,
 +
        EXEC,
 +
        iowt,
 +
        norm_val,
 +
        sql_id,
 +
        module,
 +
        rnum
 +
FROM
 +
    (SELECT sql_id,
 +
            module,
 +
            elap,
 +
            norm_val,
 +
            cput,
 +
            EXEC,
 +
            iowt,
 +
            rownum rnum
 +
      FROM
 +
          (SELECT sql_id ,
 +
                  MAX(module) module ,
 +
                              SUM(elapsed_time_delta) elap , (100 * (SUM(elapsed_time_delta) / NULLIF(:dbtime,0))) norm_val ,
 +
                                                                                                                  SUM(cpu_time_delta) cput ,                                                                                                                                      SUM(executions_delta) EXEC ,                                                                                                                                                            SUM(iowait_delta) iowt
 +
          FROM dba_hist_sqlstat
 +
          WHERE dbid = :dbid
 +
              AND instance_number = :inst_num
 +
              AND :bid < snap_id
 +
              AND snap_id <= :eid
 +
          GROUP BY sql_id
 +
          ORDER BY nvl(SUM(elapsed_time_delta), -1) DESC, sql_id))
 +
WHERE rnum < :tsql_max
 +
    AND (rnum <= :tsql_min
 +
          OR norm_val > :top_pct_sql))
 +
;
 +
</source>
 +
 
 +
<source lang="sql">
 +
SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.elap/1000000), to_number(NULL)),
 +
                            sqt.EXEC,
 +
                                decode(sqt.EXEC, 0, to_number(NULL),(sqt.elap / sqt.EXEC / 1000000)),
 +
                                sqt.norm_val,
 +
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
 +
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.iowt / sqt.elap))),
 +
                                sqt.sql_id,
 +
                                to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
 +
                                nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
 +
FROM sqt,
 +
    dba_hist_sqltext st
 +
WHERE st.sql_id(+) = sqt.sql_id
 +
AND st.dbid(+) = :dbid
 +
ORDER BY sqt.rnum
 +
;
 +
</source>
 +
 
 +
=== AWR SQL ordered BY CPU Time ===
 +
 
 +
<source lang="sql">
 +
WITH sqt AS
 +
(SELECT elap,
 +
        cput,
 +
        EXEC,
 +
        uiot,
 +
        norm_val,
 +
        sql_id,
 +
        module,
 +
        rnum
 +
FROM
 +
    (SELECT sql_id,
 +
            module,
 +
            elap,
 +
            norm_val,
 +
            cput,
 +
            EXEC,
 +
            uiot,
 +
            rownum rnum
 +
      FROM
 +
          (SELECT sql_id ,
 +
                  MAX(module) module ,
 +
                              SUM(elapsed_time_delta) elap , (100 * (SUM(cpu_time_delta) / NULLIF(:tcpu,0))) norm_val ,
 +
                                                                                                            SUM(cpu_time_delta) cput ,                                                                                                                                SUM(executions_delta) EXEC ,                                                                                                                                                      SUM(iowait_delta) uiot
 +
          FROM dba_hist_sqlstat
 +
          WHERE dbid = :dbid
 +
              AND instance_number = :inst_num
 +
              AND :bid < snap_id
 +
              AND snap_id <= :eid
 +
          GROUP BY sql_id
 +
          ORDER BY nvl(SUM(cpu_time_delta), -1) DESC, sql_id))
 +
WHERE rnum < :tsql_max
 +
    AND (rnum <= :tsql_min
 +
          OR norm_val > :top_pct_sql))
 +
;
 +
</source>
 +
 
 +
<source lang="sql">
 +
SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.cput/1000000), to_number(NULL)),
 +
                            sqt.EXEC,
 +
                                decode(sqt.EXEC, 0, to_number(NULL), (sqt.cput / sqt.EXEC /1000000)),
 +
                                sqt.norm_val,
 +
                                nvl((sqt.elap/1000000), to_number(NULL)),
 +
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
 +
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.uiot / sqt.elap))),
 +
                                sqt.sql_id,
 +
                                to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
 +
                                nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
 +
FROM sqt,
 +
    dba_hist_sqltext st
 +
WHERE st.sql_id(+) = sqt.sql_id
 +
AND st.dbid(+) = :dbid
 +
ORDER BY sqt.rnum
 +
;
 +
</source>
 +
 
 +
=== AWR SQL ordered BY USER I/O Wait Time ===
 +
<source lang="sql">  
 +
WITH sqt AS
 +
(SELECT elap,
 +
         cput,
 +
         EXEC,
 +
         uiot,
 +
         norm_val,
 +
         sql_id,
 +
         module,
 +
         rnum
 +
  FROM
 +
     (SELECT sql_id,
 +
             module,
 +
             elap,
 +
             norm_val,
 +
             cput,
 +
             EXEC,
 +
             uiot,
 +
             rownum rnum
 +
       FROM
 +
           (SELECT sql_id ,
 +
                   MAX(module) module ,
 +
                               SUM(elapsed_time_delta) elap , (100 * (SUM(iowait_delta) / NULLIF(:uiowt,0))) norm_val ,                                                                                                           SUM(cpu_time_delta) cput ,                                                                                                                                SUM(executions_delta) EXEC ,                                                                                                                                                      SUM(iowait_delta) uiot
 +
           FROM dba_hist_sqlstat
 +
           WHERE dbid = :dbid
 +
               AND instance_number = :inst_num
 +
               AND :bid < snap_id
 +
               AND snap_id <= :eid
 +
           GROUP BY sql_id
 +
           ORDER BY nvl(SUM(iowait_delta), -1) DESC, sql_id))
 +
  WHERE rnum < :tsql_max
 +
     AND (rnum <= :tsql_min
 +
           OR norm_val > :top_pct_sql))
 +
;
 +
</source>
 +
 
 +
<source lang="sql">  
 +
SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.uiot/1000000), to_number(NULL)),
 +
                             sqt.EXEC,
 +
                                 decode(sqt.EXEC, 0, to_number(NULL), (sqt.uiot / sqt.EXEC /1000000)),
 +
                                 sqt.norm_val,
 +
                                 nvl((sqt.elap/1000000), to_number(NULL)),
 +
                                 decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
 +
                                 decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.uiot / sqt.elap))),
 +
                                sqt.sql_id,
 +
                                to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
 +
                                nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
 +
FROM sqt,
 +
    dba_hist_sqltext st
 +
WHERE st.sql_id(+) = sqt.sql_id
 +
AND st.dbid(+) = :dbid
 +
ORDER BY sqt.rnum
 +
;
 +
</source>
 +
 
 +
=== AWR SQL ordered BY Gets ===
 +
 
 +
<source lang="sql">
 +
WITH sqt AS
 +
(SELECT elap,
 +
        cput,
 +
        EXEC,
 +
        uiot,
 +
        bget,
 +
        norm_val,
 +
        sql_id,
 +
        module,
 +
        rnum
 +
FROM
 +
    (SELECT sql_id,
 +
            module,
 +
            elap,
 +
            norm_val,
 +
            cput,
 +
            EXEC,
 +
            uiot,
 +
            bget,
 +
            rownum rnum
 +
      FROM
 +
          (SELECT sql_id ,
 +
                  MAX(module) module ,
 +
                              SUM(elapsed_time_delta) elap , (100 * (SUM(buffer_gets_delta) / NULLIF(:slr,0))) norm_val ,                                                                                                              SUM(cpu_time_delta) cput ,                                                                                                                                  SUM(executions_delta) EXEC ,                                                                                                                                                        SUM(iowait_delta) uiot ,                                                                                                                                                                          SUM(buffer_gets_delta) bget
 +
          FROM dba_hist_sqlstat
 +
          WHERE dbid = :dbid
 +
              AND instance_number = :inst_num
 +
              AND :bid < snap_id
 +
              AND snap_id <= :eid
 +
          GROUP BY sql_id
 +
          ORDER BY nvl(SUM(buffer_gets_delta), -1) DESC, sql_id))
 +
WHERE rnum < :tsql_max
 +
    AND (rnum <= :tsql_min
 +
          OR norm_val > :top_pct_sql))
 +
;
 +
</source>
 +
 
 +
<source lang="sql">
 +
SELECT /*+ NO_MERGE(sqt) */ sqt.bget,
 +
                            sqt.EXEC,
 +
                                decode(sqt.EXEC, 0, to_number(NULL), (sqt.bget / sqt.EXEC)),
 +
                                sqt.norm_val,
 +
                                nvl((sqt.elap/1000000), to_number(NULL)),
 +
                                decode(sqt.elap, 0, '    ', lpad(to_char(round((100 * (sqt.cput / sqt.elap)),1), 'TM9'),5)),
 +
                                decode(sqt.elap, 0, '    ', lpad(to_char(round((100 * (sqt.uiot / sqt.elap)),1), 'TM9'),5)),
 +
                                 sqt.sql_id,
 +
                                 to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
 
                                 nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
 
                                 nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
 
FROM sqt,
 
FROM sqt,
2,236번째 줄: 2,241번째 줄:
 
</source>
 
</source>
  
=== AWR SQL ordered BY Gets ===
+
=== AWR SQL ordered BY READS ===
  
 
<source lang="sql">  
 
<source lang="sql">  
2,244번째 줄: 2,249번째 줄:
 
         EXEC,
 
         EXEC,
 
         uiot,
 
         uiot,
         bget,
+
         dskr,
 
         norm_val,
 
         norm_val,
 
         sql_id,
 
         sql_id,
2,257번째 줄: 2,262번째 줄:
 
             EXEC,
 
             EXEC,
 
             uiot,
 
             uiot,
             bget,
+
             dskr,
 
             rownum rnum
 
             rownum rnum
 
       FROM
 
       FROM
 
           (SELECT sql_id ,
 
           (SELECT sql_id ,
 
                   MAX(module) module ,
 
                   MAX(module) module ,
                               SUM(elapsed_time_delta) elap , (100 * (SUM(buffer_gets_delta) / NULLIF(:slr,0))) norm_val ,
+
                               SUM(elapsed_time_delta) elap , (100 * (SUM(disk_reads_delta) / NULLIF(:phyr,0))) norm_val ,                                                                                                               SUM(cpu_time_delta) cput ,                                                                                                                                  SUM(executions_delta) EXEC ,                                                                                                                                                        SUM(iowait_delta) uiot ,                                                                                                                                                                          SUM(disk_reads_delta) dskr
                                                                                                              SUM(cpu_time_delta) cput ,                                                                                                                                  SUM(executions_delta) EXEC ,                                                                                                                                                        SUM(iowait_delta) uiot ,                                                                                                                                                                          SUM(buffer_gets_delta) bget
 
 
           FROM dba_hist_sqlstat
 
           FROM dba_hist_sqlstat
 
           WHERE dbid = :dbid
 
           WHERE dbid = :dbid
2,270번째 줄: 2,274번째 줄:
 
               AND snap_id <= :eid
 
               AND snap_id <= :eid
 
           GROUP BY sql_id
 
           GROUP BY sql_id
           ORDER BY nvl(SUM(buffer_gets_delta), -1) DESC, sql_id))
+
           ORDER BY nvl(SUM(disk_reads_delta), -1) DESC, sql_id))
 
  WHERE rnum < :tsql_max
 
  WHERE rnum < :tsql_max
 
     AND (rnum <= :tsql_min
 
     AND (rnum <= :tsql_min
2,278번째 줄: 2,282번째 줄:
  
 
<source lang="sql">  
 
<source lang="sql">  
SELECT /*+ NO_MERGE(sqt) */ sqt.bget,
+
SELECT /*+ NO_MERGE(sqt) */ sqt.dskr,
                             sqt.EXEC,
+
                             sqt.EXEC,
                                 decode(sqt.EXEC, 0, to_number(NULL), (sqt.bget / sqt.EXEC)),
+
                                 decode(sqt.EXEC, 0, to_number(NULL), (sqt.dskr / sqt.EXEC)),
                                 sqt.norm_val,
+
                                 sqt.norm_val,
                                 nvl((sqt.elap/1000000), to_number(NULL)),
+
                                 nvl((sqt.elap / 1000000), to_number(NULL)),
                                 decode(sqt.elap, 0, '    ', lpad(to_char(round((100 * (sqt.cput / sqt.elap)),1), 'TM9'),5)),
+
                                 decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
                                 decode(sqt.elap, 0, '    ', lpad(to_char(round((100 * (sqt.uiot / sqt.elap)),1), 'TM9'),5)),
+
                                 decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.uiot / sqt.elap))),
 
                                 sqt.sql_id,
 
                                 sqt.sql_id,
 
                                 to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
 
                                 to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
2,296번째 줄: 2,300번째 줄:
 
</source>
 
</source>
  
=== AWR SQL ordered BY READS ===
 
 
<source lang="sql">
 
WITH sqt AS
 
(SELECT elap,
 
        cput,
 
        EXEC,
 
        uiot,
 
        dskr,
 
        norm_val,
 
        sql_id,
 
        module,
 
        rnum
 
FROM
 
    (SELECT sql_id,
 
            module,
 
            elap,
 
            norm_val,
 
            cput,
 
            EXEC,
 
            uiot,
 
            dskr,
 
            rownum rnum
 
      FROM
 
          (SELECT sql_id ,
 
                  MAX(module) module ,
 
                              SUM(elapsed_time_delta) elap , (100 * (SUM(disk_reads_delta) / NULLIF(:phyr,0))) norm_val ,
 
                                                                                                              SUM(cpu_time_delta) cput ,                                                                                                                                  SUM(executions_delta) EXEC ,                                                                                                                                                        SUM(iowait_delta) uiot ,                                                                                                                                                                          SUM(disk_reads_delta) dskr
 
          FROM dba_hist_sqlstat
 
          WHERE dbid = :dbid
 
              AND instance_number = :inst_num
 
              AND :bid < snap_id
 
              AND snap_id <= :eid
 
          GROUP BY sql_id
 
          ORDER BY nvl(SUM(disk_reads_delta), -1) DESC, sql_id))
 
WHERE rnum < :tsql_max
 
    AND (rnum <= :tsql_min
 
          OR norm_val > :top_pct_sql))
 
;
 
</source>
 
 
<source lang="sql">
 
SELECT /*+ NO_MERGE(sqt) */ sqt.dskr,
 
                            sqt.EXEC,
 
                                decode(sqt.EXEC, 0, to_number(NULL), (sqt.dskr / sqt.EXEC)),
 
                                sqt.norm_val,
 
                                nvl((sqt.elap / 1000000), to_number(NULL)),
 
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
 
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.uiot / sqt.elap))),
 
                                sqt.sql_id,
 
                                to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
 
                                nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
 
FROM sqt,
 
    dba_hist_sqltext st
 
WHERE st.sql_id(+) = sqt.sql_id
 
AND st.dbid(+) = :dbid
 
ORDER BY sqt.rnum
 
;
 
</source>
 
 
=== AWR SQL ordered BY READS ===
 
=== AWR SQL ordered BY READS ===
  

2024년 1월 1일 (월) 22:53 판

thumb_up 추천메뉴 바로가기


DB 모니터링


목차

1 세션 정보[편집]

1.1 User 별 Session 정보 조회[편집]

  • V$SESSION
  • V$PROCESS
SELECT S.USERNAME
     , S.SID
     , S.SERIAL#
     , P.SPID
     , S.OSUSER
     , S.MACHINE
     , S.PROGRAM
     , TO_CHAR(S.LOGON_TIME, 'MM/DD HH24:MI') "LOGON_TIME"
     , ROUND(S.LAST_CALL_ET / 60) "IDLE"
  FROM V$SESSION S
     , V$PROCESS P
 WHERE S.PADDR = P.ADDR 
   AND S.USERNAME LIKE UPPER('&DBUSER%') 
 ORDER BY 9;

1.2 세션 죽이기(SID,SERAIL#)[편집]

ALTER SYSTEM KILL SESSION '8,4093' immediate;
-- RAC 
ALTER SYSTEM KILL SESSION '8,4093,@1' immediate;

1.2.1 현재 TOP 세션 gv$session[편집]

select  inst_id||'_'||sid||' '||serial# inst_sid_ser,
    username||case when regexp_substr(program,' \(...') <> ' (TNS' then regexp_substr(program,' \(.+') end username,
    sql_id sql_id, 
    round((sysdate-sql_exec_start)*24*3600,1) sql_dT,
        last_call_et call_dT,
    case state when 'WAITING' then round(wait_time_micro/1000000,2) else round(time_since_last_wait_micro/1000000,2) end W_dT,
        decode(state,'WAITING',event,'CPU') event, 
    service_name||' '||substr(module,1,20)||' '||ACTION serv_mod_action,  
          nullif(row_wait_obj#,-1) obj#,decode(taddr,null,null,'NN') tr
from gv$session
where ((state='WAITING' and wait_class<>'Idle') or (state<>'WAITING' and status='ACTIVE'))
      --and audsid != to_number(sys_context('USERENV','SESSIONID')) -- this is clean but does not work on ADG so replaced by following line
      and (machine,port) <> (select machine,port from v$session where sid=sys_context('USERENV','SID')) --workaround for ADG
order by inst_id,sql_id

1.3 오래 걸리는 세션 정보[편집]

1.3.1 현재 작업중인 세션 정보 V$SESSION_LONGOPS[편집]

  • V$SESSION_LONGOPS
  • V$SESSION
SELECT B.USERNAME, A.SID, B.OPNAME, B.TARGET
     , ROUND(B.SOFAR*100/B.TOTALWORK,0) || '%' AS "%DONE", B.TIME_REMAINING
     , TO_CHAR(B.START_TIME,'YYYY/MM/DD HH24:MI:SS') START_TIME
  FROM V$SESSION_LONGOPS B
     , V$SESSION A
 WHERE A.SID = B.SID      
 ORDER BY 6 DESC;

1.4 세션당 리소스 사용률 gv$sessmetric[편집]

  • gv$sessmetric
select * from (
  select inst_id, session_id sid, to_char(begin_time,'hh24:mi:ss') begTime, round(intsize_csec/100,0) D_sec,  cpu,          
         physical_reads PhyReads, logical_reads LogicalReads, pga_memory, hard_parses, soft_parses 
  from gv$sessmetric
  order by cpu+physical_reads desc
)
where rownum<20

1.5 대기중인 세션[편집]

  • v$session_wait
select * 
  from v$session_wait;

1.5.1 1시간 이상 idle 상태인 세션[편집]

  • V$SESSION
SELECT SID
     , SERIAL#
     , USERNAME
     , TRUNC(LAST_CALL_ET / 3600, 2) || ' HR' LAST_CALL_ET
  FROM V$SESSION 
 WHERE LAST_CALL_ET > 3600 
   AND USERNAME IS NOT NULL;

1.5.2 Active Session 중 Idle Time이 긴 작업[편집]

  • V$SESSION
  • V$PROCESS
SELECT VS.SID || ',' || VS.SERIAL# " SID"
     , VP.SPID
     , VS.MACHINE
     , VS.PROGRAM
     , VS.MODULE
     , VS.STATUS
     , TO_CHAR(VS.LOGON_TIME, 'MM/DD HH24:MI') LOGIN_TIME
     , ROUND(VS.LAST_CALL_ET / 60) "IDLE"
  FROM V$SESSION VS
     , V$PROCESS VP
 WHERE VS.STATUS = 'ACTIVE' 
   AND VS.SID NOT IN (1, 2, 3, 4, 5, 6, 7) 
   AND VS.PADDR = VP.ADDR ORDER BY 8;

1.5.3 사용자 세션 중에서 2시간 이상 idle 상태가 지속되는 세션 kill[편집]

  • V$SESSION
  • V$PROCESS
SET PAGESIZE 0 SPOOL KILLIDLE3.SQL
SELECT DISTINCT '!KILL -9 ' || B.SPID, 'ALTER SYSTEM KILL SESSION '''|| A.SID || ',' || A.SERIAL# || ''';' 
  FROM V$SESSION A
     , V$PROCESS B
 WHERE A.PADDR IN (SELECT S.PADDR
                     FROM V$SESSION S
                    WHERE STATUS = 'INACTIVE'
                    GROUP BY  S.PADDR
                   HAVING MIN(ROUND(LAST_CALL_ET / 60)) > 120)
   AND A.PADDR = B.ADDR AND A.STATUS = 'INACTIVE';
SPOOL OFF

1.5.4 트랜젝션 중인 세션[편집]

  • v$transaction
  • gv$fast_start_transactions
  • USED_UBLK
    • Number of undo blocks used , 사용된 언두 블럭 수
  • USED_UREC
    • Number of undo records used , 사용된 언두 레코드 수
select sid, serial#, username, taddr, used_ublk, used_urec
  from v$transaction t
     , v$session s
where t.addr = s.taddr;
select inst_id,addr,start_time,used_ublk,xid 
  from gv$transaction;
select inst_id,state,undoblocksdone,undoblockstotal,xid 
 from gv$fast_start_transactions;
SELECT sess.sid, sess.status, sess.username, machine, sql_id, prev_sql_id, trans.USED_UBLK, trans.start_date
from gv$session sess
   , gv$transaction trans
WHERE sess.taddr=trans.addr and sess.inst_id=trans.inst_id;

1.5.5 연결되어 있는 OS 사용자 및 프로그램 조회[편집]

  • V$SESSION
SELECT SID
     , SERIAL#
     , OSUSER
     , SUBSTRB(USERNAME, 1, 10) AS USER_NAME
     , SUBSTRB(PROGRAM, 1, 30) AS PROGRAM_NAME
     , STATUS
     , TO_CHAR(LOGON_TIME, 'YYYY/MM/DD HH:MI') AS LOGON_TIME
  FROM V$SESSION 
 WHERE TYPE!= 'BACKGROUND' AND STATUS = 'ACTIVE';

1.5.6 Session별 사용 명령어[편집]

  • V$SESSION SESS
  • V$SESSTAT STAT
  • V$STATNAME NAME
  • V$PROCESS PROC
SELECT SESS.SID
     , SESS.SERIAL#
     , SUBSTR(SESS.USERNAME, 1, 10) "USER NAME"
     , SUBSTR(OSUSER, 1, 11) "OS USER"
     , SUBSTR(SESS.MACHINE, 1, 15) "MACHINE NAME"
     , STATUS
     , UPPER(
            DECODE(NVL(COMMAND, 0)
              , 0, '---'
              , 1, 'CREATE TABLE'
              , 2, 'INSERT -'
              , 3, 'SELECT -'
              , 4, 'CREATE CLUST'
              , 5, 'ALTER CLUST'
              , 6, 'UPDATE -'
              , 7, 'DELETE -'
              , 8, 'DROP -'
              , 9, 'CREATE INDEX'
              , 10, 'DROP INDEX'
              , 11, 'ALTER INDEX'
              , 12, 'DROP TABLE'
              , 13, 'CREATE SEQ'
              , 14, 'ALTER SEQ'
              , 15, 'ALTER TABLE'
              , 16, 'DROP SEQ'
              , 17, 'GRANT'
              , 18, 'REVOKE'
              , 19, 'CREATE SYN'
              , 20, 'DROP SYN'
              , 21, 'CREATE VIEW'
              , 22, 'DROP VIEW'
              , 23, 'VALIDATE IX'
              , 24, 'CREATE PROC'
              , 25, 'ALTER PROC'
              , 26, 'LOCK TABLE'
              , 27, 'NO OPERATION'
              , 28, 'RENAME'
              , 29, 'COMMENT'
              , 30, 'AUDIT'
              , 31, 'NOAUDIT'
              , 32, 'CREATE DBLINK'
              , 33, 'DROP DB LINK'
              , 34, 'CREATE DATABASE'
              , 35, 'ALTER DATABASE'
              , 36, 'CREATE RBS'
              , 37, 'ALTER RBS'
              , 38, 'DROP RBS'
              , 39, 'CREATE TABLESPACE'
              , 40, 'ALTER TABLESPACE'
              , 41, 'DROP TABLESPACE'
              , 42, 'ALTER SESSION'
              , 43, 'ALTER USER'
              , 44, 'COMMIT'
              , 45, 'ROLLBACK'
              , 47, 'PL/SQL EXEC'
              , 48, 'SET TRANSACTION'
              , 49, 'SWITCH LOG'
              , 50, 'EXPLAIN'
              , 51, 'CREATE USER'
              , 52, 'CREATE ROLE'
              , 53, 'DROP USER'
              , 54, 'DROP ROLE'
              , 55, 'SET ROLE'
              , 56, 'CREATE SCHEMA'
              , 58, 'ALTER TRACING'
              , 59, 'CREATE TRIGGER'
              , 61, 'DROP TRIGGER'
              , 62, 'ANALYZE TABLE'
              , 63, 'ANALYZE INDEX'
              , 69, 'DROP PROCEDURE'
              , 71, 'CREATE SNAP LOG'
              , 72, 'ALTER SNAP LOG'
              , 73, 'DROP SNAP LOG'
              , 74, 'CREATE SNAPSHOT'
              , 75, 'ALTER SNAPSHOT'
              , 76, 'DROP SNAPSHOT'
              , 85, 'TRUNCATE TABLE'
              , 88, 'ALTER VIEW'
              , 91, 'CREATE FUNCTION'
              , 92, 'ALTER FUNCTION'
              , 93, 'DROP FUNCTION'
              , 94, 'CREATE PACKAGE'
              , 95, 'ALTER PACKAGE'
              , 96, 'DROP PACKAGE'
              , 46, 'SAVEPOINT'
                  )
          )
            COMMAND
     , SESS.PROCESS "C.PROC"
     , PROC.SPID "S.PROC"
     , TO_CHAR(SESS.LOGON_TIME, 'YYYY-MM-DD HH24:MI')
  FROM V$SESSION SESS
     , V$SESSTAT STAT
     , V$STATNAME NAME
     , V$PROCESS PROC
 WHERE SESS.SID = STAT.SID 
   AND STAT.STATISTIC# = NAME.STATISTIC# 
   AND SESS.USERNAME IS NOT NULL 
   AND NAME.NAME = 'RECURSIVE CALLS' 
   AND SESS.PADDR = PROC.ADDR 
 ORDER BY 3, 1, 2;

2 SQL 찾기[편집]

2.1 SQL 통계 정보확인하기[편집]

2.1.1 Module LEVEL 통계[편집]

SELECT *
    FROM
        (SELECT module ,
                count(*) sql_cnt ,
                sum(executions) executions ,
                round(avg(buffer_gets/executions)) "lio(avg)" ,
                round(avg(disk_reads/executions)) "pio(avg)" ,
                round(avg(rows_processed/executions)) "rows(avg)" ,
                round(avg(elapsed_time/executions/1000000),2) "elapsed(avg)" ,
                count(CASE WHEN elapsed_time/executions/1000000>=3 THEN 1 END) bad_sql ,
                round(max(elapsed_time/executions/1000000),2) "elapsed(max)"
         FROM v$sql
         WHERE executions > 0
         GROUP BY module)
ORDER BY "lio(avg)" * executions DESC ;


2.1.2 SCHEMA LEVEL 통계[편집]

SELECT * --9i
FROM
    ( SELECT
         (SELECT username
          FROM dba_users
          WHERE user_id = parsing_schema_id) AS SCHEMA_NAME ,
             count(*) sql_cnt ,
             sum(executions) executions ,
             round(avg(buffer_gets/executions)) "lio(avg)" ,
             round(avg(disk_reads/executions)) "pio(avg)" ,
             round(avg(rows_processed/executions)) "rows(avg)" ,
             round(avg(elapsed_time/executions/1000000),2) "elapsed(avg)" ,
             count(CASE WHEN elapsed_time/executions/1000000>=10 THEN 1 END) bad_sql ,
             round(max(elapsed_time/executions/1000000),2) "elapsed(max)"
     FROM v$sqlarea
     WHERE executions > 0
     GROUP BY parsing_schema_id)
ORDER BY "lio(avg)" * executions DESC ;
SELECT * --10g
FROM
    (SELECT parsing_schema_name ,
            count(*) sql_cnt ,
            sum(executions) executions ,
            round(avg(buffer_gets/executions)) "lio(avg)" ,
            round(avg(disk_reads/executions)) "pio(avg)" ,
            round(avg(rows_processed/executions)) "rows(avg)" ,
            round(avg(elapsed_time/executions/1000000),2) "elapsed(avg)" ,
            count(CASE WHEN elapsed_time/executions/1000000>=10 THEN 1 END) bad_sql ,
            round(max(elapsed_time/executions/1000000),2) "elapsed(max)"
     FROM v$sqlarea
     WHERE executions > 0
     GROUP BY parsing_schema_name)
ORDER BY "lio(avg)" * executions DESC ;


2.1.3 DB Time 분석하기[편집]

SELECT STAT_NAME ,
       VALUE,
       ROUND(VALUE/
                 ( SELECT VALUE
                  FROM V$SYS_TIME_MODEL
                  WHERE STAT_NAME='DB TIME' ) *100 , 2) TIME_RATIO
FROM V$SYS_TIME_MODEL
WHERE STAT_NAME NOT IN ( 'BACKGROUND ELAPSED TIME' ,
                         'BACKGROUND CPU TIME' ,
                         'RMAN CPU TIME (BACKUP/RESTORE)' ,
                         'HARD PARSE ELAPSED TIME' ,
                         'HARD PARSE (SHARING CRITERIA) ELAPSED TIME' ,
                         'HARD PARSE (BIND MISMATCH) ELAPSED TIME' ,
                         'FAILED PARSE ELAPSED TIME' ,
                         'FAILED PARSE (OUT OF SHARED MEMORY) ELAPSED TIME' ,
                         'DB CPU')
ORDER BY TIME_RATIO DESC ;

2.2 SQL 추출하기 (10g)[편집]

SELECT *
    FROM
        ( SELECT rownum cnt,
                 t1.*
         FROM
             ( SELECT parsing_schema_name SCHEMA,    --> 1
                                          module,    --> 2
                                          sql_id,    --> 3
                                          hash_value,--> 4
                                          substr(sql_text,1,100) substr_sqltext, --> 5
                                          executions,  --> 6
                                          buffer_gets, --> 7 (전체 I/O 처리량)
                                          disk_reads,  --> 8
                                          rows_processed, --> 9
                                          round(buffer_gets/executions,1) lio, --> 10 (1회 수행 당 I/O)
                                          round(elapsed_time/executions/1000000,1) elapsed_sec, --> 11 (1회 수행 당 Elapsed)
                                          round(cpu_time/executions/1000000,1) cpu_sec, --> 12 (1회 수행 당 CPU)
                                          round(elapsed_time/tot_elapsed*100,1) ratio_elapsed, --> 13 (전체 대비 Elapsed )
                                          round(cpu_time/tot_cpu*100,1) ratio_cpu --> 14 (전체 대비 CPU 사용률)
                            FROM v$sqlarea s,
                  (SELECT sum(elapsed_time) tot_elapsed,
                          sum(cpu_time) tot_cpu
                   FROM v$sqlarea) t
              WHERE s.executions > 0
                  AND parsing_schema_name NOT IN ('SYS','SYSTEM')
                  AND ((module NOT LIKE 'TOAD%'
                        AND module NOT LIKE 'SQL De%'
                        AND module NOT LIKE 'Orange%'
                        AND module NOT LIKE 'PL/SQL%'
                        AND module NOT LIKE 'plsqldev.exe')
                       OR (module IS NULL))
              ORDER BY 14 DESC ) t1
         WHERE rownum <= 50) WHERE cnt >= 1 
;

2.3 엑사 DB[편집]

2.3.1 Exa . Smart Scan으로 수행되지 않고,Interconnect Bytes가 높은 SQL[편집]

WITH Cell_Mon_SQL AS
        ( SELECT sql_id,
                 io_cell_offload_eligible_bytes AS coeb,
                 io_interconnect_bytes AS ib,
                 io_cell_offload_returned_bytes AS corb,
                 io_cell_uncompressed_bytes AS cub,
                 optimized_phy_read_requests AS oprr,
                 physical_read_requests AS prr,
                 physical_read_bytes AS prb,
                 sql_text
         FROM v$sqlarea)
    SELECT /*** Smart Scan이 되지 않으면서, Interconnect Bytes가 높은 SQL ***/ *
    FROM
        ( SELECT sql_id ,
                 decode(coeb,0,'No','Yes') AS "Offload",
                 round(prb/1024/1024/1024,3) AS "Physical_Bytes(GB)",
                 round(coeb/1024/1024/1024,3) AS "Offload_Bytes(GB)",
                 round(ib/1024/1024/1024,3) AS "Interconnect_Bytes(GB)",
                 round(oprr*8192/1024/1024/1024,3) AS "Cell_Flash_Cache(GB)",
                 round(corb/1024/1024/1024,3) AS "Returned_Bytes(GB)",
                 round(decode(coeb,0,0,100*(coeb-ib)/coeb),2) AS "Saved_IO(%)",
                 sql_text
         FROM Cell_Mon_SQL
         WHERE coeb = 0
         ORDER BY ib DESC) WHERE rownum <= 10 ;

2.3.2 Smart Scan으로 수행되지 않고,Offload Returned Bytes가 높은 SQL[편집]

  • Reverting TO Block Shipping으로 수행된 SQL로 Smart Scan으로 동작할 수 있는 SQL이지만,Direct I/O로 동작하지 않는 경우 (FULL TABLE Scan도 cell single block physical read로 수행됨.)
  • Chained Row가 있는 블록들을 읽을 때 발생. : Smart Scan을 통해서 Chained Row가 있는 블록을 읽을 때 각 블록이 다른 STORAGE Cell에 있는 경우 STORAGE Cell 간 통신할 수 없기 때문에 Buffer Cache로 전체 블록을 전송한 후 처리하도록 Block Shipping Mode로 변경
  • 읽기 일관성 모드로 변경 중인 데이터를 가진 Block에 대해서 Smart Scan을 중지하고, Single Block Read를 수행하는 Block Shipping Mode로 변경
WITH Cell_Mon_SQL AS
    ( SELECT sql_id,
             io_cell_offload_eligible_bytes AS coeb,
             io_interconnect_bytes AS ib,
             io_cell_offload_returned_bytes AS corb,
             io_cell_uncompressed_bytes AS cub,
             optimized_phy_read_requests AS oprr,
             physical_read_requests AS prr,
             physical_read_bytes AS prb,
             sql_text
     FROM v$sqlarea)
SELECT *
FROM
    ( SELECT sql_id ,
             decode(coeb,0,'No','Yes') AS "Offload",
             round(prb/1024/1024/1024,3) AS "Physical_Bytes(GB)",
             round(coeb/1024/1024/1024,3) AS "Offload_Bytes(GB)",
             round(ib/1024/1024/1024,3) AS "Interconnect_Bytes(GB)",
             round(oprr*8192/1024/1024/1024,3) AS "Cell_Flash_Cache(GB)",
             round(corb/1024/1024/1024,3) AS "Returned_Bytes(GB)",
             round(decode(coeb,0,0,100*(coeb-ib)/coeb),2) AS "Saved_IO(%)",
             sql_text
     FROM Cell_Mon_SQL
     WHERE coeb = 0
     ORDER BY corb DESC)
WHERE rownum <= 10 ;

2.4 Full Table Scan 처리가 있는 SQL문 정보 추출하기(10g)[편집]

SELECT *
FROM
    (SELECT rownum cnt,
            t1.*
     FROM
         (SELECT parsing_schema_name,
                 --> 1

                 module,
                 --> 2

                 sql_id,
                 --> 3

                 hash_value,
                 --> 4

                 substr(sql_text,1,100) substr_sqltext,
                 --> 5

                 executions,
                 --> 6

                 buffer_gets,
                 --> 7 (전체 I/O 처리량)

                 disk_reads,
                 --> 8

                 rows_processed,
                 --> 9

                 round(buffer_gets/executions,1) lio,
                 --> 10 (1회 수행 당 I/O)

                 round(elapsed_time/executions/1000000,1) elapsed_sec,
                 --> 11 (1회 수행 당 Elapsed)

                 round(cpu_time/executions/1000000,1) cpu_sec,
                 --> 12 (1회 수행 당 CPU)

                 round(elapsed_time/tot_elapsed*100,1) ratio_elapsed,
                 --> 13 (전체 대비 Elapsed )

                 round(cpu_time/tot_cpu*100,1) ratio_cpu --> 14 (전체 대비 CPU 사용률)

          FROM
              (SELECT /*+ leading(x) no_merge(x) use_hash(x s) */ s.*
               FROM v$sqlarea s,
                   ( SELECT DISTINCT hash_value
                    FROM v$sql_plan
                    WHERE OPERATION = 'TABLE ACCESS'
                        AND OPTIONS = 'FULL' --and object_owner like :b1||'%'
 ) x
               WHERE x.hash_value = s.hash_value) s,
              (SELECT sum(elapsed_time) tot_elapsed,
                      sum(cpu_time) tot_cpu
               FROM v$sqlarea) t
          WHERE executions > 0
              AND parsing_schema_name NOT IN ('SYS',
                                              'SYSTEM')
              AND ((module NOT LIKE 'TOAD%'
                    AND module NOT LIKE 'SQL De%'
                    AND module NOT LIKE 'Orange%'
                    AND module NOT LIKE 'PL/SQL%'
                    AND module NOT LIKE 'plsqldev.exe')
                   OR (module IS NULL))
          ORDER BY 10 DESC ) t1
     WHERE rownum <= 50)
WHERE cnt >= 1

2.5 하드 파싱(leteral,리터럴) SQL 찾기[편집]

SELECT *
    FROM
        ( SELECT
             ( SELECT parsing_schema_name
              FROM v$sqlarea
              WHERE sql_id=a.max_sql_id ) SCHEMA,
             ( SELECT MODULE
              FROM v$sqlarea
              WHERE sql_id=a.max_sql_id ) MODULE, a.literal_sql_cnt, a.execution_cnt, a.plan_cnt, a.max_sql_id,
             ( SELECT sql_fulltext
              FROM v$sqlarea
              WHERE sql_id = a.max_sql_id ) sql_text
         FROM
             ( SELECT s.force_matching_signature,
                      COUNT(s.exact_matching_signature) literal_sql_cnt,
                      SUM(s.executions) execution_cnt,
                      MAX(s.sql_id) max_sql_id,
                      COUNT(DISTINCT s.plan_hash_value) plan_cnt
              FROM v$sql s
              GROUP BY s.force_matching_signature HAVING COUNT(s.exact_matching_signature) >= 2 ) a
         ORDER BY 3 DESC ) WHERE ROWNUM <= 50
;

또는

SELECT /*+ leading(h) no_merge(h) use_nl(h s) */
       s.parsing_schema_name        SCHEMA                  , --> 1
       s.module                                             , --> 2
       s.sql_id                                             , --> 3
       s.hash_value                                         , --> 4
       SUBSTR (s.sql_text, 1, 100)       substr_sqltext     , --> 5
       s.executions                                         , --> 6
       s.buffer_gets                                        , --> 7 (전체 I/O 처리량)
       s.disk_reads                                         , --> 8
       s.rows_processed                                     , --> 9
       ROUND (s.buffer_gets / s.executions, 1)                lio     , --> 10 (1회 수행 당 I/O)
       ROUND (s.elapsed_time / s.executions / 1000000, 1)     elapsed_sec     , --> 11 (1회 수행 당 Elapsed)
       ROUND (s.cpu_time / s.executions / 1000000, 1)         cpu_sec --> 12 (1회 수행 당 CPU)
  FROM v$sqlarea  s
     , (SELECT *
          FROM (  SELECT *
                    FROM (  SELECT s.force_matching_signature
                                 , COUNT (s.exact_matching_signature)    literal_sql_cnt
                                 , SUM (s.executions)                    execution_cnt
                                 , MAX (s.sql_id)                        max_sql_id
                                 , COUNT (DISTINCT s.plan_hash_value)    plan_cnt
                              FROM v$sql s
                             WHERE s.executions > 0
                                   AND parsing_schema_name NOT IN
                                           ('SYS', 'SYSTEM')
                                   AND (   (    module NOT LIKE 'TOAD%'
                                            AND module NOT LIKE 'SQL De%'
                                            AND module NOT LIKE 'Orange%'
                                            AND module NOT LIKE 'PL/SQL%'
                                            AND module NOT LIKE 'plsqldev.exe')
                                        OR (module IS NULL))
                          GROUP BY s.force_matching_signature
                            HAVING COUNT (s.exact_matching_signature) >= 2) a
                ORDER BY 3 DESC)
         WHERE ROWNUM <= 50) h
 WHERE h.max_sql_id = s.sql_id;


  • DBA_HIST_SQLTEXT : SQL TEXT가 CLOB으로 저장
  • DBA_HIST_SQL_PLAN : SQL문의 수행 PLAN이 저장되어 있으므로 플랜 변경등의 이력을 조회해 볼때 용이하다.
  • DBA_HIST_SQLBIND : SQL문을 수행한 BIND VALUE를 저장하고 있는데 시간정보가 같이 있으므로 조회패턴을 분석하기 용이하다. DBA_HIST_SQLSTAT : V$SQL 정보와 같은 SQL 수행이력이 있는 VIEW로 각 SNAP_ID 마다의 Snap Shot 정보를 담고 있으므로 수행이력 패턴을 조회할 수 있다.



2.6 특정 SQL 수행내역 확인하기[편집]

-- SQL TEXT

SELECT module,
       sql_fulltext
FROM v$sqlarea
WHERE hash_value = :hash_value -- 수행내역
;
  • v$sqlarea
SELECT EXECUTIONS "Executions(total)",
           round(DISK_READS/executions,2) "Disk_reads(one)",
           round(BUFFER_GETS/executions,0) "Buffer_gets(one)",
           round(ROWS_PROCESSED/EXECUTIONS,0) "Rows(one)",
           round((ELAPSED_TIME/EXECUTIONS)/1000000,2) "Elapsed_time(one)",
           round((CPU_TIME/EXECUTIONS)/1000000,2) "Cpu_time(one)"
  FROM v$sqlarea sa 
 WHERE hash_value = :hash_value -- 바인드 변수값
;

2.7 SQL_ID를 이용하여 SQL TEXT 추출하기[편집]

  • DBA_HIST_SQLTEXT
SELECT *
  FROM DBA_HIST_SQLTEXT
 WHERE sql_id = :sql_id 
;

2.8 SQL_ID를 이용하여 SQL문의 수행내역 추출하기[편집]

  • dba_hist_sqlstat
SELECT snap_id,
           EXECUTIONS_TOTAL "Executions(total)",
           round(DISK_READS_TOTAL/executions_total,2) "Disk_reads(one)",
           round(BUFFER_GETS_TOTAL/executions_total,0) "Buffer_gets(one)",
           round(ROWS_PROCESSED_TOTAL/EXECUTIONS_TOTAL,0) "Rows(one)",
           round((ELAPSED_TIME_TOTAL/EXECUTIONS_TOTAL)/1000000,2) "Elapsed_time(one)",
           round((CPU_TIME_TOTAL/EXECUTIONS_TOTAL)/1000000,2) "Cpu_time(one)"
    FROM dba_hist_sqlstat WHERE sql_id = :sql_id
ORDER BY snap_id DESC 
;

2.9 프로세스 ID 를 이용하여 SQL 찾기[편집]

  • v$process
  • v$session
  • v$sqltext
select c.sql_text
     , b.SID
     , b.SERIAL#
     , b.machine
     , b.OSUSER
     , b.logon_time --이 쿼리를 호출한 시간
  from v$process a, v$session b, v$sqltext c
 where a.addr = b.paddr
   and b.sql_hash_value = c.hash_value
   and a.spid = '1708032' --1912870/
 order by c.PIECE

2.9.1 바인드 변수 값[편집]

  • 바인드 변수 값의 이력을 가지고 있는 뷰 조회로 SQL문의 조회 패턴 분석 가능
  • v$sql_bind_capture
SELECT name,
           sql_id,
           to_char(LAST_CAPTURED,'yyyymmdd hh24:mi:ss') LAST_CAPTURED,
           datatype,
           VALUE_STRING
    FROM v$sql_bind_capture 
   WHERE hash_value = :hash_value -- or sql_id=:sql_id;


2.9.2 바인드 변수 값2[편집]

  • gv$sql_monitor
select BINDS_XML from 
* gv$sql_monitor 
 where sql_id='&1';

2.9.3 바인드 변수 값3[편집]

  • dba_hist_sqlbind
SELECT name,
           to_char(LAST_CAPTURED,'yyyymmdd hh24:mi:ss') LAST_CAPTURED,
           datatype,
           VALUE_STRING
    FROM dba_hist_sqlbind 
   WHERE sql_id = :sql_id -- PLAN
;

2.10 플랜 정보 조회[편집]

  • V$SQL_PLAN
SELECT --cardinality , cost,
 LPAD('.', 1*(LEVEL-1),'.')|| OPERATION || decode(OPTIONS,NULL,NULL,' (') || OPTIONS || decode(OPTIONS,NULL,NULL,')') || decode(object_owner,NULL,NULL,' :')||object_owner || decode(object_name,NULL,NULL,'.') || OBJECT_NAME || decode(other_tag,NULL,NULL,'(')||other_tag||decode(other_tag,NULL,NULL,')') || DECODE(ACCESS_PREDICATES,NULL,NULL,' [AP] '||ACCESS_PREDICATES) ||DECODE(FILTER_PREDICATES,NULL,NULL,' [FP] '||FILTER_PREDICATES) "operation"
    FROM
        (SELECT /*+ NO_MERGE */ *
         FROM V$SQL_PLAN
         WHERE HASH_VALUE = :hash_value
             AND CHILD_NUMBER = 0) CONNECT BY
    PRIOR id = parent_id START WITH id=0
ORDER BY ID 
;

2.10.1 SQL_ID를 이용하여 SQL문의 PLAN 추출하기[편집]

  • DBA_HIST_SQL_PLAN
SELECT LPAD(' ',4*(depth-1))||OPERATION||DECODE(OTHER_TAG,NULL,'','*')|| DECODE(OPTIONS,NULL,'',' ('||OPTIONS||')')|| DECODE(OBJECT_NAME,NULL,'',' OF '|| OBJECT_NAME||'')|| DECODE(OBJECT_TYPE,NULL,'',' ('||OBJECT_TYPE||')')|| DECODE(ID,0,DECODE(OPTIMIZER,NULL,'',' Optimizer='||OPTIMIZER))|| DECODE(COST,NULL,'',' (Cost='||COST|| DECODE(CARDINALITY,NULL,'',' Card='||CARDINALITY)|| DECODE(BYTES,NULL,'',' Bytes='||BYTES)||')')|| DECODE(ACCESS_PREDICATES,NULL,' ',' [AP] = '||ACCESS_PREDICATES)|| DECODE(ACCESS_PREDICATES,NULL,' ',' [FP] = '||FILTER_PREDICATES) AS PLAN_OUTPUT
    FROM DBA_HIST_SQL_PLAN WHERE sql_id = :sql_id
ORDER BY ID,
         POSITION 
;

3 SQL 과 커서 조회[편집]

3.1 현재 커서 수 확인[편집]

  • V$OPEN_CURSOR
  • v$session_wait
  • v$transaction

3.1.1 sid별 열린커셔[편집]

SELECT sid, count(sid) cursor
  FROM V$OPEN_CURSOR
 WHERE user_name = 'dbcafe'
 GROUP BY sid
 ORDER BY cursor DESC;

3.1.2 sql 별 열린 커서[편집]

SELECT sql_text, count(sid) cnt
  FROM v$OPEN_CURSOR
 GROUP BY sql_text
 ORDER BY cnt DESC

4 락 모니터링[편집]

4.1 V$LOCK 을 사용한 잠금 경합 모니터링[편집]

  • V$SESSION
  • DBA_OBJECTS
  • V$LOCK
SELECT S.USERNAME, S.SID, S.SERIAL#, S.LOGON_TIME,
    DECODE(L.TYPE, 'TM', 'TABLE LOCK',
                   'TX', 'ROW LOCK',
             NULL) "LOCK LEVEL",
    O.OWNER, O.OBJECT_NAME, O.OBJECT_TYPE
FROM V$SESSION S, V$LOCK L, DBA_OBJECTS O
WHERE S.SID = L.SID
AND O.OBJECT_ID = L.ID1
AND S.USERNAME IS NOT NULL

4.2 락이 걸린 세션 간단히 보기[편집]

SELECT A.SID, A.SERIAL#, B.TYPE, C.OBJECT_NAME, A.PROGRAM, A.LOCKWAIT,
       A.LOGON_TIME, A.PROCESS, A.OSUSER, A.TERMINAL
  FROM V$SESSION   A
     , V$LOCK      B
     , DBA_OBJECTS C
 WHERE A.SID = B.SID
   AND B.ID1 = C.OBJECT_ID
   AND B.TYPE = 'TM';

4.3 락이 걸린 세션 상세 보기[편집]

  • V$SESSION
  • DBA_OBJECTS
  • V$LOCK
SELECT A.SID, A.SERIAL#,A.USERNAME,A.PROCESS,B.OBJECT_NAME
     , DECODE(C.LMODE,2,'RS',3,'RX',4,'S',5,'SRX',8,'X','NO') "TABLE LOCK"
     , DECODE (A.COMMAND,2,'INSERT',3,'SELECT',6,'UPDATE',7,'DELETE',12,'DROP TABLE',26,'LOCK TABLE','UNKNOWN') "SQL"
     , DECODE(A.LOCKWAIT, NULL,'NO WAIT','WAIT') "STATUS"
  FROM V$SESSION A
     , DBA_OBJECTS B
     , V$LOCK C
 WHERE A.SID=C.SID 
   AND B.OBJECT_ID=C.ID1
   AND C.TYPE='TM'


  • 락이 걸린 세션을 찾아 내어 세션을 죽이려고 해도 죽지 않는 경우
  • 아래 쿼리문으로 OS단의 PROCESS ID를 찾아내어 OS에서 죽인다
  • kill -9 프로세스아이디
SELECT SUBSTR(S.USERNAME,1,11) "ORACLE USER", P.PID "PROCESS ID"
     , S.SID "SESSION ID", S.SERIAL#, OSUSER "OS USER"
     , P.SPID "PROC SPID",S.PROCESS "SESS SPID", S.LOCKWAIT "LOCK WAIT"
  FROM V$PROCESS P
     , V$SESSION S
     , V$ACCESS  A
 WHERE A.SID=S.SID 
   AND P.ADDR=S.PADDR 
   AND S.USERNAME != 'SYS'
  • 위 쿼리문의 결과가 있다면 락이 걸린 세션이 있다는것이므로 아래의 쿼리문으로 세션을 죽인다
ALTER SYSTEM KILL SESSION '11,39061'
  • alter session으로 죽지않는 프로세스 죽이기
1.oracle이 설치된 서버에 텔넷으로 root로 접속한다
2.su -오라클계정
3.sqlplus '/as sysdba''
4.connect system/sys
5.ALTER SYSTEM KILL SESSION '137,1723'


4.4 1일 이상 존재 하는 조회 / kill / AWS_KILL_CMD[편집]

-- DROP VIEW RTIS_DBA.V_DBA_KILL_SESS_OVER_1DAY;

CREATE OR REPLACE FORCE VIEW V_DBA_KILL_SESS_OVER_1DAY
(
    STATUS
  , USERNAME
  , OSUSER
  , MACHINE
  , EXEC_TIME
  , SID
  , SERIAL#
  , CMD_KILL
)
BEQUEATH DEFINER
AS
      SELECT STATUS
           , USERNAME
           , OSUSER
           , MACHINE
           , NVL (A.SQL_EXEC_START, A.PREV_EXEC_START)    EXEC_TIME
           , SID
           , SERIAL#
           ,    'EXEC RDSADMIN.RDSADMIN_UTIL.KILL('
             || TO_CHAR (SID)
             || ','
             || TO_CHAR (SERIAL#)
             || ');'                                      CMD_KILL
        FROM V$SESSION A
       WHERE     STATUS = 'INACTIVE'
             AND TYPE = 'USER'
             AND MACHINE NOT LIKE 'ip%'
             AND (SYSDATE - NVL (A.SQL_EXEC_START, A.PREV_EXEC_START)) * 24 > 1
    ORDER BY EXEC_TIME DESC;



5 프로세스 정보[편집]

5.1 Oracle Process의 정보[편집]

  • V$SESSION
  • V$PROCESS
  • SYS.V_$SESS_IO
SELECT S.STATUS "STATUS"
     , S.SERIAL# "SERIAL#"
     , S.TYPE "TYPE"
     , S.USERNAME "DB USER"
     , S.OSUSER "CLIENT USER"
     , S.SERVER "SERVER"
     , S.MACHINE "MACHINE"
     , S.MODULE "MODULE"
     , S.TERMINAL "TERMINAL"
     , S.PROGRAM "PROGRAM"
     , P.PROGRAM "O.S. PROGRAM"
     , S.LOGON_TIME "CONNECT TIME"
     , LOCKWAIT "LOCK WAIT"
     , SI.PHYSICAL_READS "PHYSICAL READS"
     , SI.BLOCK_GETS "BLOCK GETS"
     , SI.CONSISTENT_GETS "CONSISTENT GETS"
     , SI.BLOCK_CHANGES "BLOCK CHANGES"
     , SI.CONSISTENT_CHANGES "CONSISTENT CHANGES"
     , S.PROCESS "PROCESS"
     , P.SPID
     , P.PID
     , S.SERIAL#
     , SI.SID
     , S.SQL_ADDRESS "ADDRESS"
     , S.SQL_HASH_VALUE "SQL HASH"
     , S.ACTION
  FROM V$SESSION S
     , V$PROCESS P
     , SYS.V_$SESS_IO SI
 WHERE S.PADDR = P.ADDR(+) 
   AND SI.SID(+) = S.SID 
   AND S.USERNAME IS NOT NULL 
   AND NVL(S.OSUSER, 'X') <> 'SYSTEM' 
   AND S.TYPE <> 'BACKGROUND' 
 ORDER BY 3;

5.2 오브젝트에 접속되어 있는 프로그램 조회[편집]

  • V$SESSION
  • V$ACCESS
SELECT SUBSTR(B.OBJECT, 1, 15) AS OBJECT, SUBSTR(A.PROGRAM, 1, 15) AS PROGRAM, COUNT(*) AS CNT 
  FROM V$SESSION A
     , V$ACCESS B
 WHERE A.SID = B.SID 
   AND B.OWNER NOT IN ('SYS') 
   AND A.TYPE!= 'BACKGROUND' 
   AND B.OBJECT LIKE UPPER('&OBJECT_NAME') || '%' 
 GROUP BY B.OBJECT, SUBSTR(A.PROGRAM, 1, 15);

6 부하 발생 모니터링[편집]

6.1 cpu를 많이 사용하는 쿼리문과 프로세스아이디,시리얼번호,머신 알아내기[편집]

  • V$PROCESS
  • V$SESSION
  • V$SQLTEXT
SELECT C.SQL_TEXT
     , B.SID
     , B.SERIAL#
     , B.MACHINE
     , B.OSUSER
     , B.LOGON_TIME --이 쿼리를 호출한 시간
  FROM V$PROCESS A
     , V$SESSION B
     , V$SQLTEXT C
 WHERE A.ADDR = B.PADDR
   AND B.SQL_HASH_VALUE = C.HASH_VALUE
--AND A.SPID = '675958'
 ORDER BY C.PIECE

6.2 롤백 세그먼트 경합 조회[편집]

  • V$ROLLSTAT
  • V$ROLLNAME
SELECT NAME T0
     , GETS T1
     , WAITS T2
     , TO_CHAR(TRUNC(WAITS / GETS * 100, 2), 099.99) || '%' T3
     , TO_CHAR(ROUND(RSSIZE / 1024)) T4
     , SHRINKS T5
     , EXTENDS T6
  FROM V$ROLLSTAT
     , V$ROLLNAME
 WHERE V$ROLLSTAT.USN = V$ROLLNAME.USN;

6.3 버퍼 캐시 히트율(Buffer Cache Hit Ratio)[편집]

  • V$SYSSTAT
SELECT ROUND(((1-(SUM(DECODE(name, 'physical reads', value,0))/(SUM(DECODE(name, 'db block gets', value,0))+ (SUM(DECODE(name, 'consistent gets', value, 0))))))*100),2) || '%' "Buffer Cache Hit Ratio"
  FROM V$SYSSTAT;

6.4 라이브러리 캐시 히트율(Library Cache Hit Ratio)[편집]

  • V$LIBRARYCACHE
SELECT (1-SUM (reloads)/SUM(pins))*100 "Library Cache Hit Ratio"
From V$LIBRARYCACHE;

6.5 데이터 딕셔너리 캐시 히트율(Data Dictionary Cache Hit Ratio)[편집]

  • V$ROWCACHE
SELECT (1-SUM(getmisses)/SUM(gets))*100 "Data Dictionary Hit Ratio"
  FROM V$ROWCACHE;

7 I/O 부하 찾기[편집]

  • V$IOFUNCMETRIC
-- iometric values in 11g

select min(begin_time) b_time, min(end_time) e_time, function_name,
       round(sum(small_read_iops+large_read_iops)) read_TOT_iops, round(sum(small_write_iops+large_write_iops)) write_TOT_iops, round(sum(large_read_mbps+small_read_mbps)) read_TOT_mbps, round(sum(large_write_mbps+small_write_mbps)) write_TOT_mbps
       from GV$IOFUNCMETRIC
       group by rollup(function_name)
       having round(sum(small_read_iops+large_read_iops)) + round(sum(large_read_mbps+small_read_mbps)) + round(sum(small_write_iops+large_write_iops)) + round(sum(large_write_mbps+small_write_mbps))  >0
       order by function_name;
-- query to iofuncmetric view in 11g

select inst_id,begin_time,function_name,
       round(small_read_iops) RD_IOPS_sm, round(large_read_iops) RD_IOPS_lg, 
       round(small_read_mbps) RD_MBPS_sm, round(large_read_mbps) RD_MBPS_lg, 
       round(small_write_iops) WT_IOPS_sm, round(large_write_iops) WT_IOPS_lg, 
       round(small_write_mbps) WT_MBPS_sm, round(large_write_mbps) WT_MBPS_lg 
from GV$IOFUNCMETRIC
--where function_name in ('Buffer Cache Reads','LGWR','DBWR','Direct Reads','Direct Writes','RMAN') 
--where round(small_read_iops+large_read_iops+small_write_iops+large_write_iops) >0
order by function_name,inst_id;
select min(begin_time) b_time, min(end_time) e_time, round(sum(small_read_iops+large_read_iops)) read_TOT_iops, round(sum(large_read_mbps+small_read_mbps)) read_TOT_mbps, round(sum(small_write_iops+large_write_iops)) write_TOT_iops, round(sum(large_write_mbps+small_write_mbps)) write_TOT_mbps from GV$IOFUNCMETRIC;

7.1 인스턴스 기동 이후 I/O 관련 대기현상 누적 값[편집]

- v$system_event의 time_waited는 centisecond (1/100 초)

SELECT EVENT ,
       TOTAL_WAITS ,
       TIME_WAITED / 100 AS "TIME_WAITED(SEC)" ,
       AVERAGE_WAIT
FROM V$SYSTEM_EVENT
WHERE EVENT IN ('DB FILE SEQUENTIAL READ' ,
                'LOG FILE SYNC' ,
                'DB FILE SCATTERED READ') 
;

7.1.1 전체 IO량(100%) 대비 사용자별 IO량[편집]

WITH io AS (
  SELECT /*+ materialize */ decode(statistic_name,'logical reads', 'lio','pio') io_type
       , sum(value) io_value
  FROM v$segment_statistics
 WHERE statistic_name IN ( 'logical reads' ,
                           'physical reads' ,
                           'physical reads direct' )
 GROUP BY decode(statistic_name,'logical reads', 'lio','pio')),
per_io AS
( SELECT OWNER,
         object_name,
         object_type,
         seg_io,
         seg_value,
         round(seg_value / decode(seg_io,'lio',
                                      (SELECT io_value
                                       FROM io
                                       WHERE io_type='lio'),
                                      (SELECT io_value
                                       FROM io
                                       WHERE io_type='pio') )*100,5) per_seg_io
 FROM
     ( SELECT ss.OWNER,
                 ss.object_name,
                 ss.object_type,
                 decode(ss.statistic_name,'logical reads', 'lio','pio') seg_io,
                                                                        sum(ss.value) seg_value
      FROM v$segment_statistics ss
      WHERE ss.statistic_name IN ( 'logical reads' ,
                                   'physical reads' ,
                                   'physical reads direct' )
      GROUP BY ss.OWNER,
                  ss.object_name,
                  ss.object_type,
                  decode(ss.statistic_name,'logical reads', 'lio','pio') ))
SELECT *
FROM
( SELECT OWNER,
         sum(decode(seg_io,'lio',per_seg_io)) AS lio,
         sum(decode(seg_io,'pio',per_seg_io)) AS pio
 FROM per_io
 GROUP BY OWNER
 ORDER BY sum(decode(seg_io,'lio',per_seg_io)) DESC)
WHERE rownum <= 50 - Segment별 전체 IO량(100%) 대비 IO량 (TABLE/INDEX 분리) WITH io AS
( SELECT /*+ materialize */ decode(statistic_name,'logical reads', 'lio','pio') io_type,
                                                                                sum(value) io_value
 FROM v$segment_statistics
 WHERE statistic_name IN ( 'logical reads' ,
                           'physical reads' ,
                           'physical reads direct' )
 GROUP BY decode(statistic_name,'logical reads', 'lio','pio')),
                                                                        per_io AS
( SELECT OWNER,
         object_name,
         object_type,
         seg_io,
         seg_value,
         round(seg_value / decode(seg_io,'lio',
                                      (SELECT io_value
                                       FROM io
                                       WHERE io_type='lio'),
                                      (SELECT io_value
                                       FROM io
                                       WHERE io_type='pio') )*100,5) per_seg_io
 FROM
     ( SELECT ss.OWNER,
                 ss.object_name,
                 ss.object_type,
                 decode(ss.statistic_name,'logical reads', 'lio','pio') seg_io,
                                                                        sum(ss.value) seg_value
      FROM v$segment_statistics ss
      WHERE ss.statistic_name IN ( 'logical reads' ,
                                   'physical reads' ,
                                   'physical reads direct' )
      GROUP BY ss.OWNER,
                  ss.object_name,
                  ss.object_type,
                  decode(ss.statistic_name,'logical reads', 'lio','pio') ))

SELECT *
  FROM per_io
ORDER BY per_seg_io DESC 
;




8 오라클 서버 스펙[편집]

8.1 테이블 스페이스 사용량[편집]

  • dba_data_files
  • dba_free_space
SELECT A.TABLESPACE_NAME,
             A.TOTAL "TOTAL(MB)",
             A.TOTAL - B.FREE "USED(MB)",
             NVL(B.FREE,0) "FREE(MB)",
             ROUND((A.TOTAL - NVL(B.FREE,0))*100/TOTAL,0)  "USED(%)"
  FROM ( SELECT TABLESPACE_NAME
                , ROUND((SUM(BYTES)/1024/1024),0) AS TOTAL
             FROM DBA_DATA_FILES
            GROUP BY TABLESPACE_NAME
       ) A
     , ( SELECT TABLESPACE_NAME
              , ROUND((SUM(BYTES)/1024/1024),0) AS FREE
           FROM DBA_FREE_SPACE
          GROUP BY  TABLESPACE_NAME
       ) B
 WHERE A.TABLESPACE_NAME = B.TABLESPACE_NAME(+)
 ORDER BY A.TABLESPACE_NAME;

8.2 System 테이블스페이스에 비시스템 세그먼트 조회[편집]

  • DBA_SEGMENTS
SELECT OWNER
     , SEGMENT_NAME
     , SEGMENT_TYPE
     , TABLESPACE_NAME
  FROM DBA_SEGMENTS 
 WHERE OWNER NOT IN ('SYS', 'SYSTEM') 
   AND TABLESPACE_NAME = 'SYSTEM';

8.3 오라클서버의 메모리[편집]

  • v$sgastat
SELECT * FROM V$SGASTAT;

SELECT POOL, SUM(BYTES) "SIZE"
  FROM V$SGASTAT
 WHERE POOL = 'SHARED POOL'
 GROUP BY POOL

8.4 총 CPU Time 대비 SQL Parsing Time[편집]

  • V$SYSSTAT
SELECT MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'CPU USED BY THIS SESSION',X.VALUE))) AS "CPU USED BY THIS SESSION" ,
       MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'PARSE TIME CPU',X.VALUE))) AS "PARSE TIME CPU" ,
       ROUND((MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'PARSE TIME CPU',X.VALUE)))/MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'CPU USED BY THIS SESSION',X.VALUE))) * 100),1)||'%' AS "PARSETIME/CPU(%)"
FROM
    ( SELECT NAME,
             VALUE
     FROM V$SYSSTAT
     WHERE NAME IN ('CPU USED BY THIS SESSION',
                    'PARSE TIME CPU') ) X,
    (SELECT LEVEL AS RNO
     FROM DUAL CONNECT BY LEVEL<=2) Y ;

=== 총 Parsing Time 대비 Hard Parsing Time ===
* V$SYS_TIME_MODEL
<source lang="sql"> 
SELECT MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'PARSE TIME ELAPSED',X.VALUE))) AS "PARSE TIME ELAPSED" ,
       MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'HARD PARSE ELAPSED TIME',X.VALUE))) AS "HARD PARSE ELAPSED TIME" ,
       ROUND((MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'HARD PARSE ELAPSED TIME',X.VALUE)))/MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'PARSE TIME ELAPSED',X.VALUE))) * 100),1)||'%' AS "HARD/PARSETORAL(%)"
FROM
    ( SELECT STAT_NAME AS NAME,
             VALUE
     FROM V$SYS_TIME_MODEL
     WHERE STAT_NAME IN ('PARSE TIME ELAPSED',
                         'HARD PARSE ELAPSED TIME') ) X,
    (SELECT LEVEL AS RNO
     FROM DUAL CONNECT BY LEVEL<=2) Y ;

8.5 Log file sync 관련 대기현상 Sync Writes Time[편집]

  • redo synch time의 단위는 centisecond (1/100 초)
  • v$sysstat의 stat 중 time 정보를 담고 있는 stat의 value 단위는 centisecond이다.
SELECT MAX(DECODE(Y.RNO,1,DECODE(X.NAME,'USER COMMITS',X.VALUE))) AS "USER COMMITS" ,
       MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'REDO SYNCH WRITES',X.VALUE))) AS "REDO SYNCH WRITES" ,
       MAX(DECODE(Y.RNO,3,DECODE(X.NAME,
        'REDO SYNCH TIME',X.VALUE/100))) AS "REDO SYNCH TIME" ,
       ROUND((MAX(DECODE(Y.RNO,3,DECODE(X.NAME,'REDO SYNCH TIME',X.VALUE/100)))/MAX(DECODE(Y.RNO,2,DECODE(X.NAME,'REDO SYNCH WRITES',X.VALUE)))),3)||'초' AS "SYNCTIME/SYNCWRITES(초)"
FROM
    ( SELECT NAME,
             VALUE
     FROM V$SYSSTAT
     WHERE NAME IN ('USER COMMITS' ,
                    'REDO SYNCH TIME' ,
                    'REDO SYNCH WRITES') ) X,
    (SELECT LEVEL AS RNO
     FROM DUAL CONNECT BY LEVEL<=3) Y 
;

9 INDEX 정보 추출하기[편집]

9.1 Function-based Index 컬럼 찾기[편집]

SELECT table_owner,
       TABLE_NAME,
       index_name,
       column_expression
FROM dba_ind_expressions
WHERE table_owner LIKE upper(ltrim(rtrim(:owner)))
    AND TABLE_NAME LIKE upper(ltrim(rtrim(:table))) ;
;

9.2 중복 인덱스 찾기(불필요 인덱스)[편집]

SELECT di.table_owner "OWNER" ,
       di.TABLE_NAME ,
          dic1.index_name || chr(10) || ' (' || replace(dic1.index_cols,' ',',') || decode(sign(dic1.cnt-6),1,'...') || ')' "삭제대상 INDEX" , dic2.index_name || chr(10) || ' (' || replace(dic2.index_cols,' ',',') || decode(sign(dic1.cnt-7),1,'...') || ')' "삭제원인 INDEX"
FROM dba_indexes di ,
    ( SELECT table_owner,
             TABLE_NAME,
             index_owner,
             index_name,
             TRIM(MAX(DECODE(column_position, 1, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 2, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 3, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 4, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 5, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 6, COLUMN_NAME))) INDEX_COLS,
             count(*) cnt
     FROM dba_ind_columns dic
     WHERE table_owner NOT IN ('SYS',
                               'SYSTEM')
     GROUP BY table_owner,
              TABLE_NAME,
              index_owner,
              index_name ) dic1 ,
    ( SELECT table_owner,
             TABLE_NAME,
             index_owner,
             index_name,
             TRIM(MAX(DECODE(column_position, 1, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 2, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 3, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 4, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 5, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 6, COLUMN_NAME)) || ' ' || MAX(DECODE(column_position, 7, COLUMN_NAME))) INDEX_COLS,
             count(*) cnt
     FROM dba_ind_columns dic
     WHERE table_owner NOT IN ('SYS',
                               'SYSTEM')
     GROUP BY table_owner,
              TABLE_NAME,
              index_owner,
              index_name ) dic2
WHERE di.table_owner NOT IN ('SYS','SYSTEM')
    AND di.owner=dic1.index_owner
    AND di.index_name=dic1.index_name
    AND di.table_owner=dic1.table_owner
    AND di.TABLE_NAME=dic1.TABLE_NAME
    AND dic1.table_owner=dic2.table_owner
    AND dic1.TABLE_NAME=dic2.TABLE_NAME
    AND dic1.index_name<>dic2.index_name
    AND dic2.index_cols LIKE dic1.index_cols || '%'
    AND dic2.cnt>dic1.cnt 
;

9.3 CONSTRAINTS 확인하기[편집]

-- 해당 테이블에 걸린 Constraints 확인하기

SELECT t.owner ,
           t.constraint_name ,
           t.constraint_type ,
           t.TABLE_NAME ,
             c.COLUMN_NAME ,
               c.position ,
               t.r_owner ,
               t.r_constraint_name ,
               t.status ,
               t.last_change ,
               t.index_owner ,
               t.index_name
    FROM dba_constraints t ,
         dba_cons_columns c WHERE t.TABLE_NAME = :table_name
    AND t.TABLE_NAME = c.TABLE_NAME
    AND t.constraint_name = c.constraint_name
    AND t.constraint_type <> 'C'
ORDER BY TABLE_NAME ASC, constraint_type DESC,
                         CONSTRAINT_NAME ASC, POSITION ASC 
;

9.4 해당 테이블을 참조하는 테이블(자식) Constraints 확인하기[편집]

SELECT t.owner ,
       t.CONSTRAINT_NAME ,
         t.constraint_type ,
         t.TABLE_NAME ,
           c.COLUMN_NAME ,
             c.POSITION ,
               t.r_owner ,
               t.r_constraint_name ,
               t.status ,
               t.last_change ,
               t.index_owner ,
               t.index_name
FROM dba_constraints t ,
     dba_cons_columns c
WHERE t.R_CONSTRAINT_NAME = '%'|| :table_name ||'%'
    AND t.TABLE_NAME = c.TABLE_NAME
    AND t.CONSTRAINT_NAME = c.CONSTRAINT_NAME
    AND t.constraint_type <> 'C'
ORDER BY TABLE_NAME ASC, constraint_type DESC,
                         CONSTRAINT_NAME ASC, POSITION ASC 
;


9.5 v$segment_statistics 활용하기[편집]

9.6 Parameter 확인하기[편집]

SET linesize 200
SET pagesize 100 col name
FOR a30 col value
FOR a10 col display_value
FOR a10 col isdefault
FOR a10 col ismodified
FOR a10

SELECT name,
       value,
       isdefault,
       ismodified
FROM v$parameter
WHERE name IN ( 'lock_sga' ,
                'db_cache_advice' ,
                'optimizer_dynamic_sampling' ,
                'session_cached_cursors' ,
                'sga_max_size' ,
                'sga_target' ,
                'db_cache_size' ,
                'shared_pool_size' ,
                'shared_pool_reserved_size' ,
                'log_buffer' ,
                'skip_unusable_indexes' ,
                'pga_aggregate_target' ,
                'workarea_size_policy' ,
                'cpu_count' ,
                'statistics_level') ;
SELECT ksppinm AS name,
       ksppstvl AS value
FROM sys.x$ksppi x
   , sys.x$ksppcv y
WHERE (x.indx = y.indx)
AND (translate(ksppinm,'_','#') LIKE '%_optim_peek_user_binds%'
     OR translate(ksppinm,'_','#') LIKE '%_kks_use_mutex_pin%'
     OR translate(ksppinm,'_','#') LIKE '%_gby_hash_aggregation_enabled%'
     OR translate(ksppinm,'_','#') LIKE '%_gc_affinity_time%'
     OR translate(ksppinm,'_','#') LIKE '%_optimizer_skip_scan_enabled%'
     OR translate(ksppinm,'_','#') LIKE '%_pga_max_size%'
     OR translate(ksppinm,'_','#') LIKE '%_smm_max_size%'
     OR translate(ksppinm,'_','#') LIKE '%_b_tree_bitmap_plans%'
     OR translate(ksppinm,'_','#') LIKE '%_undo_autotune%' ) ;

9.7 Bind Peeked 확인하기[편집]

SELECT p.plan_table_output
  FROM
( SELECT sql_id ,
         child_number
 FROM v$sql
 WHERE hash_value=:hash_value ) s 
     , TABLE(dbms_xplan.display_cursor(s.sql_id , s.child_number , 'typical +peeked_binds')) p 
;


-- Group By 처리하는 방식 변경

파라미터 : _gby_hash_aggregation_enabled VERSION : 10g에서 신규 추가된 파라미터 해석방법 : FALSE 
-
GROUP BY +
ORDER BY TRUE -
GROUP BY 주의사항 : 9i에서 10g로 업그레이드 수행 시 해당 파라미터가 True이면 기존
GROUP BY 절이 있는 SQL문의 정렬이 되지 않기 때문에 도출되는 결과가 바뀔 수 있다. 이럴 경우에는 해당 프로그램들에
ORDER by를 추가하여야 한다. _b_tree_bitmap_plans=TRUE

9.8 JOB 확인하기[편집]

SELECT *
  FROM dba_jobs
 WHERE last_date >= to_date('20110906 14:00:00' , 'yyyymmdd hh24:mi:ss')
ORDER BY last_date
SELECT *
  FROM dba_objects
 WHERE object_name = upper('proc_olap_summ_measure_run_02')
SELECT *
FROM v$sqlarea WHERE program_id = 100286 
;
SELECT *
FROM TABLE(DBMS_XPLAN.DISPLAY_CURSOR(NULL,NULL,’ALLSTATS COST LAST’));

9.9 DB Link SQL CURSOR 확인하기[편집]

SELECT inst_id ,
       kglnaown ,
       kglnaobj ,
       kglnadlk , -- DB Link
       decode(kglhdnsp , 0 , 'CURSOR' , 1 , 'TABLE/PROCEDURE' , 2 , 'BODY' , 3 , 'TRIGGER' , 4 , 'INDEX' , 5 , 'CLUSTER' , 6 , 'OBJECT' , 13 , 'JAVA SOURCE' , 14 , 'JAVA RESOURCE' , 15 , 'REPLICATED TABLE OBJECT' , 16 , 'REPLICATION INTERNAL PACKAGE' , 17 , 'CONTEXT POLICY' , 18 , 'PUB_SUB' , 19 , 'SUMMARY' , 20 , 'DIMENSION' , 21 , 'APP CONTEXT' , 22 , 'STORED OUTLINE' , 23 , 'RULESET' , 24 , 'RSRC PLAN' , 25 , 'RSRC CONSUMER GROUP' , 26 , 'PENDING RSRC PLAN' , 27 , 'PENDING RSRC CONSUMER GROUP' , 28 , 'SUBSCRIPTION' , 29 , 'LOCATION' , 30 , 'REMOTE OBJECT' , 31 , 'SNAPSHOT METADATA' , 32 , 'JAVA SHARED DATA' , 33 , 'SECURITY PROFILE' , 'INVALID NAMESPACE') ,
       decode(bitand(kglobflg , 3) , 0 , 'NOT LOADED' , 2 , 'NON-EXISTENT' , 3 , 'INVALID STATUS' , decode(kglobtyp , 0 , 'CURSOR' , 1 , 'INDEX' , 2 , 'TABLE' , 3 , 'CLUSTER' , 4 , 'VIEW' , 5 , 'SYNONYM' , 6 , 'SEQUENCE' , 7 , 'PROCEDURE' , 8 , 'FUNCTION' , 9 , 'PACKAGE' , 10 , 'NON-EXISTENT' , 11 , 'PACKAGE BODY' , 12 , 'TRIGGER' , 13 , 'TYPE' , 14 , 'TYPE BODY' , 15 , 'OBJECT' , 16 , 'USER' , 17 , 'DBLINK' , 18 , 'PIPE' , 19 , 'TABLE PARTITION' , 20 , 'INDEX PARTITION' , 21 , 'LOB' , 22 , 'LIBRARY' , 23 , 'DIRECTORY' , 24 , 'QUEUE' , 25 , 'INDEX-ORGANIZED TABLE' , 26 , 'REPLICATION OBJECT GROUP' , 27 , 'REPLICATION PROPAGATOR' , 28 , 'JAVA SOURCE' , 29 , 'JAVA CLASS' , 30 , 'JAVA RESOURCE' , 31 , 'JAVA JAR' , 32 , 'INDEX TYPE' , 33 , 'OPERATOR' , 34 , 'TABLE SUBPARTITION' , 35 , 'INDEX SUBPARTITION' , 36 , 'REPLICATED TABLE OBJECT' , 37 , 'REPLICATION INTERNAL PACKAGE' , 38 , 'CONTEXT POLICY' , 39 , 'PUB_SUB' , 40 , 'LOB PARTITION' , 41 , 'LOB SUBPARTITION' , 42 , 'SUMMARY' , 43 , 'DIMENSION' , 44 , 'APP CONTEXT' , 45 , 'STORED OUTLINE' , 46 , 'RULESET' , 47 , 'RSRC PLAN' , 48 , 'RSRC CONSUMER GROUP' , 49 , 'PENDING RSRC PLAN' , 50 , 'PENDING RSRC CONSUMER GROUP' , 51 , 'SUBSCRIPTION' , 52 , 'LOCATION' , 53 , 'REMOTE OBJECT' , 54 , 'SNAPSHOT METADATA' , 55 , 'IFS' , 56 , 'JAVA SHARED DATA' , 57 , 'SECURITY PROFILE' , 'INVALID TYPE')) ,
       kglobhs0+kglobhs1+kglobhs2+kglobhs3+kglobhs4+kglobhs5+kglobhs6 ,
       kglhdldc ,
       kglhdexc ,
       kglhdlkc ,
       kglobpc0 ,
       decode(kglhdkmk , 0 , 'NO' , 'YES') ,
       kglhdclt ,
       kglhdivc ,
       kglhdpar AS paddress,
       ------->>> 추가한 부분

       kglhdadr AS address,
       ------->>> 추가한 부분

       kglnahsh AS hash_value,
       ------->>> 추가한 부분

       kglobt03 AS sql_id ------->>> 추가한 부분
FROM x$kglob
WHERE kglhdnsp = 0 -- NAMESPACE='CURSOR'
AND kglnadlk IS NOT NULL ;


9.10 INDEX Deleted ROWS CHECK [1][편집]

- Validate + index_stats

SET serveroutput ON
SET pagesize 0
SET linesize 200
SET feedback OFF
SET timing OFF 

--------------------------------------------------------------------------------
-- Work Time
--------------------------------------------------------------------------------

COLUMN the_date new_value run_date
SELECT to_char(sysdate,'yyyymmddhh24mi') the_date
FROM dual;

--------------------------------------------------------------------------------
-- File Creation - Index Size Check Script
--------------------------------------------------------------------------------
spool index_validate_check.SQL DECLARE
CURSOR cur_index_name IS
SELECT OWNER,
       index_name
FROM dba_indexes
WHERE OWNER = 'SYSTEM' ;

BEGIN dbms_output.enable(buffer_size=>2000000);
FOR index_rec IN cur_index_name LOOP dbms_output.put_line('Validate index '||index_rec.OWNER||'.'||index_rec.index_name||';');
dbms_output.put_line(' ');
dbms_output.put_line('select  '''||index_rec.OWNER||''',');
dbms_output.put_line('        name index_name,');
dbms_output.put_line('        lf_rows Tot_rows,');
dbms_output.put_line('        del_lf_rows Deleted_Rows,');
dbms_output.put_line('        (del_lf_rows * 100)/decode(lf_rows,0,0.1,lf_rows) "deleted(%)",');
dbms_output.put_line('        round(btree_space/1024/1024/1024,3) "tot_space(GB)",');
dbms_output.put_line('        round(used_space/1024/1024/1024,3) "used_space(GB)",');
dbms_output.put_line('        pct_used "used_pct(%)",');
dbms_output.put_line('        100 - pct_used "empty_pct(%)",');
dbms_output.put_line('        decode( sign((del_lf_rows * 100)/decode(lf_rows,0,0.1,lf_rows) - 20),1,');
dbms_output.put_line('                ''--->> Rebuild required'',');
dbms_output.put_line('                ''--->> Good'') Check_Result');
dbms_output.put_line(' from index_stats ;');
END LOOP;
END;
/


--------------------------------------------------------------------------------
-- Run - Index Size Check Script
--------------------------------------------------------------------------------
col OWNER format a10;
col index_name format a33;
col tot_rows format 99999999 col deleted_rows format 99999999 spool c:\total_index_size_check_&run_date..txt prompt OWNER INDEX name total ROWS deleted ROWS deleted(%) tot_space used_space used_pct(%) empty_pct(%) prompt 
---------------------------------------------------------------------------------------------------------------------------------
@index_validate_check spool OFF
SET feedback ON
SET serveroutput OFF 
################################################################################ 
## INDEX Deleted ROWS CHECK [2] - INDEX STATISTICS 
################################################################################ 
col blevel heading "INDEX|BLEVEL" 
col leaf_blocks heading "LEAF|BLOCKS" 
col num_rows heading "NUM|ROWS" 
col usable_key_count_per_block heading "USABLE_KEY|COUNT|PER_BLOCK" 
col current_key_count_per_block heading "CURRENT_KEY|COUNT|PER_BLOCK" 
col used_percent heading "USED|PERCENT|(%)" 
col empty_percent heading "EMPTY|PERCENT|(%)"
SELECT *
FROM
( SELECT /*+ leading(i) use_hash(i s) */ i.index_name,
                                         max(i.blevel) AS blevel,
                                         max(i.leaf_blocks) AS leaf_blocks,
                                         max(i.num_rows) AS num_rows,
                                         sum(s.blocks) AS "BLOCKS",
                                         sum(s.bytes)/1024/1024 AS "SIZE(MB)",
                                         max(i.usable_key_count_per_block) AS usable_key_count_per_block,
                                         max(i.current_key_count_per_block) AS current_key_count_per_block,
                                         max(i.used_percent) AS used_percent,
                                         max(i.empty_percent) AS empty_percent
 FROM
     ( SELECT i.index_name,
              i.blevel,
              i.leaf_blocks,
              i.num_rows,
              round(i.usable_block_size / (i.avg_key_length),0) AS usable_key_count_per_block,
              round(i.num_rows / i.leaf_blocks,0) AS current_key_count_per_block,
              round((i.num_rows / i.leaf_blocks) / (i.usable_block_size / i.avg_key_length) * 100,0) AS used_percent,
              round(100 -((i.num_rows / i.leaf_blocks) / (i.usable_block_size / i.avg_key_length) * 100)) AS empty_percent
      FROM
          ( SELECT i.index_name,
                   sum(c1.avg_col_len)+9 AS avg_key_length,
                   max(t.block_size*0.98) usable_block_size,
                   max(i.blevel) blevel,
                   max(i.leaf_blocks) leaf_blocks,
                   max(i.num_rows) num_rows
           FROM dba_indexes i,
                dba_tab_columns c1,
                dba_ind_columns c2,
                dba_tablespaces t
           WHERE i.OWNER=upper('GCKDPROD') --and    i.table_name = upper('TSD_PTSEQ_I')
 --and    i.index_name LIKE '%'

               AND i.OWNER=c1.OWNER
               AND i.TABLE_NAME=c1.TABLE_NAME
               AND c1.OWNER=c2.table_owner
               AND c1.TABLE_NAME=c2.TABLE_NAME
               AND c1.COLUMN_NAME=c2.COLUMN_NAME
               AND i.OWNER=c2.index_owner
               AND i.index_name=c2.index_name
               AND i.tablespace_name=t.tablespace_name
           GROUP BY i.index_name HAVING max(i.leaf_blocks) >= 10000 ) i ) i,
                                                                          dba_segments s
 WHERE s.OWNER = 'GCKDPROD'
     AND i.index_name = s.segment_name
 GROUP BY i.index_name
 ORDER BY max(i.empty_percent) DESC)
WHERE rownum <= 50 ;
################################################################################ 
## Locking Contention Query 
################################################################################
SELECT OS_USER_NAME AS OSUSER,
       s.serial# AS "SERIAL NO.",
       PROCESS AS "PID",
       ORACLE_USERNAME AS "USERNAME",
       l.SID AS "SID",
       DECODE(l.TYPE -- Long locks, 'TM', 'dml/data enq (TM)', 'TX', 'transac enq (TX) ', 'UL', 'pls usr lock (UL)'
-- Short locks, 'BL', 'buf hash tbl (BL)', 'CF', 'control file (CF)', 'CI', 'cross inst f (CI)', 'CU', 'cursor bind (CU) ', 'DF', 'data file (CF) ', 'DL', 'direct load (DL) ', 'DM', 'mount/strtup (DM)', 'DR', 'reco lock (DR) ', 'DX', 'distrib tran (DX)', 'FI', 'sga opn file (FI)', 'FS', 'file set (FS) ', 'IN', 'instance num (IN)', 'IR', 'instce recvr (IR)', 'IS', 'get state (IS) ', 'IV', 'libcache inv (IV)', 'JQ', 'job queue (JQ) ', 'KK', 'log sw kick (KK) ', 'LS', 'log switch (LS) ', 'MM', 'mount def (MM) ', 'MR', 'media recvry (MR)', 'PF', 'pwfile enq (PF) ', 'PR', 'process strt (PR)', 'RW', 'row wait (RW) ', 'RT', 'redo thread (RT) ', 'SC', 'scn enq (SC) ', 'SM', 'smon lock (SM) ', 'SN', 'seqno instce (SN)', 'SQ', 'seqno enq (SQ) ', 'ST', 'space transc (ST)', 'SV', 'seqno value (SV) ', 'TA', 'generic enq (TA) ', 'TD', 'dll enq (TD) ', 'TE', 'extend seg (TE) ', 'TS', 'temp segment (TS)', 'TT', 'temp table (TT) ', 'UN', 'user name (UN) ', 'WL', 'write redo (WL) ', 'TYPE = ' || l.TYPE) AS type,
 decode(l.lmode, 0, 'none', 1, 'null', 2, 'RS', 3, 'RX', 4, 'S', 5, 'SRX', 6, 'Exclusive', TO_CHAR(l.lmode)) AS lmode,
 decode(l.request, 0, 'none', 1, 'null', 2, 'RS', 3, 'RX', 4, 'S', 5, 'SRX', 6, 'X', TO_CHAR(l.request)) AS lrequest,
 decode(BLOCK, 0, 'Not Blocking', 1, 'Blocking', 2, 'Global', block) AS "DETAIL",
 OWNER,
 object_name
FROM sys.v_$locked_object lo,
                          dba_objects DO,
                                      sys.v_$lock l,
(SELECT a.sid,
        a.serial#
 FROM v$session a,
                v$bgprocess b
 WHERE a.paddr = b.paddr(+)) s
WHERE lo.object_id = DO.object_id
AND l.sid = lo.session_id
AND s.sid = l.sid 
;

10 ASH를 이용한 모니터링[편집]

  • 최근 가장 많이 수행 된 SQL과 수행 점유율(수행 횟수)
  • v$active_session_history
SELECT sql_id ,
       COUNT(*) ,
       COUNT(*) *100/sum(COUNT(*)) over() pctload
  FROM v$active_session_history 
 WHERE sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
AND sample_time < to_date(:to_time,'yyyymmdd hh24miss')
GROUP BY sql_id
ORDER BY COUNT(*) DESC ;

10.1 특정 Session이 가장 많이 수행 된 SQL과 수행 점유율(수행 횟수)[편집]

  • v$active_session_history
SELECT sql_id ,
       COUNT(*) ,
       COUNT(*) *100/sum(COUNT(*)) over() pctload
FROM v$active_session_history
WHERE sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
AND sample_time < to_date(:to_time,'yyyymmdd hh24miss')
AND session_id = :b1
GROUP BY sql_id
ORDER BY COUNT(*) DESC ;

10.2 주요한 이벤트 메트릭 표시 gv$eventmetric v$event_name[편집]

  • sqlplus 스크립트
/* 
   eventmetric.sql - sqlplus script - displays significant event metrics
*/

col "Time /Delta" for a14
col name for a40
col INST_ID for 999
set linesize 140
set pagesize 1000

set wrap off 
select "Time /Delta",inst_id,name, 
        T_per_wait_fg*10 "Avg_FG_wait_ms", round(T_waited_fg/100,1) "Waited_FG_sec", W_count_fg "W_count_FG",
        round(T_waited/100,1) "Waited_tot_sec", W_count "W_count_tot"       
from (
  select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time /Delta",
       em.inst_id,en.name,
       sum(em.time_waited_fg) T_waited_fg, sum(em.time_waited) T_waited,sum(wait_count) W_count, sum(wait_count_fg) W_count_fg,
       sum(decode(em.wait_count, 0,0,round(em.time_waited/em.wait_count,2))) T_per_wait,
       sum(decode(em.wait_count_fg, 0,0,round(em.time_waited_fg/em.wait_count_fg,2))) T_per_wait_fg
  from gv$eventmetric em
     , v$event_name en
  where em.event#=en.event#
      and en.wait_class <>'Idle'
  group by em.inst_id,en.name,em.event_id
  order by T_waited_fg desc
  ) 
where rownum<=20;
set wrap on

10.3 중요한 시스템 메트릭 표시 gv$sysmetric[편집]

select "Time+Delta", "Metric", 
       case when "Total" >10000000 then '* '||round("Total"/1024/1024,0)||' M' 
            when "Total" between 10000 and 10000000 then '+ '||round("Total"/1024,0)||' K'
            when "Total" between 10 and 1024 then '  '||to_char(round("Total",0))
            else '  '||to_char("Total") 
       end "Total"
from (
 select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time+Delta",
       metric_name||' - '||metric_unit "Metric", 
       nvl(sum(value_inst1),0)+nvl(sum(value_inst2),0)+nvl(sum(value_inst3),0)+nvl(sum(value_inst4),0)+
       nvl(sum(value_inst5),0)+nvl(sum(value_inst6),0)+nvl(sum(value_inst7),0)+nvl(sum(value_inst8),0) "Total",
       sum(value_inst1) inst1, sum(value_inst2) inst2, sum(value_inst3) inst3, sum(value_inst4) inst4,
       sum(value_inst5) inst5, sum(value_inst6) inst6, sum(value_inst7) inst7, sum(value_inst8) inst8
 from
  ( select begin_time,intsize_csec,metric_name,metric_unit,metric_id,group_id,
       case inst_id when 1 then round(value,1) end value_inst1,
       case inst_id when 2 then round(value,1) end value_inst2,
       case inst_id when 3 then round(value,1) end value_inst3,
       case inst_id when 4 then round(value,1) end value_inst4,
       case inst_id when 5 then round(value,1) end value_inst5,
       case inst_id when 6 then round(value,1) end value_inst6,
       case inst_id when 7 then round(value,1) end value_inst7,
       case inst_id when 8 then round(value,1) end value_inst8
  from gv$sysmetric
  where metric_name in ('Host CPU Utilization (%)','Current OS Load', 'Physical Write Total IO Requests Per Sec', 
        'Physical Write Total Bytes Per Sec', 'Physical Write IO Requests Per Sec', 'Physical Write Bytes Per Sec',
         'I/O Requests per Second', 'I/O Megabytes per Second',
        'Physical Read Total Bytes Per Sec', 'Physical Read Total IO Requests Per Sec', 'Physical Read IO Requests Per Sec',
        'CPU Usage Per Sec','Network Traffic Volume Per Sec','Logons Per Sec','Redo Generated Per Sec','Redo Writes Per Sec',
        'User Transaction Per Sec','Average Active Sessions','Average Synchronous Single-Block Read Latency',
        'Logical Reads Per Sec','DB Block Changes Per Sec')
  )
 group by metric_id,group_id,metric_name,metric_unit
 order by metric_name
);

10.4 RAC 인스턴스별로 상세한 중요한 시스템 메트릭 gv$sysmetric[편집]

select to_char(min(begin_time),'hh24:mi:ss')||' /'||round(avg(intsize_csec/100),0)||'s' "Time+Delta",
       metric_name||' - '||metric_unit "Metric", 
       sum(value_inst1) inst1, sum(value_inst2) inst2, sum(value_inst3) inst3, sum(value_inst4) inst4,
       sum(value_inst5) inst5, sum(value_inst6) inst6
 from
  ( select begin_time,intsize_csec,metric_name,metric_unit,metric_id,group_id,
       case inst_id when 1 then round(value,1) end value_inst1,
       case inst_id when 2 then round(value,1) end value_inst2,
       case inst_id when 3 then round(value,1) end value_inst3,
       case inst_id when 4 then round(value,1) end value_inst4,
       case inst_id when 5 then round(value,1) end value_inst5,
       case inst_id when 6 then round(value,1) end value_inst6
  from gv$sysmetric
  where metric_name in ('Host CPU Utilization (%)','Current OS Load', 'Physical Write Total IO Requests Per Sec',
        'Physical Write Total Bytes Per Sec', 'Physical Write IO Requests Per Sec', 'Physical Write Bytes Per Sec',
         'I/O Requests per Second', 'I/O Megabytes per Second',
        'Physical Read Total Bytes Per Sec', 'Physical Read Total IO Requests Per Sec', 'Physical Read IO Requests Per Sec',
        'CPU Usage Per Sec','Network Traffic Volume Per Sec','Logons Per Sec','Redo Generated Per Sec',
        'User Transaction Per Sec','Average Active Sessions','Average Synchronous Single-Block Read Latency',
        'Logical Reads Per Sec','DB Block Changes Per Sec')
  )
 group by metric_id,group_id,metric_name,metric_unit
 order by metric_name;

10.5 특정 구간 이벤트 별 대기 시간 v$active_session_history[편집]

SELECT NVL(a.event, 'ON CPU') AS event,
       COUNT(*) AS total_wait_time
FROM v$active_session_history a
WHERE sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
AND sample_time < to_date(:to_time,'yyyymmdd hh24miss')
GROUP BY a.event
ORDER BY total_wait_time DESC;

10.6 특정 구간 CPU 점유율 순 - TOP SQL[편집]

SELECT ash.session_id ,
       ash.session_serial# ,
       ash.user_id ,
       ash.program ,
       MAX(en.name) event_name ,
       SUM(decode(ash.session_state , 'ON CPU' , 1 , 0)) "CPU" ,
       SUM(decode(ash.session_state , 'WAITING' , 1 , 0)) - SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "WAITING" ,
       SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "IO" ,
       SUM(decode(session_state , 'ON CPU' , 1 , 1)) "TOTAL"
FROM v$active_session_history ash 
   , v$event_name en
WHERE en.event# = ash.event#
AND ash.sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
AND ash.sample_time < to_date(:to_time,'yyyymmdd hh24miss')
GROUP BY session_id ,
         user_id ,
         session_serial# ,
         program
ORDER BY SUM(decode(session_state , 'ON CPU' , 1 , 1)) 
;

10.7 특정 구간 CPU 점유율 순 - TOP SESSION v$active_session_history[편집]

SELECT ash.session_id ,
       ash.session_serial# ,
       ash.user_id ,
       ash.program ,
       SUM(decode(ash.session_state , 'ON CPU' , 1 , 0)) "CPU" ,
       SUM(decode(ash.session_state , 'WAITING' , 1 , 0)) - SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "WAITING" ,
       SUM(decode(ash.session_state , 'WAITING' , decode(en.wait_class , 'User I/O' , 1 , 0) , 0)) "IO" ,
       SUM(decode(session_state , 'ON CPU' , 1 , 1)) "TOTAL"
FROM v$active_session_history ash 
   , v$event_name en
WHERE en.event# = ash.event#
AND ash.sample_time >= to_date(:from_time,'yyyymmdd hh24miss')
AND ash.sample_time < to_date(:to_time,'yyyymmdd hh24miss')
GROUP BY session_id ,
         user_id ,
         session_serial# ,
         program
ORDER BY SUM(decode(session_state , 'ON CPU' , 1 , 1)) 
;

10.8 특정 구간 수행 이력 v$active_session_history[편집]

SELECT ash.sample_time TIME ,
       ash.session_id ,
       ash.session_serial# ,
       ash.user_id ,
       ash.program ,
       ash.module ,
       ash.client_id ,
       ash.machine ,
       ash.session_state ,
       ash.event ,
       ash.sql_id ,
       ash.blocking_session ,
       ash.current_obj# ,
       ash.current_file# ,
       ash.pga_allocated ,
       ash.temp_space_allocated
FROM v$active_session_history ash
WHERE ash.sample_time >= TO_DATE(:from_time , 'yyyymmdd hh24miss')
AND ash.sample_time < TO_DATE(:to_time , 'yyyymmdd hh24miss')
ORDER BY ash.sample_time DESC 
;

11 AWR을 이용한 모니터링[편집]


11.1 AWR을 이용한 literal SQL 추출 방법[편집]

  • get_literal_sql.SQL
SET linesize 120 col SCHEMA_NAME
FOR a8 col module_name
FOR a15 col sql_text
FOR a35 col SCHEMA_NAME heading "SCHEMA|NAME" col module_name heading "MODULE|NAME" col literal_sql_cnt heading "LITERAL|CNT"
FOR 99999 col execution_cnt heading "EXECUTION|CNT"
FOR 99999 col plan_cnt heading "PLAN|CNT"
FOR 999 col literal_sql_ratio heading "LITERAL|RATIO(%)"
FOR 999 accept i_begin_time prompt 'Enter begin time[YYYYMMDDHH24]: ' accept i_end_time prompt 'Enter end   time[YYYYMMDDHH24]: ' VARIABLE v_begin_time char(10) VARIABLE v_end_time char(10) EXEC :v_begin_time:=&i_begin_time EXEC :v_end_time :=&i_end_time

SELECT a.SCHEMA_NAME , a.module_name , a.literal_sql_cnt , a.execution_cnt , round(a.literal_sql_cnt/a.execution_cnt*100,1) literal_sql_ratio, a.plan_cnt,
    ( SELECT sql_text
     FROM dba_hist_sqltext
     WHERE dbid = a.dbid
         AND sql_id = a.max_sql_id ) sql_text
FROM
    ( SELECT s.force_matching_signature,
             s.dbid ,
             s.parsing_schema_name SCHEMA_NAME ,
                                   s.module module_name ,
                                   count(*) literal_sql_cnt ,
                                   sum(s.executions_total) execution_cnt ,
                                   max(s.sql_id) max_sql_id,
                                   count(DISTINCT s.plan_hash_value) plan_cnt
     FROM sys.wrm$_snapshot w ,
                            dba_hist_sqlstat s
     WHERE w.begin_interval_time >= to_timestamp(:v_begin_time , 'yyyymmddhh24')
         AND w.end_interval_time <= to_timestamp(:v_end_time , 'yyyymmddhh24')
         AND w.snap_id = s.snap_id
         AND w.dbid = s.dbid
         AND w.instance_number = s.instance_number
         AND s.parsing_schema_name <> 'SYS'
     GROUP BY s.dbid ,
              s.force_matching_signature ,
              s.parsing_schema_name ,
              s.module
     ORDER BY count(*) DESC ) a
WHERE rownum<=10;


11.2 AWR SQL ordered BY Elapsed Time[편집]

def dbid="&1" 
def inst_num="&2" 
def snap_start="&3" 
def snap_end="&4" 
def top_num="&5" 
col ela_Time format 999990.00 heading "ElaTime|(s)" 
col EXEC format 9999990 heading "Exec" 
col elapexec format 999990.00 heading "ElaTimeperexec (s)" 
--col Total               format 9999990.00         heading "DBTime%"
col CPU format 999990.00 heading "CPU%" 
col IO format 999990.00 heading "IO%" 
col SQLId format a15 heading "SQL_ID" 
col SQLModule format a50 heading "SQL_Module" 
col SQLText format a50 heading "SQL_Text" 

WITH sqt AS
(SELECT elap,
        cput,
        EXEC,
        norm_val,
        iowt,
        sql_id,
        module,
        rnum
 FROM
     (SELECT sql_id,
             module,
             elap,
             norm_val,
             cput,
             EXEC,
             iowt,
             rownum rnum
      FROM
          (SELECT sql_id,
                  MAX(module) module,
                              SUM(elapsed_time_delta) elap, (100 * (SUM(elapsed_time_delta) / NULLIF(
                                                                                                         (SELECT (SUM(e.VALUE) - SUM(b.VALUE)) / 1000000 / 60
                                                                                                          FROM DBA_HIST_SYS_TIME_MODEL e, DBA_HIST_SYS_TIME_MODEL b
                                                                                                          WHERE e.SNAP_ID = &snap_end
                                                                                                              AND e.DBID = &dbid
                                                                                                              AND e.INSTANCE_NUMBER = &inst_num
                                                                                                              AND e.STAT_NAME = 'DB time'
                                                                                                              AND b.SNAP_ID = &snap_start
                                                                                                              AND b.DBID = &dbid
                                                                                                              AND b.INSTANCE_NUMBER = &inst_num
                                                                                                              AND b.STAT_NAME = 'DB time'), 0))) norm_val,
                                                                                                                                                 SUM(cpu_time_delta) cput,
                                                                                                                                                                     SUM(executions_delta) EXEC,
                                                                                                                                                                                           SUM(iowait_delta) iowt
           FROM dba_hist_sqlstat
           WHERE dbid = &dbid
               AND instance_number = &inst_num
               AND &snap_start < snap_id
               AND snap_id <= &snap_end
           GROUP BY sql_id
           ORDER BY nvl(SUM(elapsed_time_delta), -1) DESC, sql_id))
 WHERE rnum < &top_num --  and (rnum <= :tsql_min or norm_val > :top_pct_sql)
 )
;


SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.elap / 1000000), to_number(NULL)) ela_Time,
                            sqt.EXEC EXEC,
                                     decode(sqt.EXEC, 0, to_number(NULL), (sqt.elap / sqt.EXEC / 1000000)) elapexec,
                                     sqt.norm_val Total ,
                                     --(100 * (sum(elap) /nullif(dbtime.dbtime,0))) norm_val
 --null Total,

                                     decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))) CPU,
                                     decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.iowt / sqt.elap))) IO,
                                     sqt.sql_id SQLId,
                                     to_clob(decode(sqt.module, NULL, NULL, 'Module: ' || sqt.module)) SQLModule,
                                     nvl(substr(st.sql_text, 0, 50), to_clob('** SQL Text Not Available **')) SQLText
FROM sqt,
     dba_hist_sqltext st
WHERE st.sql_id(+) = sqt.sql_id
AND st.dbid(+) = &dbid
ORDER BY sqt.rnum 
/

11.3 AWR SQL ordered BY Elapsed Time[편집]

undef dbid 
undef inst_num 
undef snap_start 
undef snap_end 
undef sql_id 
undef top_num 

WITH sqt AS
(SELECT elap,
        cput,
        EXEC,
        iowt,
        norm_val,
        sql_id,
        module,
        rnum
 FROM
     (SELECT sql_id,
             module,
             elap,
             norm_val,
             cput,
             EXEC,
             iowt,
             rownum rnum
      FROM
          (SELECT sql_id ,
                  MAX(module) module ,
                              SUM(elapsed_time_delta) elap , (100 * (SUM(elapsed_time_delta) / NULLIF(:dbtime,0))) norm_val ,
                                                                                                                   SUM(cpu_time_delta) cput ,                                                                                                                                       SUM(executions_delta) EXEC ,                                                                                                                                                             SUM(iowait_delta) iowt
           FROM dba_hist_sqlstat
           WHERE dbid = :dbid
               AND instance_number = :inst_num
               AND :bid < snap_id
               AND snap_id <= :eid
           GROUP BY sql_id
           ORDER BY nvl(SUM(elapsed_time_delta), -1) DESC, sql_id))
 WHERE rnum < :tsql_max
     AND (rnum <= :tsql_min
          OR norm_val > :top_pct_sql))
;
SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.elap/1000000), to_number(NULL)),
                            sqt.EXEC,
                                decode(sqt.EXEC, 0, to_number(NULL),(sqt.elap / sqt.EXEC / 1000000)),
                                sqt.norm_val,
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.iowt / sqt.elap))),
                                sqt.sql_id,
                                to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
                                nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
FROM sqt,
     dba_hist_sqltext st
WHERE st.sql_id(+) = sqt.sql_id
AND st.dbid(+) = :dbid
ORDER BY sqt.rnum 
;

11.4 AWR SQL ordered BY CPU Time[편집]

WITH sqt AS
(SELECT elap,
        cput,
        EXEC,
        uiot,
        norm_val,
        sql_id,
        module,
        rnum
 FROM
     (SELECT sql_id,
             module,
             elap,
             norm_val,
             cput,
             EXEC,
             uiot,
             rownum rnum
      FROM
          (SELECT sql_id ,
                  MAX(module) module ,
                              SUM(elapsed_time_delta) elap , (100 * (SUM(cpu_time_delta) / NULLIF(:tcpu,0))) norm_val ,
                                                                                                             SUM(cpu_time_delta) cput ,                                                                                                                                 SUM(executions_delta) EXEC ,                                                                                                                                                       SUM(iowait_delta) uiot
           FROM dba_hist_sqlstat
           WHERE dbid = :dbid
               AND instance_number = :inst_num
               AND :bid < snap_id
               AND snap_id <= :eid
           GROUP BY sql_id
           ORDER BY nvl(SUM(cpu_time_delta), -1) DESC, sql_id))
 WHERE rnum < :tsql_max
     AND (rnum <= :tsql_min
          OR norm_val > :top_pct_sql))
;
SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.cput/1000000), to_number(NULL)),
                            sqt.EXEC,
                                decode(sqt.EXEC, 0, to_number(NULL), (sqt.cput / sqt.EXEC /1000000)),
                                sqt.norm_val,
                                nvl((sqt.elap/1000000), to_number(NULL)),
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.uiot / sqt.elap))),
                                sqt.sql_id,
                                to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
                                nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
FROM sqt,
     dba_hist_sqltext st
WHERE st.sql_id(+) = sqt.sql_id
AND st.dbid(+) = :dbid
ORDER BY sqt.rnum 
;

11.5 AWR SQL ordered BY USER I/O Wait Time[편집]

WITH sqt AS
(SELECT elap,
        cput,
        EXEC,
        uiot,
        norm_val,
        sql_id,
        module,
        rnum
 FROM
     (SELECT sql_id,
             module,
             elap,
             norm_val,
             cput,
             EXEC,
             uiot,
             rownum rnum
      FROM
          (SELECT sql_id ,
                  MAX(module) module ,
                              SUM(elapsed_time_delta) elap , (100 * (SUM(iowait_delta) / NULLIF(:uiowt,0))) norm_val ,                                                                                                            SUM(cpu_time_delta) cput ,                                                                                                                                SUM(executions_delta) EXEC ,                                                                                                                                                      SUM(iowait_delta) uiot
           FROM dba_hist_sqlstat
           WHERE dbid = :dbid
               AND instance_number = :inst_num
               AND :bid < snap_id
               AND snap_id <= :eid
           GROUP BY sql_id
           ORDER BY nvl(SUM(iowait_delta), -1) DESC, sql_id))
 WHERE rnum < :tsql_max
     AND (rnum <= :tsql_min
          OR norm_val > :top_pct_sql))
;
SELECT /*+ NO_MERGE(sqt) */ nvl((sqt.uiot/1000000), to_number(NULL)),
                            sqt.EXEC,
                                decode(sqt.EXEC, 0, to_number(NULL), (sqt.uiot / sqt.EXEC /1000000)),
                                sqt.norm_val,
                                nvl((sqt.elap/1000000), to_number(NULL)),
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.uiot / sqt.elap))),
                                sqt.sql_id,
                                to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
                                nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
FROM sqt,
     dba_hist_sqltext st
WHERE st.sql_id(+) = sqt.sql_id
AND st.dbid(+) = :dbid
ORDER BY sqt.rnum 
;

11.6 AWR SQL ordered BY Gets[편집]

WITH sqt AS
(SELECT elap,
        cput,
        EXEC,
        uiot,
        bget,
        norm_val,
        sql_id,
        module,
        rnum
 FROM
     (SELECT sql_id,
             module,
             elap,
             norm_val,
             cput,
             EXEC,
             uiot,
             bget,
             rownum rnum
      FROM
          (SELECT sql_id ,
                  MAX(module) module ,
                              SUM(elapsed_time_delta) elap , (100 * (SUM(buffer_gets_delta) / NULLIF(:slr,0))) norm_val ,                                                                                                               SUM(cpu_time_delta) cput ,                                                                                                                                   SUM(executions_delta) EXEC ,                                                                                                                                                         SUM(iowait_delta) uiot ,                                                                                                                                                                           SUM(buffer_gets_delta) bget
           FROM dba_hist_sqlstat
           WHERE dbid = :dbid
               AND instance_number = :inst_num
               AND :bid < snap_id
               AND snap_id <= :eid
           GROUP BY sql_id
           ORDER BY nvl(SUM(buffer_gets_delta), -1) DESC, sql_id))
 WHERE rnum < :tsql_max
     AND (rnum <= :tsql_min
          OR norm_val > :top_pct_sql))
;
SELECT /*+ NO_MERGE(sqt) */ sqt.bget,
                            sqt.EXEC,
                                decode(sqt.EXEC, 0, to_number(NULL), (sqt.bget / sqt.EXEC)),
                                sqt.norm_val,
                                nvl((sqt.elap/1000000), to_number(NULL)),
                                decode(sqt.elap, 0, '     ', lpad(to_char(round((100 * (sqt.cput / sqt.elap)),1), 'TM9'),5)),
                                decode(sqt.elap, 0, '     ', lpad(to_char(round((100 * (sqt.uiot / sqt.elap)),1), 'TM9'),5)),
                                sqt.sql_id,
                                to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
                                nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
FROM sqt,
     dba_hist_sqltext st
WHERE st.sql_id(+) = sqt.sql_id
AND st.dbid(+) = :dbid
ORDER BY sqt.rnum 
;

11.7 AWR SQL ordered BY READS[편집]

WITH sqt AS
(SELECT elap,
        cput,
        EXEC,
        uiot,
        dskr,
        norm_val,
        sql_id,
        module,
        rnum
 FROM
     (SELECT sql_id,
             module,
             elap,
             norm_val,
             cput,
             EXEC,
             uiot,
             dskr,
             rownum rnum
      FROM
          (SELECT sql_id ,
                  MAX(module) module ,
                              SUM(elapsed_time_delta) elap , (100 * (SUM(disk_reads_delta) / NULLIF(:phyr,0))) norm_val ,                                                                                                               SUM(cpu_time_delta) cput ,                                                                                                                                   SUM(executions_delta) EXEC ,                                                                                                                                                         SUM(iowait_delta) uiot ,                                                                                                                                                                           SUM(disk_reads_delta) dskr
           FROM dba_hist_sqlstat
           WHERE dbid = :dbid
               AND instance_number = :inst_num
               AND :bid < snap_id
               AND snap_id <= :eid
           GROUP BY sql_id
           ORDER BY nvl(SUM(disk_reads_delta), -1) DESC, sql_id))
 WHERE rnum < :tsql_max
     AND (rnum <= :tsql_min
          OR norm_val > :top_pct_sql))
;
SELECT /*+ NO_MERGE(sqt) */ sqt.dskr,
                            sqt.EXEC,
                                decode(sqt.EXEC, 0, to_number(NULL), (sqt.dskr / sqt.EXEC)),
                                sqt.norm_val,
                                nvl((sqt.elap / 1000000), to_number(NULL)),
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.cput / sqt.elap))),
                                decode(sqt.elap, 0, to_number(NULL), (100 * (sqt.uiot / sqt.elap))),
                                sqt.sql_id,
                                to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
                                nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
FROM sqt,
     dba_hist_sqltext st
WHERE st.sql_id(+) = sqt.sql_id
AND st.dbid(+) = :dbid
ORDER BY sqt.rnum 
;

11.8 AWR SQL ordered BY READS[편집]

WITH sqt AS
(SELECT EXEC,
        pdr,
        prq,
        porq,
        norm_val,
        sql_id,
        module,
        rnum
 FROM
     (SELECT sql_id,
             module,
             norm_val,
             EXEC,
             pdr,
             prq,
             porq,
             rownum rnum
      FROM
          (SELECT sql_id ,
                  MAX(module) module , (100 * ((SUM(physical_read_requests_delta) - SUM(optimized_physical_reads_delta)) / NULLIF(:phydrq,0))) norm_val ,                                                                                                                                               SUM(executions_delta) EXEC ,                                                                                                                                                                     SUM(physical_read_requests_delta) - SUM(optimized_physical_reads_delta) pdr ,
SUM(physical_read_requests_delta) prq ,
                                  SUM(optimized_physical_reads_delta) porq
           FROM dba_hist_sqlstat
WHERE dbid = :dbid
AND instance_number = :inst_num
AND :bid < snap_id
AND snap_id <= :eid
           GROUP BY sql_id
           ORDER BY nvl(SUM(physical_read_requests_delta) - SUM(optimized_physical_reads_delta), -1) DESC, sql_id))
WHERE rnum < :tsql_max
AND (rnum <= :tsql_min
 OR norm_val > :top_pct_sql))
;
SELECT /*+ NO_MERGE(sqt) */ sqt.pdr,
                sqt.prq,
                sqt.EXEC,
        decode(sqt.EXEC, 0, to_number(NULL), (sqt.prq/ sqt.EXEC)),
        decode(sqt.prq, 0, to_number(NULL), (100 * (sqt.porq / sqt.prq))),
        sqt.norm_val,
        sqt.sql_id,
        to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
        nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
FROM sqt,
dba_hist_sqltext st
WHERE st.sql_id(+) = sqt.sql_id
AND st.dbid(+) = :dbid
ORDER BY sqt.rnum 
;

11.9 AWR SQL ordered BY Sharable Memory[편집]

WITH sqt AS
(SELECT EXEC,
sharable_mem,
sql_id,
module,
rnum
FROM
(SELECT sql_id,
    module,
    EXEC,
    sharable_mem,
    rownum rnum
FROM
 (SELECT sql_id,
         module,
         EXEC,
         sharable_mem
  FROM
      (SELECT sharable_mem,
              sql_id
       FROM dba_hist_sqlstat
       WHERE dbid = :dbid
           AND snap_id = :eid
           AND instance_number = :inst_num
           AND sharable_mem > :shmem_thres) y
  LEFT OUTER JOIN
      (SELECT sql_id ,
              MAX(module) module ,
                          SUM(executions_delta) EXEC
       FROM dba_hist_sqlstat
       WHERE dbid = :dbid
           AND instance_number = :inst_num
           AND :bid < snap_id
           AND snap_id <= :eid
       GROUP BY sql_id) x USING (sql_id)
  ORDER BY nvl(sharable_mem, -1) DESC, sql_id))
WHERE rnum <= :tsql_max)
;
SELECT /*+ NO_MERGE(sqt) */ sqt.sharable_mem,
                sqt.EXEC,
        decode(:espm, 0, 0, 100 * sqt.sharable_mem/:espm),
        sqt.sql_id,
        to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
        nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
FROM sqt,
dba_hist_sqltext st
WHERE st.sql_id(+) = sqt.sql_id
AND st.dbid(+) = :dbid
ORDER BY sqt.rnum 
;

11.10 AWR SQL ordered BY VERSION COUNT[편집]

WITH sqt AS
(SELECT EXEC,
version_count,
sql_id,
module,
rnum
FROM
(SELECT sql_id,
    module,
    EXEC,
    version_count,
    rownum rnum
FROM
 (SELECT sql_id,
         module,
         EXEC,
         version_count
  FROM
      (SELECT version_count,
              sql_id
       FROM dba_hist_sqlstat
       WHERE dbid = :dbid
           AND snap_id = :eid
           AND instance_number = :inst_num
           AND version_count > :vcnt_thres) y
  LEFT OUTER JOIN
      (SELECT sql_id ,
              MAX(module) module ,
                          SUM(executions_delta) EXEC
       FROM dba_hist_sqlstat
       WHERE dbid = :dbid
           AND instance_number = :inst_num
           AND :bid < snap_id
           AND snap_id <= :eid
       GROUP BY sql_id) x USING (sql_id)
  ORDER BY nvl(y.version_count, -1) DESC, sql_id))
WHERE rnum <= :tsql_max)
;
SELECT /*+ NO_MERGE(sqt) */ sqt.version_count,
                sqt.EXEC,
        sqt.sql_id,
        to_clob(decode(sqt.module, NULL,NULL, 'Module: ' || sqt.module)),
        nvl(st.sql_text,to_clob('** SQL Text Not Available **'))
FROM sqt,
dba_hist_sqltext st
WHERE st.sql_id(+) = sqt.sql_id
AND st.dbid(+) = :dbid
ORDER BY sqt.rnum