행위

UNUSABLE 파티션 테이블

DB CAFE

thumb_up 추천메뉴 바로가기


1 UNUSABLE 파티션 테이블 테스트[편집]

  • 테스트목적 : 파티션테이블에 UNIQUE/일반 인덱스가 UNUSABLE 일때 데이터를 입력할수 있는지?
  • 결론  : UNIQUE 인덱스가 UNUSABLE 일때 데이터를 입력할수 없다.
               일반 인덱스는 UNUSABLE 일때 데이터를 입력 할수 있다. 

-- 파티션 테이블 UNUSABLE 생성/변경 테스트

1.1 테이블 생성[편집]

CREATE TABLE KCY_UNIQUE_IX_TEST
(
  STR_CD              VARCHAR2(5 BYTE)          NOT NULL,
  AGG_DT              VARCHAR2(8 BYTE)          NOT NULL,
  ITEM_CD             VARCHAR2(14 BYTE)         NOT NULL
)
TABLESPACE TS_MIG
NOLOGGING
PARTITION BY RANGE (AGG_DT)
(
  PARTITION PT_1804 VALUES LESS THAN ('20180499') NOLOGGING NOCOMPRESS TABLESPACE TS_MIG,
  PARTITION PT_1805 VALUES LESS THAN ('20180599') NOLOGGING NOCOMPRESS TABLESPACE TS_MIG,
  PARTITION PT_1806 VALUES LESS THAN ('20180699') NOLOGGING NOCOMPRESS TABLESPACE TS_MIG,
  PARTITION PT_1807 VALUES LESS THAN ('20180799') NOLOGGING NOCOMPRESS TABLESPACE TS_MIG,
  PARTITION PT_1808 VALUES LESS THAN ('20180899') NOLOGGING NOCOMPRESS TABLESPACE TS_MIG,
  PARTITION PT_1809 VALUES LESS THAN ('20180999') NOLOGGING NOCOMPRESS TABLESPACE TS_MIG,
  PARTITION PT_1810 VALUES LESS THAN ('20181099') NOLOGGING NOCOMPRESS TABLESPACE TS_MIG,
  PARTITION PT_1811 VALUES LESS THAN ('20181199') NOLOGGING NOCOMPRESS TABLESPACE TS_MIG,
  PARTITION PT_1812 VALUES LESS THAN ('20181299') NOLOGGING NOCOMPRESS TABLESPACE TS_MIG,
  PARTITION PT_MAX VALUES LESS THAN (MAXVALUE)
    NOLOGGING
    NOCOMPRESS
    TABLESPACE TS_MIG
)
NOCOMPRESS
NOCACHE
PARALLEL 8
MONITORING;

1.2 UNIQUE 인덱스 생성[편집]

CREATE UNIQUE INDEX UX_KCY_UNIQUE_IX_01 ON KCY_UNIQUE_IX_TEST(ITEM_CD,AGG_DT)

            LOCAL (
                    PARTITION PT_1804,
                    PARTITION PT_1805,
                    PARTITION PT_1806,
                    PARTITION PT_1807,
                    PARTITION PT_1808,
                    PARTITION PT_1809,
                    PARTITION PT_1810,
                    PARTITION PT_1811,
                    PARTITION PT_1812,
                    PARTITION PT_MAX   
                 )
             UNUSABLE ;

1.3 일반 인덱스 생성[편집]

CREATE INDEX IX_KCY_UNIQUE_IX_02 ON KCY_UNIQUE_IX_TEST(ITEM_CD,AGG_DT)

            LOCAL (
                    PARTITION PT_1804,
                    PARTITION PT_1805,
                    PARTITION PT_1806,
                    PARTITION PT_1807,
                    PARTITION PT_1808,
                    PARTITION PT_1809,
                    PARTITION PT_1810,
                    PARTITION PT_1811,
                    PARTITION PT_1812,
                    PARTITION PT_MAX   
                 )
             UNUSABLE ;

1.4 데이터 입력[편집]

INSERT INTO KCY_UNIQUE_IX_TEST (STR_CD,AGG_DT,ITEM_CD) VALUES ('A','20180401','2222');

1.5 UNUSABLE 조회[편집]

SELECT INDEX_OWNER,INDEX_NAME,PARTITION_NAME,STATUS
  FROM DBA_IND_PARTITIONS 
 WHERE INDEX_OWNER = 'MIG_ADM'
   AND STATUS='UNUSABLE';

1.6 인덱스 리빌드[편집]

ALTER INDEX MIG_ADM.UX_KCY_UNIQUE_IX_01 REBUILD PARTITION PT_1804;

1.7 인덱스 REBUILD 처리DDL 생성[편집]

SELECT 'ALTER INDEX '||INDEX_OWNER||'.'||INDEX_NAME||' REBUILD PARTITION '||PARTITION_NAME||';' 
  FROM DBA_IND_PARTITIONS WHERE STATUS='UNUSABLE';

1.8 인덱스 UNUSABLE 파티션 삭제[편집]

SELECT 'DROP INDEX '||INDEX_OWNER||'.'||INDEX_NAME||' REBUILD PARTITION '||PARTITION_NAME||';' 
  FROM DBA_IND_PARTITIONS WHERE STATUS='UNUSABLE';

SELECT *
 FROM KCY_UNIQUE_IX_TEST;

1.9 테이블 UNUSABLE 상태로 변경[편집]

ALTER INDEX MIG_ADM.UX_KCY_UNIQUE_IX_01 MODIFY PARTITION PT_1804 UNUSABLE;