Active Session History를 이용한 TOP SQL 분석
DB Version : Oracle 11.2.0.2
OS Version : AIX 6.1
* TOP 10 Event (RAC)
- 현재 일자 -1 부터 보기(AND SAMPLE_TIME >= TRUNC(SYSDATE) -1)
SELECT
SAMPLE_TIME
, INST_ID
, EVENT
, TOT_COUNT
, DECODE(RANK, 1, 'TOP',NULL) "RANK"
FROM (
SELECT
TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)') "SAMPLE_TIME"
, INST_ID
, EVENT
, COUNT(*) "TOT_COUNT"
, RANK() OVER(PARTITION BY TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)'), INST_ID ORDER BY COUNT(*) DESC, EVENT) "RANK"
FROM GV$ACTIVE_SESSION_HISTORY
WHERE EVENT IS NOT NULL
AND SAMPLE_TIME >= TRUNC(SYSDATE) -1
GROUP BY TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)'), INST_ID, EVENT
HAVING COUNT(*) > 10
)
WHERE RANK <= 10
ORDER BY 1, 2, RANK;
SAMPLE_TIME
, INST_ID
, EVENT
, TOT_COUNT
, DECODE(RANK, 1, 'TOP',NULL) "RANK"
FROM (
SELECT
TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)') "SAMPLE_TIME"
, INST_ID
, EVENT
, COUNT(*) "TOT_COUNT"
, RANK() OVER(PARTITION BY TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)'), INST_ID ORDER BY COUNT(*) DESC, EVENT) "RANK"
FROM GV$ACTIVE_SESSION_HISTORY
WHERE EVENT IS NOT NULL
AND SAMPLE_TIME >= TRUNC(SYSDATE) -1
GROUP BY TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)'), INST_ID, EVENT
HAVING COUNT(*) > 10
)
WHERE RANK <= 10
ORDER BY 1, 2, RANK;
* TOP 10 SQL (RAC)
- 현재 일자 -1 부터 보기(AND SAMPLE_TIME >= TRUNC(SYSDATE) -1)
SELECT
DISTINCT
A.SAMPLE_TIME
, A.INST_ID
, A.SQL_ID
, A.TOT_COUNT
, DECODE(A.RANK, 1, 'TOP',NULL) "RANK"
, B.SQL_TEXT
FROM (
SELECT
TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)') "SAMPLE_TIME"
, INST_ID
, SQL_ID
, COUNT(*) "TOT_COUNT"
, RANK() OVER(PARTITION BY TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)'), INST_ID ORDER BY COUNT(*) DESC, SQL_ID) "RANK"
FROM GV$ACTIVE_SESSION_HISTORY
WHERE SQL_ID IS NOT NULL
AND SAMPLE_TIME >= TRUNC(SYSDATE) -1
GROUP BY TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)'), INST_ID, SQL_ID
HAVING COUNT(*) > 10
) A,
GV$SQL B
WHERE 1=1
AND A.SQL_ID = B.SQL_ID
AND A.INST_ID = B.INST_ID
AND RANK <= 10
ORDER BY 1, 2, RANK;
DISTINCT
A.SAMPLE_TIME
, A.INST_ID
, A.SQL_ID
, A.TOT_COUNT
, DECODE(A.RANK, 1, 'TOP',NULL) "RANK"
, B.SQL_TEXT
FROM (
SELECT
TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)') "SAMPLE_TIME"
, INST_ID
, SQL_ID
, COUNT(*) "TOT_COUNT"
, RANK() OVER(PARTITION BY TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)'), INST_ID ORDER BY COUNT(*) DESC, SQL_ID) "RANK"
FROM GV$ACTIVE_SESSION_HISTORY
WHERE SQL_ID IS NOT NULL
AND SAMPLE_TIME >= TRUNC(SYSDATE) -1
GROUP BY TO_CHAR(SAMPLE_TIME, 'YY/MM/DD(DY)'), INST_ID, SQL_ID
HAVING COUNT(*) > 10
) A,
GV$SQL B
WHERE 1=1
AND A.SQL_ID = B.SQL_ID
AND A.INST_ID = B.INST_ID
AND RANK <= 10
ORDER BY 1, 2, RANK;
댓글 0
번호 | 제목 | 글쓴이 | 날짜 | 조회 수 |
---|---|---|---|---|
14 | Schema Password 복사 하기 | Talros | 2016.10.05 | 3487 |
13 | Block Cleanout(블럭 클린아웃) | 명품관 | 2016.09.23 | 1797 |
12 | Fixed Table에 대한 권한은 직접적으로 부여되지 않는다. | 명품관 | 2016.08.26 | 2945 |
11 | Oracle Archive log 사용량 확인(GV$ARCHIVED_LOG) [1] | 에밀리오 | 2016.08.04 | 11896 |
10 | Oracle Resource Limit를 이용한 간단한 Parameter Check (GV$RESOURCE_LIMIT) | 에밀리오 | 2016.07.15 | 2469 |
9 | Oracle VMSTAT을 이용한 CPU 사용량 활용법 | 에밀리오 | 2016.07.14 | 1113 |
8 | Kill Session Script (GV$SESSION) | 에밀리오 | 2016.07.12 | 2350 |
» | Active Session History를 이용한 TOP SQL 분석 (GV$ACTIVE_SESSION_HISTORY) | 에밀리오 | 2016.07.12 | 1419 |
6 | DB에 생성된 ROLE의 생성 정보 확인 [2] | 명품관 | 2016.05.31 | 2404 |
5 | 내가 돌린 SQL ID 찾기 [1] | Talros | 2016.05.12 | 9031 |
4 | 테이블 컬럼의 Default 값에 대한 흔적은 Dictionary에 계속 남게 된다. | 명품관 | 2016.04.05 | 1729 |
3 | Result Cache(oracle11g NF) [6] | ocm10gr2 | 2016.03.14 | 384 |
2 | Alert Log를 SQL 사용하여 보기 (X$DBGALERTEXT) [1] | 에밀리오 | 2016.01.28 | 2305 |
1 | Partition 추가의 계절 - Range Partition 추가시 알아 두어야할 부분 [1] | 명품관 | 2015.12.03 | 2551 |