반응형
■ [2026-01-06] Oracle 12cR2 to 19c 환경에서 DB Replay 테스트 (ACFS 사용 및 ACFS 사용을 위한 커널 변경 절차 포함)

 

[제목]

 

[2026-01-06] Oracle 12cR2 to 19c 환경에서 DB Replay 테스트 (ACFS 사용 및 ACFS 사용을 위한 커널 변경 절차 포함)

 

[테스트 환경]

<소스 DB>

OS : Oracle Linux Server 7.9 (grep ^PRETTY_NAME= /etc/os-release | cut -d= -f2- | tr -d '"')
OS Kernal : 5.4.17-2102.201.3.el7uek.x86_64 (uname -r)
Oracle Version : Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
                 (echo -e "set pages 0 lines 200 feedback off heading off\nselect banner from v\$version where banner like 'Oracle Database%';" | sqlplus -s / as sysdba)
Oracle Configuration
    DB명 : ORA12RF (echo -e 'set pages 0 feedback off heading off verify off\nselect '\''DB명 : '\''||name from v$database;' | sqlplus -s / as sysdba) '
 PDB 정보
  Non-CDB

  RAC Node 1
   Hostname : ol7ora12rf1 (hostname)
   Public IP : 192.168.240.11 (getent ahostsv4 `hostname` | awk '{print $1; exit}')
   Instance Name : ORA12RF1 (echo -e 'set pages 0 feedback off heading off verify off\nselect '\''Instance Name : '\''||instance_name from v$instance;' | sqlplus -s / as sysdba) '
  RAC Node 2
   Hostname : ol7ora12rf2 (hostname)
   Public IP : 192.168.240.12 (getent ahostsv4 `hostname` | awk '{print $1; exit}')
   Instance Name : ORA12RF2 (echo -e 'set pages 0 feedback off heading off verify off\nselect '\''Instance Name : '\''||instance_name from v$instance;' | sqlplus -s / as sysdba) '
Patch Info
 Grid (opatch lspatches) (grid os user)
 33610989;TOMCAT RELEASE UPDATE 12.2.0.1.0(ID:RELEASE) (33610989)
 26839277;DBWLM RELEASE UPDATE 12.2.0.1.0(ID:170913) (26839277)
 33116894;ACFS JUL 2021 RELEASE UPDATE 12.2.0.1.210720 (33116894)
 33678030;OCW JAN 2022 RELEASE UPDATE 12.2.0.1.220118 (33678030)
 33587128;Database Jan 2022 Release Update : 12.2.0.1.220118 (33587128)

 Oracle (opatch lspatches) (oracle os user)
 33587128;Database Jan 2022 Release Update : 12.2.0.1.220118 (33587128)
 33678030;OCW JAN 2022 RELEASE UPDATE 12.2.0.1.220118 (33678030)

 

<타켓 DB>

OS : Oracle Linux Server 8.10 (grep ^PRETTY_NAME= /etc/os-release | cut -d= -f2- | tr -d '"')
OS Kernal : 5.15.0-206.153.7.1.el8uek.x86_64 (uname -r)
Oracle Version : Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
                 (echo -e "set pages 0 lines 200 feedback off heading off\nselect banner from v\$version where banner like 'Oracle Database%';" | sqlplus -s / as sysdba)
Oracle Configuration
    DB명 : ORA19RF (echo -e 'set pages 0 feedback off heading off verify off\nselect '\''DB명 : '\''||name from v$database;' | sqlplus -s / as sysdba) '
 PDB 정보
  Non-CDB

  RAC Node 1
   Hostname : ol8ora19rf1 (hostname)
   Public IP : 192.168.240.31 (getent ahostsv4 `hostname` | awk '{print $1; exit}')
   Instance Name : ORA19RF1 (echo -e 'set pages 0 feedback off heading off verify off\nselect '\''Instance Name : '\''||instance_name from v$instance;' | sqlplus -s / as sysdba) '
  RAC Node 2
   Hostname : ol8ora19rf2 (hostname)
   Public IP : 192.168.240.32 (getent ahostsv4 `hostname` | awk '{print $1; exit}')
   Instance Name : ORA19RF2 (echo -e 'set pages 0 feedback off heading off verify off\nselect '\''Instance Name : '\''||instance_name from v$instance;' | sqlplus -s / as sysdba) '
Patch Info
 Grid (opatch lspatches) (grid os user)
 38380425;TOMCAT RELEASE UPDATE 19.0.0.0.0 (38380425)
 38322923;OCW RELEASE UPDATE 19.29.0.0.0 (38322923)
 38311528;ACFS RELEASE UPDATE 19.29.0.0.0 (38311528)
 38291812;Database Release Update : 19.29.0.0.251021 (38291812)
 36758186;DBWLM RELEASE UPDATE 19.0.0.0.0 (36758186)

 Oracle (opatch lspatches) (oracle os user)
 38322923;OCW RELEASE UPDATE 19.29.0.0.0 (38322923)
 38291812;Database Release Update : 19.29.0.0.251021 (38291812)

 

[테스트 개요]

 

1. 테스트 목적
   - Real Application Testing (RAT) 옵션의 DB Replay 기능을 활용한 워크로드 재현 및 성능 비교
   - Source(12c)와 Target(19c) 간의 SQL 성능 변화 및 시스템 리소스 사용량 분석

2. 테스트 환경 구성
   A. Source System (Legacy)
      - OS: Oracle Linux 7.9 (UEK 5.4 -> 3.10 Kernel Downgrade for ACFS)
      - DB: Oracle 12.2.0.1.0 RAC (2 Node)
      - 구성: ACFS를 활용한 워크로드 캡처 파일 시스템 구성

   B. Target System (New)
      - OS: Oracle Linux 8.10
      - DB: Oracle 19.29.0.0.0 RAC (2 Node)
      - 구성: Flashback Database 구성을 통한 반복 테스트 환경 마련

3. 주요 수행 절차
   Step 1. 사전 데이터 구성
      - Source DB에 테스트용 스키마(TUNER) 및 대량의 데이터(100만~5000만 건) 생성
      - 통계 정보 수집 및 확인

   Step 2. 데이터 이관 (Migration)
      - Data Pump(expdp/impdp)를 사용하여 Source 데이터 시점을 Target으로 복제

   Step 3. 워크로드 캡처 (Workload Capture)
      - Source DB에서 ACFS 파일시스템 구성 (커널 버전 조정 포함)
      - 커스텀 부하 발생 스크립트(PL/SQL Loop)를 통해 트랜잭션 유발
      - DBMS_WORKLOAD_CAPTURE를 이용해 워크로드 캡처 수행

   Step 4. 워크로드 전처리 (Preprocessing)
      - 캡처된 파일을 Target DB로 전송
      - DBMS_WORKLOAD_REPLAY.PROCESS_CAPTURE 수행

   Step 5. 워크로드 리플레이 (Workload Replay)
      - Target DB Flashback 설정 및 Restore Point(BEFORE_REPLAY) 생성
      - Connection Remapping (Source TNS -> Target TNS)
      - Replay Client (wrc) 구동 및 리플레이 수행

   Step 6. 결과 분석 및 리포팅
      - Source(Capture) 및 Target(Replay)의 AWR 데이터 Export/Import
      - AWR Diff Report 생성 및 성능 지표 비교

   Step 7. 환경 복구 (Cleanup)
      - Target DB: Flashback 수행 및 Restore Point 갱신, 관련 객체 삭제
      - Source DB: ACFS 볼륨/드라이버 제거, OS 커널 원복, 테스트 계정 삭제

 

[목차]

 

1. 소스 서버에서 SQL 실습 환경 구축
2. 소스 서버에서 tuner 스키마를 data pump로 export 시킴
3. 타켓 서버에서 user 및 테이블 스페이스 생성
4. 타켓 서버에 소스 서버에서 export한 data pump 파일을 import 시키기
5. 소스에서 실행 시킬 부하 발생용 스크립트 생성
6. 소스에서 양쪽 노드의 워크로드 캡처를 위한 ACFS 구축
   6-1. 공유 디스크 추가
   6-2. ASM 디스크 그룹 추가
   6-3. 커널 변경
   6-4. acfs 드라이버 설치 (!!!!!)
   6-4. ACFS 볼륨 생성
   6-5. 볼륨 공간을 10기가에서 32기가로 확장
7. 소스에서 db replay 워크로드 캡처
   7-1. oracle rat 관련 라이센스 확인
   7-2. 캡처 시작 전 소스 DB의 파라미터를 설정
   7-3. 워크로드 캡처
   7-4. 워크로드 캡처 종료 후 awr export
8. 타켓에서 pre-processing
9. 타켓에서 db replay 준비
   9-1. flashback database 여부 확인 및 설정
   9-2. restore point 생성
   9-3. Replay 초기화
   9-4. connection remapping
   9-5. replay 준비
   9-6. replay 전 파라미터 설정
   9-7. replay 시작
   9-9. AWR export
   9-8. 리포트 출력
10. awr 비교 리포트 출력
11. 다시 테스트를 하기 위한 타켓 디비를 되돌리기
12. 원상복구
    12-1. 타켓 DB에서 Replay 정리 및 Flashback 해제
    12-2. 타켓 DB에서 Import된 AWR 데이터 삭제
    12-3. 타켓 DB에서 TUNER 계정 삭제
    12-4. 타켓 DB에서 os 파일 삭제
    12-5. 소스 db에서 acfs 볼륨 제거
    12-6. 소스 db에서 tuner 계정 제거
    12-7. 소스 db에서 DBA_WORKLOAD_CAPTURES 뷰 정리
    12-8. 소스 서버에서 os 파일 제거
    12-9. OS 레벨 디스크 정리
    12-10. 소스 서버 ACFS 드라이버 제거
    12-11. 소스 서버 OS 커널 원복 (Kernel Revert)
    12-12. 소스 DB 변경 파라미터 원복 (Reset Parameters)
    12-13. 타켓 서버 tnsnames.ora 정리

 

[내용]

 

1. 소스 서버에서 SQL 실습 환경 구축

 

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ ss

SQL*Plus: Release 12.2.0.1.0 Production on Mon Dec 29 21:49:27 2025

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<SYS@ORA12RF1>$
----------------------------------------------------------------------------------------------------------------------------------------
--1. 사용자 계정 생성 및 테이블 스페이스 생성
----------------------------------------------------------------------------------------------------------------------------------------

DROP USER TUNER CASCADE;
CREATE USER TUNER IDENTIFIED BY "oracle";
GRANT RESOURCE, DBA, CONNECT TO TUNER;
ALTER USER TUNER ACCOUNT UNLOCK;

DROP TABLESPACE TUNER_DATA1 INCLUDING CONTENTS AND DATAFILES;
CREATE TABLESPACE TUNER_DATA1
DATAFILE '+DATA1' SIZE 12G
AUTOEXTEND ON NEXT 512M MAXSIZE UNLIMITED
;

DROP TABLESPACE TUNER_IDX1 INCLUDING CONTENTS AND DATAFILES;
CREATE TABLESPACE TUNER_IDX1
DATAFILE '+DATA1' SIZE 12G
AUTOEXTEND ON NEXT 512M MAXSIZE UNLIMITED
;

DROP TABLESPACE TUNER_TEMP INCLUDING CONTENTS AND DATAFILES;
CREATE TEMPORARY TABLESPACE TUNER_TEMP
TEMPFILE '+DATA1' SIZE 4G
AUTOEXTEND ON NEXT 100M MAXSIZE UNLIMITED
;

ALTER USER TUNER DEFAULT TABLESPACE TUNER_DATA1;
ALTER USER TUNER TEMPORARY TABLESPACE TUNER_TEMP;

 

[ol7ora12rf1]<SYS@ORA12RF1>$ quit

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle/oracle_scripts]$ alias st
alias st='rlwrap sqlplus tuner/oracle'
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle/oracle_scripts]$ st

SQL*Plus: Release 12.2.0.1.0 Production on Mon Dec 29 21:53:44 2025

Copyright (c) 1982, 2016, Oracle.  All rights reserved.

Last Successful login time: Mon Dec 29 2025 21:53:40 +09:00

Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<TUNER@ORA12RF1>$

----------------------------------------------------------------------------------------------------------------------------------------
--2. 바인드 변수 세팅 (tuner 계정으로 실행할 것)
--SYS@PTDB> conn tuner
--Enter password:
--Connected.
--TUNER@PTDB>
----------------------------------------------------------------------------------------------------------------------------------------
--conn tuner;

[ol7ora12rf1]<TUNER@ORA12RF1>$ conn tuner
Enter password:
Connected.


VAR V_TB_CUST_CNT NUMBER;
EXEC :V_TB_CUST_CNT := 1000000;

VAR V_TB_ITEM_CNT NUMBER;
EXEC :V_TB_ITEM_CNT := 100000;

--:V_TB_CUST_CNT        1000000 String
--:V_TB_ITEM_CNT        100000  String
--예시
--V_TB_CUST_CNT가 100만인 경우
----TB_CUST : 100만
----TB_CUST_ADDR : 200만
----TB_ORD : 1000만
----TB_ORD_DTL : 5000만
----TB_DLVY: 3000만
--V_TB_ITEM_CNT가 10만인 경우
----TB_ITEM : 10만
----------------------------------------------------------------------------------------------------------------------------------------
--3. 테이블, 인덱스, 데이터입력, 통계정보 생성
----------------------------------------------------------------------------------------------------------------------------------------
ALTER SESSION SET "_px_hybrid_TSM_HWMB_load"=FALSE;
ALTER SESSION SET NLS_DATE_FORMAT='YYYY-MM-DD HH24:MI:SS';
----------------------------------------------------------------------------------------------------------------------------------------
--시작시간
COLUMN START_TIME NEW_VALUE START_TIME
SELECT TO_CHAR(SYSTIMESTAMP, 'YYYY-MM-DD HH24:MI:SS.FF') AS START_TIME FROM DUAL;
----------------------------------------------------------------------------------------------------------------------------------------
DROP TABLE TUNER.TB_CUST PURGE;
DROP TABLE TUNER.TB_CUST_ADDR PURGE;
DROP TABLE TUNER.TB_DLVY PURGE;
DROP TABLE TUNER.TB_ITEM PURGE;
DROP TABLE TUNER.TB_ORD PURGE;
DROP TABLE TUNER.TB_ORD_DTL PURGE;
----------------------------------------------------------------------------------------------------------------------------------------
CREATE TABLE TUNER.TB_CUST
(
  CUST_NO VARCHAR2(10) NOT NULL
, CUST_ID VARCHAR2(20) NOT NULL
, CUST_NM VARCHAR2(50) NOT NULL
, BRTHDY VARCHAR2(8)
, SEX_CD VARCHAR2(6) NOT NULL
, JOIN_DT VARCHAR2(14) NOT NULL
, CUST_STS_CD VARCHAR2(6) NOT NULL
, INPUT_ID VARCHAR2(20) NOT NULL
, INPUT_DT VARCHAR2(14) NOT NULL
, UPDT_ID VARCHAR2(20)
, UPDT_DT VARCHAR2(14)
)
TABLESPACE TUNER_DATA1;

COMMENT ON COLUMN TUNER.TB_CUST.CUST_NO IS '고객번호';
COMMENT ON COLUMN TUNER.TB_CUST.CUST_ID IS '고객아이디';
COMMENT ON COLUMN TUNER.TB_CUST.CUST_NM IS '고객명';
COMMENT ON COLUMN TUNER.TB_CUST.BRTHDY IS '생년월일';
COMMENT ON COLUMN TUNER.TB_CUST.SEX_CD IS '성별코드';
COMMENT ON COLUMN TUNER.TB_CUST.JOIN_DT IS '가입일시';
COMMENT ON COLUMN TUNER.TB_CUST.CUST_STS_CD IS '고객상태코드';
COMMENT ON COLUMN TUNER.TB_CUST.INPUT_ID IS '입력아이디';
COMMENT ON COLUMN TUNER.TB_CUST.INPUT_DT IS '입력일시';
COMMENT ON COLUMN TUNER.TB_CUST.UPDT_ID IS '수정아이디';
COMMENT ON COLUMN TUNER.TB_CUST.UPDT_DT IS '수정일시';
COMMENT ON TABLE TUNER.TB_CUST IS '고객';

ALTER TABLE TUNER.TB_CUST NOLOGGING;

INSERT /*+ APPEND */
  INTO TUNER.TB_CUST
SELECT 'C' || LPAD(ROWNUM, 9, '0') AS CUST_NO
     , DBMS_RANDOM.STRING('A', TRUNC(DBMS_RANDOM.VALUE(10, 20))) AS CUST_ID
     , DBMS_RANDOM.STRING('A', TRUNC(DBMS_RANDOM.VALUE(10, 50))) AS CUST_NM
     , TO_CHAR(TO_DATE('2030-12-31', 'YYYY-MM-DD') - DBMS_RANDOM.VALUE(365*20, 365*80), 'YYYYMMDD') AS BRTHDY
     , 'SC' || LPAD(MOD(ROWNUM, 2), 4, '0') AS SEX_CD
     , TO_CHAR(TO_DATE('2030-12-31', 'YYYY-MM-DD') - DBMS_RANDOM.VALUE(0, 365*10), 'YYYYMMDDHH24MISS') AS JOIN_DT
     , 'CSC' || LPAD(MOD(ROWNUM, 5), 3, '0') AS CUST_STS_CD
     , DBMS_RANDOM.STRING('A', TRUNC(DBMS_RANDOM.VALUE(10, 20))) AS INPUT_ID
     , TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS') AS INPUT_DT
     , NULL AS UPDT_ID
     , NULL AS UPDT_DT
  FROM DUAL CONNECT BY LEVEL <= :V_TB_CUST_CNT;

COMMIT;

CREATE UNIQUE INDEX TUNER.PK_TB_CUST ON TUNER.TB_CUST(CUST_NO) TABLESPACE TUNER_IDX1 PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.PK_TB_CUST PARALLEL 1;
ALTER INDEX TUNER.PK_TB_CUST LOGGING;
ALTER TABLE TUNER.TB_CUST ADD CONSTRAINT PK_TB_CUST PRIMARY KEY (CUST_NO);

CREATE INDEX TUNER.IDX_TB_CUST_01 ON TUNER.TB_CUST(CUST_STS_CD) TABLESPACE TUNER_IDX1 PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.IDX_TB_CUST_01 PARALLEL 1;
ALTER INDEX TUNER.IDX_TB_CUST_01 LOGGING;

CREATE INDEX TUNER.IDX_TB_CUST_02 ON TUNER.TB_CUST(BRTHDY) TABLESPACE TUNER_IDX1 PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.IDX_TB_CUST_02 PARALLEL 1;
ALTER INDEX TUNER.IDX_TB_CUST_02 LOGGING;

CREATE INDEX TUNER.IDX_TB_CUST_03 ON TUNER.TB_CUST(CUST_STS_CD, BRTHDY) TABLESPACE TUNER_IDX1 PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.IDX_TB_CUST_03 PARALLEL 1;
ALTER INDEX TUNER.IDX_TB_CUST_03 LOGGING;

ALTER TABLE TUNER.TB_CUST LOGGING;
----------------------------------------------------------------------------------------------------------------------------------------
CREATE TABLE TUNER.TB_CUST_ADDR
(
  CUST_NO VARCHAR2(10) NOT NULL
, ADDR_SN NUMBER(6) NOT NULL
, POST_NO VARCHAR2(10) NOT NULL
, ADDR VARCHAR2(500) NOT NULL
, REG_DT VARCHAR2(14) NOT NULL
, INPUT_ID VARCHAR2(20) NOT NULL
, INPUT_DT VARCHAR2(14) NOT NULL
, UPDT_ID VARCHAR2(20)
, UPDT_DT VARCHAR2(14)
)
TABLESPACE TUNER_DATA1;

COMMENT ON COLUMN TUNER.TB_CUST_ADDR.CUST_NO IS '고객번호';
COMMENT ON COLUMN TUNER.TB_CUST_ADDR.ADDR_SN IS '주소순번';
COMMENT ON COLUMN TUNER.TB_CUST_ADDR.POST_NO IS '우편번호';
COMMENT ON COLUMN TUNER.TB_CUST_ADDR.ADDR IS '주소';
COMMENT ON COLUMN TUNER.TB_CUST_ADDR.REG_DT IS '등록일시';
COMMENT ON COLUMN TUNER.TB_CUST_ADDR.INPUT_ID IS '입력아이디';
COMMENT ON COLUMN TUNER.TB_CUST_ADDR.INPUT_DT IS '입력일시';
COMMENT ON COLUMN TUNER.TB_CUST_ADDR.UPDT_ID IS '수정아이디';
COMMENT ON COLUMN TUNER.TB_CUST_ADDR.UPDT_DT IS '수정일시';
COMMENT ON TABLE TUNER.TB_CUST_ADDR IS '고객주소';

ALTER TABLE TUNER.TB_CUST_ADDR NOLOGGING;

INSERT /*+ APPEND */
  INTO TUNER.TB_CUST_ADDR
SELECT A.CUST_NO
     , B.LVL AS ADDR_SN
     , TRUNC(DBMS_RANDOM.VALUE(11111, 99999)) AS POST_NO
     , DBMS_RANDOM.STRING('A', TRUNC(DBMS_RANDOM.VALUE(50, 100))) AS ADDR
     , TO_CHAR(TO_DATE(A.JOIN_DT, 'YYYYMMDDHH24MISS') + TRUNC(DBMS_RANDOM.VALUE(1, 240))/24, 'YYYYMMDDHH24MISS') AS REG_DT
     , DBMS_RANDOM.STRING('A', TRUNC(DBMS_RANDOM.VALUE(10, 20))) AS INPUT_ID
     , TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS') AS INPUT_DT
     , NULL AS UPDT_ID
     , NULL AS UPDT_DT
  FROM TUNER.TB_CUST A
     , (SELECT LEVEL AS LVL FROM DUAL CONNECT BY LEVEL <= 2) B
;

COMMIT;

CREATE UNIQUE INDEX TUNER.PK_TB_CUST_ADDR ON TUNER.TB_CUST_ADDR (CUST_NO, ADDR_SN) TABLESPACE TUNER_IDX1 PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.PK_TB_CUST_ADDR PARALLEL 1;
ALTER INDEX TUNER.PK_TB_CUST_ADDR LOGGING;
ALTER TABLE TUNER.TB_CUST_ADDR ADD CONSTRAINT PK_TB_CUST_ADDR PRIMARY KEY (CUST_NO,ADDR_SN);

ALTER TABLE TUNER.TB_CUST_ADDR LOGGING;
----------------------------------------------------------------------------------------------------------------------------------------
CREATE TABLE TUNER.TB_ORD
(
    CUST_NO VARCHAR2(10) NOT NULL
  , ORD_DT VARCHAR2(14) NOT NULL
  , ORD_TOT_AMT NUMBER(15, 2) NOT NULL
  , ORD_STS_CD VARCHAR2(6) NOT NULL
  , INPUT_ID VARCHAR2(20) NOT NULL
  , INPUT_DT VARCHAR2(14) NOT NULL
  , UPDT_ID VARCHAR2(20)
  , UPDT_DT VARCHAR2(14)
)
PARTITION BY RANGE(ORD_DT)
(
    PARTITION P_BEF_2020 VALUES LESS THAN ('20200101')
  , PARTITION P2020 VALUES LESS THAN ('20210101')
  , PARTITION P2021 VALUES LESS THAN ('20220101')
  , PARTITION P2022 VALUES LESS THAN ('20230101')
  , PARTITION P2023 VALUES LESS THAN ('20240101')
  , PARTITION P2024 VALUES LESS THAN ('20250101')
  , PARTITION P2025 VALUES LESS THAN ('20260101')
  , PARTITION P2026 VALUES LESS THAN ('20270101')
  , PARTITION P2027 VALUES LESS THAN ('20280101')
  , PARTITION P2028 VALUES LESS THAN ('20290101')
  , PARTITION P2029 VALUES LESS THAN ('20300101')
  , PARTITION P2030 VALUES LESS THAN ('20310101')
  , PARTITION P_AFT_2030 VALUES LESS THAN (MAXVALUE)
)
TABLESPACE TUNER_DATA1;

COMMENT ON COLUMN TUNER.TB_ORD.CUST_NO IS '고객번호';
COMMENT ON COLUMN TUNER.TB_ORD.ORD_DT IS '주문일시';
COMMENT ON COLUMN TUNER.TB_ORD.ORD_TOT_AMT IS '주문총금액';
COMMENT ON COLUMN TUNER.TB_ORD.ORD_STS_CD IS '주문상태코드';
COMMENT ON COLUMN TUNER.TB_ORD.INPUT_ID IS '입력아이디';
COMMENT ON COLUMN TUNER.TB_ORD.INPUT_DT IS '입력일시';
COMMENT ON COLUMN TUNER.TB_ORD.UPDT_ID IS '수정아이디';
COMMENT ON COLUMN TUNER.TB_ORD.UPDT_DT IS '수정일시';
COMMENT ON TABLE TUNER.TB_ORD IS '주문';

ALTER TABLE TUNER.TB_ORD NOLOGGING;

INSERT /*+ APPEND */
  INTO TUNER.TB_ORD
SELECT /*+ PARALEL(2) ENABLE_PARALLEL_DML */
       A.CUST_NO
     , TO_CHAR(TO_DATE(A.JOIN_DT, 'YYYYMMDDHH24MISS') + B.LVL/24/60, 'YYYYMMDDHH24MISS') AS ORD_DT
     , 0 AS ORD_TOT_AMT
     , CASE MOD(ROWNUM, 4) WHEN 0 THEN 'OSC001' WHEN  1 THEN 'OSC002' WHEN 2 THEN 'OSC003' WHEN 3 THEN 'OSC004' END AS ORD_STS_CD
     , DBMS_RANDOM.STRING('A', TRUNC(DBMS_RANDOM.VALUE(10, 20))) AS INPUT_ID
     , TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS') AS INPUT_DT
     , NULL AS UPDT_ID
     , NULL AS UPDT_DT
  FROM TUNER.TB_CUST A
     , (SELECT LEVEL AS LVL FROM DUAL CONNECT BY LEVEL <= 10) B
;

COMMIT;

CREATE UNIQUE INDEX TUNER.PK_TB_ORD ON TUNER.TB_ORD(CUST_NO, ORD_DT) TABLESPACE TUNER_IDX1 PARALLEL 2 LOCAL NOLOGGING;
ALTER INDEX TUNER.PK_TB_ORD PARALLEL 1;
ALTER INDEX TUNER.PK_TB_ORD LOGGING;


ALTER TABLE TUNER.TB_ORD ADD CONSTRAINT PK_TB_ORD PRIMARY KEY (CUST_NO, ORD_DT);

CREATE INDEX TUNER.IDX_TB_ORD_01 ON TUNER.TB_ORD(ORD_STS_CD) TABLESPACE TUNER_IDX1 LOCAL PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.IDX_TB_ORD_01 PARALLEL 1;
ALTER INDEX TUNER.IDX_TB_ORD_01 LOGGING;

ALTER TABLE TUNER.TB_ORD LOGGING;
----------------------------------------------------------------------------------------------------------------------------------------
CREATE TABLE TUNER.TB_DLVY
(
  CUST_NO VARCHAR2(10) NOT NULL
, ORD_DT VARCHAR2(14) NOT NULL
, DLVY_SN NUMBER(6) NOT NULL
, DLVY_DT VARCHAR2(14) NOT NULL
, DLVY_STS_CD VARCHAR2(6) NOT NULL
, HDRY_CMPNY_CD VARCHAR2(6)
, WAYBIL_NO VARCHAR2(50)
, ADDR_SN NUMBER(6) NOT NULL
, INPUT_ID VARCHAR2(20) NOT NULL
, INPUT_DT VARCHAR2(14) NOT NULL
, UPDT_ID VARCHAR2(20)
, UPDT_DT VARCHAR2(14)
)
PARTITION BY RANGE (ORD_DT)
SUBPARTITION BY HASH (CUST_NO)
SUBPARTITIONS 8
(
  PARTITION P_BEF_2020 VALUES LESS THAN ('20200101')
, PARTITION P2020 VALUES LESS THAN ('20210101')
, PARTITION P2021 VALUES LESS THAN ('20220101')
, PARTITION P2022 VALUES LESS THAN ('20230101')
, PARTITION P2023 VALUES LESS THAN ('20240101')
, PARTITION P2024 VALUES LESS THAN ('20250101')
, PARTITION P2025 VALUES LESS THAN ('20260101')
, PARTITION P2026 VALUES LESS THAN ('20270101')
, PARTITION P2027 VALUES LESS THAN ('20280101')
, PARTITION P2028 VALUES LESS THAN ('20290101')
, PARTITION P2029 VALUES LESS THAN ('20300101')
, PARTITION P2030 VALUES LESS THAN ('20310101')
, PARTITION P_AFT_2030 VALUES LESS THAN (MAXVALUE)
)
TABLESPACE TUNER_DATA1;

COMMENT ON COLUMN TUNER.TB_DLVY.CUST_NO IS '고객번호';
COMMENT ON COLUMN TUNER.TB_DLVY.ORD_DT IS '주문일시';
COMMENT ON COLUMN TUNER.TB_DLVY.DLVY_SN IS '배송순번';
COMMENT ON COLUMN TUNER.TB_DLVY.DLVY_DT IS '배송일시';
COMMENT ON COLUMN TUNER.TB_DLVY.DLVY_STS_CD IS '배송상태코드';
COMMENT ON COLUMN TUNER.TB_DLVY.HDRY_CMPNY_CD IS '택배사코드';
COMMENT ON COLUMN TUNER.TB_DLVY.WAYBIL_NO IS '운송장번호';
COMMENT ON COLUMN TUNER.TB_DLVY.ADDR_SN IS '주소순번';
COMMENT ON COLUMN TUNER.TB_DLVY.INPUT_ID IS '입력아이디';
COMMENT ON COLUMN TUNER.TB_DLVY.INPUT_DT IS '입력일시';
COMMENT ON COLUMN TUNER.TB_DLVY.UPDT_ID IS '수정아이디';
COMMENT ON COLUMN TUNER.TB_DLVY.UPDT_DT IS '수정일시';
COMMENT ON TABLE TUNER.TB_DLVY IS '배송';

ALTER TABLE TUNER.TB_DLVY NOLOGGING;

INSERT /*+ ENABLE_PARALLEL_DML APPEND */
  INTO TUNER.TB_DLVY
SELECT /*+ PARALLEL(2) LEADING(A B L) USE_HASH(L) NO_MERGE(L) NO_SWAP_JOIN_INPUTS(L) */
       A.CUST_NO
     , A.ORD_DT
     , B.LVL AS DLVY_SN
     , TO_CHAR(TO_DATE(A.ORD_DT, 'YYYYMMDDHH24MISS') + TRUNC(DBMS_RANDOM.VALUE(1, 240))/24, 'YYYYMMDDHH24MISS') AS DLVY_DT
     , 'DSC' || LPAD(MOD(ROWNUM, 5), 3, '0') AS DLVY_STS_CD
     , 'HCC' || LPAD(MOD(ROWNUM, 20), 3, '0') AS HDRY_CMPNY_CD
     , LPAD(ROWNUM, 20, '0') AS WAYBIL_NO
     , L.ADDR_SN
     , DBMS_RANDOM.STRING('A', TRUNC(DBMS_RANDOM.VALUE(10, 20))) AS INPUT_ID
     , TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS') AS INPUT_DT
     , NULL AS UPDT_ID
     , NULL AS UPDT_DT
  FROM TUNER.TB_ORD A
 INNER JOIN (SELECT LEVEL LVL FROM DUAL CONNECT BY LEVEL <= 3) B ON (1=1)
  LEFT OUTER JOIN (
                    SELECT *
                      FROM
                         (
                            SELECT L.CUST_NO, L.ADDR_SN, ROW_NUMBER() OVER (PARTITION BY L.CUST_NO ORDER BY DBMS_RANDOM.VALUE) AS RN
                              FROM TUNER.TB_CUST_ADDR L
                         ) L
                     WHERE L.RN = 1
                   ) L
               ON (A.CUST_NO = L.CUST_NO)
;


COMMIT;

CREATE UNIQUE INDEX TUNER.PK_TB_DLVY ON TUNER.TB_DLVY(CUST_NO, ORD_DT, DLVY_SN) TABLESPACE TUNER_IDX1 LOCAL PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.PK_TB_DLVY PARALLEL 1;
ALTER INDEX TUNER.PK_TB_DLVY LOGGING;
ALTER TABLE TUNER.TB_DLVY ADD CONSTRAINT PK_TB_DLVY PRIMARY KEY (CUST_NO, ORD_DT, DLVY_SN);

CREATE INDEX TUNER.IDX_TB_DLVY_01 ON TUNER.TB_DLVY(CUST_NO, ADDR_SN) TABLESPACE TUNER_IDX1 LOCAL PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.IDX_TB_DLVY_01 PARALLEL 1;
ALTER INDEX TUNER.IDX_TB_DLVY_01 LOGGING;

CREATE INDEX TUNER.IDX_TB_DLVY_02 ON TUNER.TB_DLVY(DLVY_STS_CD, DLVY_DT) TABLESPACE TUNER_IDX1 LOCAL PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.IDX_TB_DLVY_02 PARALLEL 1;
ALTER INDEX TUNER.IDX_TB_DLVY_02 LOGGING;

CREATE INDEX TUNER.IDX_TB_DLVY_03 ON TUNER.TB_DLVY(HDRY_CMPNY_CD, WAYBIL_NO) TABLESPACE TUNER_IDX1 LOCAL PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.IDX_TB_DLVY_03 PARALLEL 1;
ALTER INDEX TUNER.IDX_TB_DLVY_03 LOGGING;

ALTER TABLE TUNER.TB_DLVY LOGGING;
----------------------------------------------------------------------------------------------------------------------------------------
CREATE TABLE TUNER.TB_ITEM
(
  ITEM_NO VARCHAR2(10) NOT NULL
, ITEM_NM VARCHAR2(500) NOT NULL
, ITEM_PRC NUMBER(15, 2) NOT NULL
, REG_DT VARCHAR2(14) NOT NULL
, INPUT_ID VARCHAR2(20) NOT NULL
, INPUT_DT VARCHAR2(14) NOT NULL
, UPDT_ID VARCHAR2(20)
, UPDT_DT VARCHAR2(14)
)
TABLESPACE TUNER_DATA1;

COMMENT ON COLUMN TUNER.TB_ITEM.ITEM_NO IS '상품번호';
COMMENT ON COLUMN TUNER.TB_ITEM.ITEM_NM IS '상품명';
COMMENT ON COLUMN TUNER.TB_ITEM.ITEM_PRC IS '상품가격';
COMMENT ON COLUMN TUNER.TB_ITEM.REG_DT IS '등록일시';
COMMENT ON COLUMN TUNER.TB_ITEM.INPUT_ID IS '입력아이디';
COMMENT ON COLUMN TUNER.TB_ITEM.INPUT_DT IS '입력일시';
COMMENT ON COLUMN TUNER.TB_ITEM.UPDT_ID IS '수정아이디';
COMMENT ON COLUMN TUNER.TB_ITEM.UPDT_DT IS '수정일시';
COMMENT ON TABLE TUNER.TB_ITEM IS '상품';

ALTER TABLE TUNER.TB_ITEM NOLOGGING;
INSERT /*+ APPEND */
  INTO TUNER.TB_ITEM
SELECT 'I' || LPAD(ROWNUM, 9, '0') AS ITEM_NO
     , DBMS_RANDOM.STRING('A', TRUNC(DBMS_RANDOM.VALUE(50, 150))) AS ITEM_NM
     , TRUNC(DBMS_RANDOM.VALUE(5000, 100000), -3) AS ITEM_PRC
     , TO_CHAR(TO_DATE('2030-12-31', 'YYYY-MM-DD') - DBMS_RANDOM.VALUE(0, 365*10), 'YYYYMMDDHH24MISS') AS REG_DT
     , DBMS_RANDOM.STRING('A', TRUNC(DBMS_RANDOM.VALUE(1, 20))) AS INPUT_ID
     , TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS') AS INPUT_DT
     , NULL AS UPDT_ID
     , NULL AS UPDT_DT
  FROM DUAL CONNECT BY LEVEL <= :V_TB_ITEM_CNT;

COMMIT;

CREATE UNIQUE INDEX TUNER.PK_TB_ITEM ON TUNER.TB_ITEM ( ITEM_NO ) TABLESPACE TUNER_IDX1 PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.PK_TB_ITEM PARALLEL 1;
ALTER INDEX TUNER.PK_TB_ITEM LOGGING;
ALTER TABLE TUNER.TB_ITEM ADD CONSTRAINT PK_TB_ITEM PRIMARY KEY (ITEM_NO);

ALTER TABLE TUNER.TB_ITEM LOGGING;
----------------------------------------------------------------------------------------------------------------------------------------
CREATE TABLE TUNER.TB_ORD_DTL
(
  CUST_NO VARCHAR2(10) NOT NULL
, ORD_DT VARCHAR2(14) NOT NULL
, ORD_DTL_SN NUMBER(6) NOT NULL
, ORD_DTL_STS_CD VARCHAR2(6) NOT NULL
, ORD_AMT NUMBER(15, 2) NOT NULL
, ITEM_NO VARCHAR2(10) NOT NULL
, DLVY_SN VARCHAR2(14)
, INPUT_ID VARCHAR2(20) NOT NULL
, INPUT_DT VARCHAR2(14) NOT NULL
, UPDT_ID VARCHAR2(20)
, UPDT_DT VARCHAR2(14)
)
PARTITION BY RANGE (ORD_DT)
SUBPARTITION BY HASH (CUST_NO)
SUBPARTITIONS 8
(
  PARTITION P_BEF_2020 VALUES LESS THAN ('20200101')
, PARTITION P2020 VALUES LESS THAN ('20210101')
, PARTITION P2021 VALUES LESS THAN ('20220101')
, PARTITION P2022 VALUES LESS THAN ('20230101')
, PARTITION P2023 VALUES LESS THAN ('20240101')
, PARTITION P2024 VALUES LESS THAN ('20250101')
, PARTITION P2025 VALUES LESS THAN ('20260101')
, PARTITION P2026 VALUES LESS THAN ('20270101')
, PARTITION P2027 VALUES LESS THAN ('20280101')
, PARTITION P2028 VALUES LESS THAN ('20290101')
, PARTITION P2029 VALUES LESS THAN ('20300101')
, PARTITION P2030 VALUES LESS THAN ('20310101')
, PARTITION P_AFT_2030 VALUES LESS THAN (MAXVALUE)
)
TABLESPACE TUNER_DATA1;

COMMENT ON COLUMN TUNER.TB_ORD_DTL.CUST_NO IS '고객번호';
COMMENT ON COLUMN TUNER.TB_ORD_DTL.ORD_DT IS '주문일시';
COMMENT ON COLUMN TUNER.TB_ORD_DTL.ORD_DTL_SN IS '주문상세순번';
COMMENT ON COLUMN TUNER.TB_ORD_DTL.ORD_DTL_STS_CD IS '주문상세상태코드';
COMMENT ON COLUMN TUNER.TB_ORD_DTL.ORD_AMT IS '주문금액';
COMMENT ON COLUMN TUNER.TB_ORD_DTL.ITEM_NO IS '상품번호';
COMMENT ON COLUMN TUNER.TB_ORD_DTL.DLVY_SN IS '배송순번';
COMMENT ON COLUMN TUNER.TB_ORD_DTL.INPUT_ID IS '입력아이디';
COMMENT ON COLUMN TUNER.TB_ORD_DTL.INPUT_DT IS '입력일시';
COMMENT ON COLUMN TUNER.TB_ORD_DTL.UPDT_ID IS '수정아이디';
COMMENT ON COLUMN TUNER.TB_ORD_DTL.UPDT_DT IS '수정일시';
COMMENT ON TABLE TUNER.TB_ORD_DTL IS '주문상세';

ALTER TABLE TUNER.TB_ORD_DTL NOLOGGING;

INSERT /*+ ENABLE_PARALLEL_DML APPEND */
  INTO TUNER.TB_ORD_DTL
SELECT /*+ PARALLEL(2) NO_MERGE(A) LEADING(A) USE_HASH(B) */A.CUST_NO
     , A.ORD_DT
     , A.ORD_DTL_SN
     , 'ODSC' || LPAD(MOD(ROWNUM, 5), 2, '0') AS ORD_DTL_STS_CD
     , B.ITEM_PRC AS ORD_AMT
     , A.ITEM_NO
--     , CASE WHEN A.ORD_DTL_SN > A.MAX_DLVY_SN THEN MOD(A.ORD_DTL_SN, A.MAX_DLVY_SN)
--        ELSE A.DLVY_SN
--END AS DLVY_SN
     , CASE WHEN A.ORD_DTL_SN > A.MAX_DLVY_SN THEN NULL
        ELSE A.DLVY_SN
  END AS DLVY_SN
     , DBMS_RANDOM.STRING('A', TRUNC(DBMS_RANDOM.VALUE(10, 20))) AS INPUT_ID
     , TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS') AS INPUT_DT
     , NULL AS UPDT_ID
     , NULL AS UPDT_DT
  FROM
     (
        SELECT /*+ LEADING(A B L) USE_HASH(L) NO_MERGE(L) NO_SWAP_JOIN_INPUTS(L) */ A.CUST_NO
             , A.ORD_DT
             , B.LVL AS ORD_DTL_SN
             , 0 AS ORD_AMT
             , 'I' || LPAD(TRUNC(DBMS_RANDOM.VALUE(1, :V_TB_ITEM_CNT)), 9, '0') AS ITEM_NO
             , L.DLVY_SN
             , MAX(L.DLVY_SN) OVER (PARTITION BY A.CUST_NO, A.ORD_DT ORDER BY L.DLVY_SN
                                    ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS MAX_DLVY_SN
          FROM TUNER.TB_ORD A
          INNER JOIN (SELECT LEVEL LVL FROM DUAL CONNECT BY LEVEL <= 5) B ON (1=1)
          LEFT OUTER JOIN (
                            SELECT L.CUST_NO, L.ORD_DT, L.DLVY_SN
                              FROM
                                 (
                                    SELECT L.CUST_NO, L.ORD_DT, L.DLVY_SN
                                      FROM TUNER.TB_DLVY L
                                 ) L
                          ) L
          ON (L.CUST_NO = A.CUST_NO AND L.ORD_DT = A.ORD_DT AND L.DLVY_SN = B.LVL)
     ) A
INNER JOIN TUNER.TB_ITEM B
ON (A.ITEM_NO = B.ITEM_NO)
;

COMMIT;

CREATE UNIQUE INDEX TUNER.PK_TB_ORD_DTL ON TUNER.TB_ORD_DTL( CUST_NO,ORD_DT,ORD_DTL_SN ) TABLESPACE TUNER_IDX1 LOCAL PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.PK_TB_ORD_DTL PARALLEL 1;
ALTER INDEX TUNER.PK_TB_ORD_DTL LOGGING;
ALTER TABLE TUNER.TB_ORD_DTL ADD CONSTRAINT PK_TB_ORD_DTL PRIMARY KEY ( CUST_NO,ORD_DT,ORD_DTL_SN );

CREATE INDEX TUNER.IDX_TB_ORD_DTL_01 ON TUNER.TB_ORD_DTL(ITEM_NO) TABLESPACE TUNER_IDX1 LOCAL PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.IDX_TB_ORD_DTL_01 PARALLEL 1;
ALTER INDEX TUNER.IDX_TB_ORD_DTL_01 LOGGING;

CREATE INDEX TUNER.IDX_TB_ORD_DTL_02 ON TUNER.TB_ORD_DTL(ORD_DTL_STS_CD) TABLESPACE TUNER_IDX1 LOCAL PARALLEL 2 NOLOGGING;
ALTER INDEX TUNER.IDX_TB_ORD_DTL_02 PARALLEL 1;
ALTER INDEX TUNER.IDX_TB_ORD_DTL_02 LOGGING;

ALTER TABLE TUNER.TB_ORD_DTL LOGGING;
----------------------------------------------------------------------------------------------------------------------------------------

ALTER TABLE TUNER.TB_ORD NOLOGGING;
ALTER INDEX TUNER.PK_TB_ORD NOLOGGING;
ALTER INDEX TUNER.IDX_TB_ORD_01 NOLOGGING;
--MERGE문이라 REDO LOG가 쌓이는건 막을수 없음 ARCHIVE LOG가 과도하게 쌓이는 것을 방지하려면 NO ARCHIVE LOG 모드로 설정 후 돌려야함
MERGE /*+ PARALLEL(2) ENABLE_PARALLEL_DML LEADING(A Z) USE_NL(Z) */ INTO TUNER.TB_ORD Z
USING (
            SELECT /*+ LEADING(A B) USE_HASH(B) */ A.CUST_NO, A.ORD_DT, SUM(B.ORD_AMT) AS ORD_TOT_AMT
              FROM TUNER.TB_ORD A
                 , TUNER.TB_ORD_DTL B
             WHERE 1=1
               AND A.CUST_NO = B.CUST_NO
               AND A.ORD_DT = B.ORD_DT
             GROUP BY A.CUST_NO, A.ORD_DT
      ) A
   ON (Z.CUST_NO = A.CUST_NO AND Z.ORD_DT = A.ORD_DT)
WHEN MATCHED THEN UPDATE SET Z.ORD_TOT_AMT = A.ORD_TOT_AMT
;

COMMIT;
ALTER TABLE TUNER.TB_ORD LOGGING;
ALTER INDEX TUNER.PK_TB_ORD LOGGING;
ALTER INDEX TUNER.IDX_TB_ORD_01 LOGGING;
----------------------------------------------------------------------------------------------------------------------------------------
EXEC DBMS_STATS.GATHER_TABLE_STATS('TUNER', 'TB_CUST', method_opt => 'for all indexed columns' , cascade => true, DEGREE=> 2);
EXEC DBMS_STATS.GATHER_TABLE_STATS('TUNER', 'TB_CUST_ADDR', method_opt => 'for all indexed columns' , cascade => true, DEGREE=> 2);
EXEC DBMS_STATS.GATHER_TABLE_STATS('TUNER', 'TB_DLVY', method_opt => 'for all indexed columns' , cascade => true, DEGREE=> 2);
EXEC DBMS_STATS.GATHER_TABLE_STATS('TUNER', 'TB_ITEM', method_opt => 'for all indexed columns' , cascade => true, DEGREE=> 2);
EXEC DBMS_STATS.GATHER_TABLE_STATS('TUNER', 'TB_ORD', method_opt => 'for all indexed columns' , cascade => true, DEGREE=> 2);
EXEC DBMS_STATS.GATHER_TABLE_STATS('TUNER', 'TB_ORD_DTL', method_opt => 'for all indexed columns' , cascade => true, DEGREE=> 2);
----------------------------------------------------------------------------------------------------------------------------------------
SELECT /*+ PARALLEL(2) */
       A.*
  FROM
     (
        SELECT 'TUNER.TB_CUST' AS TABLE_NAME, COUNT(*) AS CNT FROM TUNER.TB_CUST A
        UNION ALL
        SELECT 'TUNER.TB_CUST_ADDR' AS TABLE_NAME, COUNT(*) AS CNT FROM TUNER.TB_CUST_ADDR A
        UNION ALL
        SELECT /*+ INDEX_FFS(A) */ 'TUNER.TB_DLVY' AS TABLE_NAME, COUNT(*) AS CNT FROM TUNER.TB_DLVY A
        UNION ALL
        SELECT 'TUNER.TB_ITEM' AS TABLE_NAME, COUNT(*) AS CNT FROM TUNER.TB_ITEM A
        UNION ALL
        SELECT 'TUNER.TB_ORD' AS TABLE_NAME, COUNT(*) AS CNT FROM TUNER.TB_ORD A
        UNION ALL
        SELECT /*+ INDEX_FFS(A) */ 'TUNER.TB_ORD_DTL' AS TABLE_NAME, COUNT(*) AS CNT FROM TUNER.TB_ORD_DTL A
    ) A
;

TABLE_NAME                                                    CNT
------------------------------------------------------ ----------
TUNER.TB_CUST                                             1000000
TUNER.TB_CUST_ADDR                                        2000000
TUNER.TB_DLVY                                            30000000
TUNER.TB_ITEM                                              100000
TUNER.TB_ORD                                             10000000
TUNER.TB_ORD_DTL                                         50000000

6 rows selected.

Elapsed: 00:00:01.49

----------------------------------------------------------------------------------------------------------------------------------------
--종료시간
COLUMN END_TIME NEW_VALUE END_TIME
SELECT TO_CHAR(SYSTIMESTAMP, 'YYYY-MM-DD HH24:MI:SS.FF') AS END_TIME FROM DUAL;

END_TIME
---------------------------------------------------------------------------------------
2025-12-29 23:07:22.262839

1 row selected.

Elapsed: 00:00:00.00

----------------------------------------------------------------------------------------------------------------------------------------
--경과시간
SELECT (TO_TIMESTAMP('&END_TIME', 'YYYY-MM-DD HH24:MI:SS.FF')
      - TO_TIMESTAMP('&START_TIME', 'YYYY-MM-DD HH24:MI:SS.FF')) AS ELAPSED_TIME
FROM DUAL;

ELAPSED_TIME
---------------------------------------------------------------------------
+000000000 00:16:00.431068000

1 row selected.

Elapsed: 00:00:00.00

----------------------------------------------------------------------------------------------------------------------------------------

 

--통계 정보 확인
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ alias st
alias st='rlwrap sqlplus tuner/oracle'

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ st

SQL*Plus: Release 12.2.0.1.0 Production on Mon Dec 29 23:16:43 2025

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<TUNER@ORA12RF1>$

SET LINESIZE 200
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF

COL OWNER          FORMAT A10 HEADING 'Owner'
COL TABLE_NAME     FORMAT A15 HEADING 'Table Name'
COL NUM_ROWS       FORMAT 999,999,999 HEADING 'Num Rows'
COL BLOCKS         FORMAT 9,999,999 HEADING 'Blocks'
COL AVG_ROW_LEN    FORMAT 99,999 HEADING 'Avg Row|Len'
COL LAST_ANALYZED  FORMAT A20 HEADING 'Last Analyzed'
COL STATUS         FORMAT A8 HEADING 'Status'
COL PCT_FREE       FORMAT 999999 HEADING 'Pct|Free'
COL INI_TRANS      FORMAT 999999 HEADING 'Ini|Trns'
COL LOGGING        FORMAT A7 HEADING 'Logging'
COL DEGREE         FORMAT A10 HEADING 'Degree'
COL PARTITIONED    FORMAT A5  HEADING 'Part?'

SELECT A.OWNER
     , A.TABLE_NAME
     , A.NUM_ROWS
     , A.BLOCKS
     , A.AVG_ROW_LEN
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
     , A.STATUS
     , A.PCT_FREE
     , A.INI_TRANS
     , A.LOGGING
     , A.DEGREE
     , A.PARTITIONED
  FROM DBA_TABLES A
 WHERE A.TABLE_NAME IN ('TB_CUST', 'TB_CUST_ADDR', 'TB_DLVY', 'TB_ITEM', 'TB_ORD', 'TB_ORD_DTL')
   AND A.OWNER = 'TUNER'
 ORDER BY A.OWNER, A.TABLE_NAME
;

                                                   Avg Row                                   Pct     Ini
Owner      Table Name          Num Rows     Blocks     Len Last Analyzed        Status      Free    Trns Logging Degree     Part?
---------- --------------- ------------ ---------- ------- -------------------- -------- ------- ------- ------- ---------- -----
TUNER      TB_CUST            1,000,000     18,380     125 2026-01-03 20:44:54  VALID         10       1 YES              1 NO
TUNER      TB_CUST_ADDR       2,000,000     41,054     142 2026-01-03 20:44:56  VALID         10       1 YES              1 NO
TUNER      TB_DLVY           30,000,000    500,848     112 2026-01-03 20:45:20  VALID    (NULL)  (NULL)  (NULL)           1 YES
TUNER      TB_ITEM              100,000      2,300     156 2026-01-03 20:45:31  VALID         10       1 YES              1 NO
TUNER      TB_ORD            10,000,000     99,211      67 2026-01-03 20:45:37  VALID    (NULL)  (NULL)  (NULL)           1 YES
TUNER      TB_ORD_DTL        50,000,000    620,773      84 2026-01-03 20:46:10  VALID    (NULL)  (NULL)  (NULL)           1 YES

6 rows selected.

Elapsed: 00:00:00.01


[ol7ora12rf1]<TUNER@ORA12RF1>$

SET LINESIZE 300
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF
SET LONG 2000          -- HIGH_VALUE(LONG 타입)가 잘리지 않도록 길이 설정

COL TABLE_OWNER       FORMAT A10              HEADING 'Owner'
COL TABLE_NAME        FORMAT A12              HEADING 'Table Name'
COL PARTITION_NAME    FORMAT A15              HEADING 'Part Name'
COL NUM_ROWS          FORMAT 999,999,999      HEADING 'Num Rows'
COL BLOCKS            FORMAT 9,999,999        HEADING 'Blocks'
COL AVG_ROW_LEN       FORMAT 99,999           HEADING 'Avg Row|Len'
COL LAST_ANALYZED     FORMAT A19              HEADING 'Last Analyzed'
COL SUBPARTITION_COUNT FORMAT 999             HEADING 'Sub|Cnt'
COL HIGH_VALUE        FORMAT A30              HEADING 'High Value' WRAPPED
COL PCT_FREE          FORMAT 999999           HEADING 'Pct|Free'
COL INI_TRANS         FORMAT 999999           HEADING 'Ini|Trns'
COL LOGGING           FORMAT A7               HEADING 'Logging'

SELECT A.TABLE_OWNER
     , A.TABLE_NAME
     , A.PARTITION_NAME
     , A.NUM_ROWS
     , A.BLOCKS
     , A.AVG_ROW_LEN
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
     , A.SUBPARTITION_COUNT
     , A.HIGH_VALUE
     , A.PCT_FREE
     , A.INI_TRANS
     , A.LOGGING
  FROM DBA_TAB_PARTITIONS A
 WHERE 1=1
   AND A.TABLE_NAME IN ('TB_ORD', 'TB_DLVY', 'TB_ORD_DTL')
   AND A.TABLE_OWNER = 'TUNER'
 ORDER BY A.TABLE_OWNER
        , A.TABLE_NAME
        , A.PARTITION_POSITION  -- 파티션의 논리적 순서대로 정렬
;

                                                                Avg Row                      Sub                                    Pct     Ini
Owner      Table Name   Part Name           Num Rows     Blocks     Len Last Analyzed        Cnt High Value                        Free    Trns Logging
---------- ------------ --------------- ------------ ---------- ------- ------------------- ---- ------------------------------ ------- ------- -------
TUNER      TB_DLVY      P_BEF_2020                 0          0       0 2026-01-03 20:45:09    8 '20200101'                          10       1 YES
TUNER      TB_DLVY      P2020                      0          0       0 2026-01-03 20:44:56    8 '20210101'                          10       1 YES
TUNER      TB_DLVY      P2021              2,997,630     50,028     112 2026-01-03 20:44:58    8 '20220101'                          10       1 YES
TUNER      TB_DLVY      P2022              3,008,910     50,235     113 2026-01-03 20:44:59    8 '20230101'                          10       1 YES
TUNER      TB_DLVY      P2023              2,996,814     50,037     112 2026-01-03 20:45:00    8 '20240101'                          10       1 YES
TUNER      TB_DLVY      P2024              3,014,505     50,327     113 2026-01-03 20:45:01    8 '20250101'                          10       1 YES
TUNER      TB_DLVY      P2025              3,001,749     50,101     112 2026-01-03 20:45:03    8 '20260101'                          10       1 YES
TUNER      TB_DLVY      P2026              2,994,912     50,004     112 2026-01-03 20:45:04    8 '20270101'                          10       1 YES
TUNER      TB_DLVY      P2027              2,987,250     49,879     112 2026-01-03 20:45:05    8 '20280101'                          10       1 YES
TUNER      TB_DLVY      P2028              3,019,020     50,400     112 2026-01-03 20:45:07    8 '20290101'                          10       1 YES
TUNER      TB_DLVY      P2029              2,993,838     49,988     112 2026-01-03 20:45:08    8 '20300101'                          10       1 YES
TUNER      TB_DLVY      P2030              2,985,372     49,849     112 2026-01-03 20:45:09    8 '20310101'                          10       1 YES
TUNER      TB_DLVY      P_AFT_2030                 0          0       0 2026-01-03 20:45:09    8 MAXVALUE                            10       1 YES
TUNER      TB_ORD       P_BEF_2020                 0          0       0 2026-01-03 20:45:34    0 '20200101'                          10       1 YES
TUNER      TB_ORD       P2020                      0          0       0 2026-01-03 20:45:31    0 '20210101'                          10       1 YES
TUNER      TB_ORD       P2021                999,210      9,914      68 2026-01-03 20:45:31    0 '20220101'                          10       1 YES
TUNER      TB_ORD       P2022              1,002,970      9,950      67 2026-01-03 20:45:32    0 '20230101'                          10       1 YES
TUNER      TB_ORD       P2023                998,938      9,910      67 2026-01-03 20:45:32    0 '20240101'                          10       1 YES
TUNER      TB_ORD       P2024              1,004,835      9,969      68 2026-01-03 20:45:32    0 '20250101'                          10       1 YES
TUNER      TB_ORD       P2025              1,000,583      9,927      67 2026-01-03 20:45:33    0 '20260101'                          10       1 YES
TUNER      TB_ORD       P2026                998,304      9,906      68 2026-01-03 20:45:33    0 '20270101'                          10       1 YES
TUNER      TB_ORD       P2027                995,750      9,879      68 2026-01-03 20:45:33    0 '20280101'                          10       1 YES
TUNER      TB_ORD       P2028              1,006,340      9,983      67 2026-01-03 20:45:34    0 '20290101'                          10       1 YES
TUNER      TB_ORD       P2029                997,946      9,900      67 2026-01-03 20:45:34    0 '20300101'                          10       1 YES
TUNER      TB_ORD       P2030                995,124      9,873      68 2026-01-03 20:45:34    0 '20310101'                          10       1 YES
TUNER      TB_ORD       P_AFT_2030                 0          0       0 2026-01-03 20:45:34    0 MAXVALUE                            10       1 YES
TUNER      TB_ORD_DTL   P_BEF_2020                 0          0       0 2026-01-03 20:45:56    8 '20200101'                          10       1 YES
TUNER      TB_ORD_DTL   P2020                      0          0       0 2026-01-03 20:45:39    8 '20210101'                          10       1 YES
TUNER      TB_ORD_DTL   P2021              4,996,050     62,027      83 2026-01-03 20:45:41    8 '20220101'                          10       1 YES
TUNER      TB_ORD_DTL   P2022              5,014,850     62,260      84 2026-01-03 20:45:43    8 '20230101'                          10       1 YES
TUNER      TB_ORD_DTL   P2023              4,994,690     62,014      84 2026-01-03 20:45:44    8 '20240101'                          10       1 YES
TUNER      TB_ORD_DTL   P2024              5,024,175     62,378      83 2026-01-03 20:45:46    8 '20250101'                          10       1 YES
TUNER      TB_ORD_DTL   P2025              5,002,915     62,113      84 2026-01-03 20:45:47    8 '20260101'                          10       1 YES
TUNER      TB_ORD_DTL   P2026              4,991,520     61,973      84 2026-01-03 20:45:49    8 '20270101'                          10       1 YES
TUNER      TB_ORD_DTL   P2027              4,978,750     61,816      83 2026-01-03 20:45:51    8 '20280101'                          10       1 YES
TUNER      TB_ORD_DTL   P2028              5,031,700     62,464      83 2026-01-03 20:45:52    8 '20290101'                          10       1 YES
TUNER      TB_ORD_DTL   P2029              4,989,730     61,950      83 2026-01-03 20:45:54    8 '20300101'                          10       1 YES
TUNER      TB_ORD_DTL   P2030              4,975,620     61,778      83 2026-01-03 20:45:56    8 '20310101'                          10       1 YES
TUNER      TB_ORD_DTL   P_AFT_2030                 0          0       0 2026-01-03 20:45:56    8 MAXVALUE                            10       1 YES

39 rows selected.

Elapsed: 00:00:00.01


[ol7ora12rf1]<TUNER@ORA12RF1>$
SET LINESIZE 300
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF

COL TABLE_OWNER       FORMAT A10              HEADING 'Owner'
COL TABLE_NAME        FORMAT A12              HEADING 'Table Name'
COL PARTITION_NAME    FORMAT A10              HEADING 'Part Name'
COL SUBPARTITION_NAME FORMAT A20              HEADING 'Subpart Name'
COL NUM_ROWS          FORMAT 999,999,999      HEADING 'Num Rows'
COL BLOCKS            FORMAT 9,999,999        HEADING 'Blocks'
COL AVG_ROW_LEN       FORMAT 99,999           HEADING 'Avg Row|Len'
COL COMPRESSION       FORMAT A10              HEADING 'Compress'
COL LAST_ANALYZED     FORMAT A19              HEADING 'Last Analyzed'
COL PCT_FREE          FORMAT 999999           HEADING 'Pct|Free'
COL INI_TRANS         FORMAT 999999           HEADING 'Ini|Trns'
COL LOGGING           FORMAT A7               HEADING 'Logging'

SELECT A.TABLE_OWNER
     , A.TABLE_NAME
     , A.PARTITION_NAME
     , A.SUBPARTITION_NAME
     , A.NUM_ROWS
     , A.BLOCKS
     , A.AVG_ROW_LEN
     , A.COMPRESSION
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
     , A.PCT_FREE
     , A.INI_TRANS
     , A.LOGGING
  FROM DBA_TAB_SUBPARTITIONS A
 WHERE A.TABLE_NAME IN ('TB_DLVY', 'TB_ORD_DTL')
   AND A.PARTITION_NAME = 'P2024'
   AND A.TABLE_OWNER = 'TUNER'
 ORDER BY A.TABLE_NAME
        , A.SUBPARTITION_POSITION  -- 서브파티션의 논리적 순서 정렬
;

                                                                                Avg Row                                    Pct     Ini
Owner      Table Name   Part Name  Subpart Name             Num Rows     Blocks     Len Compress   Last Analyzed          Free    Trns Logging
---------- ------------ ---------- -------------------- ------------ ---------- ------- ---------- ------------------- ------- ------- -------
TUNER      TB_DLVY      P2024      SYS_SUBP2525         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2526         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2527         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2528         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2529         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2530         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2531         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2532         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2629         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2630         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2631         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2632         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2633         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2634         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2635         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2636         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES


16 rows selected.

Elapsed: 00:00:00.02
--> 서브 파티션 테이블 통계는 수집되지 않은 상태임

[ol7ora12rf1]<TUNER@ORA12RF1>$
SET LINESIZE 300
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF

COL TABLE_OWNER       FORMAT A10              HEADING 'Owner'
COL TABLE_NAME        FORMAT A15              HEADING 'Table Name'
COL INDEX_NAME        FORMAT A20              HEADING 'Index Name'
COL BLEVEL            FORMAT 99               HEADING 'BLv'
COL LEAF_BLOCKS       FORMAT 9,999,999        HEADING 'Leaf Blks'
COL DISTINCT_KEYS     FORMAT 999,999,999      HEADING 'Dst Keys'
COL CLUSTERING_FACTOR FORMAT 999,999,999      HEADING 'Clust Fctr'
COL NUM_ROWS          FORMAT 999,999,999      HEADING 'Num Rows'
COL UNIQUENESS        FORMAT A9               HEADING 'Unique'
COL INI_TRANS         FORMAT 999999               HEADING 'Ini|Trns'
COL PCT_FREE          FORMAT 999999               HEADING 'Pct|Free'
COL LOGGING           FORMAT A7               HEADING 'Logging'
COL STATUS            FORMAT A8               HEADING 'Status'
COL LAST_ANALYZED     FORMAT A19              HEADING 'Last Analyzed'

SELECT A.TABLE_OWNER
     , A.TABLE_NAME
     , A.INDEX_NAME
     , A.BLEVEL
     , A.LEAF_BLOCKS
     , A.DISTINCT_KEYS
     , A.CLUSTERING_FACTOR
     , A.NUM_ROWS
     , A.UNIQUENESS
     , A.INI_TRANS
     , A.PCT_FREE
     , A.LOGGING
     , A.STATUS
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
  FROM DBA_INDEXES A
 WHERE 1=1
   AND A.TABLE_OWNER = 'TUNER'
   AND A.TABLE_NAME IN ('TB_CUST', 'TB_CUST_ADDR', 'TB_DLVY', 'TB_ITEM', 'TB_ORD', 'TB_ORD_DTL')
 ORDER BY A.TABLE_NAME, A.INDEX_NAME
;

                                                                                                                    Ini     Pct
Owner      Table Name      Index Name           BLv  Leaf Blks     Dst Keys   Clust Fctr     Num Rows Unique       Trns    Free Logging Status   Last Analyzed
---------- --------------- -------------------- --- ---------- ------------ ------------ ------------ --------- ------- ------- ------- -------- -------------------
TUNER      TB_CUST         IDX_TB_CUST_01         2      2,513            5       91,069    1,000,000 NONUNIQUE       2      10 YES     VALID    2026-01-03 20:44:55
TUNER      TB_CUST         IDX_TB_CUST_02         2      2,787       21,792      998,770    1,000,000 NONUNIQUE       2      10 YES     VALID    2026-01-03 20:44:55
TUNER      TB_CUST         IDX_TB_CUST_03         2      3,775      109,490      999,787    1,000,000 NONUNIQUE       2      10 YES     VALID    2026-01-03 20:44:56
TUNER      TB_CUST         PK_TB_CUST             2      2,934    1,000,000       18,236    1,000,000 UNIQUE          2      10 YES     VALID    2026-01-03 20:44:55
TUNER      TB_CUST_ADDR    PK_TB_CUST_ADDR        2      6,742    2,015,914    2,015,914    2,015,914 UNIQUE          2      10 YES     VALID    2026-01-03 20:44:56
TUNER      TB_DLVY         IDX_TB_DLVY_01         2    105,438    1,004,664    1,597,897   30,255,443 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:24
TUNER      TB_DLVY         IDX_TB_DLVY_02         2    138,053   29,783,888   29,796,132   29,957,441 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:27
TUNER      TB_DLVY         IDX_TB_DLVY_03         2    166,040   30,541,059   10,117,176   30,541,059 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:31
TUNER      TB_DLVY         PK_TB_DLVY             2    165,456   30,407,119    1,647,410   30,407,119 UNIQUE    (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:22
TUNER      TB_ITEM         PK_TB_ITEM             1        294      100,000        2,256      100,000 UNIQUE          2      10 YES     VALID    2026-01-03 20:45:31
TUNER      TB_ORD          IDX_TB_ORD_01          2     25,525            4      421,877   10,159,148 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:39
TUNER      TB_ORD          PK_TB_ORD              2     49,598    9,866,518    9,865,668    9,866,518 UNIQUE    (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:38
TUNER      TB_ORD_DTL      IDX_TB_ORD_DTL_01      2    158,369       99,888   49,970,416   51,628,286 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:46:15
TUNER      TB_ORD_DTL      IDX_TB_ORD_DTL_02      2    120,606            5    3,047,288   48,001,055 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:46:17
TUNER      TB_ORD_DTL      PK_TB_ORD_DTL          2    263,745   48,529,155   48,157,051   48,529,155 UNIQUE    (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:46:13

15 rows selected.

Elapsed: 00:00:00.02

--CLUSTERING_FACTOR:
--인덱스 정렬 순서와 실제 테이블 데이터 블록의 저장 순서가 얼마나 일치하는지를 나타내는 수치입니다.
--Good: 값이 BLOCKS(테이블 블록 수)에 가까울수록 인덱스 스캔 시 테이블 랜덤 액세스가 적게 발생하여 성능이 좋습니다.
--Bad: 값이 NUM_ROWS(테이블 행 수)에 가까울수록 인덱스를 경유한 테이블 액세스 시 I/O 부하가 큽니다. 옵티마이저는 이 값이 높으면 인덱스 스캔 대신 Full Table Scan을 선택할 확률이 높습니다.

 

SET LINESIZE 300
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF
SET LONG 4000          -- HIGH_VALUE(LONG 타입) 데이터가 잘리지 않도록 설정

COL INDEX_OWNER       FORMAT A10              HEADING 'Owner'
COL INDEX_NAME        FORMAT A20              HEADING 'Index Name'
COL PARTITION_NAME    FORMAT A15              HEADING 'Part Name'
COL BLEVEL            FORMAT 99               HEADING 'BLv'
COL LEAF_BLOCKS       FORMAT 9,999,999        HEADING 'Leaf Blks'
COL DISTINCT_KEYS     FORMAT 9,999,999,999    HEADING 'Dst Keys'
COL NUM_ROWS          FORMAT 9,999,999,999    HEADING 'Num Rows'
COL CLUSTERING_FACTOR FORMAT 9,999,999,999    HEADING 'Clust Fctr'
COL COMPOSITE         FORMAT A5               HEADING 'Comp?'
COL SUBPARTITION_COUNT FORMAT 999             HEADING 'Sub|Cnt'
COL HIGH_VALUE        FORMAT A30              HEADING 'High Value' WRAPPED
COL PARTITION_POSITION FORMAT 999             HEADING 'Pos'
COL PCT_FREE          FORMAT 999999           HEADING 'Pct|Free'
COL INI_TRANS         FORMAT 999999           HEADING 'Ini|Trns'
COL GLOBAL_STATS      FORMAT A5               HEADING 'Gbl|Sts'
COL LAST_ANALYZED     FORMAT A19              HEADING 'Last Analyzed'

SELECT A.INDEX_OWNER
     , A.INDEX_NAME
     , A.PARTITION_NAME
     , A.BLEVEL
     , A.LEAF_BLOCKS
     , A.DISTINCT_KEYS
     , A.NUM_ROWS
     , A.CLUSTERING_FACTOR
     , A.COMPOSITE
     , A.SUBPARTITION_COUNT
     , A.HIGH_VALUE
     , A.PARTITION_POSITION
     , A.PCT_FREE
     , A.INI_TRANS
     , A.GLOBAL_STATS
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
  FROM DBA_IND_PARTITIONS A
 WHERE 1=1
   AND A.INDEX_OWNER = 'TUNER'
   AND A.INDEX_NAME IN ('IDX_TB_ORD_DTL_01', 'IDX_TB_ORD_DTL_02', 'PK_TB_ORD_DTL')
 ORDER BY A.INDEX_NAME, A.PARTITION_POSITION
;

                                                                                                                   Sub                                         Pct     Ini Gbl
Owner      Index Name           Part Name       BLv  Leaf Blks       Dst Keys       Num Rows     Clust Fctr Comp?  Cnt High Value                      Pos    Free    Trns Sts   Last Analyzed
---------- -------------------- --------------- --- ---------- -------------- -------------- -------------- ----- ---- ------------------------------ ---- ------- ------- ----- -------------------
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020        0          0              0              0              0 YES      8 '20200101'                        1      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2020             0          0              0              0              0 YES      8 '20210101'                        2      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2021             2     15,178         99,888      4,942,453      4,786,182 YES      8 '20220101'                        3      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2022             2     15,440         99,888      5,032,524      4,870,969 YES      8 '20230101'                        4      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2023             2     15,000         99,888      4,889,906      4,734,841 YES      8 '20240101'                        5      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2024             2     15,558         99,888      5,071,116      4,907,648 YES      8 '20250101'                        6      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2025             2     15,838         99,888      5,162,460      4,997,337 YES      8 '20260101'                        7      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2026             2     14,814         99,888      4,829,396      4,676,751 YES      8 '20270101'                        8      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2027             2     15,732         99,888      5,128,757      4,963,062 YES      8 '20280101'                        9      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2028             2     15,120         99,888      4,929,207      4,772,611 YES      8 '20290101'                       10      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2029             2     15,430         99,888      5,030,249      4,869,430 YES      8 '20300101'                       11      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2030             2     15,334         99,888      4,993,375      4,836,662 YES      8 '20310101'                       12      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P_AFT_2030        0          0              0              0              0 YES      8 MAXVALUE                         13      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_02    P_BEF_2020        0          0              0              0              0 YES      8 '20200101'                        1      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2020             0          0              0              0              0 YES      8 '20210101'                        2      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2021             2     12,947              5      5,150,084        325,524 YES      8 '20220101'                        3      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2022             2     12,800              5      5,090,826        321,552 YES      8 '20230101'                        4      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2023             2     12,955              5      5,151,462        325,816 YES      8 '20240101'                        5      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2024             2     12,399              5      4,930,427        312,272 YES      8 '20250101'                        6      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2025             2     12,521              5      4,983,521        316,340 YES      8 '20260101'                        7      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2026             2     12,764              5      5,072,296        320,685 YES      8 '20270101'                        8      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2027             2     12,344              5      4,909,755        311,387 YES      8 '20280101'                        9      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2028             2     13,218              5      5,260,703        332,732 YES      8 '20290101'                       10      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2029             2     12,787              5      5,085,071        322,324 YES      8 '20300101'                       11      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2030             2     12,269              5      4,883,146        308,609 YES      8 '20310101'                       12      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P_AFT_2030        0          0              0              0              0 YES      8 MAXVALUE                         13      10       2 YES   2026-01-03 20:46:17
TUNER      PK_TB_ORD_DTL        P_BEF_2020        0          0              0              0              0 YES      8 '20200101'                        1      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2020             0          0              0              0              0 YES      8 '20210101'                        2      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2021             2     26,861      4,941,518      4,941,518      4,903,128 YES      8 '20220101'                        3      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2022             2     26,573      4,889,315      4,889,315      4,850,683 YES      8 '20230101'                        4      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2023             2     26,708      4,914,309      4,914,309      4,876,245 YES      8 '20240101'                        5      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2024             2     27,722      5,099,702      5,099,702      5,060,433 YES      8 '20250101'                        6      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2025             2     27,005      4,966,323      4,966,323      4,927,624 YES      8 '20260101'                        7      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2026             2     28,387      5,223,181      5,223,181      5,183,178 YES      8 '20270101'                        8      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2027             2     26,728      4,917,946      4,917,946      4,881,270 YES      8 '20280101'                        9      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2028             2     27,371      5,035,855      5,035,855      4,997,237 YES      8 '20290101'                       10      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2029             2     27,572      5,069,253      5,069,253      5,030,119 YES      8 '20300101'                       11      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2030             2     27,083      4,983,271      4,983,271      4,945,312 YES      8 '20310101'                       12      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P_AFT_2030        0          0              0              0              0 YES      8 MAXVALUE                         13      10       2 YES   2026-01-03 20:46:13

39 rows selected.

Elapsed: 00:00:00.02


SET LINESIZE 300
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF

COL INDEX_OWNER       FORMAT A10              HEADING 'Owner'
COL INDEX_NAME        FORMAT A20              HEADING 'Index Name'
COL PARTITION_NAME    FORMAT A10              HEADING 'Part Name'
COL SUBPARTITION_NAME FORMAT A20              HEADING 'Subpart Name'
COL BLEVEL            FORMAT 99               HEADING 'BLv'
COL LEAF_BLOCKS       FORMAT 9,999,999        HEADING 'Leaf Blks'
COL NUM_ROWS          FORMAT 9,999,999,999    HEADING 'Num Rows'
COL CLUSTERING_FACTOR FORMAT 9,999,999,999    HEADING 'Clust Fctr'
COL PARTITION_POSITION FORMAT 999             HEADING 'P_Pos'
COL SUBPARTITION_POSITION FORMAT 999          HEADING 'S_Pos'
COL STATUS            FORMAT A8               HEADING 'Status'
COL PCT_FREE          FORMAT 999999           HEADING 'Pct|Free'
COL INI_TRANS         FORMAT 999999               HEADING 'Ini|Trns'
COL LAST_ANALYZED     FORMAT A19              HEADING 'Last Analyzed'

SELECT A.INDEX_OWNER
     , A.INDEX_NAME
     , A.PARTITION_NAME
     , A.SUBPARTITION_NAME
     , A.BLEVEL
     , A.LEAF_BLOCKS
     , A.NUM_ROWS
     , A.CLUSTERING_FACTOR
     , A.PARTITION_POSITION
     , A.SUBPARTITION_POSITION
     , A.STATUS
     , A.PCT_FREE
     , A.INI_TRANS
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
  FROM DBA_IND_SUBPARTITIONS A
 WHERE 1=1
   AND A.INDEX_OWNER = 'TUNER'
   AND A.INDEX_NAME IN ('IDX_TB_ORD_DTL_01', 'IDX_TB_ORD_DTL_02', 'PK_TB_ORD_DTL')
   AND ROWNUM <= 15  -- 샘플링 제한
 ORDER BY A.INDEX_NAME
        , A.PARTITION_NAME
        , A.SUBPARTITION_POSITION
;

                                                                                                                                      Pct     Ini
Owner      Index Name           Part Name  Subpart Name         BLv  Leaf Blks       Num Rows     Clust Fctr P_Pos S_Pos Status      Free    Trns Last Analyzed
---------- -------------------- ---------- -------------------- --- ---------- -------------- -------------- ----- ----- -------- ------- ------- -------------------
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2597           0          0              0              0     2     1 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2598           0          0              0              0     2     2 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2599           0          0              0              0     2     3 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2600           0          0              0              0     2     4 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2602           0          0              0              0     2     6 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2603           0          0              0              0     2     7 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2604           0          0              0              0     2     8 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2589           0          0              0              0     1     1 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2590           0          0              0              0     1     2 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2591           0          0              0              0     1     3 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2592           0          0              0              0     1     4 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2593           0          0              0              0     1     5 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2594           0          0              0              0     1     6 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2595           0          0              0              0     1     7 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2596           0          0              0              0     1     8 USABLE        10       2 2026-01-03 20:41:52

15 rows selected.

Elapsed: 00:00:00.03

 

[ol7ora12rf1]<TUNER@ORA12RF1>$
SET LINESIZE 300
SET PAGESIZE 100
COL OWNER          FORMAT A10              HEADING 'Owner'
COL TABLE_NAME     FORMAT A15              HEADING 'Table Name'
COL COLUMN_NAME    FORMAT A15              HEADING 'Column Name'
COL DATA_TYPE      FORMAT A10              HEADING 'Type'
COL NUM_DISTINCT   FORMAT 9,999,999,999    HEADING 'NDV'
COL LOW_VALUE      FORMAT A20              HEADING 'Low Value'
COL HIGH_VALUE     FORMAT A20              HEADING 'High Value'
COL DENSITY        FORMAT 0.999999         HEADING 'Density'
COL HISTOGRAM      FORMAT A20              HEADING 'HISTOGRAM'
COL NUM_NULLS      FORMAT 9,999,999        HEADING 'Num Nulls'
COL LAST_ANALYZED  FORMAT A19              HEADING 'Last Analyzed'

-- WITH FUNCTION과 SELECT를 한 덩어리로 묶어서 실행
WITH FUNCTION Convert_Raw(p_raw RAW, p_type VARCHAR2) RETURN VARCHAR2 IS
    v_num  NUMBER;
    v_date DATE;
    v_char VARCHAR2(4000);
BEGIN
    IF p_raw IS NULL THEN RETURN NULL; END IF;

    -- 데이터 타입에 따라 변환 로직 분기
    IF p_type IN ('NUMBER', 'FLOAT', 'BINARY_FLOAT', 'BINARY_DOUBLE') THEN
        DBMS_STATS.CONVERT_RAW_VALUE(p_raw, v_num);
        RETURN TO_CHAR(v_num);
    ELSIF p_type = 'DATE' THEN
        DBMS_STATS.CONVERT_RAW_VALUE(p_raw, v_date);
        RETURN TO_CHAR(v_date, 'YYYY-MM-DD HH24:MI:SS');
    ELSIF p_type LIKE '%CHAR%' THEN -- CHAR, VARCHAR2, NVARCHAR2
        DBMS_STATS.CONVERT_RAW_VALUE(p_raw, v_char);
        RETURN SUBSTR(v_char, 1, 20); -- 화면 출력을 위해 길이 제한
    ELSE
        RETURN 'RAW Type'; -- 기타 타입은 변환하지 않음
    END IF;
EXCEPTION
    WHEN OTHERS THEN RETURN 'Conv Error';
END;
SELECT A.OWNER
     , A.TABLE_NAME
     , A.COLUMN_NAME
     , B.DATA_TYPE
     , A.NUM_DISTINCT
     , A.NUM_NULLS
     , Convert_Raw(A.LOW_VALUE, B.DATA_TYPE)  AS LOW_VALUE
     , Convert_Raw(A.HIGH_VALUE, B.DATA_TYPE) AS HIGH_VALUE
     , A.DENSITY
     , A.HISTOGRAM
     , A.NUM_BUCKETS
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
  FROM DBA_TAB_COL_STATISTICS A
     , DBA_TAB_COLUMNS B
 WHERE 1=1
   AND A.OWNER = 'TUNER'
   -- JOIN 조건: 통계 뷰에는 데이터 타입이 없으므로 컬럼 뷰와 조인 필수
   AND A.OWNER = B.OWNER
   AND A.TABLE_NAME = B.TABLE_NAME
   AND A.COLUMN_NAME = B.COLUMN_NAME
 ORDER BY A.OWNER
        , A.TABLE_NAME
        , A.COLUMN_NAME
;
/

Owner      Table Name      Column Name     Type                  NDV  Num Nulls Low Value            High Value             Density HISTOGRAM            NUM_BUCKETS Last Analyzed
---------- --------------- --------------- ---------- -------------- ---------- -------------------- -------------------- --------- -------------------- ----------- -------------------
TUNER      TB_CUST         BRTHDY          VARCHAR2           21,792          0 19510120             20110104              0.000046 HYBRID                        75 2026-01-03 20:44:54
TUNER      TB_CUST         CUST_NO         VARCHAR2        1,000,000          0 C000000001           C001000000            0.000001 HYBRID                        75 2026-01-03 20:44:54
TUNER      TB_CUST         CUST_STS_CD     VARCHAR2                5          0 CSC000               CSC004                0.000001 FREQUENCY                      5 2026-01-03 20:44:54
TUNER      TB_CUST_ADDR    ADDR_SN         NUMBER                  2          0 1                    2                     0.000000 FREQUENCY                      2 2026-01-03 20:44:56
TUNER      TB_CUST_ADDR    CUST_NO         VARCHAR2          995,520          0 C000000001           C001000000            0.000001 HYBRID                        75 2026-01-03 20:44:56
TUNER      TB_DLVY         ADDR_SN         NUMBER                  2          0 1                    2                     0.000000 FREQUENCY                      2 2026-01-03 20:45:09
TUNER      TB_DLVY         CUST_NO         VARCHAR2          995,520          0 C000000001           C001000000            0.000001 HYBRID                        75 2026-01-03 20:45:09
TUNER      TB_DLVY         DLVY_DT         VARCHAR2       28,493,824          0 20210102022303       20310109220026        0.000000 HYBRID                        75 2026-01-03 20:45:09
TUNER      TB_DLVY         DLVY_SN         NUMBER                  3          0 1                    3                     0.000000 FREQUENCY                      3 2026-01-03 20:45:09
TUNER      TB_DLVY         DLVY_STS_CD     VARCHAR2                5          0 DSC000               DSC004                0.000000 FREQUENCY                      5 2026-01-03 20:45:09
TUNER      TB_DLVY         HDRY_CMPNY_CD   VARCHAR2               20          0 HCC000               HCC019                0.000000 FREQUENCY                     20 2026-01-03 20:45:09
TUNER      TB_DLVY         ORD_DT          VARCHAR2        9,689,088          0 20210102000819       20301231000626        0.000000 HYBRID                        75 2026-01-03 20:45:09
TUNER      TB_DLVY         WAYBIL_NO       VARCHAR2       30,000,000          0 00000000000000000001 00000000000030000000  0.000000 HYBRID                        75 2026-01-03 20:45:09
TUNER      TB_ITEM         ITEM_NO         VARCHAR2          100,000          0 I000000001           I000100000            0.000010 HYBRID                        75 2026-01-03 20:45:31
TUNER      TB_ORD          CUST_NO         VARCHAR2          995,520          0 C000000001           C001000000            0.000001 HYBRID                        75 2026-01-03 20:45:34
TUNER      TB_ORD          ORD_DT          VARCHAR2        9,689,088          0 20210102000819       20301231000626        0.000000 HYBRID                        75 2026-01-03 20:45:34
TUNER      TB_ORD          ORD_STS_CD      VARCHAR2                4          0 OSC001               OSC004                0.000000 FREQUENCY                      4 2026-01-03 20:45:34
TUNER      TB_ORD_DTL      CUST_NO         VARCHAR2          995,520          0 C000000001           C001000000            0.000001 HYBRID                        75 2026-01-03 20:45:56
TUNER      TB_ORD_DTL      ITEM_NO         VARCHAR2           99,888          0 I000000001           I000099999            0.000010 HYBRID                        75 2026-01-03 20:45:56
TUNER      TB_ORD_DTL      ORD_DT          VARCHAR2        9,689,088          0 20210102000819       20301231000626        0.000000 HYBRID                        75 2026-01-03 20:45:56
TUNER      TB_ORD_DTL      ORD_DTL_SN      NUMBER                  5          0 1                    5                     0.000000 FREQUENCY                      5 2026-01-03 20:45:56
TUNER      TB_ORD_DTL      ORD_DTL_STS_CD  VARCHAR2                5          0 ODSC00               ODSC04                0.000000 FREQUENCY                      5 2026-01-03 20:45:56

22 rows selected.

Elapsed: 00:00:00.04

 

2. 소스 서버에서 tuner 스키마를 data pump로 export 시킴

 

--1번 노드 (oracle os user)

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ mkdir -pv /home/oracle/dmp
mkdir: created directory ‘/home/oracle/dmp’

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ ss

SQL*Plus: Release 12.2.0.1.0 Production on Mon Dec 29 23:13:27 2025

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<SYS@ORA12RF1>$ CREATE OR REPLACE DIRECTORY DMP_DIR AS '/home/oracle/dmp';

Directory created.

Elapsed: 00:00:00.04
[ol7ora12rf1]<
SYS@ORA12RF1>$ GRANT READ, WRITE ON DIRECTORY DMP_DIR TO TUNER;

Grant succeeded.

Elapsed: 00:00:00.02
[ol7ora12rf1]<
SYS@ORA12RF1>$ quit
Disconnected from Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$
expdp system/oracle \
DIRECTORY=DMP_DIR \
DUMPFILE=tuner_12c_full.dmp \
LOGFILE=exp_tuner_12c.log \
SCHEMAS=TUNER \
CONTENT=ALL \
CLUSTER=N \
METRICS=Y

...로그 생략
Dump file set for SYSTEM.SYS_EXPORT_SCHEMA_01 is:
  /home/oracle/dmp/tuner_12c_full.dmp
Job "SYSTEM"."SYS_EXPORT_SCHEMA_01" successfully completed at Sat Jan 3 22:20:01 2026 elapsed 0 00:01:08


[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ ls -l  /home/oracle/dmp/
total 8787444
-rw-r--r--. 1 oracle asmadmin      28131 Dec 29 23:15 exp_tuner_12c.log
-rw-r-----. 1 oracle asmadmin 8998301696 Dec 29 23:15 tuner_12c_full.dmp

 

3. 타켓 서버에서 user 및 테이블 스페이스 생성

 

--1번 노드 (oracle os user)

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Sat Jan 3 22:20:37 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$

----------------------------------------------------------------------------------------------------------------------------------------
--1. 사용자 계정 생성 및 테이블 스페이스 생성
----------------------------------------------------------------------------------------------------------------------------------------

DROP USER TUNER CASCADE;
CREATE USER TUNER IDENTIFIED BY "oracle";
GRANT RESOURCE, DBA, CONNECT TO TUNER;
ALTER USER TUNER ACCOUNT UNLOCK;

DROP TABLESPACE TUNER_DATA1 INCLUDING CONTENTS AND DATAFILES;
CREATE TABLESPACE TUNER_DATA1
DATAFILE '+DATA1' SIZE 12G
AUTOEXTEND ON NEXT 512M MAXSIZE UNLIMITED
;

DROP TABLESPACE TUNER_IDX1 INCLUDING CONTENTS AND DATAFILES;
CREATE TABLESPACE TUNER_IDX1
DATAFILE '+DATA1' SIZE 12G
AUTOEXTEND ON NEXT 512M MAXSIZE UNLIMITED
;

DROP TABLESPACE TUNER_TEMP INCLUDING CONTENTS AND DATAFILES;
CREATE TEMPORARY TABLESPACE TUNER_TEMP
TEMPFILE '+DATA1' SIZE 4G
AUTOEXTEND ON NEXT 100M MAXSIZE UNLIMITED
;

ALTER USER TUNER DEFAULT TABLESPACE TUNER_DATA1;
ALTER USER TUNER TEMPORARY TABLESPACE TUNER_TEMP;

[ol8ora19rf1]<SYS@ORA19RF1>$ quit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$


4. 타켓 서버에 소스 서버에서 export한 data pump 파일을 import 시키기

 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ mkdir -pv /home/oracle/dmp
mkdir: created directory '/home/oracle/dmp'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ cd /home/oracle/dmp
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/dmp]$ scp 192.168.240.11:/home/oracle/dmp/tuner_12c_full.dmp /home/oracle/dmp
oracle@192.168.240.11's password:
tuner_12c_full.dmp                   100% 8581MB 142.9MB/s   01:00


 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/dmp]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/dmp]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Mon Dec 29 23:36:50 2025
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$ CREATE OR REPLACE DIRECTORY DMP_DIR AS '/home/oracle/dmp';

Directory created.

Elapsed: 00:00:00.02
[ol8ora19rf1]<
SYS@ORA19RF1>$ GRANT READ, WRITE ON DIRECTORY DMP_DIR TO TUNER;

Grant succeeded.

Elapsed: 00:00:00.01
[ol8ora19rf1]<
SYS@ORA19RF1>$ quit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/dmp]$
impdp tuner/oracle \
DIRECTORY=DMP_DIR \
DUMPFILE=tuner_12c_full.dmp \
LOGFILE=imp_tuner_19c.log \
SCHEMAS=TUNER

...로그 생략


--통계 정보 확인 (타켓에서 확인, 소스 DB와 동일한 통계 정보인지 확인)
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ alias st
alias st='rlwrap sqlplus tuner/oracle'
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ st

SQL*Plus: Release 12.2.0.1.0 Production on Mon Dec 29 23:16:43 2025

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol8ora19rf1]<SYS@ORA19RF1>$

SET LINESIZE 200
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF

COL OWNER          FORMAT A10 HEADING 'Owner'
COL TABLE_NAME     FORMAT A15 HEADING 'Table Name'
COL NUM_ROWS       FORMAT 999,999,999 HEADING 'Num Rows'
COL BLOCKS         FORMAT 9,999,999 HEADING 'Blocks'
COL AVG_ROW_LEN    FORMAT 99,999 HEADING 'Avg Row|Len'
COL LAST_ANALYZED  FORMAT A20 HEADING 'Last Analyzed'
COL STATUS         FORMAT A8 HEADING 'Status'
COL PCT_FREE       FORMAT 999999 HEADING 'Pct|Free'
COL INI_TRANS      FORMAT 999999 HEADING 'Ini|Trns'
COL LOGGING        FORMAT A7 HEADING 'Logging'
COL DEGREE         FORMAT A10 HEADING 'Degree'
COL PARTITIONED    FORMAT A5  HEADING 'Part?'

SELECT A.OWNER
     , A.TABLE_NAME
     , A.NUM_ROWS
     , A.BLOCKS
     , A.AVG_ROW_LEN
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
     , A.STATUS
     , A.PCT_FREE
     , A.INI_TRANS
     , A.LOGGING
     , A.DEGREE
     , A.PARTITIONED
  FROM DBA_TABLES A
 WHERE A.TABLE_NAME IN ('TB_CUST', 'TB_CUST_ADDR', 'TB_DLVY', 'TB_ITEM', 'TB_ORD', 'TB_ORD_DTL')
   AND A.OWNER = 'TUNER'
 ORDER BY A.OWNER, A.TABLE_NAME
;

                                                   Avg Row                                   Pct     Ini
Owner      Table Name          Num Rows     Blocks     Len Last Analyzed        Status      Free    Trns Logging Degree     Part?
---------- --------------- ------------ ---------- ------- -------------------- -------- ------- ------- ------- ---------- -----
TUNER      TB_CUST            1,000,000     18,380     125 2026-01-03 20:44:54  VALID         10       1 YES              1 NO
TUNER      TB_CUST_ADDR       2,000,000     41,054     142 2026-01-03 20:44:56  VALID         10       1 YES              1 NO
TUNER      TB_DLVY           30,000,000    500,848     112 2026-01-03 20:45:20  VALID    (NULL)  (NULL)  (NULL)           1 YES
TUNER      TB_ITEM              100,000      2,300     156 2026-01-03 20:45:31  VALID         10       1 YES              1 NO
TUNER      TB_ORD            10,000,000     99,211      67 2026-01-03 20:45:37  VALID    (NULL)  (NULL)  (NULL)           1 YES
TUNER      TB_ORD_DTL        50,000,000    620,773      84 2026-01-03 20:46:10  VALID    (NULL)  (NULL)  (NULL)           1 YES

6 rows selected.

Elapsed: 00:00:00.02

 

[ol8ora19rf1]<SYS@ORA19RF1>$

SET LINESIZE 300
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF
SET LONG 2000          -- HIGH_VALUE(LONG 타입)가 잘리지 않도록 길이 설정

COL TABLE_OWNER       FORMAT A10              HEADING 'Owner'
COL TABLE_NAME        FORMAT A12              HEADING 'Table Name'
COL PARTITION_NAME    FORMAT A15              HEADING 'Part Name'
COL NUM_ROWS          FORMAT 999,999,999      HEADING 'Num Rows'
COL BLOCKS            FORMAT 9,999,999        HEADING 'Blocks'
COL AVG_ROW_LEN       FORMAT 99,999           HEADING 'Avg Row|Len'
COL LAST_ANALYZED     FORMAT A19              HEADING 'Last Analyzed'
COL SUBPARTITION_COUNT FORMAT 999             HEADING 'Sub|Cnt'
COL HIGH_VALUE        FORMAT A30              HEADING 'High Value' WRAPPED
COL PCT_FREE          FORMAT 999999           HEADING 'Pct|Free'
COL INI_TRANS         FORMAT 999999           HEADING 'Ini|Trns'
COL LOGGING           FORMAT A7               HEADING 'Logging'

SELECT A.TABLE_OWNER
     , A.TABLE_NAME
     , A.PARTITION_NAME
     , A.NUM_ROWS
     , A.BLOCKS
     , A.AVG_ROW_LEN
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
     , A.SUBPARTITION_COUNT
     , A.HIGH_VALUE
     , A.PCT_FREE
     , A.INI_TRANS
     , A.LOGGING
  FROM DBA_TAB_PARTITIONS A
 WHERE 1=1
   AND A.TABLE_NAME IN ('TB_ORD', 'TB_DLVY', 'TB_ORD_DTL')
   AND A.TABLE_OWNER = 'TUNER'
 ORDER BY A.TABLE_OWNER
        , A.TABLE_NAME
        , A.PARTITION_POSITION  -- 파티션의 논리적 순서대로 정렬
;

Owner      Table Name   Part Name           Num Rows     Blocks     Len Last Analyzed        Cnt High Value                        Free    Trns Logging
---------- ------------ --------------- ------------ ---------- ------- ------------------- ---- ------------------------------ ------- ------- -------
TUNER      TB_DLVY      P_BEF_2020                 0          0       0 2026-01-03 20:45:09    8 '20200101'                          10       1 YES
TUNER      TB_DLVY      P2020                      0          0       0 2026-01-03 20:44:56    8 '20210101'                          10       1 YES
TUNER      TB_DLVY      P2021              2,997,630     50,028     112 2026-01-03 20:44:58    8 '20220101'                          10       1 YES
TUNER      TB_DLVY      P2022              3,008,910     50,235     113 2026-01-03 20:44:59    8 '20230101'                          10       1 YES
TUNER      TB_DLVY      P2023              2,996,814     50,037     112 2026-01-03 20:45:00    8 '20240101'                          10       1 YES
TUNER      TB_DLVY      P2024              3,014,505     50,327     113 2026-01-03 20:45:01    8 '20250101'                          10       1 YES
TUNER      TB_DLVY      P2025              3,001,749     50,101     112 2026-01-03 20:45:03    8 '20260101'                          10       1 YES
TUNER      TB_DLVY      P2026              2,994,912     50,004     112 2026-01-03 20:45:04    8 '20270101'                          10       1 YES
TUNER      TB_DLVY      P2027              2,987,250     49,879     112 2026-01-03 20:45:05    8 '20280101'                          10       1 YES
TUNER      TB_DLVY      P2028              3,019,020     50,400     112 2026-01-03 20:45:07    8 '20290101'                          10       1 YES
TUNER      TB_DLVY      P2029              2,993,838     49,988     112 2026-01-03 20:45:08    8 '20300101'                          10       1 YES
TUNER      TB_DLVY      P2030              2,985,372     49,849     112 2026-01-03 20:45:09    8 '20310101'                          10       1 YES
TUNER      TB_DLVY      P_AFT_2030                 0          0       0 2026-01-03 20:45:09    8 MAXVALUE                            10       1 YES
TUNER      TB_ORD       P_BEF_2020                 0          0       0 2026-01-03 20:45:34    0 '20200101'                          10       1 YES
TUNER      TB_ORD       P2020                      0          0       0 2026-01-03 20:45:31    0 '20210101'                          10       1 YES
TUNER      TB_ORD       P2021                999,210      9,914      68 2026-01-03 20:45:31    0 '20220101'                          10       1 YES
TUNER      TB_ORD       P2022              1,002,970      9,950      67 2026-01-03 20:45:32    0 '20230101'                          10       1 YES
TUNER      TB_ORD       P2023                998,938      9,910      67 2026-01-03 20:45:32    0 '20240101'                          10       1 YES
TUNER      TB_ORD       P2024              1,004,835      9,969      68 2026-01-03 20:45:32    0 '20250101'                          10       1 YES
TUNER      TB_ORD       P2025              1,000,583      9,927      67 2026-01-03 20:45:33    0 '20260101'                          10       1 YES
TUNER      TB_ORD       P2026                998,304      9,906      68 2026-01-03 20:45:33    0 '20270101'                          10       1 YES
TUNER      TB_ORD       P2027                995,750      9,879      68 2026-01-03 20:45:33    0 '20280101'                          10       1 YES
TUNER      TB_ORD       P2028              1,006,340      9,983      67 2026-01-03 20:45:34    0 '20290101'                          10       1 YES
TUNER      TB_ORD       P2029                997,946      9,900      67 2026-01-03 20:45:34    0 '20300101'                          10       1 YES
TUNER      TB_ORD       P2030                995,124      9,873      68 2026-01-03 20:45:34    0 '20310101'                          10       1 YES
TUNER      TB_ORD       P_AFT_2030                 0          0       0 2026-01-03 20:45:34    0 MAXVALUE                            10       1 YES
TUNER      TB_ORD_DTL   P_BEF_2020                 0          0       0 2026-01-03 20:45:56    8 '20200101'                          10       1 YES
TUNER      TB_ORD_DTL   P2020                      0          0       0 2026-01-03 20:45:39    8 '20210101'                          10       1 YES
TUNER      TB_ORD_DTL   P2021              4,996,050     62,027      83 2026-01-03 20:45:41    8 '20220101'                          10       1 YES
TUNER      TB_ORD_DTL   P2022              5,014,850     62,260      84 2026-01-03 20:45:43    8 '20230101'                          10       1 YES
TUNER      TB_ORD_DTL   P2023              4,994,690     62,014      84 2026-01-03 20:45:44    8 '20240101'                          10       1 YES
TUNER      TB_ORD_DTL   P2024              5,024,175     62,378      83 2026-01-03 20:45:46    8 '20250101'                          10       1 YES
TUNER      TB_ORD_DTL   P2025              5,002,915     62,113      84 2026-01-03 20:45:47    8 '20260101'                          10       1 YES
TUNER      TB_ORD_DTL   P2026              4,991,520     61,973      84 2026-01-03 20:45:49    8 '20270101'                          10       1 YES
TUNER      TB_ORD_DTL   P2027              4,978,750     61,816      83 2026-01-03 20:45:51    8 '20280101'                          10       1 YES
TUNER      TB_ORD_DTL   P2028              5,031,700     62,464      83 2026-01-03 20:45:52    8 '20290101'                          10       1 YES
TUNER      TB_ORD_DTL   P2029              4,989,730     61,950      83 2026-01-03 20:45:54    8 '20300101'                          10       1 YES
TUNER      TB_ORD_DTL   P2030              4,975,620     61,778      83 2026-01-03 20:45:56    8 '20310101'                          10       1 YES
TUNER      TB_ORD_DTL   P_AFT_2030                 0          0       0 2026-01-03 20:45:56    8 MAXVALUE                            10       1 YES

39 rows selected.

Elapsed: 00:00:00.02

 

[ol8ora19rf1]<SYS@ORA19RF1>$
SET LINESIZE 300
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF

COL TABLE_OWNER       FORMAT A10              HEADING 'Owner'
COL TABLE_NAME        FORMAT A12              HEADING 'Table Name'
COL PARTITION_NAME    FORMAT A10              HEADING 'Part Name'
COL SUBPARTITION_NAME FORMAT A20              HEADING 'Subpart Name'
COL NUM_ROWS          FORMAT 999,999,999      HEADING 'Num Rows'
COL BLOCKS            FORMAT 9,999,999        HEADING 'Blocks'
COL AVG_ROW_LEN       FORMAT 99,999           HEADING 'Avg Row|Len'
COL COMPRESSION       FORMAT A10              HEADING 'Compress'
COL LAST_ANALYZED     FORMAT A19              HEADING 'Last Analyzed'
COL PCT_FREE          FORMAT 999999           HEADING 'Pct|Free'
COL INI_TRANS         FORMAT 999999           HEADING 'Ini|Trns'
COL LOGGING           FORMAT A7               HEADING 'Logging'

SELECT A.TABLE_OWNER
     , A.TABLE_NAME
     , A.PARTITION_NAME
     , A.SUBPARTITION_NAME
     , A.NUM_ROWS
     , A.BLOCKS
     , A.AVG_ROW_LEN
     , A.COMPRESSION
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
     , A.PCT_FREE
     , A.INI_TRANS
     , A.LOGGING
  FROM DBA_TAB_SUBPARTITIONS A
 WHERE A.TABLE_NAME IN ('TB_DLVY', 'TB_ORD_DTL')
   AND A.PARTITION_NAME = 'P2024'
   AND A.TABLE_OWNER = 'TUNER'
 ORDER BY A.TABLE_NAME
        , A.SUBPARTITION_POSITION  -- 서브파티션의 논리적 순서 정렬
;


Owner      Table Name   Part Name  Subpart Name             Num Rows     Blocks     Len Compress   Last Analyzed          Free    Trns Logging
---------- ------------ ---------- -------------------- ------------ ---------- ------- ---------- ------------------- ------- ------- -------
TUNER      TB_DLVY      P2024      SYS_SUBP2525         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2526         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2527         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2528         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2529         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2530         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2531         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_DLVY      P2024      SYS_SUBP2532         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2629         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2630         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2631         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2632         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2633         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2634         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2635         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES
TUNER      TB_ORD_DTL   P2024      SYS_SUBP2636         (NULL)       (NULL)     (NULL)  DISABLED   (NULL)                   10       1 YES

16 rows selected.

Elapsed: 00:00:00.02


--> 서브 파티션 테이블 통계는 수집되지 않은 상태임

[ol8ora19rf1]<SYS@ORA19RF1>$
SET LINESIZE 300
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF

COL TABLE_OWNER       FORMAT A10              HEADING 'Owner'
COL TABLE_NAME        FORMAT A15              HEADING 'Table Name'
COL INDEX_NAME        FORMAT A20              HEADING 'Index Name'
COL BLEVEL            FORMAT 99               HEADING 'BLv'
COL LEAF_BLOCKS       FORMAT 9,999,999        HEADING 'Leaf Blks'
COL DISTINCT_KEYS     FORMAT 999,999,999      HEADING 'Dst Keys'
COL CLUSTERING_FACTOR FORMAT 999,999,999      HEADING 'Clust Fctr'
COL NUM_ROWS          FORMAT 999,999,999      HEADING 'Num Rows'
COL UNIQUENESS        FORMAT A9               HEADING 'Unique'
COL INI_TRANS         FORMAT 999999               HEADING 'Ini|Trns'
COL PCT_FREE          FORMAT 999999               HEADING 'Pct|Free'
COL LOGGING           FORMAT A7               HEADING 'Logging'
COL STATUS            FORMAT A8               HEADING 'Status'
COL LAST_ANALYZED     FORMAT A19              HEADING 'Last Analyzed'

SELECT A.TABLE_OWNER
     , A.TABLE_NAME
     , A.INDEX_NAME
     , A.BLEVEL
     , A.LEAF_BLOCKS
     , A.DISTINCT_KEYS
     , A.CLUSTERING_FACTOR
     , A.NUM_ROWS
     , A.UNIQUENESS
     , A.INI_TRANS
     , A.PCT_FREE
     , A.LOGGING
     , A.STATUS
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
  FROM DBA_INDEXES A
 WHERE 1=1
   AND A.TABLE_OWNER = 'TUNER'
   AND A.TABLE_NAME IN ('TB_CUST', 'TB_CUST_ADDR', 'TB_DLVY', 'TB_ITEM', 'TB_ORD', 'TB_ORD_DTL')
 ORDER BY A.TABLE_NAME, A.INDEX_NAME
;

                                                                                                                    Ini     Pct
Owner      Table Name      Index Name           BLv  Leaf Blks     Dst Keys   Clust Fctr     Num Rows Unique       Trns    Free Logging Status   Last Analyzed
---------- --------------- -------------------- --- ---------- ------------ ------------ ------------ --------- ------- ------- ------- -------- -------------------
TUNER      TB_CUST         IDX_TB_CUST_01         2      2,513            5       91,069    1,000,000 NONUNIQUE       2      10 YES     VALID    2026-01-03 20:44:55
TUNER      TB_CUST         IDX_TB_CUST_02         2      2,787       21,792      998,770    1,000,000 NONUNIQUE       2      10 YES     VALID    2026-01-03 20:44:55
TUNER      TB_CUST         IDX_TB_CUST_03         2      3,775      109,490      999,787    1,000,000 NONUNIQUE       2      10 YES     VALID    2026-01-03 20:44:56
TUNER      TB_CUST         PK_TB_CUST             2      2,934    1,000,000       18,236    1,000,000 UNIQUE          2      10 YES     VALID    2026-01-03 20:44:55
TUNER      TB_CUST_ADDR    PK_TB_CUST_ADDR        2      6,742    2,015,914    2,015,914    2,015,914 UNIQUE          2      10 YES     VALID    2026-01-03 20:44:56
TUNER      TB_DLVY         IDX_TB_DLVY_01         2    105,438    1,004,664    1,597,897   30,255,443 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:24
TUNER      TB_DLVY         IDX_TB_DLVY_02         2    138,053   29,783,888   29,796,132   29,957,441 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:27
TUNER      TB_DLVY         IDX_TB_DLVY_03         2    166,040   30,541,059   10,117,176   30,541,059 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:31
TUNER      TB_DLVY         PK_TB_DLVY             2    165,456   30,407,119    1,647,410   30,407,119 UNIQUE    (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:22
TUNER      TB_ITEM         PK_TB_ITEM             1        294      100,000        2,256      100,000 UNIQUE          2      10 YES     VALID    2026-01-03 20:45:31
TUNER      TB_ORD          IDX_TB_ORD_01          2     25,525            4      421,877   10,159,148 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:39
TUNER      TB_ORD          PK_TB_ORD              2     49,598    9,866,518    9,865,668    9,866,518 UNIQUE    (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:45:38
TUNER      TB_ORD_DTL      IDX_TB_ORD_DTL_01      2    158,369       99,888   49,970,416   51,628,286 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:46:15
TUNER      TB_ORD_DTL      IDX_TB_ORD_DTL_02      2    120,606            5    3,047,288   48,001,055 NONUNIQUE (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:46:17
TUNER      TB_ORD_DTL      PK_TB_ORD_DTL          2    263,745   48,529,155   48,157,051   48,529,155 UNIQUE    (NULL)  (NULL)  (NULL)  N/A      2026-01-03 20:46:13

15 rows selected.

Elapsed: 00:00:00.01


--CLUSTERING_FACTOR:
--인덱스 정렬 순서와 실제 테이블 데이터 블록의 저장 순서가 얼마나 일치하는지를 나타내는 수치입니다.
--Good: 값이 BLOCKS(테이블 블록 수)에 가까울수록 인덱스 스캔 시 테이블 랜덤 액세스가 적게 발생하여 성능이 좋습니다.
--Bad: 값이 NUM_ROWS(테이블 행 수)에 가까울수록 인덱스를 경유한 테이블 액세스 시 I/O 부하가 큽니다. 옵티마이저는 이 값이 높으면 인덱스 스캔 대신 Full Table Scan을 선택할 확률이 높습니다.

[ol8ora19rf1]<SYS@ORA19RF1>$

SET LINESIZE 300
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF
SET LONG 4000          -- HIGH_VALUE(LONG 타입) 데이터가 잘리지 않도록 설정

COL INDEX_OWNER       FORMAT A10              HEADING 'Owner'
COL INDEX_NAME        FORMAT A20              HEADING 'Index Name'
COL PARTITION_NAME    FORMAT A15              HEADING 'Part Name'
COL BLEVEL            FORMAT 99               HEADING 'BLv'
COL LEAF_BLOCKS       FORMAT 9,999,999        HEADING 'Leaf Blks'
COL DISTINCT_KEYS     FORMAT 9,999,999,999    HEADING 'Dst Keys'
COL NUM_ROWS          FORMAT 9,999,999,999    HEADING 'Num Rows'
COL CLUSTERING_FACTOR FORMAT 9,999,999,999    HEADING 'Clust Fctr'
COL COMPOSITE         FORMAT A5               HEADING 'Comp?'
COL SUBPARTITION_COUNT FORMAT 999             HEADING 'Sub|Cnt'
COL HIGH_VALUE        FORMAT A30              HEADING 'High Value' WRAPPED
COL PARTITION_POSITION FORMAT 999             HEADING 'Pos'
COL PCT_FREE          FORMAT 999999           HEADING 'Pct|Free'
COL INI_TRANS         FORMAT 999999           HEADING 'Ini|Trns'
COL GLOBAL_STATS      FORMAT A5               HEADING 'Gbl|Sts'
COL LAST_ANALYZED     FORMAT A19              HEADING 'Last Analyzed'

SELECT A.INDEX_OWNER
     , A.INDEX_NAME
     , A.PARTITION_NAME
     , A.BLEVEL
     , A.LEAF_BLOCKS
     , A.DISTINCT_KEYS
     , A.NUM_ROWS
     , A.CLUSTERING_FACTOR
     , A.COMPOSITE
     , A.SUBPARTITION_COUNT
     , A.HIGH_VALUE
     , A.PARTITION_POSITION
     , A.PCT_FREE
     , A.INI_TRANS
     , A.GLOBAL_STATS
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
  FROM DBA_IND_PARTITIONS A
 WHERE 1=1
   AND A.INDEX_OWNER = 'TUNER'
   AND A.INDEX_NAME IN ('IDX_TB_ORD_DTL_01', 'IDX_TB_ORD_DTL_02', 'PK_TB_ORD_DTL')
 ORDER BY A.INDEX_NAME, A.PARTITION_POSITION
;

                                                                                                                   Sub                                         Pct     Ini Gbl
Owner      Index Name           Part Name       BLv  Leaf Blks       Dst Keys       Num Rows     Clust Fctr Comp?  Cnt High Value                      Pos    Free    Trns Sts   Last Analyzed
---------- -------------------- --------------- --- ---------- -------------- -------------- -------------- ----- ---- ------------------------------ ---- ------- ------- ----- -------------------
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020        0          0              0              0              0 YES      8 '20200101'                        1      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2020             0          0              0              0              0 YES      8 '20210101'                        2      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2021             2     15,178         99,888      4,942,453      4,786,182 YES      8 '20220101'                        3      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2022             2     15,440         99,888      5,032,524      4,870,969 YES      8 '20230101'                        4      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2023             2     15,000         99,888      4,889,906      4,734,841 YES      8 '20240101'                        5      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2024             2     15,558         99,888      5,071,116      4,907,648 YES      8 '20250101'                        6      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2025             2     15,838         99,888      5,162,460      4,997,337 YES      8 '20260101'                        7      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2026             2     14,814         99,888      4,829,396      4,676,751 YES      8 '20270101'                        8      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2027             2     15,732         99,888      5,128,757      4,963,062 YES      8 '20280101'                        9      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2028             2     15,120         99,888      4,929,207      4,772,611 YES      8 '20290101'                       10      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2029             2     15,430         99,888      5,030,249      4,869,430 YES      8 '20300101'                       11      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P2030             2     15,334         99,888      4,993,375      4,836,662 YES      8 '20310101'                       12      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_01    P_AFT_2030        0          0              0              0              0 YES      8 MAXVALUE                         13      10       2 YES   2026-01-03 20:46:15
TUNER      IDX_TB_ORD_DTL_02    P_BEF_2020        0          0              0              0              0 YES      8 '20200101'                        1      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2020             0          0              0              0              0 YES      8 '20210101'                        2      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2021             2     12,947              5      5,150,084        325,524 YES      8 '20220101'                        3      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2022             2     12,800              5      5,090,826        321,552 YES      8 '20230101'                        4      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2023             2     12,955              5      5,151,462        325,816 YES      8 '20240101'                        5      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2024             2     12,399              5      4,930,427        312,272 YES      8 '20250101'                        6      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2025             2     12,521              5      4,983,521        316,340 YES      8 '20260101'                        7      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2026             2     12,764              5      5,072,296        320,685 YES      8 '20270101'                        8      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2027             2     12,344              5      4,909,755        311,387 YES      8 '20280101'                        9      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2028             2     13,218              5      5,260,703        332,732 YES      8 '20290101'                       10      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2029             2     12,787              5      5,085,071        322,324 YES      8 '20300101'                       11      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P2030             2     12,269              5      4,883,146        308,609 YES      8 '20310101'                       12      10       2 YES   2026-01-03 20:46:17
TUNER      IDX_TB_ORD_DTL_02    P_AFT_2030        0          0              0              0              0 YES      8 MAXVALUE                         13      10       2 YES   2026-01-03 20:46:17
TUNER      PK_TB_ORD_DTL        P_BEF_2020        0          0              0              0              0 YES      8 '20200101'                        1      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2020             0          0              0              0              0 YES      8 '20210101'                        2      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2021             2     26,861      4,941,518      4,941,518      4,903,128 YES      8 '20220101'                        3      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2022             2     26,573      4,889,315      4,889,315      4,850,683 YES      8 '20230101'                        4      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2023             2     26,708      4,914,309      4,914,309      4,876,245 YES      8 '20240101'                        5      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2024             2     27,722      5,099,702      5,099,702      5,060,433 YES      8 '20250101'                        6      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2025             2     27,005      4,966,323      4,966,323      4,927,624 YES      8 '20260101'                        7      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2026             2     28,387      5,223,181      5,223,181      5,183,178 YES      8 '20270101'                        8      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2027             2     26,728      4,917,946      4,917,946      4,881,270 YES      8 '20280101'                        9      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2028             2     27,371      5,035,855      5,035,855      4,997,237 YES      8 '20290101'                       10      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2029             2     27,572      5,069,253      5,069,253      5,030,119 YES      8 '20300101'                       11      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P2030             2     27,083      4,983,271      4,983,271      4,945,312 YES      8 '20310101'                       12      10       2 YES   2026-01-03 20:46:13
TUNER      PK_TB_ORD_DTL        P_AFT_2030        0          0              0              0              0 YES      8 MAXVALUE                         13      10       2 YES   2026-01-03 20:46:13

39 rows selected.

Elapsed: 00:00:00.02


[ol8ora19rf1]<SYS@ORA19RF1>$

SET LINESIZE 300
SET PAGESIZE 100
SET TRIMOUT ON
SET TRIMSPOOL ON
SET VERIFY OFF

COL INDEX_OWNER       FORMAT A10              HEADING 'Owner'
COL INDEX_NAME        FORMAT A20              HEADING 'Index Name'
COL PARTITION_NAME    FORMAT A10              HEADING 'Part Name'
COL SUBPARTITION_NAME FORMAT A20              HEADING 'Subpart Name'
COL BLEVEL            FORMAT 99               HEADING 'BLv'
COL LEAF_BLOCKS       FORMAT 9,999,999        HEADING 'Leaf Blks'
COL NUM_ROWS          FORMAT 9,999,999,999    HEADING 'Num Rows'
COL CLUSTERING_FACTOR FORMAT 9,999,999,999    HEADING 'Clust Fctr'
COL PARTITION_POSITION FORMAT 999             HEADING 'P_Pos'
COL SUBPARTITION_POSITION FORMAT 999          HEADING 'S_Pos'
COL STATUS            FORMAT A8               HEADING 'Status'
COL PCT_FREE          FORMAT 999999           HEADING 'Pct|Free'
COL INI_TRANS         FORMAT 999999               HEADING 'Ini|Trns'
COL LAST_ANALYZED     FORMAT A19              HEADING 'Last Analyzed'

SELECT A.INDEX_OWNER
     , A.INDEX_NAME
     , A.PARTITION_NAME
     , A.SUBPARTITION_NAME
     , A.BLEVEL
     , A.LEAF_BLOCKS
     , A.NUM_ROWS
     , A.CLUSTERING_FACTOR
     , A.PARTITION_POSITION
     , A.SUBPARTITION_POSITION
     , A.STATUS
     , A.PCT_FREE
     , A.INI_TRANS
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
  FROM DBA_IND_SUBPARTITIONS A
 WHERE 1=1
   AND A.INDEX_OWNER = 'TUNER'
   AND A.INDEX_NAME IN ('IDX_TB_ORD_DTL_01', 'IDX_TB_ORD_DTL_02', 'PK_TB_ORD_DTL')
   AND ROWNUM <= 15  -- 샘플링 제한
 ORDER BY A.INDEX_NAME
        , A.PARTITION_NAME
        , A.SUBPARTITION_POSITION
;

                                                                                                                                      Pct     Ini
Owner      Index Name           Part Name  Subpart Name         BLv  Leaf Blks       Num Rows     Clust Fctr P_Pos S_Pos Status      Free    Trns Last Analyzed
---------- -------------------- ---------- -------------------- --- ---------- -------------- -------------- ----- ----- -------- ------- ------- -------------------
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2597           0          0              0              0     2     1 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2598           0          0              0              0     2     2 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2599           0          0              0              0     2     3 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2600           0          0              0              0     2     4 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2602           0          0              0              0     2     6 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2603           0          0              0              0     2     7 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P2020      SYS_SUBP2604           0          0              0              0     2     8 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2589           0          0              0              0     1     1 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2590           0          0              0              0     1     2 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2591           0          0              0              0     1     3 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2592           0          0              0              0     1     4 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2593           0          0              0              0     1     5 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2594           0          0              0              0     1     6 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2595           0          0              0              0     1     7 USABLE        10       2 2026-01-03 20:41:52
TUNER      IDX_TB_ORD_DTL_01    P_BEF_2020 SYS_SUBP2596           0          0              0              0     1     8 USABLE        10       2 2026-01-03 20:41:52


15 rows selected.

Elapsed: 00:00:00.03

 

[ol8ora19rf1]<SYS@ORA19RF1>$
SET LINESIZE 300
SET PAGESIZE 100
COL OWNER          FORMAT A10              HEADING 'Owner'
COL TABLE_NAME     FORMAT A15              HEADING 'Table Name'
COL COLUMN_NAME    FORMAT A15              HEADING 'Column Name'
COL DATA_TYPE      FORMAT A10              HEADING 'Type'
COL NUM_DISTINCT   FORMAT 9,999,999,999    HEADING 'NDV'
COL LOW_VALUE      FORMAT A20              HEADING 'Low Value'
COL HIGH_VALUE     FORMAT A20              HEADING 'High Value'
COL DENSITY        FORMAT 0.999999         HEADING 'Density'
COL HISTOGRAM      FORMAT A20              HEADING 'HISTOGRAM'
COL NUM_NULLS      FORMAT 9,999,999        HEADING 'Num Nulls'
COL LAST_ANALYZED  FORMAT A19              HEADING 'Last Analyzed'

-- WITH FUNCTION과 SELECT를 한 덩어리로 묶어서 실행
WITH FUNCTION Convert_Raw(p_raw RAW, p_type VARCHAR2) RETURN VARCHAR2 IS
    v_num  NUMBER;
    v_date DATE;
    v_char VARCHAR2(4000);
BEGIN
    IF p_raw IS NULL THEN RETURN NULL; END IF;

    -- 데이터 타입에 따라 변환 로직 분기
    IF p_type IN ('NUMBER', 'FLOAT', 'BINARY_FLOAT', 'BINARY_DOUBLE') THEN
        DBMS_STATS.CONVERT_RAW_VALUE(p_raw, v_num);
        RETURN TO_CHAR(v_num);
    ELSIF p_type = 'DATE' THEN
        DBMS_STATS.CONVERT_RAW_VALUE(p_raw, v_date);
        RETURN TO_CHAR(v_date, 'YYYY-MM-DD HH24:MI:SS');
    ELSIF p_type LIKE '%CHAR%' THEN -- CHAR, VARCHAR2, NVARCHAR2
        DBMS_STATS.CONVERT_RAW_VALUE(p_raw, v_char);
        RETURN SUBSTR(v_char, 1, 20); -- 화면 출력을 위해 길이 제한
    ELSE
        RETURN 'RAW Type'; -- 기타 타입은 변환하지 않음
    END IF;
EXCEPTION
    WHEN OTHERS THEN RETURN 'Conv Error';
END;
SELECT A.OWNER
     , A.TABLE_NAME
     , A.COLUMN_NAME
     , B.DATA_TYPE
     , A.NUM_DISTINCT
     , A.NUM_NULLS
     , Convert_Raw(A.LOW_VALUE, B.DATA_TYPE)  AS LOW_VALUE
     , Convert_Raw(A.HIGH_VALUE, B.DATA_TYPE) AS HIGH_VALUE
     , A.DENSITY
     , A.HISTOGRAM
     , A.NUM_BUCKETS
     , TO_CHAR(A.LAST_ANALYZED, 'YYYY-MM-DD HH24:MI:SS') AS LAST_ANALYZED
  FROM DBA_TAB_COL_STATISTICS A
     , DBA_TAB_COLUMNS B
 WHERE 1=1
   AND A.OWNER = 'TUNER'
   -- JOIN 조건: 통계 뷰에는 데이터 타입이 없으므로 컬럼 뷰와 조인 필수
   AND A.OWNER = B.OWNER
   AND A.TABLE_NAME = B.TABLE_NAME
   AND A.COLUMN_NAME = B.COLUMN_NAME
 ORDER BY A.OWNER
        , A.TABLE_NAME
        , A.COLUMN_NAME
;
/

Owner      Table Name      Column Name     Type                  NDV  Num Nulls Low Value            High Value             Density HISTOGRAM            NUM_BUCKETS Last Analyzed
---------- --------------- --------------- ---------- -------------- ---------- -------------------- -------------------- --------- -------------------- ----------- -------------------
TUNER      TB_CUST         BRTHDY          VARCHAR2           21,792          0 19510120             20110104              0.000046 HYBRID                        75 2026-01-03 20:44:54
TUNER      TB_CUST         CUST_NO         VARCHAR2        1,000,000          0 C000000001           C001000000            0.000001 HYBRID                        75 2026-01-03 20:44:54
TUNER      TB_CUST         CUST_STS_CD     VARCHAR2                5          0 CSC000               CSC004                0.000001 FREQUENCY                      5 2026-01-03 20:44:54
TUNER      TB_CUST_ADDR    ADDR_SN         NUMBER                  2          0 1                    2                     0.000000 FREQUENCY                      2 2026-01-03 20:44:56
TUNER      TB_CUST_ADDR    CUST_NO         VARCHAR2          995,520          0 C000000001           C001000000            0.000001 HYBRID                        75 2026-01-03 20:44:56
TUNER      TB_DLVY         ADDR_SN         NUMBER                  2          0 1                    2                     0.000000 FREQUENCY                      2 2026-01-03 20:45:09
TUNER      TB_DLVY         CUST_NO         VARCHAR2          995,520          0 C000000001           C001000000            0.000001 HYBRID                        75 2026-01-03 20:45:09
TUNER      TB_DLVY         DLVY_DT         VARCHAR2       28,493,824          0 20210102022303       20310109220026        0.000000 HYBRID                        75 2026-01-03 20:45:09
TUNER      TB_DLVY         DLVY_SN         NUMBER                  3          0 1                    3                     0.000000 FREQUENCY                      3 2026-01-03 20:45:09
TUNER      TB_DLVY         DLVY_STS_CD     VARCHAR2                5          0 DSC000               DSC004                0.000000 FREQUENCY                      5 2026-01-03 20:45:09
TUNER      TB_DLVY         HDRY_CMPNY_CD   VARCHAR2               20          0 HCC000               HCC019                0.000000 FREQUENCY                     20 2026-01-03 20:45:09
TUNER      TB_DLVY         ORD_DT          VARCHAR2        9,689,088          0 20210102000819       20301231000626        0.000000 HYBRID                        75 2026-01-03 20:45:09
TUNER      TB_DLVY         WAYBIL_NO       VARCHAR2       30,000,000          0 00000000000000000001 00000000000030000000  0.000000 HYBRID                        75 2026-01-03 20:45:09
TUNER      TB_ITEM         ITEM_NO         VARCHAR2          100,000          0 I000000001           I000100000            0.000010 HYBRID                        75 2026-01-03 20:45:31
TUNER      TB_ORD          CUST_NO         VARCHAR2          995,520          0 C000000001           C001000000            0.000001 HYBRID                        75 2026-01-03 20:45:34
TUNER      TB_ORD          ORD_DT          VARCHAR2        9,689,088          0 20210102000819       20301231000626        0.000000 HYBRID                        75 2026-01-03 20:45:34
TUNER      TB_ORD          ORD_STS_CD      VARCHAR2                4          0 OSC001               OSC004                0.000000 FREQUENCY                      4 2026-01-03 20:45:34
TUNER      TB_ORD_DTL      CUST_NO         VARCHAR2          995,520          0 C000000001           C001000000            0.000001 HYBRID                        75 2026-01-03 20:45:56
TUNER      TB_ORD_DTL      ITEM_NO         VARCHAR2           99,888          0 I000000001           I000099999            0.000010 HYBRID                        75 2026-01-03 20:45:56
TUNER      TB_ORD_DTL      ORD_DT          VARCHAR2        9,689,088          0 20210102000819       20301231000626        0.000000 HYBRID                        75 2026-01-03 20:45:56
TUNER      TB_ORD_DTL      ORD_DTL_SN      NUMBER                  5          0 1                    5                     0.000000 FREQUENCY                      5 2026-01-03 20:45:56
TUNER      TB_ORD_DTL      ORD_DTL_STS_CD  VARCHAR2                5          0 ODSC00               ODSC04                0.000000 FREQUENCY                      5 2026-01-03 20:45:56

22 rows selected.

Elapsed: 00:00:00.50

 

5. 소스에서 실행 시킬 부하 발생용 스크립트 생성

 

--1번 노드 (oracle os user)

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ mkdir -pv /home/oracle/db_replay_load

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ vi /home/oracle/db_replay_load/run_db_replay_load.sh

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle/db_replay_load]$ cat run_db_replay_load.sh
#!/bin/bash

# ------------------------------------------------------------------------
# [제목] Oracle 12cR2 부하 발생 및 SQL 실행 스크립트
# [작성일] 2025-12-29
# [작성자] kolee
# [설명]
# ------------------------------------------------------------------------

# 환경 변수 설정 (필요 시 ORACLE_HOME, ORACLE_SID 등을 주석 해제하여 설정)
#export ORACLE_SID=ORA12RF1
export ORACLE_HOME=/u01/app/oracle/product/12c/db_1

# 로그 파일 정의
LOG_FILE="/home/oracle/db_replay_load/load_gen_output_$(date +%Y%m%d_%H).log"

echo "Load Generation Started at $(date)"
echo "Log File: ${LOG_FILE}"

sqlplus -s tuner/oracle <<EOF
SET LINESIZE 200
SET PAGESIZE 1000
SET TIMING ON
SET TIME ON
SET ECHO ON
SET FEEDBACK ON
SET TRIMOUT ON
SET TAB OFF
SET SERVEROUTPUT ON
SET AUTOTRACE TRACEONLY STATISTICS

-- Spool 시작
SPOOL ${LOG_FILE} APPEND

PROMPT =========================================================================
PROMPT 1. SQL DB_REPLAY_TEST_01 Execution
PROMPT =========================================================================

VARIABLE V_BEGIN_ORD_DT VARCHAR2(32);
EXEC :V_BEGIN_ORD_DT := '20240101000000';
VARIABLE V_END_ORD_DT VARCHAR2(32);
EXEC :V_END_ORD_DT := '20240131235959';
VARIABLE V_ORD_TOT_AMT NUMBER;
EXEC :V_ORD_TOT_AMT := 100000;

SELECT /*+ LEADING(A B) USE_HASH(B) NO_MERGE(B) NO_PUSH_PRED(B) */ /* DB_REPLAY_TEST_01_SELECT_01 */
       1 AS DUMMY
     , A.CUST_NO
     , A.ORD_DT
     , A.ORD_TOT_AMT
     , A.ORD_STS_CD
     , B.ADDR_LIST
  FROM TB_ORD A
     , (SELECT 1 AS DUMMY
             , M.CUST_NO
             , M.ORD_DT
             , LISTAGG(M.DLVY_SN || '^' || N.ADDR, ',')
                       WITHIN GROUP (ORDER BY M.DLVY_SN) AS ADDR_LIST
          FROM TB_CUST L
             , TB_CUST_ADDR N
             , TB_DLVY M
         WHERE 1=1
           AND L.CUST_NO = N.CUST_NO
           AND M.CUST_NO = N.CUST_NO
           AND M.ADDR_SN = N.ADDR_SN
           AND M.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
         GROUP BY M.CUST_NO, M.ORD_DT) B
 WHERE 1=1
   AND A.CUST_NO = B.CUST_NO
   AND A.ORD_DT = B.ORD_DT
   AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
   AND A.ORD_TOT_AMT >= :V_ORD_TOT_AMT
 ORDER BY A.CUST_NO, A.ORD_DT
;


UPDATE /* DB_REPLAY_TEST_01_UPDATE_01 */ TB_ORD T
   SET T.UPDT_ID = 'DBRT_01_UPDATE_01'
     , T.UPDT_DT = TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS')
 WHERE (T.CUST_NO, T.ORD_DT) IN
                              (
                                 SELECT /*+ LEADING(A B) USE_HASH(B) NO_MERGE(B) NO_PUSH_PRED(B) */
                                        A.CUST_NO
                                      , A.ORD_DT
                                   FROM TB_ORD A
                                      , (SELECT 1 AS DUMMY
                                              , M.CUST_NO
                                              , M.ORD_DT
                                              , LISTAGG(M.DLVY_SN || '^' || N.ADDR, ',')
                                                        WITHIN GROUP (ORDER BY M.DLVY_SN) AS ADDR_LIST
                                           FROM TB_CUST L
                                              , TB_CUST_ADDR N
                                              , TB_DLVY M
                                          WHERE 1=1
                                            AND L.CUST_NO = N.CUST_NO
                                            AND M.CUST_NO = N.CUST_NO
                                            AND M.ADDR_SN = N.ADDR_SN
                                            AND M.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
                                          GROUP BY M.CUST_NO, M.ORD_DT) B
                                  WHERE 1=1
                                    AND A.CUST_NO = B.CUST_NO
                                    AND A.ORD_DT = B.ORD_DT
                                    AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
                                    AND A.ORD_TOT_AMT >= :V_ORD_TOT_AMT
         AND ROWNUM <= 100
                              )
;

COMMIT;

UPDATE /* DB_REPLAY_TEST_01_UPDATE_02 */ TB_ORD T
   SET T.UPDT_ID = NULL
     , T.UPDT_DT = NULL
 WHERE (T.CUST_NO, T.ORD_DT) IN
                              (
                                 SELECT /*+ LEADING(A B) USE_HASH(B) NO_MERGE(B) NO_PUSH_PRED(B) */
                                        A.CUST_NO
                                      , A.ORD_DT
                                   FROM TB_ORD A
                                      , (SELECT 1 AS DUMMY
                                              , M.CUST_NO
                                              , M.ORD_DT
                                              , LISTAGG(M.DLVY_SN || '^' || N.ADDR, ',')
                                                        WITHIN GROUP (ORDER BY M.DLVY_SN) AS ADDR_LIST
                                           FROM TB_CUST L
                                              , TB_CUST_ADDR N
                                              , TB_DLVY M
                                          WHERE 1=1
                                            AND L.CUST_NO = N.CUST_NO
                                            AND M.CUST_NO = N.CUST_NO
                                            AND M.ADDR_SN = N.ADDR_SN
                                            AND M.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
                                          GROUP BY M.CUST_NO, M.ORD_DT) B
                                  WHERE 1=1
                                    AND A.CUST_NO = B.CUST_NO
                                    AND A.ORD_DT = B.ORD_DT
                                    AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
                                    AND A.ORD_TOT_AMT >= :V_ORD_TOT_AMT
                              )
   AND T.UPDT_ID IS NOT NULL
   AND T.UPDT_DT IS NOT NULL
;

COMMIT;

PROMPT =========================================================================
PROMPT 2. SQL DB_REPLAY_TEST_02 Execution
PROMPT =========================================================================

VARIABLE V_BEGIN_ORD_DT VARCHAR2(32);
EXEC :V_BEGIN_ORD_DT := '20240101000000';
VARIABLE V_END_ORD_DT VARCHAR2(32);
EXEC :V_END_ORD_DT := '20240131235959';
VARIABLE V_ITEM_NM VARCHAR2(500);
EXEC :V_ITEM_NM := 'ZA';

SELECT /*+ NO_MERGE(B) LEADING(B) USE_HASH(A) */ /* DB_REPLAY_TEST_02_SELECT_01 */
       A.CUST_NO
     , A.ORD_DT
     , A.ORD_TOT_AMT
  FROM TB_ORD A
     , (
          SELECT B.CUST_NO, B.ORD_DT
            FROM TB_ORD_DTL B
           WHERE 1=1
             AND B.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
             AND B.ITEM_NO IN (
                                 SELECT J.ITEM_NO
                                   FROM TB_ITEM J
                                  WHERE J.ITEM_NM LIKE :V_ITEM_NM || '%')
       ) B
 WHERE A.CUST_NO = B.CUST_NO
   AND A.ORD_DT = B.ORD_DT
   AND (SELECT COUNT(*)
          FROM TB_DLVY K
         WHERE K.ORD_DT = A.ORD_DT
           AND K.CUST_NO = A.CUST_NO) > 1
;

UPDATE /* DB_REPLAY_TEST_02_UPDATE_01 */ TB_ORD_DTL T
   SET T.UPDT_ID = 'DBRT_02_UPDATE_01'
     , T.UPDT_DT = TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS')
 WHERE (T.CUST_NO, T.ORD_DT) IN
                               (
                                SELECT /*+ NO_MERGE(B) LEADING(B) USE_HASH(A) */
                                       A.CUST_NO
                                     , A.ORD_DT
                                  FROM TB_ORD A
                                     , (
                                          SELECT B.CUST_NO, B.ORD_DT
                                            FROM TB_ORD_DTL B
                                           WHERE 1=1
                                             AND B.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
                                             AND B.ITEM_NO IN (
                                                                 SELECT J.ITEM_NO
                                                                   FROM TB_ITEM J
                                                                  WHERE J.ITEM_NM LIKE :V_ITEM_NM || '%')
                                       ) B
                                 WHERE A.CUST_NO = B.CUST_NO
                                   AND A.ORD_DT = B.ORD_DT
                                   AND (SELECT COUNT(*)
                                          FROM TB_DLVY K
                                         WHERE K.ORD_DT = A.ORD_DT
                                           AND K.CUST_NO = A.CUST_NO) > 1
           AND ROWNUM <= 100
                               )
;

COMMIT;

UPDATE /* DB_REPLAY_TEST_02_UPDATE_02 */ TB_ORD_DTL T
   SET T.UPDT_ID = NULL
     , T.UPDT_DT = NULL
 WHERE (T.CUST_NO, T.ORD_DT) IN
                               (
                                SELECT /*+ NO_MERGE(B) LEADING(B) USE_HASH(A) */
                                       A.CUST_NO
                                     , A.ORD_DT
                                  FROM TB_ORD A
                                     , (
                                          SELECT B.CUST_NO, B.ORD_DT
                                            FROM TB_ORD_DTL B
                                           WHERE 1=1
                                             AND B.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
                                             AND B.ITEM_NO IN (
                                                                 SELECT J.ITEM_NO
                                                                   FROM TB_ITEM J
                                                                  WHERE J.ITEM_NM LIKE :V_ITEM_NM || '%')
                                       ) B
                                 WHERE A.CUST_NO = B.CUST_NO
                                   AND A.ORD_DT = B.ORD_DT
                                   AND (SELECT COUNT(*)
                                          FROM TB_DLVY K
                                         WHERE K.ORD_DT = A.ORD_DT
                                           AND K.CUST_NO = A.CUST_NO) > 1
                               )
   AND T.UPDT_ID IS NOT NULL
   AND T.UPDT_DT IS NOT NULL
;

COMMIT;

PROMPT =========================================================================
PROMPT 3. SQL DB_REPLAY_TEST_03 Execution
PROMPT =========================================================================

VARIABLE V_BRTHDY VARCHAR2(8);
VARIABLE V_BEGIN_ORD_DT VARCHAR2(32);
VARIABLE V_END_ORD_DT VARCHAR2(32);
VARIABLE V_ITEM_PRC NUMBER;
EXEC :V_BRTHDY := '200001';
EXEC :V_BEGIN_ORD_DT := '20241201000000';
EXEC :V_END_ORD_DT := '20241231235959';
EXEC :V_ITEM_PRC := 5000;

WITH TMP_1 AS (SELECT /*+ MATERIALIZE */ CUST_NO
                 FROM TB_CUST
                WHERE BRTHDY LIKE :V_BRTHDY || '%')
SELECT /* DB_REPLAY_TEST_03_SELECT_01 */
       A.CUST_NO
     , B.ITEM_NO
     , B.ITEM_NM
     , B.ITEM_PRC
  FROM (SELECT A.CUST_NO
             , MAX(A.ITEM_NO) KEEP(DENSE_RANK FIRST ORDER BY A.ORD_AMT DESC) AS ITEM_NO
          FROM TB_ORD_DTL A
             , TMP_1 B
         WHERE A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
           AND B.CUST_NO = A.CUST_NO
         GROUP BY A.CUST_NO ) A
     , TB_ITEM B
     , TMP_1 C
 WHERE 1=1
   AND B.ITEM_PRC >= :V_ITEM_PRC
   AND B.ITEM_NO = A.ITEM_NO
   AND C.CUST_NO = A.CUST_NO
;

PROMPT =========================================================================
PROMPT 4. SQL DB_REPLAY_TEST_04 Execution
PROMPT =========================================================================

VARIABLE V_ORD_DT VARCHAR2(32);
VARIABLE V_CUST_NO VARCHAR2(32);
EXEC :V_ORD_DT := '20240101000000';
EXEC :V_CUST_NO := 'C000000000';

SELECT /* DB_REPLAY_TEST_04_SELECT_01 */
       A.CUST_NO
     , A.ORD_DT
     , A.ORD_DTL_SN
     , A.ITEM_NO
     , A.ORD_AMT
     , (SELECT B.ORD_TOT_AMT FROM TB_ORD B WHERE A.CUST_NO=B.CUST_NO AND A.ORD_DT = B.ORD_DT ) ORD_TOT_AMT
  FROM (SELECT ROWNUM RN
             , A.CUST_NO
             , A.ORD_DT
             , A.ORD_DTL_SN
             , A.ITEM_NO
             , A.ORD_AMT
          FROM (SELECT B.CUST_NO
                     , B.ORD_DT
                     , B.ORD_DTL_SN
                     , B.ITEM_NO
                     , B.ORD_AMT
                  FROM (SELECT A.CUST_NO
                          FROM (SELECT A.CUST_NO
                                  FROM (SELECT /*+ INDEX_DESC(B PK_TB_ORD_DTL) */B.CUST_NO
                                          FROM TB_ORD_DTL B
                                         WHERE EXISTS (SELECT /*+ NO_UNNEST */ 'X'
                                                         FROM TB_ORD A
                                                        WHERE A.CUST_NO= B.CUST_NO
                                                          AND A.ORD_DT = B.ORD_DT )
                                           AND B.CUST_NO > :V_CUST_NO
                                           AND B.ORD_DT > :V_ORD_DT
                                       ORDER BY CUST_NO DESC ) A
                                 WHERE ROWNUM <= 100
                                 GROUP BY A.CUST_NO ) A ) A
                     , TB_ORD_DTL B
                 WHERE B.CUST_NO= A.CUST_NO
                   AND B.ORD_DT > :V_ORD_DT
                 ORDER BY B.CUST_NO DESC , B.ORD_DT, B.ORD_DTL_SN ) A
         WHERE ROWNUM <= 100 ) A
 WHERE RN >= 1;


 UPDATE /* DB_REPLAY_TEST_04_UPDATE_01 */ TB_ORD_DTL T
   SET T.UPDT_ID = 'DBRT_04_UPDATE_01'
     , T.UPDT_DT = TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS')
  WHERE (T.CUST_NO, T.ORD_DT, T.ORD_DTL_SN) IN
  (
        SELECT A.CUST_NO
             , A.ORD_DT
             , A.ORD_DTL_SN
          FROM (SELECT ROWNUM RN
                     , A.CUST_NO
                     , A.ORD_DT
                     , A.ORD_DTL_SN
                     , A.ITEM_NO
                     , A.ORD_AMT
                  FROM (SELECT B.CUST_NO
                             , B.ORD_DT
                             , B.ORD_DTL_SN
                             , B.ITEM_NO
                             , B.ORD_AMT
                          FROM (SELECT A.CUST_NO
                                  FROM (SELECT A.CUST_NO
                                          FROM (SELECT /*+ INDEX_DESC(B PK_TB_ORD_DTL) */B.CUST_NO
                                                  FROM TB_ORD_DTL B
                                                 WHERE EXISTS (SELECT /*+ NO_UNNEST */ 'X'
                                                                 FROM TB_ORD A
                                                                WHERE A.CUST_NO= B.CUST_NO
                                                                  AND A.ORD_DT = B.ORD_DT )
                                                   AND B.CUST_NO > :V_CUST_NO
                                                   AND B.ORD_DT > :V_ORD_DT
                                               ORDER BY CUST_NO DESC ) A
                                         WHERE ROWNUM <= 100
                                         GROUP BY A.CUST_NO ) A ) A
                             , TB_ORD_DTL B
                         WHERE B.CUST_NO= A.CUST_NO
                           AND B.ORD_DT > :V_ORD_DT
                         ORDER BY B.CUST_NO DESC , B.ORD_DT, B.ORD_DTL_SN ) A
                 WHERE ROWNUM <= 100 ) A
         WHERE RN >= 1
     AND ROWNUM <= 100
  )
;


COMMIT;


UPDATE /* DB_REPLAY_TEST_04_UPDATE_02 */ TB_ORD_DTL T
   SET T.UPDT_ID = NULL
     , T.UPDT_DT = NULL
  WHERE (T.CUST_NO, T.ORD_DT, T.ORD_DTL_SN) IN
  (
        SELECT A.CUST_NO
             , A.ORD_DT
             , A.ORD_DTL_SN
          FROM (SELECT ROWNUM RN
                     , A.CUST_NO
                     , A.ORD_DT
                     , A.ORD_DTL_SN
                     , A.ITEM_NO
                     , A.ORD_AMT
                  FROM (SELECT B.CUST_NO
                             , B.ORD_DT
                             , B.ORD_DTL_SN
                             , B.ITEM_NO
                             , B.ORD_AMT
                          FROM (SELECT A.CUST_NO
                                  FROM (SELECT A.CUST_NO
                                          FROM (SELECT /*+ INDEX_DESC(B PK_TB_ORD_DTL) */B.CUST_NO
                                                  FROM TB_ORD_DTL B
                                                 WHERE EXISTS (SELECT /*+ NO_UNNEST */ 'X'
                                                                 FROM TB_ORD A
                                                                WHERE A.CUST_NO= B.CUST_NO
                                                                  AND A.ORD_DT = B.ORD_DT )
                                                   AND B.CUST_NO > :V_CUST_NO
                                                   AND B.ORD_DT > :V_ORD_DT
                                               ORDER BY CUST_NO DESC ) A
                                         WHERE ROWNUM <= 100
                                         GROUP BY A.CUST_NO ) A ) A
                             , TB_ORD_DTL B
                         WHERE B.CUST_NO= A.CUST_NO
                           AND B.ORD_DT > :V_ORD_DT
                         ORDER BY B.CUST_NO DESC , B.ORD_DT, B.ORD_DTL_SN ) A
                 WHERE ROWNUM <= 100 ) A
         WHERE RN >= 1
  )
   AND T.UPDT_ID IS NOT NULL
   AND T.UPDT_DT IS NOT NULL
;

COMMIT;


PROMPT =========================================================================
PROMPT 5. SQL DB_REPLAY_TEST_05 Execution
PROMPT =========================================================================

VARIABLE V_BEGIN_ORD_DT VARCHAR2(32);
EXEC :V_BEGIN_ORD_DT := '20240101000000';
VARIABLE V_END_ORD_DT VARCHAR2(32);
EXEC :V_END_ORD_DT := '20240131235959';
VARIABLE V_CUST_STS_CD VARCHAR2(6);
EXEC :V_CUST_STS_CD := 'CSC002';
VARIABLE V_BRTHDY_MMDD VARCHAR2(4);
EXEC :V_BRTHDY_MMDD := '1027';

SELECT /*+ LEADING(J@SQ1) USE_NL(A) */ /* DB_REPLAY_TEST_05_SELECT_01 */
       A.CUST_NO
     , A.ORD_DT
     , A.ORD_DTL_SN
     , A.ORD_DTL_STS_CD
     , A.ORD_AMT
     , A.ITEM_NO
     , A.DLVY_SN
  FROM TB_ORD_DTL A
 WHERE 1=1
   AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
   AND A.CUST_NO IN (SELECT /*+ QB_NAME(SQ1) INDEX(J IDX_TB_CUST_03) */ J.CUST_NO
                       FROM TB_CUST J
                      WHERE J.CUST_STS_CD = :V_CUST_STS_CD
                        AND SUBSTR(J.BRTHDY, 5, 4) = :V_BRTHDY_MMDD
                    )
;


 UPDATE /* DB_REPLAY_TEST_05_UPDATE_01 */ TB_ORD_DTL T
   SET T.UPDT_ID = 'DBRT_05_UPDATE_01'
     , T.UPDT_DT = TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS')
  WHERE (T.CUST_NO, T.ORD_DT, T.ORD_DTL_SN) IN
  (
    SELECT /*+ LEADING(
J@SQ1) USE_NL(A) */
           A.CUST_NO
         , A.ORD_DT
         , A.ORD_DTL_SN
      FROM TB_ORD_DTL A
     WHERE 1=1
       AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
       AND A.CUST_NO IN (SELECT /*+ QB_NAME(SQ1) INDEX(J IDX_TB_CUST_03) */ J.CUST_NO
                           FROM TB_CUST J
                          WHERE J.CUST_STS_CD = :V_CUST_STS_CD
                            AND SUBSTR(J.BRTHDY, 5, 4) = :V_BRTHDY_MMDD
                        )
    AND ROWNUM <= 100
  )
;

COMMIT;

 UPDATE /* DB_REPLAY_TEST_05_UPDATE_02 */ TB_ORD_DTL T
   SET T.UPDT_ID = NULL
     , T.UPDT_DT = NULL
  WHERE (T.CUST_NO, T.ORD_DT, T.ORD_DTL_SN) IN
  (
    SELECT /*+ LEADING(
J@SQ1) USE_NL(A) */
           A.CUST_NO
         , A.ORD_DT
         , A.ORD_DTL_SN
      FROM TB_ORD_DTL A
     WHERE 1=1
       AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
       AND A.CUST_NO IN (SELECT /*+ QB_NAME(SQ1) INDEX(J IDX_TB_CUST_03) */ J.CUST_NO
                           FROM TB_CUST J
                          WHERE J.CUST_STS_CD = :V_CUST_STS_CD
                            AND SUBSTR(J.BRTHDY, 5, 4) = :V_BRTHDY_MMDD
                        )
  )
   AND T.UPDT_ID IS NOT NULL
   AND T.UPDT_DT IS NOT NULL
;

COMMIT;

PROMPT =========================================================================
PROMPT 6. SQL DB_REPLAY_TEST_06 Execution
PROMPT =========================================================================

ALTER SESSION SET OPTIMIZER_MODE = ALL_ROWS;

VARIABLE V_BEGIN_BRTHDY VARCHAR2(32);
VARIABLE V_END_BRTHDY VARCHAR2(32);
VARIABLE V_BEGIN_ORD_DT VARCHAR2(32);
VARIABLE V_END_ORD_DT VARCHAR2(32);
VARIABLE V_CUST_NO VARCHAR2(32);
EXEC :V_BEGIN_BRTHDY := '19900101000000';
EXEC :V_END_BRTHDY := '19901231235959';
EXEC :V_BEGIN_ORD_DT := '20240101000000';
EXEC :V_END_ORD_DT := '20241231235959';
EXEC :V_CUST_NO := 'C';

SELECT /* DB_REPLAY_TEST_06_SELECT_01 */
       /*+ LEADING(A) USE_HASH(B) SWAP_JOIN_INPUTS(B) FULL(A) FULL(B) */
       A.CUST_NO
     , SUBSTR(A.ORD_DT, 1, 6) ORD_DT
     , SUM(A.ORD_AMT) ORD_TOT_AMT
     , B.BRTHDY
  FROM TB_ORD_DTL A
     , (SELECT A.CUST_NO
             , A.BRTHDY
          FROM TB_CUST A
         WHERE BRTHDY BETWEEN :V_BEGIN_BRTHDY AND :V_END_BRTHDY
           AND SEX_CD ='SC0000') B
 WHERE A.CUST_NO = B.CUST_NO(+)
   AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
   AND A.CUST_NO LIKE :V_CUST_NO||'%'
   AND A.ORD_DTL_STS_CD='ODSC04'
   AND A.DLVY_SN IS NOT NULL
 GROUP BY A.CUST_NO, SUBSTR(A.ORD_DT, 1, 6), B.BRTHDY
;

UPDATE /* DB_REPLAY_TEST_06_UPDATE_01 */ TB_CUST T
   SET T.UPDT_ID = 'DBRT_06_UPDATE_01'
     , T.UPDT_DT = TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS')
 WHERE T.CUST_NO IN
 (
   SELECT *
  FROM (
     SELECT
        /*+ LEADING(A) USE_HASH(B) SWAP_JOIN_INPUTS(B) FULL(A) FULL(B) */
        A.CUST_NO
      FROM TB_ORD_DTL A
      , (SELECT A.CUST_NO
        , A.BRTHDY
        FROM TB_CUST A
       WHERE BRTHDY BETWEEN :V_BEGIN_BRTHDY AND :V_END_BRTHDY
         AND SEX_CD ='SC0000') B
     WHERE A.CUST_NO = B.CUST_NO(+)
       AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
       AND A.CUST_NO LIKE :V_CUST_NO||'%'
       AND A.ORD_DTL_STS_CD='ODSC04'
       AND A.DLVY_SN IS NOT NULL
     GROUP BY A.CUST_NO
   )
  WHERE 1=1
    AND ROWNUM <= 100
)
;

COMMIT;

UPDATE /* DB_REPLAY_TEST_06_UPDATE_02 */ TB_CUST T
   SET T.UPDT_ID = NULL
     , T.UPDT_DT = NULL
 WHERE T.CUST_NO IN
 (
     SELECT
           /*+ LEADING(A) USE_HASH(B) SWAP_JOIN_INPUTS(B) FULL(A) FULL(B) */
           A.CUST_NO
      FROM TB_ORD_DTL A
         , (SELECT A.CUST_NO
                 , A.BRTHDY
              FROM TB_CUST A
             WHERE BRTHDY BETWEEN :V_BEGIN_BRTHDY AND :V_END_BRTHDY
               AND SEX_CD ='SC0000') B
     WHERE A.CUST_NO = B.CUST_NO(+)
       AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
       AND A.CUST_NO LIKE :V_CUST_NO||'%'
       AND A.ORD_DTL_STS_CD='ODSC04'
       AND A.DLVY_SN IS NOT NULL
     GROUP BY A.CUST_NO
 )
   AND T.UPDT_ID IS NOT NULL
   AND T.UPDT_DT IS NOT NULL
;

COMMIT;

PROMPT =========================================================================
PROMPT 7. SQL DB_REPLAY_TEST_07 Execution
PROMPT =========================================================================

VARIABLE V_DLVY_STS_CD VARCHAR2(32);
VARIABLE V_BEGIN_DLVY_DT VARCHAR2(32);
VARIABLE V_END_DLVY_DT VARCHAR2(32);
VARIABLE V_HDRY_CMPNY_CD VARCHAR2(32);
VARIABLE V_WAYBIL_NO VARCHAR2(32);
EXEC :V_DLVY_STS_CD := 'DSC004';
EXEC :V_BEGIN_DLVY_DT := '20241201000000';
EXEC :V_END_DLVY_DT := '20241231235959';
EXEC :V_HDRY_CMPNY_CD := 'HCC0';
EXEC :V_WAYBIL_NO := '00000000000';

SELECT /* DB_REPLAY_TEST_07_SELECT_01 */
       /*+ BATCH_TABLE_ACCESS_BY_ROWID(A)
           INDEX(A IDX_TB_DLVY_02)
           PARALLEL_INDEX(A IDX_TB_DLVY_02 2)   */
       CUST_NO
     , COUNT(*)
  FROM TB_DLVY A
 WHERE 1=1
   AND A.DLVY_STS_CD LIKE :V_DLVY_STS_CD||'%'
   AND A.DLVY_DT BETWEEN :V_BEGIN_DLVY_DT AND :V_END_DLVY_DT
   AND A.HDRY_CMPNY_CD LIKE :V_HDRY_CMPNY_CD||'%'
   AND A.WAYBIL_NO LIKE :V_WAYBIL_NO||'%'
 GROUP BY CUST_NO
 ORDER BY CUST_NO;

 UPDATE /* DB_REPLAY_TEST_07_UPDATE_01 */ TB_DLVY T
   SET T.UPDT_ID = 'DBRT_07_UPDATE_01'
     , T.UPDT_DT = TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS')
 WHERE T.CUST_NO IN
 (
  SELECT *
    FROM
    (
  SELECT /*+ BATCH_TABLE_ACCESS_BY_ROWID(A)
       INDEX(A IDX_TB_DLVY_02)
       PARALLEL_INDEX(A IDX_TB_DLVY_02 2)
      */
      CUST_NO
    FROM TB_DLVY A
   WHERE 1=1
     AND A.DLVY_STS_CD LIKE :V_DLVY_STS_CD||'%'
     AND A.DLVY_DT BETWEEN :V_BEGIN_DLVY_DT AND :V_END_DLVY_DT
     AND A.HDRY_CMPNY_CD LIKE :V_HDRY_CMPNY_CD||'%'
     AND A.WAYBIL_NO LIKE :V_WAYBIL_NO||'%'
   GROUP BY CUST_NO
    )
  WHERE ROWNUM <= 100
 );

COMMIT;

  UPDATE /* DB_REPLAY_TEST_07_UPDATE_01 */ TB_DLVY T
   SET T.UPDT_ID = NULL
     , T.UPDT_DT = NULL
 WHERE T.CUST_NO IN
 (
    SELECT /*+ BATCH_TABLE_ACCESS_BY_ROWID(A)
               INDEX(A IDX_TB_DLVY_02)
               PARALLEL_INDEX(A IDX_TB_DLVY_02 2)
           */
           CUST_NO
      FROM TB_DLVY A
     WHERE 1=1
       AND A.DLVY_STS_CD LIKE :V_DLVY_STS_CD||'%'
       AND A.DLVY_DT BETWEEN :V_BEGIN_DLVY_DT AND :V_END_DLVY_DT
       AND A.HDRY_CMPNY_CD LIKE :V_HDRY_CMPNY_CD||'%'
       AND A.WAYBIL_NO LIKE :V_WAYBIL_NO||'%'
     GROUP BY CUST_NO
 )
   AND T.UPDT_ID IS NOT NULL
   AND T.UPDT_DT IS NOT NULL ;

COMMIT;

PROMPT =========================================================================
PROMPT 8. SQL DB_REPLAY_TEST_08 Execution
PROMPT =========================================================================

VARIABLE V_STD_DT VARCHAR2(8);
EXEC :V_STD_DT := '20240125';

SELECT /*+ LEADING(A B C) INDEX_SS(A IDX_TB_DLVY_02) USE_NL(B) USE_NL(C) */
       /* DB_REPLAY_TEST_07_SELECT_01 */
       A.CUST_NO, SUM(C.ORD_TOT_AMT) SUM_ORD_TOT_AMT
  FROM TB_DLVY A
     , TB_CUST B
     , TB_ORD C
  WHERE A.DLVY_DT LIKE TO_CHAR(TO_DATE(:V_STD_DT, 'YYYYMMDD')-1, 'YYYYMMDD') || '%'
    AND SUBSTR(B.BRTHDY, 5, 4) = SUBSTR(A.DLVY_DT, 5, 4)
    AND A.CUST_NO = B.CUST_NO
    AND B.CUST_NO = C.CUST_NO
    AND C.ORD_DT BETWEEN TO_CHAR(TO_DATE(:V_STD_DT, 'YYYYMMDD')-366, 'YYYYMMDD')
                     AND TO_CHAR(TO_DATE(:V_STD_DT, 'YYYYMMDD')-1, 'YYYYMMDD')
GROUP BY A.CUST_NO
HAVING SUM(C.ORD_TOT_AMT) >= 1000000
;

PROMPT =========================================================================
PROMPT 9. DB_REPLAY_TEST_09 Execution
PROMPT =========================================================================

VARIABLE V_BRTHDY VARCHAR2(8);
EXEC :V_BRTHDY := '19811101';
VARIABLE V_STD_DT VARCHAR2(8);
EXEC :V_STD_DT := '20240125';

SELECT /*+ LEADING(A B C) USE_NL(B) NO_MERGE(C) PUSH_PRED(C) USE_NL(C) */
       /* DB_REPLAY_TEST_09_SELECT_01 */
       A.CUST_ID, A.CUST_NM, B.ORD_TOT_AMT, C.ORD_DT, C.ORD_DTL_STS_CD, C.SUM_ORD_AMT
  FROM TB_CUST A
     , TB_ORD B
     , (SELECT C.ORD_DT, C.CUST_NO, MAX(C.ORD_DTL_STS_CD) AS ORD_DTL_STS_CD, SUM(C.ORD_AMT) AS SUM_ORD_AMT
          FROM TB_ORD_DTL C
         WHERE 1=1
           AND C.ORD_DTL_STS_CD = 'ODSC03'
         GROUP BY C.ORD_DT, C.CUST_NO
         UNION ALL
        SELECT C.ORD_DT, C.CUST_NO, MAX(C.ORD_DTL_STS_CD) AS ORD_DTL_STS_CD, SUM(C.ORD_AMT) AS SUM_ORD_AMT
          FROM TB_ORD_DTL C
         WHERE 1=1
           AND C.ORD_DTL_STS_CD = 'ODSC04'
         GROUP BY C.ORD_DT, C.CUST_NO
       ) C
 WHERE 1=1
   AND A.BRTHDY = :V_BRTHDY
   AND A.CUST_NO = B.CUST_NO
   AND B.ORD_DT BETWEEN TO_CHAR(TO_DATE(:V_STD_DT, 'YYYYMMDD')-365, 'YYYYMMDD')  || '000000'
                    AND TO_CHAR(TO_DATE(:V_STD_DT, 'YYYYMMDD')-1  , 'YYYYMMDD')  || '235959'
   AND B.ORD_DT = C.ORD_DT
   AND B.CUST_NO = C.CUST_NO
;

PROMPT =========================================================================
PROMPT 10. SQL DB_REPLAY_TEST_10 Execution
PROMPT =========================================================================

VARIABLE V_DLVY_STS_CD VARCHAR2(32);
VARIABLE V_BEGIN_DLVY_DT VARCHAR2(32);
VARIABLE V_END_DLVY_DT VARCHAR2(32);
VARIABLE V_HDRY_CMPNY_CD VARCHAR2(32);
VARIABLE V_WAYBIL_NO VARCHAR2(32);
EXEC :V_DLVY_STS_CD := 'DSC004';
EXEC :V_BEGIN_DLVY_DT := '20241201000000';
EXEC :V_END_DLVY_DT := '20241231235959';
EXEC :V_HDRY_CMPNY_CD := 'HCC019';
EXEC :V_WAYBIL_NO := '00000000000';

SELECT /* DB_REPLAY_TEST_10_SELECT_01 */
       CUST_NO
     , ORD_DT
     , DLVY_SN
     , DLVY_DT
     , HDRY_CMPNY_CD
     , WAYBIL_NO
  FROM TB_DLVY A
 WHERE 1=1
   AND A.DLVY_STS_CD = :V_DLVY_STS_CD
   AND A.DLVY_DT BETWEEN :V_BEGIN_DLVY_DT AND :V_END_DLVY_DT
   AND A.HDRY_CMPNY_CD =:V_HDRY_CMPNY_CD
   AND A.WAYBIL_NO LIKE :V_WAYBIL_NO||'%'
 ORDER BY CUST_NO, ORD_DT, DLVY_SN
;

UPDATE /* DB_REPLAY_TEST_10_UPDATE_01 */ TB_DLVY T
   SET T.UPDT_ID = 'DBRT_10_UPDATE_01'
     , T.UPDT_DT = TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS')
  WHERE (T.CUST_NO, T.ORD_DT, T.DLVY_SN) IN
  (
      SELECT
           A.CUST_NO
         , A.ORD_DT
         , A.DLVY_SN
      FROM TB_DLVY A
     WHERE 1=1
       AND A.DLVY_STS_CD = :V_DLVY_STS_CD
       AND A.DLVY_DT BETWEEN :V_BEGIN_DLVY_DT AND :V_END_DLVY_DT
       AND A.HDRY_CMPNY_CD =:V_HDRY_CMPNY_CD
       AND A.WAYBIL_NO LIKE :V_WAYBIL_NO||'%'
    AND ROWNUM <= 100
  )
;

COMMIT;

UPDATE /* DB_REPLAY_TEST_10_UPDATE_02 */ TB_DLVY T
   SET T.UPDT_ID = NULL
     , T.UPDT_DT = NULL
  WHERE (T.CUST_NO, T.ORD_DT, T.DLVY_SN) IN
  (
      SELECT
           A.CUST_NO
         , A.ORD_DT
         , A.DLVY_SN
      FROM TB_DLVY A
     WHERE 1=1
       AND A.DLVY_STS_CD = :V_DLVY_STS_CD
       AND A.DLVY_DT BETWEEN :V_BEGIN_DLVY_DT AND :V_END_DLVY_DT
       AND A.HDRY_CMPNY_CD =:V_HDRY_CMPNY_CD
       AND A.WAYBIL_NO LIKE :V_WAYBIL_NO||'%'
  )
   AND T.UPDT_ID IS NOT NULL
   AND T.UPDT_DT IS NOT NULL
;

COMMIT;

PROMPT =========================================================================
PROMPT 11. SQL DB_REPLAY_TEST_11 Execution
PROMPT =========================================================================

VARIABLE V_BEGIN_ORD_DT VARCHAR2(32);
VARIABLE V_END_ORD_DT VARCHAR2(32);
VARIABLE V_CUST_NO VARCHAR2(32);
EXEC :V_BEGIN_ORD_DT := '20241201000000';
EXEC :V_END_ORD_DT := '20241231235959';
EXEC :V_CUST_NO := 'C';

SELECT /* DB_REPLAY_TEST_11_SELECT_01 */1 AS DUMMY
     , A.CUST_NO
     , A.ORD_DT
     , A.ORD_TOT_AMT
     , B.AVG_ORD_AMT
     , B.MAX_ORD_AMT
     , B.SUM_ORD_AMT
     , B.RN AS KEY_RN
  FROM TB_ORD A
     , LATERAL (SELECT B.CUST_NO , B.ORD_DT , ROUND(AVG_ORD_AMT,1) AVG_ORD_AMT ,
                       MAX_ORD_AMT , SUM_ORD_AMT , ROWNUM RN
          FROM (SELECT B.CUST_NO
                     , B.ORD_DT
                     , AVG(B.ORD_AMT) OVER ( PARTITION BY B.CUST_NO,B.ORD_DT ) AVG_ORD_AMT
                     , MAX(B.ORD_AMT) OVER ( PARTITION BY B.CUST_NO, B.ORD_DT ) MAX_ORD_AMT
                     , SUM(B.ORD_AMT) OVER ( PARTITION BY B.CUST_NO,B.ORD_DT ) SUM_ORD_AMT
                     , ROW_NUMBER() OVER ( PARTITION BY B.CUST_NO,B.ORD_DT
                          ORDER BY B.CUST_NO,B.ORD_DT ) RN
                  FROM TB_ORD_DTL B
                 WHERE 1=1
                   AND b.ORD_DTL_STS_CD='ODSC04'
                   AND A.CUST_NO = B.CUST_NO
                   AND A.ORD_DT = B.ORD_DT) B
         WHERE RN = 1 ) B
 WHERE A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
   AND A.CUST_NO LIKE :V_CUST_NO||'%' ;

PROMPT =========================================================================
PROMPT 12. SQL DB_REPLAY_TEST_12 Execution
PROMPT =========================================================================

VARIABLE V_BEGIN_ORD_DT VARCHAR2(32);
VARIABLE V_END_ORD_DT VARCHAR2(32);
VARIABLE V_ORD_DTL_STS_CD VARCHAR2(32);
VARIABLE V_ITEM_NO VARCHAR2(32);
EXEC :V_BEGIN_ORD_DT := '20240101000000';
EXEC :V_END_ORD_DT := '20241231235959';
EXEC :V_ORD_DTL_STS_CD := 'ODSC02';
EXEC :V_ITEM_NO := 'I000075707';

SELECT
       /* DB_REPLAY_TEST_12_SELECT_01 */ A.*, B.POST_NO, B.ADDR
 FROM
    (
        SELECT
               A.CUST_NO
             , A.ORD_DT
             , A.ORD_DTL_SN
             , A.DLVY_SN
             , A.ITEM_NO
             , (
                 SELECT MAX(L.ADDR_SN)
                   FROM TB_CUST_ADDR L
                  WHERE L.CUST_NO = A.CUST_NO
               ) AS MAX_ADDR_SN
          FROM TB_ORD_DTL A
         WHERE 1=1
           AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
           AND A.ORD_DTL_STS_CD = :V_ORD_DTL_STS_CD
           AND A.ITEM_NO = :V_ITEM_NO
    ) A
    , TB_CUST_ADDR B
WHERE A.CUST_NO = B.CUST_NO
  AND A.MAX_ADDR_SN = B.ADDR_SN
;

UPDATE /* DB_REPLAY_TEST_12_UPDATE_01 */ TB_CUST_ADDR T
   SET T.UPDT_ID = 'DBRT_12_UPDATE_01'
     , T.UPDT_DT = TO_CHAR(SYSDATE, 'YYYYMMDDHH24MISS')
 WHERE (T.CUST_NO, T.ADDR_SN)
    IN (
        SELECT A.CUST_NO, B.ADDR_SN
         FROM
            (
                SELECT
                       A.CUST_NO
                     , A.ORD_DT
                     , A.ORD_DTL_SN
                     , A.DLVY_SN
                     , A.ITEM_NO
                     , (
                         SELECT MAX(L.ADDR_SN)
                           FROM TB_CUST_ADDR L
                          WHERE L.CUST_NO = A.CUST_NO
                       ) AS MAX_ADDR_SN
                  FROM TB_ORD_DTL A
                 WHERE 1=1
                   AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
                   AND A.ORD_DTL_STS_CD = :V_ORD_DTL_STS_CD
                   AND A.ITEM_NO = :V_ITEM_NO
            ) A
            , TB_CUST_ADDR B
        WHERE A.CUST_NO = B.CUST_NO
          AND A.MAX_ADDR_SN = B.ADDR_SN
    AND ROWNUM <= 100
      )
;

COMMIT;

UPDATE /* DB_REPLAY_TEST_12_UPDATE_02 */ TB_CUST_ADDR T
   SET T.UPDT_ID = NULL
     , T.UPDT_DT = NULL
 WHERE (T.CUST_NO, T.ADDR_SN)
    IN (
        SELECT A.CUST_NO, B.ADDR_SN
         FROM
            (
                SELECT
                       A.CUST_NO
                     , A.ORD_DT
                     , A.ORD_DTL_SN
                     , A.DLVY_SN
                     , A.ITEM_NO
                     , (
                         SELECT MAX(L.ADDR_SN)
                           FROM TB_CUST_ADDR L
                          WHERE L.CUST_NO = A.CUST_NO
                       ) AS MAX_ADDR_SN
                  FROM TB_ORD_DTL A
                 WHERE 1=1
                   AND A.ORD_DT BETWEEN :V_BEGIN_ORD_DT AND :V_END_ORD_DT
                   AND A.ORD_DTL_STS_CD = :V_ORD_DTL_STS_CD
                   AND A.ITEM_NO = :V_ITEM_NO
            ) A
            , TB_CUST_ADDR B
        WHERE A.CUST_NO = B.CUST_NO
          AND A.MAX_ADDR_SN = B.ADDR_SN
      )
   AND T.UPDT_ID IS NOT NULL
   AND T.UPDT_DT IS NOT NULL
;

COMMIT;

SPOOL OFF
EXIT
EOF

echo "Load Generation Completed."

 

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ chmod 775 /home/oracle/db_replay_load/run_db_replay_load.sh

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ vi /home/oracle/db_replay_load/loop_db_replay_load.sh
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ cat /home/oracle/db_replay_load/loop_db_replay_load.sh
#!/bin/bash

# ------------------------------------------------------------------------
# [제목] Oracle Workload Generator Wrapper Script
# [작성일] 2025-12-29
# [작성자] Oracle Expert
# [설명] run_load_gen.sh를 반복 실행하여 DB에 지속적인 부하를 발생시킵니다.
#        인자값(숫자)을 주면 해당 횟수만큼, 인자값이 없으면 무한 반복합니다.
# ------------------------------------------------------------------------

# 실행할 타겟 스크립트 경로
TARGET_SCRIPT="/home/oracle/db_replay_load/run_db_replay_load.sh"
SLEEP_SEC=1

# 타겟 스크립트 존재 및 실행 권한 확인
if [ ! -x "$TARGET_SCRIPT" ]; then
    echo "[ERROR] $TARGET_SCRIPT 파일을 찾을 수 없거나 실행 권한이 없습니다."
    echo "실행 권한 부여: chmod +x $TARGET_SCRIPT"
    exit 1
fi

# Ctrl+C (SIGINT) 입력 시 안전하게 종료하기 위한 Trap 설정
trap "echo -e '\n[STOP] 사용자에 의해 스크립트가 중단되었습니다.'; exit 0" SIGINT SIGTERM

# 인자값 확인 (반복 횟수)
ITERATION=$1
COUNTER=1

echo "========================================================"
echo "         Oracle Workload Generator Wrapper              "
echo "========================================================"
echo "Start Time : $(date)"

# ----------------------------------------------------------------------
# Logic: 인자가 숫자면 유한 반복, 없거나 숫자가 아니면 무한 반복
# ----------------------------------------------------------------------
if [[ "$ITERATION" =~ ^[0-9]+$ ]]; then
    # [Case 1] 유한 반복 (Finite Loop)
    echo "Mode       : Count Loop ($ITERATION 회 실행)"
    echo "========================================================"

    while [ $COUNTER -le $ITERATION ]; do
        echo ""
        echo ">>> Iteration: $COUNTER / $ITERATION [ $(date '+%Y-%m-%d %H:%M:%S') ]"

        # 스크립트 실행
        $TARGET_SCRIPT

        COUNTER=$((COUNTER+1))

        # 과도한 연속 실행 방지를 위한 짧은 대기 (필요 시 주석 처리)
        if [ $COUNTER -le $ITERATION ]; then
            sleep $SLEEP_SEC
        fi
    done

else
    # [Case 2] 무한 반복 (Infinite Loop)
    echo "Mode       : Infinite Loop (종료하려면 Ctrl+C)"
    echo "========================================================"

    while true; do
        echo ""
        echo ">>> Iteration: $COUNTER (Infinite) [ $(date '+%Y-%m-%d %H:%M:%S') ]"

        # 스크립트 실행
        $TARGET_SCRIPT

        COUNTER=$((COUNTER+1))
        sleep $SLEEP_SEC
    done
fi

echo ""
echo "========================================================"
echo "Workload Generation Finished at $(date)"
echo "========================================================"

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ chmod 775 /home/oracle/db_replay_load/loop_db_replay_load.sh

 

--잘 돌아가는지 검증
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle/db_replay_load]$ /home/oracle/db_replay_load/loop_db_replay_load.sh 1

 

--2번 노드도 실행
[ORA12RF2:oracle@ol7ora12rf2][/home/oracle]$ mkdir -pv /home/oracle/db_replay_load/
mkdir: created directory ‘/home/oracle/db_replay_load/’
[ORA12RF2:oracle@ol7ora12rf2][/home/oracle]$ cd /home/oracle/db_replay_load/
[ORA12RF2:oracle@ol7ora12rf2][/home/oracle/db_replay_load]$ scp ol7ora12rf1:/home/oracle/db_replay_load/* /home/oracle/db_replay_load

loop_db_replay_load.sh      100% 2828     2.8MB/s   00:00
run_db_replay_load.sh       100%   17KB  11.8MB/s   00:00

 

[ORA12RF2:oracle@ol7ora12rf2][/home/oracle/db_replay_load]$ ll
total 24
-rwxr-xr-x. 1 oracle oinstall  2828 Jan  1 00:43 loop_db_replay_load.sh
-rwxr-xr-x. 1 oracle oinstall 17489 Jan  1 00:43 run_db_replay_load.sh

 

--잘 돌아가는지 검증
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle/db_replay_load]$ /home/oracle/db_replay_load/loop_db_replay_load.sh 1

 

6. 소스에서 양쪽 노드의 워크로드 캡처를 위한 ACFS 구축

 

6-1. 공유 디스크 추가

 

ol7ora12rf1 VM 선택 -> Settings -> Add -> Hard Disk -> SCSI -> Create a new virtual disk -> 40 GB
-> Allocte all disk space now 체크 -> Store virtual disk as a single file 선택
-> 경로 지정 : D:\VMware\OL7_ORA12RF\Storage\ORA12RF_ACFS1_1.vmdk -> Finish

신규로 추가한 디스크 선택 후 -> Advanced -> Independent 체크 -> Persistent 선택 -> SCCI 노드 선택 (여기서는 "SCSI 1:6" 으로 설정)

D:\VMware\OL7_ORA12RF\ol7ora12rf1 경로에 있는 ol7ora12rf1.vmx 파일에
scsi1:6.deviceType = "disk"
--> 추가


ol7ora12rf2 VM 선택 -> Settings -> Add -> Hard Disk -> SCSI -> Use an existing vitrual disk
-> 파일 선택 : D:\VMware\OL7_ORA12RF\Storage\ORA12RF_ACFS1_1.vmdk

신규로 추가한 디스크 선택 후 -> Advanced -> Independent 체크 -> Persistent 선택 -> SCCI 노드 선택 (여기서는 "SCSI 1:6" 으로 설정)

D:\VMware\OL7_ORA12RF\ol7ora12rf2 경로에 ㅇㅆ는 ol7ora12rf2.vmx 파일에
scsi1:6.deviceType = "disk"
--> 추가

 

--디바이스 인식 (1번 노드)
[root@ol7ora12rf1][/root]$ ls -l /dev/sd*
brw-rw----. 1 root disk     8,  0 Dec 29 22:45 /dev/sda
brw-rw----. 1 root disk     8,  1 Dec 29 22:45 /dev/sda1
brw-rw----. 1 root disk     8,  2 Dec 29 22:45 /dev/sda2
brw-rw----. 1 grid asmadmin 8, 16 Jan  1 12:13 /dev/sdb
brw-rw----. 1 grid asmadmin 8, 32 Jan  1 12:13 /dev/sdc
brw-rw----. 1 grid asmadmin 8, 48 Jan  1 12:13 /dev/sdd
brw-rw----. 1 grid asmadmin 8, 64 Jan  1 12:13 /dev/sde
brw-rw----. 1 grid asmadmin 8, 80 Jan  1 12:13 /dev/sdf
brw-rw----. 1 grid asmadmin 8, 96 Jan  1 12:12 /dev/sdg

 

[root@ol7ora12rf1][/root]$ rpm -qa | grep sg3_utils
sg3_utils-libs-1.37-19.0.1.el7.x86_64
sg3_utils-1.37-19.0.1.el7.x86_64

 

[root@ol7ora12rf1][/root]$ /usr/bin/rescan-scsi-bus.sh -a
which: no multipath in (/u01/app/12c/grid/bin:/usr/sbin:/usr/local/sbin:/usr/local/bin:/usr/sbin:/usr/bin:/root/bin)
Scanning SCSI subsystem for new devices
Scanning host 0 for  SCSI target IDs  0 1 2 3 4 5 6 7, all LUNs
Scanning host 1 for  SCSI target IDs  0 1 2 3 4 5 6 7, all LUNs
 Scanning for device 1 0 0 0 ...
OLD: Host: scsi1 Channel: 00 Id: 00 Lun: 00
      Vendor: NECVMWar Model: VMware IDE CDR10 Rev: 1.00
      Type:   CD-ROM                           ANSI SCSI revision: 05
Scanning host 2 for  SCSI target IDs  0 1 2 3 4 5 6 7, all LUNs
 Scanning for device 2 0 0 0 ...
OLD: Host: scsi2 Channel: 00 Id: 00 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
Scanning host 3 for  SCSI target IDs  0 1 2 3 4 5 6 7, all LUNs
 Scanning for device 3 0 0 0 ...
OLD: Host: scsi3 Channel: 00 Id: 00 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 1 0 ...
OLD: Host: scsi3 Channel: 00 Id: 01 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 2 0 ...
OLD: Host: scsi3 Channel: 00 Id: 02 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 3 0 ...
OLD: Host: scsi3 Channel: 00 Id: 03 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 4 0 ...
OLD: Host: scsi3 Channel: 00 Id: 04 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 5 0 ...
OLD: Host: scsi3 Channel: 00 Id: 05 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 6 0 ...
NEW: Host: scsi3 Channel: 00 Id: 06 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
1 new or changed device(s) found.
        [3:0:6:0]
0 remapped or resized device(s) found.
0 device(s) removed.

 

[root@ol7ora12rf1][/root]$ ls -l /dev/sd*
brw-rw----. 1 root disk     8,   0 Dec 29 22:45 /dev/sda
brw-rw----. 1 root disk     8,   1 Dec 29 22:45 /dev/sda1
brw-rw----. 1 root disk     8,   2 Dec 29 22:45 /dev/sda2
brw-rw----. 1 grid asmadmin 8,  16 Jan  1 12:15 /dev/sdb
brw-rw----. 1 grid asmadmin 8,  32 Jan  1 12:15 /dev/sdc
brw-rw----. 1 grid asmadmin 8,  48 Jan  1 12:15 /dev/sdd
brw-rw----. 1 grid asmadmin 8,  64 Jan  1 12:15 /dev/sde
brw-rw----. 1 grid asmadmin 8,  80 Jan  1 12:15 /dev/sdf
brw-rw----. 1 grid asmadmin 8,  96 Jan  1 12:12 /dev/sdg
brw-rw----. 1 root disk     8, 112 Jan  1 12:15 /dev/sdh

 

--디바이스 인식 (2번 노드)
[root@ol7ora12rf2][/root]$ ls -l /dev/sd*
brw-rw----. 1 root disk     8,  0 Dec 29 21:33 /dev/sda
brw-rw----. 1 root disk     8,  1 Dec 29 21:33 /dev/sda1
brw-rw----. 1 root disk     8,  2 Dec 29 21:33 /dev/sda2
brw-rw----. 1 grid asmadmin 8, 16 Jan  1 12:16 /dev/sdb
brw-rw----. 1 grid asmadmin 8, 32 Jan  1 12:16 /dev/sdc
brw-rw----. 1 grid asmadmin 8, 48 Jan  1 12:16 /dev/sdd
brw-rw----. 1 grid asmadmin 8, 64 Jan  1 12:16 /dev/sde
brw-rw----. 1 grid asmadmin 8, 80 Jan  1 12:16 /dev/sdf
brw-rw----. 1 grid asmadmin 8, 96 Jan  1 12:16 /dev/sdg

 

[root@ol7ora12rf2][/root]$ rpm -qa | grep sg3_utils
sg3_utils-libs-1.37-19.0.1.el7.x86_64
sg3_utils-1.37-19.0.1.el7.x86_64

 

[root@ol7ora12rf2][/root]$ /usr/bin/rescan-scsi-bus.sh -a
which: no multipath in (/u01/app/12c/grid/bin:/usr/sbin:/usr/local/sbin:/usr/local/bin:/usr/sbin:/usr/bin:/root/bin)
Scanning SCSI subsystem for new devices
Scanning host 0 for  SCSI target IDs  0 1 2 3 4 5 6 7, all LUNs
Scanning host 1 for  SCSI target IDs  0 1 2 3 4 5 6 7, all LUNs
 Scanning for device 1 0 0 0 ...
OLD: Host: scsi1 Channel: 00 Id: 00 Lun: 00
      Vendor: NECVMWar Model: VMware IDE CDR10 Rev: 1.00
      Type:   CD-ROM                           ANSI SCSI revision: 05
Scanning host 2 for  SCSI target IDs  0 1 2 3 4 5 6 7, all LUNs
 Scanning for device 2 0 0 0 ...
OLD: Host: scsi2 Channel: 00 Id: 00 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
Scanning host 3 for  SCSI target IDs  0 1 2 3 4 5 6 7, all LUNs
 Scanning for device 3 0 0 0 ...
OLD: Host: scsi3 Channel: 00 Id: 00 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 1 0 ...
OLD: Host: scsi3 Channel: 00 Id: 01 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 2 0 ...
OLD: Host: scsi3 Channel: 00 Id: 02 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 3 0 ...
OLD: Host: scsi3 Channel: 00 Id: 03 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 4 0 ...
OLD: Host: scsi3 Channel: 00 Id: 04 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 5 0 ...
OLD: Host: scsi3 Channel: 00 Id: 05 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
 Scanning for device 3 0 6 0 ...
NEW: Host: scsi3 Channel: 00 Id: 06 Lun: 00
      Vendor: VMware,  Model: VMware Virtual S Rev: 1.0
      Type:   Direct-Access                    ANSI SCSI revision: 02
1 new or changed device(s) found.
        [3:0:6:0]
0 remapped or resized device(s) found.
0 device(s) removed.

 

[root@ol7ora12rf2][/root]$ ls -l /dev/sd*
brw-rw----. 1 root disk     8,   0 Dec 29 21:33 /dev/sda
brw-rw----. 1 root disk     8,   1 Dec 29 21:33 /dev/sda1
brw-rw----. 1 root disk     8,   2 Dec 29 21:33 /dev/sda2
brw-rw----. 1 grid asmadmin 8,  16 Jan  1 12:16 /dev/sdb
brw-rw----. 1 grid asmadmin 8,  32 Jan  1 12:16 /dev/sdc
brw-rw----. 1 grid asmadmin 8,  48 Jan  1 12:16 /dev/sdd
brw-rw----. 1 grid asmadmin 8,  64 Jan  1 12:16 /dev/sde
brw-rw----. 1 grid asmadmin 8,  80 Jan  1 12:16 /dev/sdf
brw-rw----. 1 grid asmadmin 8,  96 Jan  1 12:16 /dev/sdg
brw-rw----. 1 root disk     8, 112 Jan  1 12:16 /dev/sdh

 

--1번 노드 (root os user)
[root@ol7ora12rf1][/root]$ /usr/lib/udev/scsi_id --whitelisted --replace-whitespace --device=/dev/sdh
36000c296d91f4f3acad9e0269556ea8c

[root@ol7ora12rf1][/root]$ cat /etc/udev/rules.d/99-oracle-asmdevices.rules
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29be3461e82ead5bac00667ffba", SYMLINK+="oracleasm/disks/CRS1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292b19a7e4bec0ae55ea582d62a", SYMLINK+="oracleasm/disks/CRS2", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c299c11b68fe30ad90dffdd12bba", SYMLINK+="oracleasm/disks/CRS3", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292006e0eb5849448351f3c74ef", SYMLINK+="oracleasm/disks/DATA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29459cd8180f417bc7733a3c1b4", SYMLINK+="oracleasm/disks/FRA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c295816c4f95a2f55045af76ec2e", SYMLINK+="oracleasm/disks/GIMR1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"

[root@ol7ora12rf1][/root]$ vi /etc/udev/rules.d/99-oracle-asmdevices.rules
[root@ol7ora12rf1][/root]$ cat /etc/udev/rules.d/99-oracle-asmdevices.rules
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29be3461e82ead5bac00667ffba", SYMLINK+="oracleasm/disks/CRS1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292b19a7e4bec0ae55ea582d62a", SYMLINK+="oracleasm/disks/CRS2", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c299c11b68fe30ad90dffdd12bba", SYMLINK+="oracleasm/disks/CRS3", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292006e0eb5849448351f3c74ef", SYMLINK+="oracleasm/disks/DATA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29459cd8180f417bc7733a3c1b4", SYMLINK+="oracleasm/disks/FRA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c295816c4f95a2f55045af76ec2e", SYMLINK+="oracleasm/disks/GIMR1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c296d91f4f3acad9e0269556ea8c", SYMLINK+="oracleasm/disks/ACFS1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
--> ACFS1_1 추가

 

[root@ol7ora12rf1][/root]$ udevadm control --reload-rules
[root@ol7ora12rf1][/root]$ udevadm trigger

[root@ol7ora12rf1][/root]$ ls -l /dev/oracleasm/disks
total 0
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 ACFS1_1 -> ../../sdh
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 CRS1 -> ../../sdb
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 CRS2 -> ../../sdc
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 CRS3 -> ../../sdd
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 DATA1_1 -> ../../sde
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 FRA1_1 -> ../../sdf
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 GIMR1_1 -> ../../sdg

 

--2번 노드 (root os user)

[root@ol7ora12rf2][/root]$ /usr/lib/udev/scsi_id --whitelisted --replace-whitespace --device=/dev/sdh
36000c296d91f4f3acad9e0269556ea8c
[root@ol7ora12rf2][/root]$ cat /etc/udev/rules.d/99-oracle-asmdevices.rules
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29be3461e82ead5bac00667ffba", SYMLINK+="oracleasm/disks/CRS1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292b19a7e4bec0ae55ea582d62a", SYMLINK+="oracleasm/disks/CRS2", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c299c11b68fe30ad90dffdd12bba", SYMLINK+="oracleasm/disks/CRS3", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292006e0eb5849448351f3c74ef", SYMLINK+="oracleasm/disks/DATA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29459cd8180f417bc7733a3c1b4", SYMLINK+="oracleasm/disks/FRA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c295816c4f95a2f55045af76ec2e", SYMLINK+="oracleasm/disks/GIMR1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"

[root@ol7ora12rf2][/root]$ vi /etc/udev/rules.d/99-oracle-asmdevices.rules
[root@ol7ora12rf2][/root]$ cat /etc/udev/rules.d/99-oracle-asmdevices.rules
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29be3461e82ead5bac00667ffba", SYMLINK+="oracleasm/disks/CRS1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292b19a7e4bec0ae55ea582d62a", SYMLINK+="oracleasm/disks/CRS2", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c299c11b68fe30ad90dffdd12bba", SYMLINK+="oracleasm/disks/CRS3", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292006e0eb5849448351f3c74ef", SYMLINK+="oracleasm/disks/DATA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29459cd8180f417bc7733a3c1b4", SYMLINK+="oracleasm/disks/FRA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c295816c4f95a2f55045af76ec2e", SYMLINK+="oracleasm/disks/GIMR1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c296d91f4f3acad9e0269556ea8c", SYMLINK+="oracleasm/disks/ACFS1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"

 

[root@ol7ora12rf2][/root]$ udevadm control --reload-rules
[root@ol7ora12rf2][/root]$ udevadm trigger

[root@ol7ora12rf2][/root]$ ls -l /dev/oracleasm/disks
total 0
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 ACFS1_1 -> ../../sdh
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 CRS1 -> ../../sdb
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 CRS2 -> ../../sdc
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 CRS3 -> ../../sdd
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 DATA1_1 -> ../../sde
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 FRA1_1 -> ../../sdf
lrwxrwxrwx. 1 root root 9 Jan  1 12:20 GIMR1_1 -> ../../sdg

 

6-2. ASM 디스크 그룹 추가

 

[+ASM1:grid@ol7ora12rf1][/home/grid]$ alias sa
alias sa='rlwrap sqlplus "/as sysasm"'

[+ASM1:grid@ol7ora12rf1][/home/grid]$ sa

SQL*Plus: Release 12.2.0.1.0 Production on Thu Jan 1 12:25:16 2026

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<SYS@+ASM1>$ CREATE DISKGROUP ACFS1 EXTERNAL REDUNDANCY DISK '/dev/oracleasm/disks/ACFS1_1' SIZE 40960M;

Diskgroup created.

Elapsed: 00:00:07.91

[ol7ora12rf1]<SYS@+ASM1>$

SET LINE 200
COL DISK_GROUP FOR A10
COL LABEL FOR A10
COL STATE FOR A10
SELECT A.NAME AS DISK_GROUP, D.NAME "LABEL", A.STATE
  FROM V$ASM_DISK D
     , V$ASM_DISKGROUP A
 WHERE D.GROUP_NUMBER=A.GROUP_NUMBER
   and A.NAME = 'ACFS1'
   ORDER BY 2
;

DISK_GROUP LABEL      STATE
---------- ---------- ----------
ACFS1      ACFS1_0000 MOUNTED

1 row selected.

Elapsed: 00:00:00.06

 

col COMPATIBILITY form a10
col DATABASE_COMPATIBILITY form a30
col NAME form a20
select group_number, name, compatibility, database_compatibility
from v$asm_diskgroup
where NAME = 'ACFS1';

GROUP_NUMBER NAME                 COMPATIBIL DATABASE_COMPATIBILITY
------------ -------------------- ---------- ------------------------------
           5 ACFS1                11.2.0.2.0 10.1.0.0.0

1 row selected.

Elapsed: 00:00:00.02

 

[ol7ora12rf1]<SYS@+ASM1>$ ALTER DISKGROUP ACFS1 SET ATTRIBUTE 'compatible.asm' = '12.2.0.1.0';


col COMPATIBILITY form a10
col DATABASE_COMPATIBILITY form a30
col NAME form a20
select group_number, name, compatibility, database_compatibility
from v$asm_diskgroup
where NAME = 'ACFS1';

GROUP_NUMBER NAME                 COMPATIBIL DATABASE_COMPATIBILITY
------------ -------------------- ---------- ------------------------------
           5 ACFS1                12.2.0.1.0 10.1.0.0.0

1 row selected.

Elapsed: 00:00:00.02


[+ASM2:grid@ol7ora12rf2][/home/grid]$ asmcmd
ASMCMD [+] > lsdg
State    Type    Rebal  Sector  Logical_Sector  Block       AU  Total_MB  Free_MB  Req_mir_free_MB  Usable_file_MB  Offline_disks  Voting_files  Name
MOUNTED  NORMAL  N         512             512   4096  4194304      6144     5276             2048            1614              0             Y  CRS/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536    18140                0           18140              0             N  DATA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536    61116                0           61116              0             N  FRA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     40960     6808                0            6808              0             N  MGMT/

ASMCMD [+] > mount ACFS1
ASMCMD [+] > lsdg
State    Type    Rebal  Sector  Logical_Sector  Block       AU  Total_MB  Free_MB  Req_mir_free_MB  Usable_file_MB  Offline_disks  Voting_files  Name
MOUNTED  EXTERN  N         512             512   4096  1048576     40960    40862                0           40862              0             N  ACFS1/
MOUNTED  NORMAL  N         512             512   4096  4194304      6144     5276             2048            1614              0             Y  CRS/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536    18140                0           18140              0             N  DATA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536    61116                0           61116              0             N  FRA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     40960     6808                0            6808              0             N  MGMT/


[+ASM1:grid@ol7ora12rf1][/home/grid]$ crsctl status resource ora.ACFS1.dg -t
--------------------------------------------------------------------------------
Name           Target  State        Server                   State details
--------------------------------------------------------------------------------
Local Resources
--------------------------------------------------------------------------------
ora.ACFS1.dg
               ONLINE  ONLINE       ol7ora12rf1              STABLE
               ONLINE  ONLINE       ol7ora12rf2              STABLE
--------------------------------------------------------------------------------

 

6-3. 커널 변경

 

--기존에 사용하던 커널이 "/boot/vmlinuz-5.4.17-2102.201.3.el7uek.x86_64" 이었음
--해당 커널에서는 ACFS 드라이버 지원이 불가하여 "/boot/vmlinuz-3.10.0-1160.el7.x86_64" 커널로 변경

 

--1번 노드 (root os user)

[root@ol7ora12rf1][/root]$ crsctl stop crs

[root@ol7ora12rf1][/root]$ ls -l /boot/vmlinuz-*
-rwxr-xr-x. 1 root root 6771656 Oct  2 18:18 /boot/vmlinuz-0-rescue-f31ed6c0df6d45eb99ea3f099ac6ef41
-rwxr-xr-x. 1 root root 6771656 Oct  2  2020 /boot/vmlinuz-3.10.0-1160.el7.x86_64
-rwxr-xr-x. 1 root root 8918536 Apr 24  2021 /boot/vmlinuz-5.4.17-2102.201.3.el7uek.x86_64
[root@ol7ora12rf1][/root]$ grubby --set-default /boot/vmlinuz-3.10.0-1160.el7.x86_64
[root@ol7ora12rf1][/root]$ shutdown -Fr now

[root@ol7ora12rf1][/root]$ uname -r
3.10.0-1160.el7.x86_64

 

--2번 노드 (root os user)
[root@ol7ora12rf2][/root]$ crsctl stop crs
[root@ol7ora12rf2][/root]$ ls -l /boot/vmlinuz-*
-rwxr-xr-x. 1 root root 6771656 Oct  2 18:18 /boot/vmlinuz-0-rescue-f31ed6c0df6d45eb99ea3f099ac6ef41
-rwxr-xr-x. 1 root root 6771656 Oct  2  2020 /boot/vmlinuz-3.10.0-1160.el7.x86_64
-rwxr-xr-x. 1 root root 8918536 Apr 24  2021 /boot/vmlinuz-5.4.17-2102.201.3.el7uek.x86_64
[root@ol7ora12rf2][/root]$ grubby --set-default /boot/vmlinuz-3.10.0-1160.el7.x86_64
[root@ol7ora12rf2][/root]$ shutdown -Fr now

[root@ol7ora12rf2][/root]$ uname -r
3.10.0-1160.el7.x86_64


6-4. acfs 드라이버 설치

 

--1번 노드 (root os user)

[root@ol7ora12rf1][/root]$ /u01/app/12c/grid/bin/acfsroot install
ACFS-9300: ADVM/ACFS distribution files found.
ACFS-9314: Removing previous ADVM/ACFS installation.
ACFS-9315: Previous ADVM/ACFS components successfully removed.
ACFS-9307: Installing requested ADVM/ACFS software.
ACFS-9308: Loading installed ADVM/ACFS drivers.
ACFS-9321: Creating udev for ADVM/ACFS.
ACFS-9323: Creating module dependencies - this may take some time.
ACFS-9154: Loading 'oracleoks.ko' driver.
ACFS-9154: Loading 'oracleadvm.ko' driver.
ACFS-9154: Loading 'oracleacfs.ko' driver.
ACFS-9327: Verifying ADVM/ACFS devices.
ACFS-9156: Detecting control device '/dev/asm/.asm_ctl_spec'.
ACFS-9156: Detecting control device '/dev/ofsctl'.
ACFS-9309: ADVM/ACFS installation correctness verified.

 

[root@ol7ora12rf1][/root]$ /u01/app/12c/grid/bin/acfsload start
ACFS-9391: Checking for existing ADVM/ACFS installation.
ACFS-9392: Validating ADVM/ACFS installation files for operating system.
ACFS-9393: Verifying ASM Administrator setup.
ACFS-9308: Loading installed ADVM/ACFS drivers.
ACFS-9327: Verifying ADVM/ACFS devices.
ACFS-9156: Detecting control device '/dev/asm/.asm_ctl_spec'.
ACFS-9156: Detecting control device '/dev/ofsctl'.
ACFS-9322: completed

 

[root@ol7ora12rf1][/root]$ /u01/app/12c/grid/bin/acfsroot enable
ACFS-9376: Adding ADVM/ACFS drivers resource succeeded.
CRS-2672: Attempting to start 'ora.drivers.acfs' on 'ol7ora12rf1'
CRS-2676: Start of 'ora.drivers.acfs' on 'ol7ora12rf1' succeeded
ACFS-9380: Starting ADVM/ACFS drivers resource succeeded.

 

[root@ol7ora12rf1][/root]$ lsmod | grep oracle
oracleacfs           5116285  0
oracleadvm            810063  0
oracleoks             644150  2 oracleacfs,oracleadvm

 

--2번 노드 (root os user)

[root@ol7ora12rf2][/root]$ /u01/app/12c/grid/bin/acfsroot install
ACFS-9300: ADVM/ACFS distribution files found.
ACFS-9314: Removing previous ADVM/ACFS installation.
ACFS-9315: Previous ADVM/ACFS components successfully removed.
ACFS-9307: Installing requested ADVM/ACFS software.
ACFS-9308: Loading installed ADVM/ACFS drivers.
ACFS-9321: Creating udev for ADVM/ACFS.
ACFS-9323: Creating module dependencies - this may take some time.
ACFS-9154: Loading 'oracleoks.ko' driver.
ACFS-9154: Loading 'oracleadvm.ko' driver.
ACFS-9154: Loading 'oracleacfs.ko' driver.
ACFS-9327: Verifying ADVM/ACFS devices.
ACFS-9156: Detecting control device '/dev/asm/.asm_ctl_spec'.
ACFS-9156: Detecting control device '/dev/ofsctl'.
ACFS-9309: ADVM/ACFS installation correctness verified.

 

[root@ol7ora12rf2][/root]$ /u01/app/12c/grid/bin/acfsload start
ACFS-9391: Checking for existing ADVM/ACFS installation.
ACFS-9392: Validating ADVM/ACFS installation files for operating system.
ACFS-9393: Verifying ASM Administrator setup.
ACFS-9308: Loading installed ADVM/ACFS drivers.
ACFS-9327: Verifying ADVM/ACFS devices.
ACFS-9156: Detecting control device '/dev/asm/.asm_ctl_spec'.
ACFS-9156: Detecting control device '/dev/ofsctl'.
ACFS-9322: completed

 

[root@ol7ora12rf2][/root]$ lsmod | grep oracle
oracleacfs           5116285  0
oracleadvm            810063  0
oracleoks             644150  2 oracleacfs,oracleadvm


[root@ol7ora12rf2][/root]$ /u01/app/12c/grid/bin/acfsroot enable
ACFS-9376: Adding ADVM/ACFS drivers resource succeeded.
CRS-2672: Attempting to start 'ora.drivers.acfs' on 'ol7ora12rf2'
CRS-2676: Start of 'ora.drivers.acfs' on 'ol7ora12rf2' succeeded
ACFS-9380: Starting ADVM/ACFS drivers resource succeeded.


6-4. ACFS 볼륨 생성


[+ASM1:grid@ol7ora12rf1][/home/grid]$ asmcmd
ASMCMD [+] > volcreate -G ACFS1 -s 10G ACFS1_VOL1
ASMCMD [+] > volinfo --all
Diskgroup Name: ACFS1

         Volume Name: ACFS1_VOL1
         Volume Device: /dev/asm/acfs1_vol1-244
         State: ENABLED
         Size (MB): 10240
         Resize Unit (MB): 64
         Redundancy: UNPROT
         Stripe Columns: 8
         Stripe Width (K): 1024
         Usage:
         Mountpath:


[+ASM1:grid@ol7ora12rf1][/home/grid]$ crsctl stat res ora.ACFS1.ACFS1_VOL1.advm -t
--------------------------------------------------------------------------------
Name           Target  State        Server                   State details
--------------------------------------------------------------------------------
Local Resources
--------------------------------------------------------------------------------
ora.ACFS1.ACFS1_VOL1.advm
               ONLINE  ONLINE       ol7ora12rf1              STABLE
               ONLINE  ONLINE       ol7ora12rf2              STABLE
--------------------------------------------------------------------------------


[root@ol7ora12rf1][/root]$ mkdir /acfs1_vol1
[root@ol7ora12rf1][/root]$ chown oracle:oinstall /acfs1_vol1

[root@ol7ora12rf2][/root]$ mkdir /acfs1_vol1
[root@ol7ora12rf2][/root]$ chown oracle:oinstall /acfs1_vol1

 

 

[+ASM1:grid@ol7ora12rf1][/home/grid]$ cd /dev/asm
[+ASM1:grid@ol7ora12rf1][/dev/asm]$ ls
acfs1_vol1-436

[+ASM1:grid@ol7ora12rf1][/dev/asm]$ cd ~
[+ASM1:grid@ol7ora12rf1][/home/grid]$ ls -l /dev/asm
total 0
brwxrwx---. 1 root asmadmin 252, 124929 Jan  4 10:40 acfs1_vol1-244

[+ASM1:grid@ol7ora12rf1][/home/grid]$ mkfs -t acfs /dev/asm/acfs1_vol1-244
mkfs.acfs: version                   = 12.2.0.1.0
mkfs.acfs: on-disk version           = 46.0
mkfs.acfs: volume                    = /dev/asm/acfs1_vol1-244
mkfs.acfs: volume size               = 10737418240  (  10.00 GB )
mkfs.acfs: Format complete.

 

[root@ol7ora12rf1][/root]$ srvctl add filesystem -d /dev/asm/acfs1_vol1-244 -m /acfs1_vol1 -u oracle -fstype ACFS -autostart ALWAYS
[root@ol7ora12rf1][/root]$ crsctl stat res ora.acfs1.acfs1_vol1.acfs -t
--------------------------------------------------------------------------------
Name           Target  State        Server                   State details
--------------------------------------------------------------------------------
Local Resources
--------------------------------------------------------------------------------
ora.acfs1.acfs1_vol1.acfs
               OFFLINE OFFLINE      ol7ora12rf1              STABLE
               OFFLINE OFFLINE      ol7ora12rf2              STABLE
--------------------------------------------------------------------------------

 

[root@ol7ora12rf1][/root]$ srvctl start filesystem -d /dev/asm/acfs1_vol1-244
[root@ol7ora12rf1][/root]$ crsctl stat res ora.acfs1.acfs1_vol1.acfs -t
--------------------------------------------------------------------------------
Name           Target  State        Server                   State details
--------------------------------------------------------------------------------
Local Resources
--------------------------------------------------------------------------------
ora.acfs1.acfs1_vol1.acfs
               ONLINE  ONLINE       ol7ora12rf1              mounted on /acfs1_vo
                                                             l1,STABLE
               ONLINE  ONLINE       ol7ora12rf2              mounted on /acfs1_vo
                                                             l1,STABLE
--------------------------------------------------------------------------------


[root@ol7ora12rf1][/root]$ srvctl config filesystem
Volume device: /dev/asm/acfs1_vol1-244
Diskgroup name: acfs1
Volume name: acfs1_vol1
Canonical volume device: /dev/asm/acfs1_vol1-244
Accelerator volume devices:
Mountpoint path: /acfs1_vol1
Mount point owner: oracle
Mount users:
Type: ACFS
Mount options:
Description:
ACFS file system is enabled
ACFS file system is individually enabled on nodes:
ACFS file system is individually disabled on nodes:

 

[root@ol7ora12rf1][/root]$ df -h |grep acfs
/dev/asm/acfs1_vol1-244   10G  506M  9.6G   5% /acfs1_vol1

 

[root@ol7ora12rf2][/root]$ df -h |grep acfs
/dev/asm/acfs1_vol1-244   10G  506M  9.6G   5% /acfs1_vol1

 

6-5. 볼륨 공간을 10기가에서 32기가로 확장

 

[+ASM1:grid@ol7ora12rf1][/home/grid]$ asmcmd lsdg
State    Type    Rebal  Sector  Logical_Sector  Block       AU  Total_MB  Free_MB  Req_mir_free_MB  Usable_file_MB  Offline_disks  Voting_files  Name
MOUNTED  EXTERN  N         512             512   4096  1048576     40960    30619                0           30619              0             N  ACFS1/
MOUNTED  NORMAL  N         512             512   4096  4194304      6144     5276             2048            1614              0             Y  CRS/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536    18120                0           18120              0             N  DATA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536    60936                0           60936              0             N  FRA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     40960     6808                0            6808              0             N  MGMT/

 

[root@ol7ora12rf1][/root]$ /sbin/acfsutil size 32G /acfs1_vol1
acfsutil size: new file system size: 34359738368 (32768MB)

 

[root@ol7ora12rf1][/root]$ df -h /acfs1_vol1
Filesystem               Size  Used Avail Use% Mounted on
/dev/asm/acfs1_vol1-244   32G  550M   32G   2% /acfs1_vol1

 

[root@ol7ora12rf2][/root]$ df -h /acfs1_vol1
Filesystem               Size  Used Avail Use% Mounted on
/dev/asm/acfs1_vol1-244   32G  550M   32G   2% /acfs1_vol1


[+ASM1:grid@ol7ora12rf1][/home/grid]$ asmcmd volinfo -G ACFS1 ACFS1_VOL1
Diskgroup Name: ACFS1

         Volume Name: ACFS1_VOL1
         Volume Device: /dev/asm/acfs1_vol1-244
         State: ENABLED
         Size (MB): 32768
         Resize Unit (MB): 64
         Redundancy: UNPROT
         Stripe Columns: 8
         Stripe Width (K): 1024
         Usage: ACFS
         Mountpath: /acfs1_vol1

 

7. 소스에서 db replay 워크로드 캡처

 

7-1. oracle rat 관련 라이센스 확인

 

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ ss

SQL*Plus: Release 12.2.0.1.0 Production on Thu Jan 1 16:13:13 2026

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<SYS@ORA12RF1>$

set lines 200
col PARAMETER for a30
col VALUE for a10
SELECT PARAMETER, VALUE FROM V$OPTION WHERE PARAMETER = 'Real Application Testing';

PARAMETER                      VALUE
------------------------------ ----------
Real Application Testing       TRUE

1 row selected.

Elapsed: 00:00:00.01

 

7-2. 캡처 시작 전 소스 DB의 파라미터를 설정

 

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ ss

SQL*Plus: Release 12.2.0.1.0 Production on Sun Jan 4 11:06:07 2026

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<SYS@ORA12RF1>$


SET LINESIZE 300
SET PAGESIZE 100
COL "TYPE" FORMAT A10
COL "PARAMETER" FORMAT A45
COL "VALUE" FORMAT A20
COL "DISPLAY_VALUE" FORMAT A20
COL "DEFAULT_VALUE" FORMAT A15
COL "IS_DEFAULT" FORMAT A10
COL "IS_SESSION_MODI" FORMAT A15
COL "IS_SYSTEM_MODI" FORMAT A15
COL "IS_INSTANCE_MODI" FORMAT A15
COL "IS_PDB_MODI" FORMAT A15

SELECT *
  FROM (
       SELECT 'STANDARD' AS "TYPE"
            , UP.NAME AS "PARAMETER"
            , UP.VALUE AS "VALUE"
            , UP.DISPLAY_VALUE AS "DISPLAY_VALUE"
            , UP.DEFAULT_VALUE AS "DEFAULT_VALUE"
            , UP.ISDEFAULT AS "IS_DEFAULT"
            , UP.ISSES_MODIFIABLE AS "IS_SESSION_MODI"
            , UP.ISSYS_MODIFIABLE AS "IS_SYSTEM_MODI"
            , UP.ISINSTANCE_MODIFIABLE AS "IS_INSTANCE_MODI"
            , UP.ISPDB_MODIFIABLE AS "IS_PDB_MODI"
         FROM V$PARAMETER UP
        WHERE NOT EXISTS (
              SELECT 1
                FROM SYS.X$KSPPI K
               WHERE K.KSPPINM = UP.NAME
                 AND K.KSPPINM LIKE '\_%' ESCAPE '\'
              )
       UNION ALL
       SELECT 'HIDDEN' AS "TYPE"
            , A.KSPPINM AS "PARAMETER"
            , B.KSPPSTVL AS "VALUE"
            , B.KSPPSTDVL AS "DISPLAY_VALUE"
            , B.KSPPSTDFL AS "DEFAULT_VALUE"
            , B.KSPPSTDF AS "IS_DEFAULT"
            , DECODE(BITAND(A.KSPPIFLG / 256, 1), 1, 'TRUE', 'FALSE') AS "IS_SESSION_MODI"
            , DECODE(BITAND(A.KSPPIFLG / 65536, 3), 1, 'IMMEDIATE', 2, 'DEFERRED', 3, 'IMMEDIATE', 'FALSE') AS "IS_SYSTEM_MODI"
            , DECODE(BITAND(A.KSPPIFLG, 4), 4, 'FALSE', DECODE(BITAND(A.KSPPIFLG / 65536, 3), 0, 'FALSE', 'TRUE')) AS "IS_INSTANCE_MODI"
            , DECODE(BITAND(A.KSPPIFLG / 524288, 1), 1, 'TRUE', 'FALSE') AS "IS_PDB_MODI"
         FROM SYS.X$KSPPI A
            , SYS.X$KSPPCV B
        WHERE A.INDX = B.INDX
          AND A.KSPPINM LIKE '\_%' ESCAPE '\'
       ) A
 WHERE UPPER(A."PARAMETER") IN (
       UPPER('optimizer_mode')
     , UPPER('_optimizer_unnest_scalar_sq')
     , UPPER('_optimizer_push_pred_cost_based')
     , UPPER('_optimizer_cost_based_transformation')
     , UPPER('_optimizer_skip_scan_enabled')
     , UPPER('_b_tree_bitmap_plans')
     )
 ORDER BY A."TYPE", A."PARAMETER";

TYPE       PARAMETER                                     VALUE                DISPLAY_VALUE        DEFAULT_VALUE   IS_DEFAULT IS_SESSION_MODI IS_SYSTEM_MODI  IS_INSTANCE_MOD IS_PDB_MODI
---------- --------------------------------------------- -------------------- -------------------- --------------- ---------- --------------- --------------- --------------- ---------------
HIDDEN     _b_tree_bitmap_plans                          TRUE                 TRUE                 FALSE           TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_cost_based_transformation          LINEAR               LINEAR               linear          TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_push_pred_cost_based               TRUE                 TRUE                 TRUE            TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_skip_scan_enabled                  TRUE                 TRUE                 TRUE            TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_unnest_scalar_sq                   TRUE                 TRUE                 TRUE            TRUE       TRUE            IMMEDIATE       TRUE            TRUE
STANDARD   optimizer_mode                                ALL_ROWS             ALL_ROWS             all_rows        TRUE       TRUE            IMMEDIATE       TRUE            TRUE

6 rows selected.

Elapsed: 00:00:00.01

 

-- 1. Optimizer Mode (표준 파라미터)
ALTER SYSTEM SET OPTIMIZER_MODE = ALL_ROWS SCOPE=BOTH SID='*';

-- 2. Hidden Parameters (큰따옴표 필수, SCOPE 먼저 선언)
ALTER SYSTEM SET "_optimizer_unnest_scalar_sq" = FALSE SCOPE=BOTH SID='*';
ALTER SYSTEM SET "_optimizer_push_pred_cost_based" = TRUE SCOPE=BOTH SID='*';
ALTER SYSTEM SET "_optimizer_cost_based_transformation" = ON SCOPE=BOTH SID='*';
ALTER SYSTEM SET "_optimizer_skip_scan_enabled" = TRUE SCOPE=BOTH SID='*';
ALTER SYSTEM SET "_b_tree_bitmap_plans" = TRUE SCOPE=BOTH SID='*';

 

--바뀐 파라미터 확인

SET LINESIZE 300
SET PAGESIZE 100
COL "TYPE" FORMAT A10
COL "PARAMETER" FORMAT A45
COL "VALUE" FORMAT A20
COL "DISPLAY_VALUE" FORMAT A20
COL "DEFAULT_VALUE" FORMAT A15
COL "IS_DEFAULT" FORMAT A10
COL "IS_SESSION_MODI" FORMAT A15
COL "IS_SYSTEM_MODI" FORMAT A15
COL "IS_INSTANCE_MODI" FORMAT A15
COL "IS_PDB_MODI" FORMAT A15

SELECT *
  FROM (
       SELECT 'STANDARD' AS "TYPE"
            , UP.NAME AS "PARAMETER"
            , UP.VALUE AS "VALUE"
            , UP.DISPLAY_VALUE AS "DISPLAY_VALUE"
            , UP.DEFAULT_VALUE AS "DEFAULT_VALUE"
            , UP.ISDEFAULT AS "IS_DEFAULT"
            , UP.ISSES_MODIFIABLE AS "IS_SESSION_MODI"
            , UP.ISSYS_MODIFIABLE AS "IS_SYSTEM_MODI"
            , UP.ISINSTANCE_MODIFIABLE AS "IS_INSTANCE_MODI"
            , UP.ISPDB_MODIFIABLE AS "IS_PDB_MODI"
         FROM V$PARAMETER UP
        WHERE NOT EXISTS (
              SELECT 1
                FROM SYS.X$KSPPI K
               WHERE K.KSPPINM = UP.NAME
                 AND K.KSPPINM LIKE '\_%' ESCAPE '\'
              )
       UNION ALL
       SELECT 'HIDDEN' AS "TYPE"
            , A.KSPPINM AS "PARAMETER"
            , B.KSPPSTVL AS "VALUE"
            , B.KSPPSTDVL AS "DISPLAY_VALUE"
            , B.KSPPSTDFL AS "DEFAULT_VALUE"
            , B.KSPPSTDF AS "IS_DEFAULT"
            , DECODE(BITAND(A.KSPPIFLG / 256, 1), 1, 'TRUE', 'FALSE') AS "IS_SESSION_MODI"
            , DECODE(BITAND(A.KSPPIFLG / 65536, 3), 1, 'IMMEDIATE', 2, 'DEFERRED', 3, 'IMMEDIATE', 'FALSE') AS "IS_SYSTEM_MODI"
            , DECODE(BITAND(A.KSPPIFLG, 4), 4, 'FALSE', DECODE(BITAND(A.KSPPIFLG / 65536, 3), 0, 'FALSE', 'TRUE')) AS "IS_INSTANCE_MODI"
            , DECODE(BITAND(A.KSPPIFLG / 524288, 1), 1, 'TRUE', 'FALSE') AS "IS_PDB_MODI"
         FROM SYS.X$KSPPI A
            , SYS.X$KSPPCV B
        WHERE A.INDX = B.INDX
          AND A.KSPPINM LIKE '\_%' ESCAPE '\'
       ) A
 WHERE UPPER(A."PARAMETER") IN (
       UPPER('optimizer_mode')
     , UPPER('_optimizer_unnest_scalar_sq')
     , UPPER('_optimizer_push_pred_cost_based')
     , UPPER('_optimizer_cost_based_transformation')
     , UPPER('_optimizer_skip_scan_enabled')
     , UPPER('_b_tree_bitmap_plans')
     )
 ORDER BY A."TYPE", A."PARAMETER";

TYPE       PARAMETER                                     VALUE                DISPLAY_VALUE        DEFAULT_VALUE   IS_DEFAULT IS_SESSION_MODI IS_SYSTEM_MODI  IS_INSTANCE_MOD IS_PDB_MODI
---------- --------------------------------------------- -------------------- -------------------- --------------- ---------- --------------- --------------- --------------- ---------------
HIDDEN     _b_tree_bitmap_plans                          TRUE                 TRUE                 FALSE           TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_cost_based_transformation          ON                   ON                   linear          TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_push_pred_cost_based               TRUE                 TRUE                 TRUE            TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_skip_scan_enabled                  TRUE                 TRUE                 TRUE            TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_unnest_scalar_sq                   FALSE                FALSE                TRUE            TRUE       TRUE            IMMEDIATE       TRUE            TRUE
STANDARD   optimizer_mode                                ALL_ROWS             ALL_ROWS             all_rows        TRUE       TRUE            IMMEDIATE       TRUE            TRUE

6 rows selected.

Elapsed: 00:00:00.01

 

7-3. 워크로드 캡처

 

[ORA12RF1:oracle@ol7ora12rf1][/acfs1_vol1]$ mkdir -pv /acfs1_vol1/capture_dbreplay
mkdir: created directory ‘/acfs1_vol1/capture_dbreplay’

 

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ ss

SQL*Plus: Release 12.2.0.1.0 Production on Thu Jan 1 16:16:24 2026

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<SYS@ORA12RF1>$ CREATE OR REPLACE DIRECTORY CAP_DIR AS '/acfs1_vol1/capture_dbreplay';

Directory created.

Elapsed: 00:00:00.39
[ol7ora12rf1]<
SYS@ORA12RF1>$ GRANT READ, WRITE ON DIRECTORY CAP_DIR TO PUBLIC;

Grant succeeded.

Elapsed: 00:00:00.02
[ol7ora12rf1]<
SYS@ORA12RF1>$

SET LINESIZE 200
SET PAGESIZE 100
COL TYPE FORMAT A10
COL NAME FORMAT A20
COL ATTRIBUTE FORMAT A15
COL VALUE FORMAT A15
COL STATUS FORMAT A15
COL DIR_PATH FORMAT A30

PROMPT =========================================================
PROMPT [PRE-CHECK 1] Check Existing Filters (Target: FILTER_TUNER)
PROMPT =========================================================

SELECT TYPE
     , NAME
     , ATTRIBUTE
     , VALUE
  FROM DBA_WORKLOAD_FILTERS
 WHERE NAME = 'FILTER_TUNER';

no rows selected

Elapsed: 00:00:00.00

 

PROMPT =========================================================
PROMPT [PRE-CHECK 2] Check Active Captures (Status: IN PROGRESS)
PROMPT =========================================================

-- 현재 진행 중인 캡처가 있는지 확인 (있다면 먼저 종료해야 함)
SELECT ID
     , NAME
     , STATUS
     , START_TIME
  FROM DBA_WORKLOAD_CAPTURES
 WHERE STATUS = 'IN PROGRESS';

no rows selected

Elapsed: 00:00:00.01

-- EXEC DBMS_WORKLOAD_CAPTURE.DELETE_FILTER('FILTER_TUNER');

 

BEGIN
  DBMS_WORKLOAD_CAPTURE.ADD_FILTER (
     fname    => 'FILTER_TUNER'
   , fattribute => 'USER'
   , fvalue     => 'TUNER'
  );
END;
/

 

SELECT TYPE
     , NAME
     , ATTRIBUTE
     , VALUE
  FROM DBA_WORKLOAD_FILTERS
 WHERE NAME = 'FILTER_TUNER';

TYPE       NAME                 ATTRIBUTE       VALUE
---------- -------------------- --------------- ---------------
CAPTURE    FILTER_TUNER         USER            TUNER

1 row selected.

Elapsed: 00:00:00.00

 

--캡처 시작
BEGIN
  DBMS_WORKLOAD_CAPTURE.START_CAPTURE (
     name     => 'CAP_12C_TO_19C'
   , dir      => 'CAP_DIR'
   , duration => NULL  -- 수동으로 종료할 것이므로 NULL, 시간지정 가능(초 단위)
   , default_action => 'EXCLUDE' -- 필터에 정의되지 않은 것은 제외 (TUNER만 캡처됨)
   -- 만약 필터 없이 전체를 잡고 싶다면 default_action => 'INCLUDE' 로 설정
  );
END;
/

 

PL/SQL procedure successfully completed.

Elapsed: 00:00:11.34


SET LINESIZE 200
SET PAGESIZE 100

COL ID FORMAT 999999
COL NAME FORMAT A30
COL STATUS FORMAT A15
COL START_TIME FORMAT A20

ALTER SESSION SET NLS_DATE_FORMAT = 'YYYY-MM-DD HH24:MI:SS';

 

-- 쿼리 실행
SELECT ID
     , NAME
     , STATUS
     , START_TIME
  FROM DBA_WORKLOAD_CAPTURES
 WHERE STATUS = 'IN PROGRESS';

     ID NAME                           STATUS          START_TIME
------- ------------------------------ --------------- --------------------
     11 CAP_12C_TO_19C                 IN PROGRESS     2026-01-04 02:06:53

1 row selected.

Elapsed: 00:00:00.00


--소스 DB에 부하를 발생 시킴

--1번 노드
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ nohup /home/oracle/db_replay_load/loop_db_replay_load.sh 100 > /home/oracle/db_replay_load/load_run.log 2>&1 &
[1] 4541

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ ps -ef | grep loop_db_replay_load.sh
oracle    4541  7537  0 11:07 pts/2    00:00:00 /bin/bash /home/oracle/db_replay_load/loop_db_replay_load.sh 100
oracle    4856  7537  0 11:08 pts/2    00:00:00 grep --color=auto loop_db_replay_load.sh

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle/db_replay_load]$ tail -f /home/oracle/db_replay_load/load_run.log

Elapsed: 00:00:00.01

PL/SQL procedure successfully completed.

Elapsed: 00:00:00.00

PL/SQL procedure successfully completed.

Elapsed: 00:00:00.00

--소요 시간 체크 (load_run.log)
========================================================
         Oracle Workload Generator Wrapper
========================================================
Start Time : Sun Jan  4 12:10:18 KST 2026
Mode       : Count Loop (100 회 실행)
========================================================
...
========================================================
Workload Generation Finished at Sun Jan  4 12:32:36 KST 2026
========================================================
--약 22분 걸림

 


--2번 노드
[ORA12RF2:oracle@ol7ora12rf2][/home/oracle]$ nohup /home/oracle/db_replay_load/loop_db_replay_load.sh 100 > /home/oracle/db_replay_load/load_run.log 2>&1 &
[1] 5321
[ORA12RF2:oracle@ol7ora12rf2][/home/oracle]$ ps -ef | grep loop_db_replay_load.sh
oracle    5321  5148  0 11:08 pts/0    00:00:00 /bin/bash /home/oracle/db_replay_load/loop_db_replay_load.sh 100
oracle    5984  5148  0 11:08 pts/0    00:00:00 grep --color=auto loop_db_replay_load.sh

[ORA12RF2:oracle@ol7ora12rf2][/home/oracle/db_replay_load]$ tail -f /home/oracle/db_replay_load/load_run.log

Elapsed: 00:00:00.00

PL/SQL procedure successfully completed.


--소요 시간 체크 (load_run.log)
========================================================
         Oracle Workload Generator Wrapper
========================================================
Start Time : Sun Jan  4 12:10:26 KST 2026
Mode       : Count Loop (100 회 실행)
========================================================
...
========================================================
Workload Generation Finished at Sun Jan  4 12:40:16 KST 2026
========================================================
--약 30분 걸림

 

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ ss

SQL*Plus: Release 12.2.0.1.0 Production on Thu Jan 1 16:40:00 2026

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<SYS@ORA12RF1>$
BEGIN
  DBMS_WORKLOAD_CAPTURE.FINISH_CAPTURE();
END;
/

PL/SQL procedure successfully completed.

Elapsed: 00:00:46.36


SET LINESIZE 200
SET PAGESIZE 100

COL ID FORMAT 999999
COL NAME FORMAT A30
COL STATUS FORMAT A15
COL START_TIME FORMAT A20

ALTER SESSION SET NLS_DATE_FORMAT = 'YYYY-MM-DD HH24:MI:SS';

SELECT ID
     , NAME
     , STATUS
     , START_TIME
  FROM DBA_WORKLOAD_CAPTURES
 WHERE STATUS = 'COMPLETED';


     ID NAME                           STATUS          START_TIME
------- ------------------------------ --------------- --------------------
     21 CAP_12C_TO_19C                 COMPLETED       2026-01-04 03:10:01

1 row selected.

Elapsed: 00:00:00.00

 

7-4. 워크로드 캡처 종료 후 awr export

 

[ORA12RF1:oracle@ol7ora12rf1][/acfs1_vol1/capture_dbreplay/cap]$ ll
total 1224
-rw-r--r--. 1 oracle asmadmin 283148 Jan  4 12:40 wcr_cr.html
-rw-r--r--. 1 oracle asmadmin  28186 Jan  4 12:40 wcr_cr.text
-rw-r--r--. 1 oracle asmadmin 771060 Jan  4 12:41 wcr_cr.xml
-rw-r--r--. 1 oracle asmadmin    287 Jan  4 12:40 wcr_fcapture.wmd
-rw-r--r--. 1 oracle asmadmin    142 Jan  4 12:10 wcr_scapture.wmd

 

BEGIN
  DBMS_WORKLOAD_CAPTURE.EXPORT_AWR (capture_id => 21);
END;
/


PL/SQL procedure successfully completed.

Elapsed: 00:02:18.31

 

[ORA12RF1:oracle@ol7ora12rf1][/acfs1_vol1/capture_dbreplay/cap]$ ls -alrt
total 31132
-rw-r--r--. 1 oracle asmadmin      142 Jan  4 12:10 wcr_scapture.wmd
drwxr-xr-x. 4 oracle oinstall    20480 Jan  4 12:40 ..
-rw-r--r--. 1 oracle asmadmin      287 Jan  4 12:40 wcr_fcapture.wmd
-rw-r--r--. 1 oracle asmadmin   283148 Jan  4 12:40 wcr_cr.html
-rw-r--r--. 1 oracle asmadmin    28186 Jan  4 12:40 wcr_cr.text
-rw-r--r--. 1 oracle asmadmin   771060 Jan  4 12:41 wcr_cr.xml
-rw-r-----. 1 oracle asmadmin 24625152 Jan  4 12:44 wcr_ca.dmp
-rw-r--r--. 1 oracle asmadmin    66006 Jan  4 12:44 wcr_ca.log
-rw-r-----. 1 oracle asmadmin    12288 Jan  4 12:44 wcr_cap_uc_graph.extb
drwxr-xr-x. 2 oracle asmadmin    20480 Jan  4 12:44 .

--> awr dump 파일인 wcr_ca.dmp, wcr_ca.log, wcr_cap_uc_graph.extb 이 생김

 

8. 타켓에서 pre-processing

 

--타켓 1번 노드 서버에서 소스 서버에 있는 캡처 파일을 가져옴

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ mkdir -pv /home/oracle/capture_dbreplay
mkdir: created directory '/home/oracle/capture_dbreplay'

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ scp -rp 192.168.240.11:/acfs1_vol1/capture_dbreplay/ /home/oracle/
...로그 생략

 

--타켓 2번 노드 서버에서 소스 서버에 있는 캡처 파일을 가져옴

[ORA19RF2:oracle@ol8ora19rf2][/home/oracle]$ mkdir -pv /home/oracle/capture_dbreplay
mkdir: created directory '/home/oracle/capture_dbreplay'
[ORA19RF2:oracle@ol8ora19rf2][/home/oracle]$ scp -rp 192.168.240.11:/acfs1_vol1/capture_dbreplay/ /home/oracle/
...로그 생략

 

--1번 노드

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Jan 1 16:49:59 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$ CREATE OR REPLACE DIRECTORY REPLAY_DIR AS '/home/oracle/capture_dbreplay';

Directory created.

Elapsed: 00:00:00.13

[ol8ora19rf1]<SYS@ORA19RF1>$ GRANT READ, WRITE ON DIRECTORY REPLAY_DIR TO PUBLIC;

Grant succeeded.

Elapsed: 00:00:00.02

[ol8ora19rf1]<SYS@ORA19RF1>$


BEGIN
  DBMS_WORKLOAD_REPLAY.PROCESS_CAPTURE (
     capture_dir => 'REPLAY_DIR'
   , plsql_mode  => 'TOP_LEVEL' -- 또는 'EXTENDED' (PL/SQL 내부 SQL까지 캡처했다면)
  );
END;
/

PL/SQL procedure successfully completed.

Elapsed: 00:00:04.45
[ol8ora19rf1]<
SYS@ORA19RF1>$

 

--1번 노드에 있는 capture 파일을 2번 노드로 전송

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ scp -r /home/oracle/capture_dbreplay/* ol8ora19rf2:/home/oracle/capture_dbreplay/

9. 타켓에서 db replay 준비

 

9-1. flashback database 여부 확인 및 설정

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/capture_dbreplay]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/capture_dbreplay]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Jan 1 17:00:04 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$
col dbid for 99999999999
col name for a20
col FLASHBACK_ON for a30

select dbid, NAME, FLASHBACK_ON from v$database;

        DBID NAME                 FLASHBACK_ON
------------ -------------------- ------------------------------
  1289426103 ORA19RF              NO

1 row selected.

Elapsed: 00:00:00.00

 

[ol8ora19rf1]<SYS@ORA19RF1>$ show parameter recovery

NAME                                 TYPE                              VALUE
------------------------------------ --------------------------------- ------------------------------
db_recovery_file_dest                string                            (NULL)
db_recovery_file_dest_size           big integer                       0
recovery_parallelism                 integer                           0
remote_recovery_file_dest            string                            (NULL)

[ol8ora19rf1]<SYS@ORA19RF1>$ alter system set db_recovery_file_dest='+FRA1' scope=spfile sid='*';

System altered.

Elapsed: 00:00:00.07
[ol8ora19rf1]<
SYS@ORA19RF1>$ alter system set db_recovery_file_dest_size=32G scope=both sid='*';

System altered.

Elapsed: 00:00:00.01
[ol8ora19rf1]<
SYS@ORA19RF1>$ show parameter flashback

NAME                                 TYPE                              VALUE
------------------------------------ --------------------------------- ------------------------------
db_flashback_retention_target        integer                           1440
[ol8ora19rf1]<
SYS@ORA19RF1>$ alter system set db_flashback_retention_target=2880 scope=both sid='*';

System altered.

Elapsed: 00:00:00.03
[ol8ora19rf1]<
SYS@ORA19RF1>$ quit


[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/capture_dbreplay]$ srvctl stop database -db ora19rf
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/capture_dbreplay]$ srvctl start database -db ora19rf -startoption mount

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Jan 1 17:08:14 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$ alter database flashback on;

Database altered.

Elapsed: 00:00:06.30

[ol8ora19rf1]<SYS@ORA19RF1>$ quit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0


[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ crsctl stat res ora.ora19rf.db -t
--------------------------------------------------------------------------------
Name           Target  State        Server                   State details
--------------------------------------------------------------------------------
Cluster Resources
--------------------------------------------------------------------------------
ora.ora19rf.db
      1        ONLINE  INTERMEDIATE ol8ora19rf1              Mounted (Closed),HOM
                                                             E=/u01/app/oracle/pr
                                                             oduct/19.29/db_1,STA
                                                             BLE
      2        ONLINE  INTERMEDIATE ol8ora19rf2              Mounted (Closed),HOM
                                                             E=/u01/app/oracle/pr
                                                             oduct/19.29/db_1,STA
                                                             BLE
--------------------------------------------------------------------------------

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ srvctl stop database -d ora19rf -o immediate
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ srvctl start database -d ora19rf

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Jan 1 17:15:22 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$
col dbid for 99999999999
col name for a20
col FLASHBACK_ON for a30

select dbid, NAME, FLASHBACK_ON from v$database;

        DBID NAME                 FLASHBACK_ON
------------ -------------------- ------------------------------
  1289426103 ORA19RF              YES

1 row selected.

Elapsed: 00:00:00.01

 

9-2. restore point 생성

 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Jan 1 17:16:48 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$ CREATE RESTORE POINT BEFORE_REPLAY GUARANTEE FLASHBACK DATABASE;

Restore point created.

Elapsed: 00:00:00.02

 

9-3. Replay 초기화

 

BEGIN
  DBMS_WORKLOAD_REPLAY.INITIALIZE_REPLAY (
     replay_name => 'REPLAY_19C_TEST'
   , replay_dir  => 'REPLAY_DIR'
  );
END;
/

PL/SQL procedure successfully completed.

Elapsed: 00:00:00.91

 

9-4. connection remapping

 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Jan 1 17:40:02 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$

set lines 200
col capture_conn format a30
col replay_conn format a30
SELECT CONN_ID
     , CAPTURE_CONN
     , REPLAY_CONN
  FROM DBA_WORKLOAD_CONNECTION_MAP
 WHERE REPLAY_ID = (SELECT MAX(ID) FROM DBA_WORKLOAD_REPLAYS);

    CONN_ID CAPTURE_CONN                   REPLAY_CONN
---------- ------------------------------ ------------------------------
         1 (DESCRIPTION=(CONNECT_DATA=(SE (NULL)
           RVER=DEDICATED)(SERVICE_NAME=O
           RA12RF)(CID=(PROGRAM=C:\Progra
           m?Files??x86?\WareValley\Orang
           e?for?ORACLE?7.0?DBA\Orange.ex
           e)(HOST=KOLEE-LENOVO-LT)(USER=
           leeko)))(ADDRESS=(PROTOCOL=TCP
           )(HOST=192.168.240.11)(PORT=15
           21)))

         2 (DESCRIPTION=(ADDRESS=(PROTOCO (NULL)
           L=beq)(PROGRAM=/u01/app/oracle
           /product/12c/db_1/bin/oracle)(
           ARGV0=oracleORA12RF1)(ARGS='(D
           ESCRIPTION=(LOCAL=YES)(ADDRESS
           =(PROTOCOL=beq)))')(DETACH=NO)
           )(CONNECT_DATA=(CID=(PROGRAM=s
           qlplus)(HOST=ol7ora12rf1)(USER
           =oracle))))

         3 (DESCRIPTION=(ADDRESS=(PROTOCO (NULL)
           L=beq)(PROGRAM=/u01/app/oracle
           /product/12c/db_1/bin/oracle)(
           ARGV0=oracleORA12RF2)(ARGS='(D
           ESCRIPTION=(LOCAL=YES)(ADDRESS
           =(PROTOCOL=beq)))')(DETACH=NO)
           )(CONNECT_DATA=(CID=(PROGRAM=s
           qlplus)(HOST=ol7ora12rf2)(USER
           =oracle))))


3 rows selected.

Elapsed: 00:00:00.00

 

--tnsnames.ora 정보 확인 (설정이 안되어 있다면 설정)
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ vi $ORACLE_HOME/network/admin/tnsnames.ora
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ cat $ORACLE_HOME/network/admin/tnsnames.ora
# tnsnames.ora Network Configuration File: /u01/app/oracle/product/19c/db_1/network/admin/tnsnames.ora
# Generated by Oracle configuration tools.

ORA19RF =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = ol8ora19rf-scan)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

ORA19RF1 =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.240.31)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

ORA19RF2 =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.240.32)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

--> 추가


[ORA19RF2:oracle@ol8ora19rf2][/home/oracle]$ vi $ORACLE_HOME/network/admin/tnsnames.ora
[ORA19RF2:oracle@ol8ora19rf2][/home/oracle]$ cat $ORACLE_HOME/network/admin/tnsnames.ora

# tnsnames.ora Network Configuration File: /u01/app/oracle/product/19c/db_1/network/admin/tnsnames.ora
# Generated by Oracle configuration tools.

ORA19RF =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = ol8ora19rf-scan)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

ORA19RF1 =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.240.31)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

ORA19RF2 =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.240.32)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

--> 추가
[ORA19RF2:oracle@ol8ora19rf2][/home/oracle]$

 

--> ORA19RF1 와 ORA19RF2 를 추가함

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Jan 1 17:40:02 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$

BEGIN
  DBMS_WORKLOAD_REPLAY.REMAP_CONNECTION (
     connection_id => 1  -- 위 조회 결과의 모든 CONN_ID에 대해 수행
   , replay_connection => 'ORA19RF1' -- Target 접속 정보
  );
END;
/


BEGIN
  DBMS_WORKLOAD_REPLAY.REMAP_CONNECTION (
     connection_id => 2 -- 위 조회 결과의 모든 CONN_ID에 대해 수행
   , replay_connection => 'ORA19RF1' -- Target 접속 정보
  );
END;
/


BEGIN
  DBMS_WORKLOAD_REPLAY.REMAP_CONNECTION (
     connection_id => 3 -- 위 조회 결과의 모든 CONN_ID에 대해 수행
   , replay_connection => 'ORA19RF2' -- Target 접속 정보
  );
END;
/

 

9-5. replay 준비

 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Jan 1 17:44:40 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$
BEGIN
  DBMS_WORKLOAD_REPLAY.PREPARE_REPLAY (
     synchronization => 'SCN'       -- SCN 기반 동기화 (가장 정확함)
   , connect_time_scale => 100      -- 100% 속도로 접속
   , think_time_scale => 100        -- 100% Think Time 반영 (0이면 최대한 빠르게)
  );
END;
/

 

9-6. replay 전 파라미터 설정

 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Sun Jan 4 13:23:12 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$

SET LINESIZE 300
SET PAGESIZE 100
COL "TYPE" FORMAT A10
COL "PARAMETER" FORMAT A45
COL "VALUE" FORMAT A20
COL "DISPLAY_VALUE" FORMAT A20
COL "DEFAULT_VALUE" FORMAT A15
COL "IS_DEFAULT" FORMAT A10
COL "IS_SESSION_MODI" FORMAT A15
COL "IS_SYSTEM_MODI" FORMAT A15
COL "IS_INSTANCE_MODI" FORMAT A15
COL "IS_PDB_MODI" FORMAT A15

SELECT *
  FROM (
       SELECT 'STANDARD' AS "TYPE"
            , UP.NAME AS "PARAMETER"
            , UP.VALUE AS "VALUE"
            , UP.DISPLAY_VALUE AS "DISPLAY_VALUE"
            , UP.DEFAULT_VALUE AS "DEFAULT_VALUE"
            , UP.ISDEFAULT AS "IS_DEFAULT"
            , UP.ISSES_MODIFIABLE AS "IS_SESSION_MODI"
            , UP.ISSYS_MODIFIABLE AS "IS_SYSTEM_MODI"
            , UP.ISINSTANCE_MODIFIABLE AS "IS_INSTANCE_MODI"
            , UP.ISPDB_MODIFIABLE AS "IS_PDB_MODI"
         FROM V$PARAMETER UP
        WHERE NOT EXISTS (
              SELECT 1
                FROM SYS.X$KSPPI K
               WHERE K.KSPPINM = UP.NAME
                 AND K.KSPPINM LIKE '\_%' ESCAPE '\'
              )
       UNION ALL
       SELECT 'HIDDEN' AS "TYPE"
            , A.KSPPINM AS "PARAMETER"
            , B.KSPPSTVL AS "VALUE"
            , B.KSPPSTDVL AS "DISPLAY_VALUE"
            , B.KSPPSTDFL AS "DEFAULT_VALUE"
            , B.KSPPSTDF AS "IS_DEFAULT"
            , DECODE(BITAND(A.KSPPIFLG / 256, 1), 1, 'TRUE', 'FALSE') AS "IS_SESSION_MODI"
            , DECODE(BITAND(A.KSPPIFLG / 65536, 3), 1, 'IMMEDIATE', 2, 'DEFERRED', 3, 'IMMEDIATE', 'FALSE') AS "IS_SYSTEM_MODI"
            , DECODE(BITAND(A.KSPPIFLG, 4), 4, 'FALSE', DECODE(BITAND(A.KSPPIFLG / 65536, 3), 0, 'FALSE', 'TRUE')) AS "IS_INSTANCE_MODI"
            , DECODE(BITAND(A.KSPPIFLG / 524288, 1), 1, 'TRUE', 'FALSE') AS "IS_PDB_MODI"
         FROM SYS.X$KSPPI A
            , SYS.X$KSPPCV B
        WHERE A.INDX = B.INDX
          AND A.KSPPINM LIKE '\_%' ESCAPE '\'
       ) A
 WHERE UPPER(A."PARAMETER") IN (
       UPPER('optimizer_mode')
     , UPPER('_optimizer_unnest_scalar_sq')
     , UPPER('_optimizer_push_pred_cost_based')
     , UPPER('_optimizer_cost_based_transformation')
     , UPPER('_optimizer_skip_scan_enabled')
     , UPPER('_b_tree_bitmap_plans')
     )
 ORDER BY A."TYPE", A."PARAMETER";

 

TYPE       PARAMETER                                     VALUE                DISPLAY_VALUE        DEFAULT_VALUE   IS_DEFAULT IS_SESSION_MODI IS_SYSTEM_MODI  IS_INSTANCE_MOD IS_PDB_MODI
---------- --------------------------------------------- -------------------- -------------------- --------------- ---------- --------------- --------------- --------------- ---------------
HIDDEN     _b_tree_bitmap_plans                          TRUE                 TRUE                 FALSE           TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_cost_based_transformation          LINEAR               LINEAR               linear          TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_push_pred_cost_based               TRUE                 TRUE                 TRUE            TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_skip_scan_enabled                  TRUE                 TRUE                 TRUE            TRUE       TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_unnest_scalar_sq                   TRUE                 TRUE                 TRUE            TRUE       TRUE            IMMEDIATE       TRUE            TRUE
STANDARD   optimizer_mode                                ALL_ROWS             ALL_ROWS             all_rows        TRUE       TRUE            IMMEDIATE       TRUE            TRUE

6 rows selected.

Elapsed: 00:00:00.01


-- 1. Optimizer Mode (표준 파라미터)
ALTER SYSTEM SET OPTIMIZER_MODE = ALL_ROWS SCOPE=BOTH SID='*';

-- 2. Hidden Parameters (큰따옴표 필수, SCOPE 먼저 선언)
ALTER SYSTEM SET "_optimizer_unnest_scalar_sq" = FALSE SCOPE=BOTH SID='*';
ALTER SYSTEM SET "_optimizer_push_pred_cost_based" = TRUE SCOPE=BOTH SID='*';
ALTER SYSTEM SET "_optimizer_cost_based_transformation" = ON SCOPE=BOTH SID='*';
ALTER SYSTEM SET "_optimizer_skip_scan_enabled" = TRUE SCOPE=BOTH SID='*';
ALTER SYSTEM SET "_b_tree_bitmap_plans" = TRUE SCOPE=BOTH SID='*';

 

--바뀐 파라미터 확인

SET LINESIZE 300
SET PAGESIZE 100
COL "TYPE" FORMAT A10
COL "PARAMETER" FORMAT A45
COL "VALUE" FORMAT A20
COL "DISPLAY_VALUE" FORMAT A20
COL "DEFAULT_VALUE" FORMAT A15
COL "IS_DEFAULT" FORMAT A10
COL "IS_SESSION_MODI" FORMAT A15
COL "IS_SYSTEM_MODI" FORMAT A15
COL "IS_INSTANCE_MODI" FORMAT A15
COL "IS_PDB_MODI" FORMAT A15

SELECT *
  FROM (
       SELECT 'STANDARD' AS "TYPE"
            , UP.NAME AS "PARAMETER"
            , UP.VALUE AS "VALUE"
            , UP.DISPLAY_VALUE AS "DISPLAY_VALUE"
            , UP.DEFAULT_VALUE AS "DEFAULT_VALUE"
            , UP.ISDEFAULT AS "IS_DEFAULT"
            , UP.ISSES_MODIFIABLE AS "IS_SESSION_MODI"
            , UP.ISSYS_MODIFIABLE AS "IS_SYSTEM_MODI"
            , UP.ISINSTANCE_MODIFIABLE AS "IS_INSTANCE_MODI"
            , UP.ISPDB_MODIFIABLE AS "IS_PDB_MODI"
         FROM V$PARAMETER UP
        WHERE NOT EXISTS (
              SELECT 1
                FROM SYS.X$KSPPI K
               WHERE K.KSPPINM = UP.NAME
                 AND K.KSPPINM LIKE '\_%' ESCAPE '\'
              )
       UNION ALL
       SELECT 'HIDDEN' AS "TYPE"
            , A.KSPPINM AS "PARAMETER"
            , B.KSPPSTVL AS "VALUE"
            , B.KSPPSTDVL AS "DISPLAY_VALUE"
            , B.KSPPSTDFL AS "DEFAULT_VALUE"
            , B.KSPPSTDF AS "IS_DEFAULT"
            , DECODE(BITAND(A.KSPPIFLG / 256, 1), 1, 'TRUE', 'FALSE') AS "IS_SESSION_MODI"
            , DECODE(BITAND(A.KSPPIFLG / 65536, 3), 1, 'IMMEDIATE', 2, 'DEFERRED', 3, 'IMMEDIATE', 'FALSE') AS "IS_SYSTEM_MODI"
            , DECODE(BITAND(A.KSPPIFLG, 4), 4, 'FALSE', DECODE(BITAND(A.KSPPIFLG / 65536, 3), 0, 'FALSE', 'TRUE')) AS "IS_INSTANCE_MODI"
            , DECODE(BITAND(A.KSPPIFLG / 524288, 1), 1, 'TRUE', 'FALSE') AS "IS_PDB_MODI"
         FROM SYS.X$KSPPI A
            , SYS.X$KSPPCV B
        WHERE A.INDX = B.INDX
          AND A.KSPPINM LIKE '\_%' ESCAPE '\'
       ) A
 WHERE UPPER(A."PARAMETER") IN (
       UPPER('optimizer_mode')
     , UPPER('_optimizer_unnest_scalar_sq')
     , UPPER('_optimizer_push_pred_cost_based')
     , UPPER('_optimizer_cost_based_transformation')
     , UPPER('_optimizer_skip_scan_enabled')
     , UPPER('_b_tree_bitmap_plans')
     )
 ORDER BY A."TYPE", A."PARAMETER";

TYPE       PARAMETER                                     VALUE                DISPLAY_VALUE        DEFAULT_VALUE   IS_DEFAULT IS_SESSION_MODI IS_SYSTEM_MODI  IS_INSTANCE_MOD IS_PDB_MODI
---------- --------------------------------------------- -------------------- -------------------- --------------- ---------- --------------- --------------- --------------- ---------------
HIDDEN     _b_tree_bitmap_plans                          TRUE                 TRUE                 FALSE           FALSE      TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_cost_based_transformation          ON                   ON                   linear          FALSE      TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_push_pred_cost_based               TRUE                 TRUE                 TRUE            FALSE      TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_skip_scan_enabled                  TRUE                 TRUE                 TRUE            FALSE      TRUE            IMMEDIATE       TRUE            TRUE
HIDDEN     _optimizer_unnest_scalar_sq                   FALSE                FALSE                TRUE            FALSE      TRUE            IMMEDIATE       TRUE            TRUE
STANDARD   optimizer_mode                                ALL_ROWS             ALL_ROWS             all_rows        FALSE      TRUE            IMMEDIATE       TRUE            TRUE

6 rows selected.

Elapsed: 00:00:00.01


9-7. replay 시작

 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ date
Sun Jan  4 13:14:43 KST 2026
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ echo $TZ

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ export TZ='Asia/Seoul'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ echo $TZ
Asia/Seoul

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ echo $ORA_SDTZ

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ export ORA_SDTZ='Asia/Seoul'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ echo $ORA_SDTZ
Asia/Seoul


[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/capture_dbreplay]$ wrc mode=calibrate replaydir=/home/oracle/capture_dbreplay

Workload Replay Client: Release 19.29.0.0.0 - Production on Sun Jan 4 13:17:12 2026

Copyright (c) 1982, 2019, Oracle and/or its affiliates.  All rights reserved.

 

Workload Report
-----------------------
Recommendation:
Consider using at least 1 clients divided among 1 CPU(s)
You will need at least 11 MB of memory per client process.
If your machine(s) cannot match that number, consider using more clients.

Workload Characteristics:
- max concurrency: 3 sessions
- total number of sessions: 201

Assumptions:
- 100 concurrent sessions per client process
- 4 client processes per CPU
- 256 KB of memory cache per concurrent session
- think time scale = 100
- connect time scale = 100
- synchronization = TRUE

 

--새로운 ssh창 띄어서 (1번 노드)

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ echo $TZ
Asia/Seoul

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ echo $ORA_SDTZ
Asia/Seoul

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/capture_dbreplay]$ wrc mode=replay replaydir=/home/oracle/capture_dbreplay

Workload Replay Client: Release 19.29.0.0.0 - Production on Thu Jan 1 18:09:40 2026

Copyright (c) 1982, 2019, Oracle and/or its affiliates.  All rights reserved.


Username: system
Password:
2026-01-01 18:09:48.515361 Wait for the replay to start

 

--새로운 ssh창 띄어서 (2번 노드)
[ORA19RF2:oracle@ol8ora19rf2][/home/oracle/capture_dbreplay]$ export TZ='Asia/Seoul'
[ORA19RF2:oracle@ol8ora19rf2][/home/oracle/capture_dbreplay]$ export ORA_SDTZ='Asia/Seoul'
[ORA19RF2:oracle@ol8ora19rf2][/home/oracle/capture_dbreplay]$ wrc mode=replay replaydir=/home/oracle/capture_dbreplay

Workload Replay Client: Release 19.29.0.0.0 - Production on Sun Jan 4 15:00:53 2026

Copyright (c) 1982, 2019, Oracle and/or its affiliates.  All rights reserved.


Username: system
Password:
2026-01-04 15:00:56.288312 Wait for the replay to start

 

--새로운 ssh창 띄어서
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ export TZ='Asia/Seoul'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ export ORA_SDTZ='Asia/Seoul'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ echo $TZ

Asia/Seoul
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ echo $ORA_SDTZ
Asia/Seoul


[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/capture_dbreplay]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/capture_dbreplay]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Thu Jan 1 17:54:59 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0


[ol8ora19rf1]<SYS@ORA19RF1>$
col name for A20
col status for A20
SELECT NAME, STATUS FROM DBA_WORKLOAD_REPLAYS;


NAME                 STATUS
-------------------- --------------------
REPLAY_19C_TEST      PREPARE

1 row selected.

Elapsed: 00:00:00.00

SET LINESIZE 200
COL USERNAME FORMAT A10
COL PROGRAM FORMAT A40
COL MACHINE FORMAT A30
COL STATUS FORMAT A10

-- WRC 클라이언트 세션 조회
SELECT INST_ID
     , SID
     , SERIAL#
     , USERNAME
     , PROGRAM
     , MACHINE
     , STATUS
  FROM GV$SESSION
 WHERE PROGRAM LIKE '%wrc%'
    OR PROGRAM LIKE '%WRC%';

   INST_ID        SID    SERIAL# USERNAME   PROGRAM                                  MACHINE                        STATUS
---------- ---------- ---------- ---------- ---------------------------------------- ------------------------------ ----------
         1        826      22148 SYSTEM    
wrc@ol8ora19rf1 (TNS V1-V3)              ol8ora19rf1                    ACTIVE
         2       1905      33096 SYSTEM    
wrc@ol8ora19rf2 (TNS V1-V3)              ol8ora19rf2                    ACTIVE

2 rows selected.

Elapsed: 00:00:00.01


[ol8ora19rf1]<SYS@ORA19RF1>$
BEGIN
  DBMS_WORKLOAD_REPLAY.START_REPLAY();
END;
/

 

--취소한다면
--BEGIN DBMS_WORKLOAD_REPLAY.CANCEL_REPLAY(NULL); END;/

PL/SQL procedure successfully completed.

Elapsed: 00:00:01.59

 

--wrc를 실행한 ssh창에서 로그가 나오기 시작함 (wrc mode=replay replaydir=/home/oracle/capture_dbreplay 명령을 실행한 ssh창)
--1번 노드
...
2026-01-04 14:45:11.736730 Wait for the replay to start
2026-01-04 15:02:45.267788 Replay client 1 started
2026-01-04 15:02:45.267788 default trace path: /u01/app/oracle/diag/clients/user_oracle/host_3429632378_110/trace
2026-01-04 15:02:45.321852 disp4997_001: start
2026-01-04 15:02:45.322858 disp4997_001: numClients=2 ClientID=1
2026-01-04 15:02:45.322894 disp4997_001: starting replay thread r00001_4997_001 (0)
2026-01-04 15:02:45.323903 r00001_4997_001: tstart wcr_5mqhuh0000003.rec ora_4997_140737152808704.trc
2026-01-04 15:02:55.267858 disp4997_001: starting replay thread r00003_4997_001 (0)
2026-01-04 15:02:55.269139 r00003_4997_001: tstart wcr_5mqj4h0000004.rec ora_4997_140737142318848.trc
2026-01-04 15:03:12.730480 r00001_4997_001: texit wcr_5mqhuh0000003.rec
2026-01-04 15:03:13.300291 disp4997_001: joining thread r00001_4997_001
...
2026-01-04 15:43:11.004564 Replay client 1 finished

 

--2번 노드
...
2026-01-04 15:00:56.288312 Wait for the replay to start
2026-01-04 15:02:44.264627 Replay client 2 started
2026-01-04 15:02:44.264627 default trace path: /u01/app/oracle/diag/clients/user_oracle/host_2884398641_110/trace
2026-01-04 15:02:44.313128 disp7683_002: start
2026-01-04 15:02:44.314092 disp7683_002: numClients=2 ClientID=2
2026-01-04 15:02:51.264930 disp7683_002: starting replay thread r00002_7683_002 (0)
2026-01-04 15:02:51.266387 r00002_7683_002: tstart wcr_5mqj180000001.rec ora_7683_140737152808704.trc
2026-01-04 15:03:04.264910 disp7683_002: starting replay thread r00004_7683_002 (0)
2026-01-04 15:03:04.265039 disp7683_002: starting replay thread r00006_7683_002 (0)
2026-01-04 15:03:04.265085 disp7683_002: starting replay thread r00008_7683_002 (0)
2026-01-04 15:03:04.265138 disp7683_002: starting replay thread r00010_7683_002 (0)
...
2026-01-04 15:42:17.177509 Replay client 2 finished
----------------------------------------------------------------------------------------------------------------------------


SET LINESIZE 200
COL NAME FORMAT A20
COL STATUS FORMAT A15
COL PREPARE_KST FORMAT A20
COL START_KST FORMAT A20
COL DURATION_MIN FORMAT 999.99

SELECT NAME
     , STATUS
     -- UTC 시간을 가져와서(FROM_TZ), 현재 세션 타임존(KST)으로 변환(AT TIME ZONE)
     , TO_CHAR(FROM_TZ(CAST(PREPARE_TIME AS TIMESTAMP), 'UTC')
               AT TIME ZONE SESSIONTIMEZONE, 'YYYY/MM/DD HH24:MI:SS') AS PREPARE_KST
     , TO_CHAR(FROM_TZ(CAST(START_TIME AS TIMESTAMP), 'UTC')
               AT TIME ZONE SESSIONTIMEZONE, 'YYYY/MM/DD HH24:MI:SS') AS START_KST
     , ROUND(DURATION_SECS/60, 2) AS DURATION_MIN
  FROM DBA_WORKLOAD_REPLAYS
 ORDER BY ID DESC;

NAME                 STATUS          PREPARE_KST          START_KST            DURATION_MIN
-------------------- --------------- -------------------- -------------------- ------------
REPLAY_19C_TEST      IN PROGRESS     2026/01/04 14:42:18  2026/01/04 15:02:44  (NULL)


1 row selected.

Elapsed: 00:00:00.01


SET LINESIZE 200
COL NAME FORMAT A20
COL START_TIME_KST FORMAT A20
COL ELAPSED_MINS FORMAT 999.99 HEADING 'Elapsed(Min)'
COL CAPTURE_MINS FORMAT 999.99 HEADING 'Total(Min)'
COL EST_PCT FORMAT 999.99 HEADING 'Est.Progress(%)'

SELECT r.NAME
     -- 1. 포맷 변경: YYYY-MM-DD HH24:MI:SS
     , TO_CHAR(FROM_TZ(CAST(r.START_TIME AS TIMESTAMP), 'UTC')
               AT TIME ZONE SESSIONTIMEZONE, 'YYYY-MM-DD HH24:MI:SS') AS START_TIME_KST
     , ROUND((SYSDATE - CAST(FROM_TZ(CAST(r.START_TIME AS TIMESTAMP), 'UTC')
                             AT TIME ZONE SESSIONTIMEZONE AS DATE)) * 1440, 2) AS ELAPSED_MINS
     , ROUND(c.DURATION_SECS / 60, 2) AS CAPTURE_MINS
     , ROUND(((SYSDATE - CAST(FROM_TZ(CAST(r.START_TIME AS TIMESTAMP), 'UTC')
                              AT TIME ZONE SESSIONTIMEZONE AS DATE)) * 86400
              / NULLIF(c.DURATION_SECS, 0)) * 100, 2) AS EST_PCT
  FROM DBA_WORKLOAD_REPLAYS r
     , DBA_WORKLOAD_CAPTURES c
 WHERE r.CAPTURE_ID = c.ID
   AND r.STATUS = 'IN PROGRESS';

NAME                 START_TIME_KST       Elapsed(Min) Total(Min) Est.Progress(%)
-------------------- -------------------- ------------ ---------- ---------------
REPLAY_19C_TEST      2026-01-04 15:02:44          3.22      30.35           10.60

1 row selected.

Elapsed: 00:00:00.01

[ol8ora19rf1]<SYS@ORA19RF1>$ /

NAME                 START_TIME_KST       Elapsed(Min) Total(Min) Est.Progress(%)
-------------------- -------------------- ------------ ---------- ---------------
REPLAY_19C_TEST      2026-01-04 15:02:44         32.63      30.35          107.52

1 row selected.

Elapsed: 00:00:00.00


9-9. AWR export

SELECT A.ID, A.REPLAY_DIR_NUMBER
  FROM (SELECT A.ID, A.REPLAY_DIR_NUMBER
          FROM DBA_WORKLOAD_REPLAYS A
         WHERE A.STATUS = 'COMPLETED'
         ORDER BY A.END_TIME DESC
       ) A
 WHERE ROWNUM <= 1 ;

        ID REPLAY_DIR_NUMBER
---------- -----------------
         2         815340401

1 row selected.

Elapsed: 00:00:00.01


BEGIN
  DBMS_WORKLOAD_REPLAY.EXPORT_AWR (replay_id => 2);
END;
/

PL/SQL procedure successfully completed.

Elapsed: 00:00:35.86

 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ cd /home/oracle/capture_dbreplay/rep815340401/
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle/capture_dbreplay/rep815340401]$ ls -arlt

total 21888
drwxr-xr-x. 7 oracle oinstall       83 Jan  4 15:42 ..
-rw-r--r--. 1 oracle asmadmin   781119 Jan  4 15:42 wcr_replay.wmd
-rw-r-----. 1 oracle asmadmin    28672 Jan  4 15:42 wcr_replay_div_summary.extb
-rw-r-----. 1 oracle asmadmin    57344 Jan  4 15:42 wcr_tracked_commits.extb
-rw-r-----. 1 oracle asmadmin    40960 Jan  4 15:42 wcr_replay_thread.extb
-rw-r--r--. 1 oracle asmadmin   117746 Jan  4 15:43 wcr_rr_815340401.html
-rw-r-----. 1 oracle asmadmin 21315584 Jan  4 23:43 wcr_ra_815340401.dmp
-rw-r--r--. 1 oracle asmadmin    48324 Jan  4 23:43 wcr_ra_815340401.log
drwxr-x---. 2 oracle asmadmin     4096 Jan  4 23:43 .
-rw-r-----. 1 oracle asmadmin    12288 Jan  4 23:43 wcr_rep_uc_graph_815340401.extb
--> wcr_ra_815340401.dmp 이 파일이 생겼음


9-8. 리포트 출력

[ol8ora19rf1]<SYS@ORA19RF1>$

SELECT A.ID, A.REPLAY_DIR_NUMBER
  FROM (SELECT A.ID, A.REPLAY_DIR_NUMBER
          FROM DBA_WORKLOAD_REPLAYS A
         WHERE A.STATUS = 'COMPLETED'
         ORDER BY A.END_TIME DESC
       ) A
 WHERE ROWNUM <= 1 ;

        ID REPLAY_DIR_NUMBER
---------- -----------------
         2         815340401

1 row selected.

Elapsed: 00:00:00.01


[ol8ora19rf1]<SYS@ORA19RF1>$ host ls -lart /home/oracle/capture_dbreplay/rep815340401
total 21888
drwxr-xr-x. 7 oracle oinstall       83 Jan  4 15:42 ..
-rw-r--r--. 1 oracle asmadmin   781119 Jan  4 15:42 wcr_replay.wmd
-rw-r-----. 1 oracle asmadmin    28672 Jan  4 15:42 wcr_replay_div_summary.extb
-rw-r-----. 1 oracle asmadmin    57344 Jan  4 15:42 wcr_tracked_commits.extb
-rw-r-----. 1 oracle asmadmin    40960 Jan  4 15:42 wcr_replay_thread.extb
-rw-r--r--. 1 oracle asmadmin   117746 Jan  4 15:43 wcr_rr_815340401.html
-rw-r-----. 1 oracle asmadmin 21315584 Jan  4 23:43 wcr_ra_815340401.dmp
-rw-r--r--. 1 oracle asmadmin    48324 Jan  4 23:43 wcr_ra_815340401.log
drwxr-x---. 2 oracle asmadmin     4096 Jan  4 23:43 .
-rw-r-----. 1 oracle asmadmin    12288 Jan  4 23:43 wcr_rep_uc_graph_815340401.extb


[ol8ora19rf1]<SYS@ORA19RF1>$ ALTER SESSION SET TIME_ZONE = 'Asia/Seoul';
[ol8ora19rf1]<
SYS@ORA19RF1>$ SET PAGES 0 LINES 2000 TRIMSPOOL ON LONG 1000000 LONGCHUNKSIZE 1000000 SERVEROUTPUT ON
[ol8ora19rf1]<
SYS@ORA19RF1>$ spool /home/oracle/capture_dbreplay/db_replay_report_2_815340401.html
[ol8ora19rf1]<
SYS@ORA19RF1>$ SELECT DBMS_WORKLOAD_REPLAY.REPORT(replay_id => 2, format => 'HTML') FROM DUAL;
[ol8ora19rf1]<
SYS@ORA19RF1>$ SPOOL OFF


10. awr 비교 리포트 출력

 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ scp 192.168.240.11:/acfs1_vol1/capture_dbreplay/cap/wcr_ca.dmp /home/oracle/capture_dbreplay/rep815340401/
oracle@192.168.240.11's password:
wcr_ca.dmp   100%   23MB 302.2MB/s   00:00

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ls -l /home/oracle/capture_dbreplay/rep815340401/*.dmp
-rw-r-----. 1 oracle oinstall 24625152 Jan  5 22:35 /home/oracle/capture_dbreplay/rep815340401/wcr_ca.dmp --> 소스 db 워크로드 캡처에 대한 awr dump
-rw-r-----. 1 oracle asmadmin 21315584 Jan  4 23:43 /home/oracle/capture_dbreplay/rep815340401/wcr_ra_815340401.dmp --> 소스 db replay에 대한 awr dump


[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Mon Jan 5 22:37:41 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0


[ol8ora19rf1]<SYS@ORA19RF1>$ CREATE OR REPLACE DIRECTORY AWR_DIFF_DIR AS '/home/oracle/capture_dbreplay/rep815340401';

Directory created.

Elapsed: 00:00:00.05
[ol8ora19rf1]<
SYS@ORA19RF1>$ GRANT READ, WRITE ON DIRECTORY AWR_DIFF_DIR TO PUBLIC;

Grant succeeded.

Elapsed: 00:00:00.01
[ol8ora19rf1]<
SYS@ORA19RF1>$

 

--1번 노드 (oracle os user)

[ol8ora19rf1]<SYS@ORA19RF1>$ @?/rdbms/admin/awrload.sql
~~~~~~~~~~
AWR LOAD
~~~~~~~~~~
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
~  This script will load the AWR data from a dump file. The   ~
~  script will prompt users for the following information:    ~
~     (1) name of directory object                            ~
~     (2) name of dump file                                   ~
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

Specify the Directory Name
~~~~~~~~~~~~~~~~~~~~~~~~~~

Directory Name                 Directory Path
------------------------------ -------------------------------------------------
AWR_DIFF_DIR                   /home/oracle/capture_dbreplay/rep815340401
DATA_PUMP_DIR                  /u01/app/oracle/product/19c/db_1/rdbms/log/
DBMS_OPTIM_ADMINDIR            /u01/app/oracle/product/19c/db_1/rdbms/admin
DBMS_OPTIM_LOGDIR              /u01/app/oracle/product/19c/db_1/cfgtoollogs
DMP_DIR                        /home/oracle/dmp
JAVA$JOX$CUJS$DIRECTORY$       /u01/app/oracle/product/19.29/db_1/javavm/admin/
OPATCH_INST_DIR                /u01/app/oracle/product/19.29/db_1/OPatch
OPATCH_LOG_DIR                 /u01/app/oracle/product/19.29/db_1/rdbms/log
OPATCH_SCRIPT_DIR              /u01/app/oracle/product/19.29/db_1/QOpatch
ORACLE_BASE                    /u01/app/oracle
ORACLE_HOME                    /u01/app/oracle/product/19c/db_1
ORACLE_OCM_CONFIG_DIR          /u01/app/oracle/product/19c/db_1/ccr/state
ORACLE_OCM_CONFIG_DIR2         /u01/app/oracle/product/19c/db_1/ccr/state
REPLAY_DIR                     /home/oracle/capture_dbreplay
SDO_DIR_ADMIN                  /u01/app/oracle/product/19c/db_1/md/admin
SDO_DIR_WORK                   (NULL)
SPA_DIR                        /home/oracle/spa
XMLDIR                         /u01/app/oracle/product/19c/db_1/rdbms/xml
XSDDIR                         /u01/app/oracle/product/19c/db_1/rdbms/xml/schema
Elapsed: 00:00:00.01

Choose a Directory Name from the list above (case-sensitive).

Enter value for directory_name: AWR_DIFF_DIR

Using the dump directory: AWR_DIFF_DIR
Elapsed: 00:00:00.01
Elapsed: 00:00:00.00

Specify the Name of the Dump File to Load
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
Please specify the prefix of the dump file (.dmp) to load:

Enter value for file_name: wcr_ca

Loading from the file name: wcr_ca.dmp
Elapsed: 00:00:00.00
Elapsed: 00:00:00.00
Elapsed: 00:00:00.00


Elapsed: 00:00:00.00
Elapsed: 00:00:00.00
Elapsed: 00:00:00.00
|
| ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
|  Loading the AWR data from the following
|  directory/file:
|   /home/oracle/capture_dbreplay/rep815340401
|   wcr_ca.dmp
| ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
|
|  *** AWR Load Started ...
|
|  This operation will take a few moments. The
|  progress of the AWR load operation can be
|  monitored in the following directory/file:
|   /home/oracle/capture_dbreplay/rep815340401
|   wcr_ca.log
|
Elapsed: 00:00:00.00
Elapsed: 00:00:36.33

End of AWR Load
[ol8ora19rf1]<
SYS@ORA19RF1>$

--------------------------------------------------------------------------------------------------------

 

--2번 노드 (oracle os user)

[ol8ora19rf1]<SYS@ORA19RF1>$ @?/rdbms/admin/awrload.sql 1223334444
--> DBID를 임의로 지정함

~~~~~~~~~~
AWR LOAD
~~~~~~~~~~
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
~  This script will load the AWR data from a dump file. The   ~
~  script will prompt users for the following information:    ~
~     (1) name of directory object                            ~
~     (2) name of dump file                                   ~
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~

Specify the Directory Name
~~~~~~~~~~~~~~~~~~~~~~~~~~

Directory Name                 Directory Path
------------------------------ -------------------------------------------------
AWR_DIFF_DIR                   /home/oracle/capture_dbreplay/rep815340401
DATA_PUMP_DIR                  /u01/app/oracle/product/19c/db_1/rdbms/log/
DBMS_OPTIM_ADMINDIR            /u01/app/oracle/product/19c/db_1/rdbms/admin
DBMS_OPTIM_LOGDIR              /u01/app/oracle/product/19c/db_1/cfgtoollogs
DMP_DIR                        /home/oracle/dmp
JAVA$JOX$CUJS$DIRECTORY$       /u01/app/oracle/product/19.29/db_1/javavm/admin/
OPATCH_INST_DIR                /u01/app/oracle/product/19.29/db_1/OPatch
OPATCH_LOG_DIR                 /u01/app/oracle/product/19.29/db_1/rdbms/log
OPATCH_SCRIPT_DIR              /u01/app/oracle/product/19.29/db_1/QOpatch
ORACLE_BASE                    /u01/app/oracle
ORACLE_HOME                    /u01/app/oracle/product/19c/db_1
ORACLE_OCM_CONFIG_DIR          /u01/app/oracle/product/19c/db_1/ccr/state
ORACLE_OCM_CONFIG_DIR2         /u01/app/oracle/product/19c/db_1/ccr/state
REPLAY_DIR                     /home/oracle/capture_dbreplay
SDO_DIR_ADMIN                  /u01/app/oracle/product/19c/db_1/md/admin
SDO_DIR_WORK                   (NULL)
SPA_DIR                        /home/oracle/spa
XMLDIR                         /u01/app/oracle/product/19c/db_1/rdbms/xml
XSDDIR                         /u01/app/oracle/product/19c/db_1/rdbms/xml/schema
Elapsed: 00:00:00.00

Choose a Directory Name from the list above (case-sensitive).

Enter value for directory_name: AWR_DIFF_DIR

Using the dump directory: AWR_DIFF_DIR
Elapsed: 00:00:00.01
Elapsed: 00:00:00.00

Specify the Name of the Dump File to Load
~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
Please specify the prefix of the dump file (.dmp) to load:

Enter value for file_name: wcr_ra_815340401

Loading from the file name: wcr_ra_815340401.dmp
Elapsed: 00:00:00.00
Elapsed: 00:00:00.00
Elapsed: 00:00:00.00


Elapsed: 00:00:00.00
Elapsed: 00:00:00.00
Elapsed: 00:00:00.00
|
| ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
|  Loading the AWR data from the following
|  directory/file:
|   /home/oracle/capture_dbreplay/rep815340401
|   wcr_ra_815340401.dmp
| ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
|
|  *** AWR Load Started ...
|
|  This operation will take a few moments. The
|  progress of the AWR load operation can be
|  monitored in the following directory/file:
|   /home/oracle/capture_dbreplay/rep815340401
|   wcr_ra_815340401.log
|
Elapsed: 00:00:00.01
Elapsed: 00:00:25.70

End of AWR Load
[ol8ora19rf1]<
SYS@ORA19RF1>$


SET LINESIZE 200
SET PAGESIZE 100
COL DBID FORMAT 9999999999
COL INST FORMAT 999 HEADING "INST"
COL MIN_SNAP FORMAT 9999999
COL MAX_SNAP FORMAT 9999999
COL START_TIME FORMAT A22
COL END_TIME FORMAT A22
COL CNT FORMAT 999

SELECT DBID
     , INSTANCE_NUMBER AS INST
     , MIN(SNAP_ID) AS MIN_SNAP
     , MAX(SNAP_ID) AS MAX_SNAP
     , TO_CHAR(MIN(BEGIN_INTERVAL_TIME), 'YY/MM/DD HH24:MI:SS') AS START_TIME
     , TO_CHAR(MAX(END_INTERVAL_TIME), 'YY/MM/DD HH24:MI:SS') AS END_TIME
     , COUNT(*) AS CNT
  FROM DBA_HIST_SNAPSHOT
 GROUP BY DBID, INSTANCE_NUMBER
 ORDER BY START_TIME;

 1289426103    2     1630     2608 25/12/29 23:26:21      26/01/05 22:50:28       979
 1289426103    1     1630     2608 25/12/29 23:26:42      26/01/05 22:50:28       979
 4288610047    1     4517     4521 26/01/04 12:05:24      26/01/04 12:40:52         5
 4288610047    2     4517     4521 26/01/04 12:05:24      26/01/04 12:40:52         5
 1223334444    1     2416     2421 26/01/04 15:00:17      26/01/04 15:42:27         6
 1223334444    2     2416     2421 26/01/04 15:00:17      26/01/04 15:42:27         6
Elapsed: 00:00:00.02

 

--타켓 서버 1번 노드에서

 

--1번 노드에 대한 소스 vs 타켓 비교 리포트 생성
[ol8ora19rf1]<SYS@ORA19RF1>$ SET PAGESIZE 0 LINESIZE 5000 TRIMSPOOL ON LONG 5000000 LONGCHUNKSIZE 5000000 TERM OFF ECHO OFF FEEDBACK OFF HEADING OFF
[ol8ora19rf1]<
SYS@ORA19RF1>$ SPOOL /home/oracle/capture_dbreplay/awr_diff_12c_vs_19c_node1.html
[ol8ora19rf1]<
SYS@ORA19RF1>$ SELECT * FROM TABLE(SYS.DBMS_WORKLOAD_REPOSITORY.AWR_DIFF_REPORT_HTML(4288610047,1,4517,4521,1223334444,1,2416,2421));
[ol8ora19rf1]<
SYS@ORA19RF1>$ SPOOL OFF

 

--2번 노드에 대한 소스 vs 타켓 비교 리포트 생성
[ol8ora19rf1]<SYS@ORA19RF1>$ SET PAGESIZE 0 LINESIZE 5000 TRIMSPOOL ON LONG 5000000 LONGCHUNKSIZE 5000000 TERM OFF ECHO OFF FEEDBACK OFF HEADING OFF
[ol8ora19rf1]<
SYS@ORA19RF1>$ SPOOL /home/oracle/capture_dbreplay/awr_diff_12c_vs_19c_node2.html
[ol8ora19rf1]<
SYS@ORA19RF1>$ SELECT * FROM TABLE(SYS.DBMS_WORKLOAD_REPOSITORY.AWR_DIFF_REPORT_HTML(4288610047,2,4517,4521,1223334444,2,2416,2421));
[ol8ora19rf1]<
SYS@ORA19RF1>$ SPOOL OFF

[ol8ora19rf1]<SYS@ORA19RF1>$ quit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0


[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ls -alrt /home/oracle/capture_dbreplay/
total 6172
drwxr-xr-x.  4 oracle oinstall      32 Jan  4 12:10 capfiles
drwxr-xr-x.  2 oracle oinstall     175 Jan  4 12:44 cap
drwxr-x---.  2 oracle asmadmin    4096 Jan  4 14:33 rep14242003
drwxr-x---.  3 oracle asmadmin    4096 Jan  4 14:41 pp1
-rw-r--r--.  1 oracle oinstall   58878 Jan  5 00:04 db_replay_report_2_815340401.html
drwxr-x---.  2 oracle asmadmin    4096 Jan  5 22:38 rep815340401
-rw-r--r--.  1 oracle oinstall 3132925 Jan  5 22:53 awr_diff_12c_vs_19c_node1.html
drwxr-xr-x.  7 oracle oinstall    4096 Jan  5 22:54 .
-rw-r--r--.  1 oracle oinstall 3103949 Jan  5 22:54 awr_diff_12c_vs_19c_node2.html
drwx------. 12 oracle oinstall    4096 Jan  5 22:54 ..

 

11. 다시 테스트를 하기 위한 타켓 디비를 되돌리기

 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ srvctl stop database -d ora19rf -o immediate
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ srvctl start database -db ora19rf -startoption mount
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Mon Jan 5 23:06:48 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$ FLASHBACK DATABASE TO RESTORE POINT BEFORE_REPLAY;

Flashback complete.

Elapsed: 00:01:08.52
[ol8ora19rf1]<SYS@ORA19RF1>$ quit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ srvctl stop instance -db ora19rf -node ol8ora19rf2
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ crsctl stat res ora.ora19rf.db -t
--------------------------------------------------------------------------------
Name           Target  State        Server                   State details
--------------------------------------------------------------------------------
Cluster Resources
--------------------------------------------------------------------------------
ora.ora19rf.db
      1        ONLINE  INTERMEDIATE ol8ora19rf1              Mounted (Closed),HOM
                                                             E=/u01/app/oracle/pr
                                                             oduct/19.29/db_1,STA
                                                             BLE
      2        OFFLINE OFFLINE                               Instance Shutdown,ST
                                                             ABLE
--------------------------------------------------------------------------------
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss

alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Mon Jan 5 23:09:08 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$ ALTER DATABASE OPEN RESETLOGS;

Database altered.

Elapsed: 00:00:50.67
[ol8ora19rf1]<
SYS@ORA19RF1>$ quit
Disconnected from Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ srvctl stop database -d ora19rf -o immediate

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ srvctl start database -d ora19rf
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ crsctl stat res ora.ora19rf.db -t

--------------------------------------------------------------------------------
Name           Target  State        Server                   State details
--------------------------------------------------------------------------------
Cluster Resources
--------------------------------------------------------------------------------
ora.ora19rf.db
      1        ONLINE  ONLINE       ol8ora19rf1              Open,HOME=/u01/app/o
                                                             racle/product/19.29/
                                                             db_1,STABLE
      2        ONLINE  ONLINE       ol8ora19rf2              Open,HOME=/u01/app/o
                                                             racle/product/19.29/
                                                             db_1,STABLE
--------------------------------------------------------------------------------


[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Mon Jan 5 23:12:04 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$ DROP RESTORE POINT BEFORE_REPLAY;

Restore point dropped.

Elapsed: 00:00:00.02
[ol8ora19rf1]<
SYS@ORA19RF1>$ CREATE RESTORE POINT BEFORE_REPLAY GUARANTEE FLASHBACK DATABASE;

Restore point created.

Elapsed: 00:00:00.01

 

SET LINESIZE 200
COL NAME FORMAT A20
COL TIME FORMAT A35
COL GUARANTEE_FLASHBACK_DATABASE FORMAT A3
COL SCN FORMAT 999999999999999

SELECT NAME
     , TIME
     , GUARANTEE_FLASHBACK_DATABASE AS GFD
     , SCN
  FROM V$RESTORE_POINT;

NAME                 TIME                                GFD                    SCN
-------------------- ----------------------------------- --------- ----------------
BEFORE_REPLAY        26/01/05 23:12:33.000000000         YES               13510678

1 row selected.

Elapsed: 00:00:00.01

--> 지금부터 다시 replay 테스트를 진행할 수 있음

 

12. 원상복구

 

12-1. 타켓 DB에서 Replay 정리 및 Flashback 해제

 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ ss

SQL*Plus: Release 19.0.0.0.0 - Production on Sat Jan 3 18:41:20 2026
Version 19.29.0.0.0

Copyright (c) 1982, 2025, Oracle.  All rights reserved.


Connected to:
Oracle Database 19c Enterprise Edition Release 19.0.0.0.0 - Production
Version 19.29.0.0.0

[ol8ora19rf1]<SYS@ORA19RF1>$ DROP RESTORE POINT BEFORE_REPLAY;

Restore point dropped.

Elapsed: 00:00:00.07
[ol8ora19rf1]<
SYS@ORA19RF1>$ ALTER DATABASE FLASHBACK OFF;

Database altered.

Elapsed: 00:00:02.25
[ol8ora19rf1]<
SYS@ORA19RF1>$ ALTER SYSTEM RESET db_flashback_retention_target SCOPE=BOTH SID='*';

System altered.

Elapsed: 00:00:00.01
[ol8ora19rf1]<
SYS@ORA19RF1>$ ALTER SYSTEM RESET db_recovery_file_dest_size SCOPE=spfile SID='*';

System altered.

Elapsed: 00:00:00.01
[ol8ora19rf1]<
SYS@ORA19RF1>$ ALTER SYSTEM RESET db_recovery_file_dest SCOPE=BOTH SID='*';

System altered.

Elapsed: 00:00:00.01

 

12-2. 타켓 DB에서 Import된 AWR 데이터 삭제

 

[ol8ora19rf1]<SYS@ORA19RF1>$
SELECT DBID
     , MIN(SNAP_ID) MIN_SNAP_ID
     , MAX(SNAP_ID) AS MAX_SNAP_ID
  FROM DBA_HIST_SNAPSHOT
 WHERE DBID IN ('4288610047', '1223334444')
GROUP BY DBID
;

no rows selected

Elapsed: 00:00:00.01


--만약 존재한다면 아래와 같이 제거함 (플래시백으로 과거로 간 경우 없을 것임)
BEGIN
  DBMS_WORKLOAD_REPOSITORY.DROP_SNAPSHOT_RANGE(
       low_snap_id => MIN_SNAP_ID
     , high_snap_id => MAX_SNAP_ID
     , dbid => 4288610047
  );


  DBMS_WORKLOAD_REPOSITORY.DROP_SNAPSHOT_RANGE(
       low_snap_id => MIN_SNAP_ID
     , high_snap_id => MAX_SNAP_ID
     , dbid => 1223334444
  );

END;
/

 

12-3. 타켓 DB에서 TUNER 계정 삭제

 

[ol8ora19rf1]<SYS@ORA19RF1>$ DROP USER TUNER CASCADE;

User dropped.

Elapsed: 00:00:07.78
[ol8ora19rf1]<
SYS@ORA19RF1>$ DROP TABLESPACE TUNER_DATA1 INCLUDING CONTENTS AND DATAFILES;

Tablespace dropped.

Elapsed: 00:00:01.04
[ol8ora19rf1]<
SYS@ORA19RF1>$ DROP TABLESPACE TUNER_IDX1 INCLUDING CONTENTS AND DATAFILES;

Tablespace dropped.

Elapsed: 00:00:00.95
[ol8ora19rf1]<
SYS@ORA19RF1>$ DROP TABLESPACE TUNER_TEMP INCLUDING CONTENTS AND DATAFILES;

Tablespace dropped.

Elapsed: 00:00:00.23
[ol8ora19rf1]<
SYS@ORA19RF1>$ DROP DIRECTORY DMP_DIR;

Directory dropped.

Elapsed: 00:00:00.01
[ol8ora19rf1]<
SYS@ORA19RF1>$ DROP DIRECTORY REPLAY_DIR;

Directory dropped.

Elapsed: 00:00:00.01


--존재한다면 제거할 것 (플래시백으로 과거로 간 경우 없을 것임)
[ol8ora19rf1]<SYS@ORA19RF1>$ DROP DIRECTORY AWR_DIFF_DIR;

 

12-4. 타켓 DB에서 os 파일 삭제

 

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ rm -rf /home/oracle/capture_dbreplay/
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ rm -rf /home/oracle/dmp/


12-5. 소스 db에서 acfs 볼륨 제거

 

[root@ol7ora12rf1][/root]$ ls -l /dev/asm
total 0

brwxrwx---. 1 root asmadmin 252, 124929 Jan  4 10:43 acfs1_vol1-244


[root@ol7ora12rf1][/root]$ srvctl stop filesystem -d /dev/asm/acfs1_vol1-244
[root@ol7ora12rf1][/root]$ srvctl remove filesystem -d /dev/asm/acfs1_vol1-244
[root@ol7ora12rf1][/root]$ rm -rf /acfs1_vol1

 

--2번 노드
[root@ol7ora12rf2][/root]$ rm -rf /acfs1_vol1

[+ASM1:grid@ol7ora12rf1][/home/grid]$ asmcmd lsdg
State    Type    Rebal  Sector  Logical_Sector  Block       AU  Total_MB  Free_MB  Req_mir_free_MB  Usable_file_MB  Offline_disks  Voting_files  Name
MOUNTED  EXTERN  N         512             512   4096  1048576     40960     8085                0            8085              0             N  ACFS1/
MOUNTED  NORMAL  N         512             512   4096  4194304      6144     5276             2048            1614              0             Y  CRS/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536     3380                0            3380              0             N  DATA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536    63144                0           63144              0             N  FRA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     40960     6808                0            6808              0             N  MGMT/

 

[+ASM1:grid@ol7ora12rf1][/home/grid]$ asmcmd voldelete -G ACFS1 ACFS1_VOL1
[+ASM1:grid@ol7ora12rf1][/home/grid]$ asmcmd lsdg
State    Type    Rebal  Sector  Logical_Sector  Block       AU  Total_MB  Free_MB  Req_mir_free_MB  Usable_file_MB  Offline_disks  Voting_files  Name
MOUNTED  EXTERN  N         512             512   4096  1048576     40960    40854                0           40854              0             N  ACFS1/
MOUNTED  NORMAL  N         512             512   4096  4194304      6144     5276             2048            1614              0             Y  CRS/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536     3380                0            3380              0             N  DATA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536    63144                0           63144              0             N  FRA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     40960     6808                0            6808              0             N  MGMT/

 

[+ASM1:grid@ol7ora12rf1][/home/grid]$ sa

SQL*Plus: Release 12.2.0.1.0 Production on Mon Jan 5 23:31:07 2026

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

 

[ol7ora12rf1]<SYS@+ASM1>$ ALTER DISKGROUP ACFS1 DISMOUNT;

Diskgroup altered.

Elapsed: 00:00:02.24
[ol7ora12rf1]<
SYS@+ASM1>$ quit
Disconnected from Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[+ASM1:grid@ol7ora12rf1][/home/grid]$ asmcmd lsdg
State    Type    Rebal  Sector  Logical_Sector  Block       AU  Total_MB  Free_MB  Req_mir_free_MB  Usable_file_MB  Offline_disks  Voting_files  Name
MOUNTED  NORMAL  N         512             512   4096  4194304      6144     5276             2048            1614              0             Y  CRS/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536     3380                0            3380              0             N  DATA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536    63144                0           63144              0             N  FRA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     40960     6808                0            6808              0             N  MGMT/


[+ASM2:grid@ol7ora12rf2][/home/grid]$ asmcmd lsdg
State    Type    Rebal  Sector  Logical_Sector  Block       AU  Total_MB  Free_MB  Req_mir_free_MB  Usable_file_MB  Offline_disks  Voting_files  Name
MOUNTED  EXTERN  N         512             512   4096  1048576     40960    40854                0           40854              0             N  ACFS1/
MOUNTED  NORMAL  N         512             512   4096  4194304      6144     5276             2048            1614              0             Y  CRS/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536     3380                0            3380              0             N  DATA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536    63144                0           63144              0             N  FRA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     40960     6808                0            6808              0             N  MGMT/
[+ASM2:grid@ol7ora12rf2][/home/grid]$ sa

SQL*Plus: Release 12.2.0.1.0 Production on Mon Jan 5 23:33:00 2026

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf2]<SYS@+ASM2>$ ALTER DISKGROUP ACFS1 DISMOUNT;

Diskgroup altered.

Elapsed: 00:00:02.24
[ol7ora12rf2]<
SYS@+ASM2>$ quit
Disconnected from Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
[+ASM2:grid@ol7ora12rf2][/home/grid]$ asmcmd lsdg
State    Type    Rebal  Sector  Logical_Sector  Block       AU  Total_MB  Free_MB  Req_mir_free_MB  Usable_file_MB  Offline_disks  Voting_files  Name
MOUNTED  NORMAL  N         512             512   4096  4194304      6144     5276             2048            1614              0             Y  CRS/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536     3380                0            3380              0             N  DATA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     65536    63144                0           63144              0             N  FRA1/
MOUNTED  EXTERN  N         512             512   4096  4194304     40960     6808                0            6808              0             N  MGMT/

[+ASM1:grid@ol7ora12rf1][/home/grid]$ crsctl stat res ora.ACFS1.dg -t
--------------------------------------------------------------------------------
Name           Target  State        Server                   State details
--------------------------------------------------------------------------------
Local Resources
--------------------------------------------------------------------------------
ora.ACFS1.dg
               OFFLINE OFFLINE      ol7ora12rf1              STABLE
               OFFLINE OFFLINE      ol7ora12rf2              STABLE
--------------------------------------------------------------------------------

[+ASM1:grid@ol7ora12rf1][/home/grid]$ alias sa
alias sa='rlwrap sqlplus "/as sysasm"'
[+ASM1:grid@ol7ora12rf1][/home/grid]$ sa

SQL*Plus: Release 12.2.0.1.0 Production on Mon Jan 5 23:36:02 2026

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<SYS@+ASM1>$ ALTER DISKGROUP ACFS1 MOUNT RESTRICTED;

Diskgroup altered.

Elapsed: 00:00:06.29
[ol7ora12rf1]<
SYS@+ASM1>$ DROP DISKGROUP ACFS1 INCLUDING CONTENTS;

Diskgroup dropped.

Elapsed: 00:00:03.28

[+ASM1:grid@ol7ora12rf1][/home/grid]$ crsctl stat res ora.ACFS1.dg -t
CRS-2613: Could not find resource 'ora.ACFS1.dg'.


12-6. 소스 db에서 tuner 계정 제거

 

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ ss

SQL*Plus: Release 12.2.0.1.0 Production on Sat Jan 3 19:02:57 2026

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<SYS@ORA12RF1>$ DROP USER TUNER CASCADE;

User dropped.

Elapsed: 00:00:21.16
[ol7ora12rf1]<
SYS@ORA12RF1>$ DROP TABLESPACE TUNER_DATA1 INCLUDING CONTENTS AND DATAFILES;

Tablespace dropped.

Elapsed: 00:00:00.89
[ol7ora12rf1]<
SYS@ORA12RF1>$ DROP TABLESPACE TUNER_IDX1 INCLUDING CONTENTS AND DATAFILES;

Tablespace dropped.

Elapsed: 00:00:00.80
[ol7ora12rf1]<
SYS@ORA12RF1>$ DROP TABLESPACE TUNER_TEMP INCLUDING CONTENTS AND DATAFILES;

Tablespace dropped.

Elapsed: 00:00:00.29

 

12-7. 소스 db에서 DBA_WORKLOAD_CAPTURES 뷰 정리

[ol7ora12rf1]<SYS@ORA12RF1>$

col name for a20
col dbname for a20
col status for a20
select id, name, dbid, dbname, status from DBA_WORKLOAD_CAPTURES;


        ID NAME                       DBID DBNAME               STATUS
---------- -------------------- ---------- -------------------- --------------------
        21 CAP_12C_TO_19C       4288610047 ORA12RF              COMPLETED


1 row selected.

[ol7ora12rf1]<SYS@ORA12RF1>$

BEGIN DBMS_WORKLOAD_CAPTURE.DELETE_CAPTURE_INFO(21); END;
/

[ol7ora12rf1]<SYS@ORA12RF1>$ DROP DIRECTORY DMP_DIR;

Directory dropped.

Elapsed: 00:00:00.02
[ol7ora12rf1]<
SYS@ORA12RF1>$ DROP DIRECTORY CAP_DIR;

Directory dropped.

Elapsed: 00:00:00.01


12-8. 소스 서버에서 os 파일 제거

 

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ rm -rf /home/oracle/db_replay_load/
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ rm -rf /home/oracle/dmp

[ORA12RF2:oracle@ol7ora12rf2][/home/oracle]$ rm -rf /home/oracle/db_replay_load/

 

12-9. OS 레벨 디스크 정리

[root@ol7ora12rf1][/root]$ cat /etc/udev/rules.d/99-oracle-asmdevices.rules
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29be3461e82ead5bac00667ffba", SYMLINK+="oracleasm/disks/CRS1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292b19a7e4bec0ae55ea582d62a", SYMLINK+="oracleasm/disks/CRS2", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c299c11b68fe30ad90dffdd12bba", SYMLINK+="oracleasm/disks/CRS3", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292006e0eb5849448351f3c74ef", SYMLINK+="oracleasm/disks/DATA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29459cd8180f417bc7733a3c1b4", SYMLINK+="oracleasm/disks/FRA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c295816c4f95a2f55045af76ec2e", SYMLINK+="oracleasm/disks/GIMR1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c296d91f4f3acad9e0269556ea8c", SYMLINK+="oracleasm/disks/ACFS1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"

--> ACFS1_1 을 제거할 것임

 

[root@ol7ora12rf1][/root]$ vi /etc/udev/rules.d/99-oracle-asmdevices.rules
[root@ol7ora12rf1][/root]$ cat /etc/udev/rules.d/99-oracle-asmdevices.rules
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29be3461e82ead5bac00667ffba", SYMLINK+="oracleasm/disks/CRS1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292b19a7e4bec0ae55ea582d62a", SYMLINK+="oracleasm/disks/CRS2", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c299c11b68fe30ad90dffdd12bba", SYMLINK+="oracleasm/disks/CRS3", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292006e0eb5849448351f3c74ef", SYMLINK+="oracleasm/disks/DATA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29459cd8180f417bc7733a3c1b4", SYMLINK+="oracleasm/disks/FRA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c295816c4f95a2f55045af76ec2e", SYMLINK+="oracleasm/disks/GIMR1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
--> ACFS1_1 이 제거됨

 

[root@ol7ora12rf2][/root]$ cat /etc/udev/rules.d/99-oracle-asmdevices.rules
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29be3461e82ead5bac00667ffba", SYMLINK+="oracleasm/disks/CRS1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292b19a7e4bec0ae55ea582d62a", SYMLINK+="oracleasm/disks/CRS2", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c299c11b68fe30ad90dffdd12bba", SYMLINK+="oracleasm/disks/CRS3", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292006e0eb5849448351f3c74ef", SYMLINK+="oracleasm/disks/DATA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29459cd8180f417bc7733a3c1b4", SYMLINK+="oracleasm/disks/FRA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c295816c4f95a2f55045af76ec2e", SYMLINK+="oracleasm/disks/GIMR1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c296d91f4f3acad9e0269556ea8c", SYMLINK+="oracleasm/disks/ACFS1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"

--> ACFS1_1 을 제거할 것임


[root@ol7ora12rf2][/root]$ vi /etc/udev/rules.d/99-oracle-asmdevices.rules
[root@ol7ora12rf2][/root]$ cat /etc/udev/rules.d/99-oracle-asmdevices.rules
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29be3461e82ead5bac00667ffba", SYMLINK+="oracleasm/disks/CRS1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292b19a7e4bec0ae55ea582d62a", SYMLINK+="oracleasm/disks/CRS2", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c299c11b68fe30ad90dffdd12bba", SYMLINK+="oracleasm/disks/CRS3", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c292006e0eb5849448351f3c74ef", SYMLINK+="oracleasm/disks/DATA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c29459cd8180f417bc7733a3c1b4", SYMLINK+="oracleasm/disks/FRA1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
KERNEL=="sd*", ENV{ID_SERIAL}=="36000c295816c4f95a2f55045af76ec2e", SYMLINK+="oracleasm/disks/GIMR1_1", OWNER="grid", GROUP="asmadmin", MODE="0660"
--> ACFS1_1 이 제거됨

 

[root@ol7ora12rf1][/root]$ udevadm control --reload-rules && udevadm trigger
[root@ol7ora12rf1][/root]$ ls /dev/oracleasm/disks
CRS1  CRS2  CRS3  DATA1_1  FRA1_1  GIMR1_1

 

[root@ol7ora12rf2][/root]$ udevadm control --reload-rules && udevadm trigger

[root@ol7ora12rf2][/root]$ ls /dev/oracleasm/disks
CRS1  CRS2  CRS3  DATA1_1  FRA1_1  GIMR1_1

 

--VM 설정에서 Hard Disk 제거 (VMware 레벨) (1번 및 2번 노드 전부)
VM선택 -> Settings -> Hard Disk 선택 -> Remove

 

12-10. 소스 서버 ACFS 드라이버 제거

 

--1번 노드 (root os user)

[root@ol7ora12rf1][/root]$ acfsroot disable
[root@ol7ora12rf1][/root]$ crsctl stop crs -f
[root@ol7ora12rf1][/root]$ acfsload stop
[root@ol7ora12rf1][/root]$ acfsroot uninstall
[root@ol7ora12rf1][/root]$ lsmod | grep oracle

--> 아무것도 안나와야함
[root@ol7ora12rf1][/root]$ crsctl start crs

 

--2번 노드 (root os user)
[root@ol7ora12rf2][/root]$ acfsroot disable
[root@ol7ora12rf2][/root]$ crsctl stop crs -f
[root@ol7ora12rf2][/root]$ acfsload stop
[root@ol7ora12rf2][/root]$ acfsroot uninstall
[root@ol7ora12rf2][/root]$ lsmod | grep oracle

--> 아무것도 안나와야함
[root@ol7ora12rf2][/root]$ crsctl start crs

 

12-11. 소스 서버 OS 커널 원복 (Kernel Revert)

 

[root@ol7ora12rf1][/root]$ grep ^menuentry /boot/grub2/grub.cfg | cut -d "'" -f2
Oracle Linux Server 7.9, with Unbreakable Enterprise Kernel 5.4.17-2102.201.3.el7uek.x86_64
Oracle Linux Server 7.9, with Linux 3.10.0-1160.el7.x86_64
Oracle Linux Server 7.9, with Linux 0-rescue-f31ed6c0df6d45eb99ea3f099ac6ef41
[root@ol7ora12rf1][/root]$ grubby --set-default /boot/vmlinuz-5.4.17-2102.201.3.el7uek.x86_64
[root@ol7ora12rf1][/root]$ shutdown -r now
[root@ol7ora12rf1][/root]$ uname -r
5.4.17-2102.201.3.el7uek.x86_64


[root@ol7ora12rf2][/root]$ grep ^menuentry /boot/grub2/grub.cfg | cut -d "'" -f2
Oracle Linux Server 7.9, with Unbreakable Enterprise Kernel 5.4.17-2102.201.3.el7uek.x86_64
Oracle Linux Server 7.9, with Linux 3.10.0-1160.el7.x86_64
Oracle Linux Server 7.9, with Linux 0-rescue-f31ed6c0df6d45eb99ea3f099ac6ef41

[root@ol7ora12rf2][/root]$ grubby --set-default /boot/vmlinuz-5.4.17-2102.201.3.el7uek.x86_64

[root@ol7ora12rf2][/root]$ shutdown -r now
[root@ol7ora12rf2][/root]$ uname -r
5.4.17-2102.201.3.el7uek.x86_64

 

12-12. 소스 DB 변경 파라미터 원복 (Reset Parameters)

 

[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ alias ss
alias ss='rlwrap sqlplus "/as sysdba"'
[ORA12RF1:oracle@ol7ora12rf1][/home/oracle]$ ss

SQL*Plus: Release 12.2.0.1.0 Production on Mon Jan 5 23:56:59 2026

Copyright (c) 1982, 2016, Oracle.  All rights reserved.


Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production

[ol7ora12rf1]<SYS@ORA12RF1>$
ALTER SYSTEM RESET "_optimizer_unnest_scalar_sq" SCOPE=BOTH SID='*';
ALTER SYSTEM RESET "_optimizer_push_pred_cost_based" SCOPE=BOTH SID='*';
ALTER SYSTEM RESET "_optimizer_cost_based_transformation" SCOPE=BOTH SID='*';
ALTER SYSTEM RESET "_optimizer_skip_scan_enabled" SCOPE=BOTH SID='*';
ALTER SYSTEM RESET "_b_tree_bitmap_plans" SCOPE=BOTH SID='*';
ALTER SYSTEM RESET optimizer_mode SCOPE=BOTH SID='*';


12-13. 타켓 서버 tnsnames.ora 정리

 

--2번 노드 (oracle os user)

[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ alias cdt
alias cdt='cd $ORACLE_HOME/network/admin'
[ORA19RF1:oracle@ol8ora19rf1][/home/oracle]$ cdt


[ORA19RF1:oracle@ol8ora19rf1][/u01/app/oracle/product/19.29/db_1/network/admin]$ cat tnsnames.ora
# tnsnames.ora Network Configuration File: /u01/app/oracle/product/19c/db_1/network/admin/tnsnames.ora
# Generated by Oracle configuration tools.

ORA19RF =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = ol8ora19rf-scan)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

ORA19RF1 =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.240.31)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

ORA19RF2 =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.240.32)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

[ORA19RF1:oracle@ol8ora19rf1][/u01/app/oracle/product/19.29/db_1/network/admin]$ vi tnsnames.ora
[ORA19RF1:oracle@ol8ora19rf1][/u01/app/oracle/product/19.29/db_1/network/admin]$ cat tnsnames.ora
# tnsnames.ora Network Configuration File: /u01/app/oracle/product/19c/db_1/network/admin/tnsnames.ora
# Generated by Oracle configuration tools.

ORA19RF =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = ol8ora19rf-scan)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

 

--2번 노드 (oracle os user)

[ORA19RF2:oracle@ol8ora19rf2][/home/oracle]$ alias cdt
alias cdt='cd $ORACLE_HOME/network/admin'
[ORA19RF2:oracle@ol8ora19rf2][/home/oracle]$ cdt
[ORA19RF2:oracle@ol8ora19rf2][/u01/app/oracle/product/19.29/db_1/network/admin]$ cat tnsnames.ora
# tnsnames.ora Network Configuration File: /u01/app/oracle/product/19c/db_1/network/admin/tnsnames.ora
# Generated by Oracle configuration tools.

ORA19RF =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = ol8ora19rf-scan)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

ORA19RF1 =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.240.31)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

ORA19RF2 =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = 192.168.240.32)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )
[ORA19RF2:oracle@ol8ora19rf2][/u01/app/oracle/product/19.29/db_1/network/admin]$ vi tnsnames.ora
[ORA19RF2:oracle@ol8ora19rf2][/u01/app/oracle/product/19.29/db_1/network/admin]$ cat tnsnames.ora
# tnsnames.ora Network Configuration File: /u01/app/oracle/product/19c/db_1/network/admin/tnsnames.ora
# Generated by Oracle configuration tools.

ORA19RF =
  (DESCRIPTION =
    (ADDRESS = (PROTOCOL = TCP)(HOST = ol8ora19rf-scan)(PORT = 1521))
    (CONNECT_DATA =
      (SERVER = DEDICATED)
      (SERVICE_NAME = ORA19RF)
    )
  )

반응형

+ Recent posts