ORACLE 모니터링
DB CAFE
- 데이터 품질 전문기업
http://empathydata.co.kr/
DB 모니터링
목차
- 1 세션/접속사용자 정보
- 2 오래 걸리는 세션 정보
- 2.1 현재 TOP 세션 gv$session
- 2.2 현재 작업중인 세션 정보 V$SESSION_LONGOPS
- 2.3 세션당 리소스 사용률 gv$sessmetric
- 2.4 1일 이상 존재 하는 조회 / kill / AWS_KILL_CMD
- 2.5 1시간 이상 유휴 상태인 세션
- 2.6 프로세스 아이디를 이용하여 쿼리문 알아내기
- 2.7 Active Session 중 Idle Time이 긴 작업
- 2.8 DBUser 별로 Session 정보를 조회
- 2.9 Session별 사용 명령어
- 2.10 사용자 session 중에서 2시간 이상 idle 상태가 지속되는 session을 kill
- 3 프로세스 정보
- 4 부하 발생 모니터링
- 5 DB 용량 관리
- 6 오라클 서버 스펙
- 7 테이블 스페이스
- 8 DB Time 분석하기
- 9 SQL 통계 정보확인하기
- 9.1 Module LEVEL 통계
- 9.2 SCHEMA LEVEL 통계
- 9.3 SQL LEVEL 통계 -- SQL 추출하기 (9i)
- 9.4 SQL 추출하기 (10g)
- 9.5 Exa SQL[1]. Smart Scan으로 수행되지 않고,Interconnect Bytes가 높은 SQL
- 9.6 SQL[2]. Smart Scan으로 수행되지 않고,Offload Returned Bytes가 높은 SQL :
- 9.7 Full Table Scan 처리가 있는 SQL문 정보 추출하기(10g)
- 9.8 하드파싱(leteral,리터럴) 찾기
- 9.9 특정 SQL 수행내역 확인하기
- 9.10 SQL_ID를 이용하여 SQL TEXT 추출하기
- 9.11 SQL_ID를 이용하여 SQL문의 수행내역 추출하기
- 9.12 SQL_ID를 이용하여 바인드 변수 값을 추출하기
- 10 SQL_ID를 이용하여 SQL문의 PLAN 추출하기
- 11 INDEX 정보 추출하기
- 12 ASH를 이용한 모니터링
- 12.1 특정 Session이 가장 많이 수행 된 SQL과 수행 점유율(수행 횟수)
- 12.2 주요한 이벤트 메트릭 표시 gv$eventmetric v$event_name
- 12.3 중요한 시스템 메트릭 표시 gv$sysmetric
- 12.4 RAC 인스턴스별로 상세한 중요한 시스템 메트릭 gv$sysmetric
- 12.5 특정 구간 이벤트 별 대기 시간 v$active_session_history
- 12.6 특정 구간 CPU 점유율 순 - TOP SQL
- 12.7 특정 구간 CPU 점유율 순 - TOP SESSION v$active_session_history
- 12.8 특정 구간 수행 이력 v$active_session_history
- 13 AWR을 이용한 모니터링
- 13.1 AWR을 이용한 literal SQL 추출 방법
- 13.2 AWR SQL ordered BY Elapsed Time
- 13.3 AWR SQL ordered BY Elapsed Time
- 13.4 AWR SQL ordered BY CPU Time
- 13.5 AWR SQL ordered BY USER I/O Wait Time
- 13.6 AWR SQL ordered BY Gets
- 13.7 AWR SQL ordered BY READS
- 13.8 AWR SQL ordered BY READS
- 13.9 AWR SQL ordered BY Sharable Memory
- 13.10 AWR SQL ordered BY VERSION COUNT
1 세션/접속사용자 정보[편집]
1.1 세션 죽이기(SID,SERAIL#)[편집]
ALTER SYSTEM KILL SESSION '8,4093';
-- RAC
ALTER SYSTEM KILL SESSION '8,4093,@1';
1.2 오라클 세션과 관련된 테이블[편집]
- v$session
select count(*)
from v$session
where machine ='머신이름'
and schemaname ='스키마이름'
1.3 현재 커서 수 확인[편집]
- V$OPEN_CURSOR
- v$session_wait
- v$transaction
1.3.1 sid별 열린커셔[편집]
SELECT sid, count(sid) cursor
FROM V$OPEN_CURSOR
WHERE user_name = 'ilips'
GROUP BY sid
ORDER BY cursor DESC;
1.3.2 sql 별 열린 커서[편집]
SELECT sql_text, count(sid) cnt
FROM v$OPEN_CURSOR
GROUP BY sql_text
ORDER BY cnt DESC
1.3.3 대기 세션[편집]
- v$session_wait
select *
from v$session_wait;
1.3.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.4 연결되어 있는 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';
2 오래 걸리는 세션 정보[편집]
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
2.2 현재 작업중인 세션 정보 V$SESSION_LONGOPS[편집]
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;
2.3 세션당 리소스 사용률 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
2.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;
2.5 1시간 이상 유휴 상태인 세션[편집]
- 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;
2.6 프로세스 아이디를 이용하여 쿼리문 알아내기[편집]
- 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.7 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;
2.8 DBUser 별로 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;
2.9 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.10 사용자 session 중에서 2시간 이상 idle 상태가 지속되는 session을 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
3 프로세스 정보[편집]
3.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;
3.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);
4 부하 발생 모니터링[편집]
4.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
4.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;
4.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;
4.4 Library Cache Hit Ratio[편집]
- V$LIBRARYCACHE
SELECT (1-SUM (reloads)/SUM(pins))*100 "Library Cache Hit Ratio"
From V$LIBRARYCACHE;
4.5 Data Dictionary Cache Hit Ratio[편집]
- V$ROWCACHE
SELECT (1-SUM(getmisses)/SUM(gets))*100 "Data Dictionary Hit Ratio"
FROM V$ROWCACHE;
5 DB 용량 관리[편집]
5.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;
6 오라클 서버 스펙[편집]
6.1 오라클서버의 메모리[편집]
- v$sgastat
SELECT * FROM V$SGASTAT;
SELECT POOL, SUM(BYTES) "SIZE"
FROM V$SGASTAT
WHERE POOL = 'SHARED POOL'
GROUP BY POOL
6.2 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
6.3 락이 걸린 세션 자세히 알아보기[편집]
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'
6.4 락이 걸린 세션 간단히 알아보기[편집]
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';
SELECT A.SID, A.SERIAL#, A.USERNAME, A.PROCESS, B.OBJECT_NAME
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'
7 테이블 스페이스[편집]
7.1 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 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 ;
8.1 총 CPU Time 대비 SQL Parsing Time[편집]
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 ===
<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.2 Log file sync 관련 대기현상 Sync Writes Time[편집]
- redo synch time의 단위는 centisecond이다. => 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
;
8.3 인스턴스 기동 이후 I/O 관련 대기현상 누적 값[편집]
- v$system_event의 time_waited는 centisecond이다.
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')
;
9 SQL 통계 정보확인하기[편집]
9.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 ;
9.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 ;
9.3 SQL LEVEL 통계 -- SQL 추출하기 (9i)[편집]
SELECT * --9i
FROM
( SELECT rownum cnt,
t1.*
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
;
SELECT * --9i
FROM
( SELECT rownum cnt,
t1.*
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
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
;
9.4 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
;
9.5 Exa SQL[1]. 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 ;
9.6 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로 변경
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 ;
9.7 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
9.8 하드파싱(leteral,리터럴) 찾기[편집]
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
;
또는
/* Formatted on 2020/01/13 오전 11:21:11 (QP5 v5.336) */
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;
9.9 특정 SQL 수행내역 확인하기[편집]
-- SQL TEXT
SELECT module,
sql_fulltext
FROM v$sqlarea
WHERE hash_value = :hash_value -- 수행내역
;
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 -- 바인드 변수값
;
;
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
-- 바인드 변수 값의 이력을 가지고 있는 뷰 조회로 SQL문의 조회 패턴을 분석할 수 있다.
;
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
;
;
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
;
--SQL 수행 이력 추출하기 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 정보를 담고 있으므로 수행이력 패턴을 조회할 수 있다.
9.10 SQL_ID를 이용하여 SQL TEXT 추출하기[편집]
SELECT *
FROM DBA_HIST_SQLTEXT
WHERE sql_id = :sql_id
;
9.11 SQL_ID를 이용하여 SQL문의 수행내역 추출하기[편집]
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
;
9.12 SQL_ID를 이용하여 바인드 변수 값을 추출하기[편집]
SELECT name,
to_char(LAST_CAPTURED,'yyyymmdd hh24:mi:ss') LAST_CAPTURED,
datatype,
VALUE_STRING
FROM dba_hist_sqlbind
WHERE sql_id = :sql_id
-- dba_hist_sqlbind를 이용하면 바인드 변수 값의 이력을 가지고 있는 뷰이므로 SQL문의 조회 패턴을 분석할 수 있다.
;
10 SQL_ID를 이용하여 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
;
11 INDEX 정보 추출하기[편집]
11.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))) ;
;
11.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
;
11.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
;
11.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
;
11.5 v$segment_statistics 활용하기[편집]
-- User별 전체 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
;
11.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%' ) ;
11.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
11.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’));
11.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 ;
11.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
;
12 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 ;
12.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 ;
12.2 주요한 이벤트 메트릭 표시 gv$eventmetric v$event_name[편집]
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;
12.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
);
12.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;
12.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;
12.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))
;
12.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))
;
12.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
;
13 AWR을 이용한 모니터링[편집]
13.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;
13.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
/
13.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
;
13.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
;
13.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
;
13.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
;
13.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
;
13.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
;
13.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
;
13.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