CREATE TABLE SALES_DATA_2008
(
COLUMN_1 NUMBER NOT NULL,
COLUMN_2 VARCHAR2(4),
COLUMN_3 VARCHAR2(4),
COLUMN_4 VARCHAR2(2),
COLUMN_5 VARCHAR2(2),
COLUMN_6 NUMBER
)
TABLESPACE TABLE_SPACE_DATA_1
PCTFREE 5
PCTUSED 40
INITRANS 11
MAXTRANS 255
STORAGE
(
INITIAL 2048K
NEXT 1024K
PCTINCREASE 0
MINEXTENTS 1
MAXEXTENTS 121
)
PARTITION BY RANGE ( COLUMN_3, COLUMN_4, COLUMN_5 )
(
PARTITION P_200801 VALUES LESS THAN ('2008', '04', '01' ),
PARTITION P_200802 VALUES LESS THAN ('2008', '07', '01' ),
PARTITION P_200803 VALUES LESS THAN ('2008', '10', '01' ),
PARTITION P_200804 VALUES LESS THAN ('2009', '01', '01' ),
PARTITION P_5 VALUES LESS THAN (MAXVALUE)
TABLESPACE TABLE_SPACE_DATA_2
PCTFREE 5
PCTUSED 40
INITRANS 11
MAXTRANS 255
STORAGE
(
INITIAL 1M
NEXT 1M
PCTINCREASE 0
MINEXTENTS 1
MAXEXTENTS 121
);
CREATE TABLE SALES_DATA_2008
(
COLUMN_1 NUMBER NOT NULL,
COLUMN_2 VARCHAR2(4),
COLUMN_3 VARCHAR2(4),
COLUMN_4 VARCHAR2(2),
COLUMN_5 VARCHAR2(2),
COLUMN_6 NUMBER
)
TABLESPACE TABLE_SPACE_DATA_1
PCTFREE 5
PCTUSED 40
INITRANS 11
MAXTRANS 255
STORAGE
(
INITIAL 2048K
NEXT 1024K
PCTINCREASE 0
MINEXTENTS 1
MAXEXTENTS 121
)
PARTITION BY HASH ( COLUMN_3, COLUMN_4, COLUMN_5 )
(
PARTITION P_200801,
PARTITION P_200802,
PARTITION P_200803,
PARTITION P_200804,
PARTITION P_5 VALUES LESS THAN (MAXVALUE)
)
);
CREATE TABLE SALES_DATA_2008
(
COLUMN_1 NUMBER NOT NULL,
COLUMN_2 VARCHAR2(4),
COLUMN_3 VARCHAR2(4),
COLUMN_4 VARCHAR2(2),
COLUMN_5 VARCHAR2(2),
COLUMN_6 NUMBER
)
TABLESPACE TABLE_SPACE_DATA_1
PCTFREE 5
PCTUSED 40
INITRANS 11
MAXTRANS 255
STORAGE
(
INITIAL 2048K
NEXT 1024K
PCTINCREASE 0
MINEXTENTS 1
MAXEXTENTS 121
)
PARTITION BY RANGE ( COLUMN_3, COLUMN_4 )
SUBPARTITION BY HASH ( COLUMN_5 )
(PARTITION P_200801 VALUES LESS THAN ('2008', '04'),
PARTITION P_200802 VALUES LESS THAN ('2008', '07'),
PARTITION P_200803 VALUES LESS THAN ('2008', '10')
(SUBPARTITIONS P_200803_S1 TABLESPACE TABLE_SPACE_DATA_1_1,
SUBPARTITIONS P_200803_S2 TABLESPACE TABLE_SPACE_DATA_1_2,
SUBPARTITIONS P_200803_S3 TABLESPACE TABLE_SPACE_DATA_1_3,
SUBPARTITIONS P_200803_S4 TABLESPACE TABLE_SPACE_DATA_1_4,
SUBPARTITIONS P_200803_S5 TABLESPACE TABLE_SPACE_DATA_1_5,
SUBPARTITIONS P_200803_S6 TABLESPACE TABLE_SPACE_DATA_1_6,
SUBPARTITIONS P_200803_S7 TABLESPACE TABLE_SPACE_DATA_1_7,
SUBPARTITIONS P_200803_S8 TABLESPACE TABLE_SPACE_DATA_1_8
),
PARTITION P_200804 VALUES LESS THAN ('2009', '01')
);
CREATE TABLE SALES_DATA_2008
(
COLUMN_1 NUMBER NOT NULL,
COLUMN_2 VARCHAR2(4),
COLUMN_3 VARCHAR2(4),
COLUMN_4 VARCHAR2(2),
COLUMN_5 VARCHAR2(2),
COLUMN_6 NUMBER
)
TABLESPACE TABLE_SPACE_DATA_1
PCTFREE 5
PCTUSED 40
INITRANS 11
MAXTRANS 255
STORAGE
(
INITIAL 2048K
NEXT 1024K
PCTINCREASE 0
MINEXTENTS 1
MAXEXTENTS 121
)
PARTITION BY LIST(COLUMN_2)
(
PARTITION RS VALUES('A') TABLESPACE TABLE_SPACE_DATA_2,
PARTITION RM VALUES('B') TABLESPACE TABLE_SPACE_DATA_3,
PARTITION RN VALUES('C') TABLESPACE TABLE_SPACE_DATA_4,
);
CREATE TABLE CUSTOMERS
(
CUST_ID NUMBER PRIMARY KEY,
CUST_NAME VARCHAR2(200),
RATING VARCHAR2(1) NOT NULL
)
PARTITION BY LIST(RATING)
(
PARTITION PA VALUES('A'),
PARTITION PB VALUES('B')
);
-- Detail Table
CREATE TABLE SALES
(
SALES_ID NUMBER PRIMARY KEY,
CUST_ID NUMBER NOT NULL,
SALES_AMT NUMBER,
CONSTRAINT FK_SALES_01 FOREIGN KEY (CUST_ID) REFERENCES CUSTOMERS
)
PARTITION BY REFERENCE (FK_SALES_01);
-- Normal
SELECT *
FROM SALE_TMP A,
CUSTOMERS B
WHERE A.CUST_ID = B.CUST_ID
AND B.RATING = 'A';
Rows Row Source Operation
------- ------------------------------------
0 STATEMENT
28 HASH JOIN
28 PARTITION LIST SINGLE PARTITION: 1
28 TABLE ACCESS FULL CUSTOMERS PARTITION: 1
56 TABLE ACCESS FULL SALE_TMP
-- Reference Partition
SELECT *
FROM SALES A,
CUSTOMERS B
WHERE A.CUST_ID = B.CUST_ID
AND B.RATING = 'A';
Rows Row Source Operation
------- -------------------------------------
0 STATEMENT
28 PARTITION LIST SINGLE PARTITION: 1
28 HASH JOIN
28 TABLE ACCESS FULL CUSTOMERS PARTITION: 1
28 TABLE ACCESS FULL SALES PARTITION: 1
-- 1. Range Partition 생성
CREATE TABLE SALES6
(
SALES_ID NUMBER,
SALES_DT DATE
)
PARTITION BY RANGE(SALES_DT)
(
PARTITION P0701 VALUES LESS THAN (TO_DATE('20070201', 'YYYYMMDD')),
PARTITION P0701 VALUES LESS THAN (TO_DATE('20070301', 'YYYYMMDD'))
);
-- 2. Partition Key 값의 범위에 없는 값으로 Insert
INSERT INTO SALES6 VALUES(1, TO_DATE('20070401', 'YYYYMMDD'));
-- Error
ORA-14400: inserted partition key does not map to any PARTITION
-- 3. Interval Partition 생성
CREATE TABLE SALES6
(
SALES_ID NUMBER,
SALES_DT DATE
)
PARTITION BY RANGE(SALES_DT) INTERVAL (NUMTOYMINTERVAL(1, 'MONTH'))
(
PARTITION P0701 VALUES LESS THAN(TO_DATE('20080201', 'YYYYMMDD'))
);
-- 4. Partition Key 값의 범위에 없는 값으로 Insert
INSERT INTO SALES6 VALUES(1, TO_DATE('20070601', 'YYYYMMDD'));
-- No Error
1 row created.
INTERVAL (NUMTOYMINTERVAL(1, 'MONTH'))
STORE IN (TS1, TS2, TS3)
SELECT *
FROM SALES6 PARTITION FOR(TO_DATE('20080501', 'YYYYMMDD'));
CREATE TABLE SALES3
(
SALES_ID NUMBER,
PRODUCT_CODE NUMBER,
STATE_CODE NUMBER
)
PARTITION BY SYSTEM
(
PARTITION P1 TABLESPACE USERS,
PARTITION P2 TABLESPACE USERS
);
-- Insert 할 때 테이블의 파티션을 지정하지 않을 경우
INSERT INTO SALES3 VALUES(1,101,1);
-- Error
ERROR at line 1:
ORA-14701: partition-extended name or bind variable must be used for DMLs on
tables partitioned by the System method
-- Insert을 할 때 테이블의 파티션을 지정한 경우
insert into sales3 partition (p1) values (1,101,1);
-- No Error
1 row created.
DELETE SALES3 PARTITION(P1) WHERE STATUS_CODE = 1;
-- Virtual Partition 생성
CREATE TABLE SALES
(
SALES_ID NUMBER,
CUST_ID NUMBER,
SALE_CATEGORY VARCHAR2(6)
GENERATED ALWAYS AS
(
CASE WHEN SALES_AMT <= 10000 THEN 'LOW'
WHEN SALES_AMT BETWEEN 10000 AND 100000 THEN CASE WHEN CUST_ID < 101 THEN 'LOW'
WHEN BETWEEN 101 AND 200 THEN 'MEDIUM'
ELSE 'LOW' END
WHEN SALES_AMT BETWEEN 100000 AND 1000000 THEN CASE WHEN CUST_ID < 101 THEN 'MEDIUM'
WHEN BETWEEN 101 AND 200 THEN 'HIGH'
ELSE 'ULTRA' END
ELSE 'ULTRA' END
) VIRTUAL
)
PARTITION BY LIST(SALES_CATEGORY)
(
PARTITION P_LOW VALUES ('LOW'),
PARTITION P_MEDIUM VALUES ('MEDIUM'),
PARTITION P_HIGH VALUES ('HIGH'),
PARTITION P_ULTRA VALUES ('ULTRA')
);
-- Insert 테스트
INSERT INTO SALES(SALES_ID, CUST_ID, SALES_AMT) VALUES(1, 1, 100);
-- No Error
1 row created.
CREATE TABLE DEPT
(
DEPTNO NUMBER NOT NULL,
DNAME VARCHAR2(10) NOT NULL,
LOC VARCHAR2(14)
)
PARTITION BY RANGE (DEPTNO)
(PARTITION PART_1 VALUES LESS THAN (30),
PARTITION PART_2 VALUES LESS THAN (MAXVALUE)
);
CREATE INDEX DEPT_N1 ON DEPT(DEPTNO) LOCAL;
CREATE TABLE DEPT
(
DEPTNO NUMBER NOT NULL,
DNAME VARCHAR2(10) NOT NULL,
LOC VARCHAR2(14)
)
PARTITION BY RANGE (DEPTNO)
(PARTITION PART_1 VALUES LESS THAN (30),
PARTITION PART_2 VALUES LESS THAN (MAXVALUE)
);
CREATE INDEX DEPT_N2 ON DEPT(LOC) LOCAL;
-- 테이블 생성
CREATE TABLE SALES_DATA_2008
(
COLUMN_1 NUMBER NOT NULL,
COLUMN_2 VARCHAR2(4),
COLUMN_3 VARCHAR2(4),
COLUMN_4 VARCHAR2(2),
COLUMN_5 VARCHAR2(2),
COLUMN_6 NUMBER
)
PARTITION BY RANGE ( COLUMN_3, COLUMN_4 )
(
PARTITION P_200801 VALUES LESS THAN ( '04', '01' ),
PARTITION P_200802 VALUES LESS THAN ( '07', '01' ),
PARTITION P_200803 VALUES LESS THAN ( '10', '01' ),
PARTITION P_200804 VALUES LESS THAN ( '12', MAXVALUE )
);
-- Global Prefixed Index
CREATE UNIQUE INDEX RANGE2_GPX8 ON SALES_DATA_2008( COLUMN_2, COLUMN_1)
TABLESPACE TABLE_SPACE_DATA_1
PCTFREE 10
STORAGE(INITIAL 100K NEXT 100K PCTINCREASE 0 )
GLOBAL PARTITION BY RANGE ( CODE )
(
PARTITION P_2008_P1 VALUES LESS THAN ('2000'),
PARTITION P_2008_P2 VALUES LESS THAN ('3000'),
PARTITION P_2008_P3 VALUES LESS THAN (MAXVALUE)
);
exp user/password tables=number file=exp.dmp
drop table numbers;
CREATE TABLE NUMBER(QTY NUMBER(3), NAME VARCHAR2(15))
PARTITION BY RANGE(QTY)
(PARTITION P1 VALUES LESS THAN (501),
PARTITION P2 VALUES LESS THAN (MAXVALUE));
imp user/password tables=number file=exp.dmp ignore=y
CREATE TABLE PARTBL(QTY NUMBER(3), NAME VARCHAR2(15))
PARTITION BY RANGE(QTY)
(PARTITION P1 VALUES LESS THAN(501),
PARTITION P2 VALUES LESS THAN(MAXVALUE));
INSERT INTO PARTBL(QTY, NAME) SELECT * FROM ORIGTBL;
-- 파티션 테이블 생성
CREATE TABLE P_EMP (SAL NUMBER(7,2))
PARTITION BY RANGE(SAL)
(PARTITION EMP_P1 VALUES LESS THAN (2000),
PARTITION EMP_P2 VALUES LESS THAN (4000));
-- 첫번째 파티션에 들어갈 데이터
CREATE TABLE DUMMY_Y
SELECT SAL
FROM EMP
WHERE SAL < 2000;
-- 두번째 파티션에 들어갈 데이터
CREATE TABLE DUMMY_Z
SELECT SAL
FROM EMP
WHERE SAL BETWEEN 2000 AND 3999;
ALTER TABLE P_EMP EXCHANGE PARTITION EMP_P1
WITH TABLE DUMMY_Y;
ALTER TABLE P_EMP EXCHANGE PARTITION EMP_P2
WITH TABLE DUMMY_Z;
-- 데이터 생성
CREATE TABLE YEAR(COL1 DATE) PARTITION BY RANGE (COL1)
(PARTITION OCTOBER VALUES LESS THAN ('01-NOV-1999) TABLESPACE OCTOBER,
PARTITION NOVEMBER VALUES LESS THAN ('01-DEC-1999) TABLESPACE NOVEMBER,
PARTITION DECEMBER VALUES LESS THAN (MAXVALUE) TABLESPACE DECEMBER);
-- 데이타를 Import
IMP USERNAME/PASSWORD FILE=EXPDAT.DMP FROMUSER=<OWNER> TOUSER=<OWNER>
TABLES=(YEAR:OCTOBER, YEAR:NOVEMBER, YEAR:DECEMBER)
-- 파티션 테이블 생성
CREATE TABLE PART_TBL
(IN_DATE CHAR(8) PRIMARY KEY,
EMPNO NUMBER,
ENAME VARCHAR2(20),
JOB VARCHAR2(20))
PARTITION BY RANGE (IN_DATE)
(PARTITION PART_TBL_03 VALUE LESS THAN ('20000331') TABLESPACE PTS_03,
PARTITION PART_TBL_04 VALUE LESS THAN ('20000430') TABLESPACE PTS_04,
PARTITION PART_TBL_05 VALUE LESS THAN ('20000531') TABLESPACE PTS_05,
PARTITION PART_TBL_06 VALUE LESS THAN ('20000630') TABLESPACE PTS_06,
PARTITION PART_TBL_07 VALUE LESS THAN ('20000731') TABLESPACE PTS_07,
PARTITION PART_TBL_08 VALUE LESS THAN ('20000831') TABLESPACE PTS_08,
PARTITION PART_TBL_09 VALUE LESS THAN ('20000930') TABLESPACE PTS_09,
PARTITION PART_TBL_10 VALUE LESS THAN ('20001031') TABLESPACE PTS_10);
-- 파티션 추가
ALTER TABLE PART_TBL ADD PARTITION PART_TBL_11 VALUES LESS THAN ('20001130') TABLESPACE PTS_11;
ALTER TABLE PART_TBL ADD PARTITION PART_TBL_12 VALUES LESS THAN ('20001231') TABLESPACE PTS_12;
ALTER TABLE PART_TBL DROP PARTITION PART_TBL_08;
-- 3월 파티션에서 2월과 3월을 Split함.
ALTER TABLE PART_TBL SPLIT PARTITION PART_TBL_03 AT ('20000229')
INTO (PARTITION PART_TBL_02 TABLESPACE PTS_02,
PARTITION PART_TBL_03_1 TABLESPACE PTS_03);
-- 2월 파티션에서 1월과 2월을 Split함.
ALTER TABLE PART_TBL SPLIT PARTITION PART_TBL_02 AT ('20000131')
INTO (PARTITION PART_TBL_01 TABLESPACE PTS_01,
PARTITION PART_TBL_02_1 TABLESPACE PTS_02);
ALTER TABLE PART_TBL RENAME PARTITION PART_TBL_02_1 TO PART_TBL_02;
ALTER TABLE PART_TBL MOVE PARTITION PART_TBL_10 TABLESPACE PTS_10_1 NOLOGGING;
ALTER TABLE PART_TBL TRUNCATE PARTITION PART_TBL_02;
-- part_tbl의 모든 Partition의 Next 값이 변경
ALTER TABLE PART_TBL STORAGE (NEXT 10M);
-- part_tbl_05 Partition의 Maxextents 값만 변경
ALTER TABLE PART_TBL MODIFY PARTITION PART_TBL_05 STORAGE (MAXEXTENTS 1000);
-- 특정 파티션의 인덱스 Rebuild
ALTER INDEX IND_PART_TBL REBUILD PARTITION I_PART_TBL_02;
-- 글로벌 인덱스 Rebuild
ALTER INDEX PART_TBL_PK REBUILD;
$ exp scott/tiger tables=emp file=emp.dmp
-- ':' 을 이용하여 Partition 이름을 지정하며 이 경우 Emp Table의 px Partition만을 Export
$ exp scott/tiger tables=emp:px file=emp_par.dmp
-- Sales Table은 전부를, Emp Table에서는 px Partition만을 Export.
$ exp scott/tiger tables=(emp:px, sales) file=both.dmp
-- emp table(Partitioned 또는 non-Partitioned) 전체를 Import
$ imp scott/tiger file=wookpark.dmp tables=emp
-- emp table의 px Partition만을 Import.
-- ':'을 이용하여 Partition을 지정
$ imp scott/tiger file=wookpark.dmp tables=emp:px
1. 파티션되어 있지 않은 테이블을 Exp, Imp를 이용하여 파티션 하는 예
1) 파티션되어 있지 않은 테이블을 Export한다.
$ exp scott/tiger file=wookpark.dmp tables=emp
2) 해당 Table을 Drop한다.
DROP TABLE EMP
3) 파티션 테이블을 생성한다.
CREATE TABLE EMP
(EMPNO NUMBER(4) NOT NULL,
....
)
PARTITION BY RANGE (EMPNO),
(PARTITION EMP1 VALUES LESS THAN (1000) TABLESPACE TS1,
PARTITION EMP1 VALUES LESS THAN (2000) TABLESPACE TS2,
PARTITION EMP1 VALUES LESS THAN (3000) TABLESPACE TS3);
4) Import한다.
$ imp scott/tiger file=wookpark.dmp tables=emp ignore=y
2. Partitioned Table의 Partition들을 exp/imp를 이용하여 Merge하는 예
1) Merge의 대상이 되는 Partition을 Export한다.
$exp scott/tiger file=wookpark.dmp tables=emp:emp2
2) Merge의 대상이 되는 Partition을 'alter table...'문장으로 Drop한다.
ALTER TABLE EMP DROP PARTITION EMP2;
3) Import한다.
$imp scott/tiger file=wookpark.dmp tables=emp:emp3 ignore=y
① 테이블
CREATE TABLE APPS.NORMAL_TEST_TAB
(
MON_P1 DATE,
GRP_P2 NUMBER,
CNT_N1 NUMBER
);
② 샘플 데이터 넣기
INSERT INTO APPS.NORMAL_TEST_TAB
SELECT ADD_MONTHS(TO_DATE('200001', 'YYYYMM'),
DECODE(MOD(LEVEL, 10000),
0,
TRUNC(LEVEL / 10000),
TRUNC(LEVEL / 10000) + 1) - 1) MON_P1,
DECODE(MOD(LEVEL, 100),
0,
TRUNC(LEVEL / 100),
TRUNC(LEVEL / 100) + 1) * 100 GRP_P2,
LEVEL CNT_N1
FROM DUAL
CONNECT BY LEVEL <= 1000000
;
COMMIT;
③ 통계정보
BEGIN
DBMS_STATS.GATHER_TABLE_STATS('APPS',
'NORMAL_TEST_TAB',
CASCADE => TRUE);
END;
/
NORMAL_TEST_TAB
---------------
Rows=997,141 Blocks=3,032
Empty Blocks=0 Avg Space=0
Chain Count=0 Avg Row Length=16
Avg Space Freelist Blocks=0 Freelist Blocks=0
Sample Size=54,167 Last Analyze=2008/08/24
Partitioned=NO
Column Name Nullable Column Type Distinct Buckets
-------------------------------- -------- ------------- ---------- ----------
MON_P1 DATE 101 1
GRP_P2 NUMBER 9,999 1
CNT_N1 NUMBER 997,141 1
INDEX
-----------------------------------------------------------------------------
① 테이블
CREATE TABLE APPS.PARTITION_TEST_TAB
(
MON_P1 DATE,
GRP_P2 NUMBER,
CNT_N1 NUMBER
)
PARTITION BY RANGE ( MON_P1 )
SUBPARTITION BY HASH( GRP_P2 )
(
PARTITION P200001 VALUES LESS THAN(TO_DATE('200001', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200002 VALUES LESS THAN(TO_DATE('200002', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200003 VALUES LESS THAN(TO_DATE('200003', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200004 VALUES LESS THAN(TO_DATE('200004', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200005 VALUES LESS THAN(TO_DATE('200005', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200006 VALUES LESS THAN(TO_DATE('200006', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200007 VALUES LESS THAN(TO_DATE('200007', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200008 VALUES LESS THAN(TO_DATE('200008', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200009 VALUES LESS THAN(TO_DATE('200009', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200010 VALUES LESS THAN(TO_DATE('200010', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200011 VALUES LESS THAN(TO_DATE('200011', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200012 VALUES LESS THAN(TO_DATE('200012', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200101 VALUES LESS THAN(TO_DATE('200101', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200102 VALUES LESS THAN(TO_DATE('200102', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200103 VALUES LESS THAN(TO_DATE('200103', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200104 VALUES LESS THAN(TO_DATE('200104', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200105 VALUES LESS THAN(TO_DATE('200105', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200106 VALUES LESS THAN(TO_DATE('200106', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200107 VALUES LESS THAN(TO_DATE('200107', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200108 VALUES LESS THAN(TO_DATE('200108', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200109 VALUES LESS THAN(TO_DATE('200109', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200110 VALUES LESS THAN(TO_DATE('200110', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200111 VALUES LESS THAN(TO_DATE('200111', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200112 VALUES LESS THAN(TO_DATE('200112', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200201 VALUES LESS THAN(TO_DATE('200201', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200202 VALUES LESS THAN(TO_DATE('200202', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200203 VALUES LESS THAN(TO_DATE('200203', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200204 VALUES LESS THAN(TO_DATE('200204', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200205 VALUES LESS THAN(TO_DATE('200205', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200206 VALUES LESS THAN(TO_DATE('200206', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200207 VALUES LESS THAN(TO_DATE('200207', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200208 VALUES LESS THAN(TO_DATE('200208', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200209 VALUES LESS THAN(TO_DATE('200209', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200210 VALUES LESS THAN(TO_DATE('200210', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200211 VALUES LESS THAN(TO_DATE('200211', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200212 VALUES LESS THAN(TO_DATE('200212', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200301 VALUES LESS THAN(TO_DATE('200301', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200302 VALUES LESS THAN(TO_DATE('200302', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200303 VALUES LESS THAN(TO_DATE('200303', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200304 VALUES LESS THAN(TO_DATE('200304', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200305 VALUES LESS THAN(TO_DATE('200305', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200306 VALUES LESS THAN(TO_DATE('200306', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200307 VALUES LESS THAN(TO_DATE('200307', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200308 VALUES LESS THAN(TO_DATE('200308', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200309 VALUES LESS THAN(TO_DATE('200309', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200310 VALUES LESS THAN(TO_DATE('200310', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200311 VALUES LESS THAN(TO_DATE('200311', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200312 VALUES LESS THAN(TO_DATE('200312', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200401 VALUES LESS THAN(TO_DATE('200401', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200402 VALUES LESS THAN(TO_DATE('200402', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200403 VALUES LESS THAN(TO_DATE('200403', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200404 VALUES LESS THAN(TO_DATE('200404', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200405 VALUES LESS THAN(TO_DATE('200405', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200406 VALUES LESS THAN(TO_DATE('200406', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200407 VALUES LESS THAN(TO_DATE('200407', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200408 VALUES LESS THAN(TO_DATE('200408', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200409 VALUES LESS THAN(TO_DATE('200409', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200410 VALUES LESS THAN(TO_DATE('200410', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200411 VALUES LESS THAN(TO_DATE('200411', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200412 VALUES LESS THAN(TO_DATE('200412', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200501 VALUES LESS THAN(TO_DATE('200501', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200502 VALUES LESS THAN(TO_DATE('200502', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200503 VALUES LESS THAN(TO_DATE('200503', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200504 VALUES LESS THAN(TO_DATE('200504', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200505 VALUES LESS THAN(TO_DATE('200505', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200506 VALUES LESS THAN(TO_DATE('200506', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200507 VALUES LESS THAN(TO_DATE('200507', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200508 VALUES LESS THAN(TO_DATE('200508', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200509 VALUES LESS THAN(TO_DATE('200509', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200510 VALUES LESS THAN(TO_DATE('200510', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200511 VALUES LESS THAN(TO_DATE('200511', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200512 VALUES LESS THAN(TO_DATE('200512', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200601 VALUES LESS THAN(TO_DATE('200601', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200602 VALUES LESS THAN(TO_DATE('200602', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200603 VALUES LESS THAN(TO_DATE('200603', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200604 VALUES LESS THAN(TO_DATE('200604', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200605 VALUES LESS THAN(TO_DATE('200605', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200606 VALUES LESS THAN(TO_DATE('200606', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200607 VALUES LESS THAN(TO_DATE('200607', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200608 VALUES LESS THAN(TO_DATE('200608', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200609 VALUES LESS THAN(TO_DATE('200609', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200610 VALUES LESS THAN(TO_DATE('200610', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200611 VALUES LESS THAN(TO_DATE('200611', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200612 VALUES LESS THAN(TO_DATE('200612', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200701 VALUES LESS THAN(TO_DATE('200701', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200702 VALUES LESS THAN(TO_DATE('200702', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200703 VALUES LESS THAN(TO_DATE('200703', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200704 VALUES LESS THAN(TO_DATE('200704', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200705 VALUES LESS THAN(TO_DATE('200705', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200706 VALUES LESS THAN(TO_DATE('200706', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200707 VALUES LESS THAN(TO_DATE('200707', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200708 VALUES LESS THAN(TO_DATE('200708', 'YYYYMM')) SUBPARTITIONS 100,
PARTITION P200709 VALUES LESS THAN(TO_DATE('200709', 'YYYYMM')) SUBPARTITIONS 100,
-- 9400에서 10,000개 파티션에 근접해서 더 늘어나는 구간이라 MAXVALUE 처리함
PARTITION P5 VALUES LESS THAN(MAXVALUE) SUBPARTITIONS 100
);
② 샘플 데이터 넣기
INSERT INTO APPS.PARTITION_TEST_TAB
SELECT ADD_MONTHS(TO_DATE('200001', 'YYYYMM'),
DECODE(MOD(LEVEL, 10000),
0,
TRUNC(LEVEL / 10000),
TRUNC(LEVEL / 10000) + 1) - 1) MON_P1,
DECODE(MOD(LEVEL, 100),
0,
TRUNC(LEVEL / 100),
TRUNC(LEVEL / 100) + 1) * 100 GRP_P2,
LEVEL CNT_N1
FROM DUAL
CONNECT BY LEVEL <= 1000000
;
COMMIT;
③ 통계정보
BEGIN
DBMS_STATS.GATHER_TABLE_STATS('APPS',
'PARTITION_TEST_TAB',
CASCADE => TRUE);
END;
/
PARTITION_TEST_TAB
------------------
Rows=998,668 Blocks=74,646
Empty Blocks=0 Avg Space=0
Chain Count=0 Avg Row Length=16
Avg Space Freelist Blocks=0 Freelist Blocks=0
Sample Size=56,777 Last Analyze=2008/08/24
Partitioned=YES
Column Name Nullable Column Type Distinct Buckets
-------------------------------- -------- ------------- ---------- ----------
MON_P1 DATE 101 1
GRP_P2 NUMBER 9,994 1
CNT_N1 NUMBER 998,668 1
INDEX
-----------------------------------------------------------------------------
① 일반 테이블
SELECT *
FROM NORMAL_TEST_TAB
WHERE MON_P1 = :B1 -- 2007/01/01
AND GRP_P2 = :B2 -- 841000
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 11 0.080 0.087 0 3064 0 100
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 13 0.080 0.088 0 3064 0 100
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
100 TABLE ACCESS FULL NORMAL_TEST_TAB (cr=3064 pr=0 pw=0 time=70247 us)
② 파티션 테이블
SELECT *
FROM PARTITION_TEST_TAB
WHERE MON_P1 = :B1 -- 2007/01/01
AND GRP_P2 = :B2 -- 841000
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 11 0.000 0.001 0 25 0 100
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 13 0.000 0.001 0 25 0 100
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
100 PARTITION RANGE SINGLE PARTITION: KEY KEY (cr=25 pr=0 pw=0 time=120 us)
100 PARTITION HASH SINGLE PARTITION: KEY KEY (cr=25 pr=0 pw=0 time=96 us)
100 TABLE ACCESS FULL PARTITION_TEST_TAB PARTITION: KEY KEY (cr=25 pr=0 pw=0 time=80 us)
① 일반 테이블
SELECT *
FROM NORMAL_TEST_TAB
WHERE CNT_N1 = :B1 -- 900000
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 2 0.400 0.412 0 3055 0 1
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 4 0.400 0.412 0 3055 0 1
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
1 TABLE ACCESS FULL NORMAL_TEST_TAB (cr=3055 pr=0 pw=0 time=371933 us)
② 파티션 테이블
-- 2개 파티션 키 모두 없이
SELECT *
FROM PARTITION_TEST_TAB
WHERE CNT_N1 = :B1 -- 900000
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 2 0.940 0.936 0 97104 0 1
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 4 0.940 0.937 0 97104 0 1
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
1 PARTITION RANGE ALL PARTITION: 1 94 (cr=97104 pr=0 pw=0 time=873415 us)
1 PARTITION HASH ALL PARTITION: 1 100 (cr=97104 pr=0 pw=0 time=933492 us)
1 TABLE ACCESS FULL PARTITION_TEST_TAB PARTITION: 1 9400 (cr=97104 pr=0 pw=0 time=924367 us)
-- 1개 파티션 키 선두(1블럭당 5개 로우 액세스 - 그나마 효율)
SELECT *
FROM PARTITION_TEST_TAB
WHERE MON_P1 = :B1 -- 2007/01/01
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 1001 0.000 0.046 0 1948 0 10000
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 1003 0.000 0.046 0 1948 0 10000
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
10000 PARTITION RANGE SINGLE PARTITION: KEY KEY (cr=1948 pr=0 pw=0 time=40165 us)
10000 PARTITION HASH ALL PARTITION: 1 100 (cr=1948 pr=0 pw=0 time=40148 us)
10000 TABLE ACCESS FULL PARTITION_TEST_TAB PARTITION: KEY KEY (cr=1948 pr=0 pw=0 time=3704 us)
-- 1개 파티션 키 후발(100블럭당 8개 로우 액세스 - 비효율적)
SELECT *
FROM PARTITION_TEST_TAB
WHERE GRP_P2 = :B2 -- 841000
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 11 0.010 0.013 0 1240 0 100
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 13 0.010 0.013 0 1240 0 100
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
100 PARTITION RANGE ALL PARTITION: 1 94 (cr=1240 pr=0 pw=0 time=10802 us)
100 PARTITION HASH SINGLE PARTITION: KEY KEY (cr=1240 pr=0 pw=0 time=12343 us)
100 TABLE ACCESS FULL PARTITION_TEST_TAB PARTITION: (cr=1240 pr=0 pw=0 time=11913 us)
-- 파티션 키에서 선두 없이 후발만 들어오게 되면 비효율적
① 일반 테이블
CREATE INDEX APPS.NORMAL_TEST_TAB_N1 ON APPS.NORMAL_TEST_TAB (MON_P1)
TABLESPACE APPS_TS_TX_IDX COMPUTE STATISTICS PARALLEL 6;
CREATE INDEX APPS.NORMAL_TEST_TAB_N2 ON APPS.NORMAL_TEST_TAB (MON_P1, GRP_P2)
TABLESPACE APPS_TS_TX_IDX COMPUTE STATISTICS PARALLEL 6;
CREATE INDEX APPS.NORMAL_TEST_TAB_N3 ON APPS.NORMAL_TEST_TAB (CNT_N1)
TABLESPACE APPS_TS_TX_IDX COMPUTE STATISTICS PARALLEL 6;
ALTER INDEX APPS.NORMAL_TEST_TAB_N1 NOPARALLEL;
ALTER INDEX APPS.NORMAL_TEST_TAB_N2 NOPARALLEL;
ALTER INDEX APPS.NORMAL_TEST_TAB_N3 NOPARALLEL;
② 파티션 테이블
-- Local Prefixed Index
CREATE INDEX APPS.PARTITION_TEST_TAB_N1 ON APPS.PARTITION_TEST_TAB (MON_P1)
TABLESPACE APPS_TS_TX_IDX COMPUTE STATISTICS PARALLEL 6 LOCAL;
CREATE INDEX APPS.PARTITION_TEST_TAB_N2 ON APPS.PARTITION_TEST_TAB (MON_P1, GRP_P2)
TABLESPACE APPS_TS_TX_IDX COMPUTE STATISTICS PARALLEL 6 LOCAL;
-- Global Prefixed Index
CREATE INDEX APPS.PARTITION_TEST_TAB_N3 ON APPS.PARTITION_TEST_TAB (CNT_N1)
GLOBAL PARTITION BY RANGE(CNT_N1) (PARTITION P1 VALUES LESS THAN (100000),
PARTITION P2 VALUES LESS THAN (200000),
PARTITION P3 VALUES LESS THAN (300000),
PARTITION P4 VALUES LESS THAN (400000),
PARTITION P5 VALUES LESS THAN (500000),
PARTITION P6 VALUES LESS THAN (600000),
PARTITION P7 VALUES LESS THAN (700000),
PARTITION P8 VALUES LESS THAN (800000),
PARTITION P9 VALUES LESS THAN (900000),
PARTITION P10 VALUES LESS THAN (1000000),
PARTITION P11 VALUES LESS THAN (MAXVALUE))
TABLESPACE APPS_TS_TX_IDX COMPUTE STATISTICS PARALLEL 6;
ALTER INDEX APPS.PARTITION_TEST_TAB_N1 NOPARALLEL;
ALTER INDEX APPS.PARTITION_TEST_TAB_N2 NOPARALLEL;
ALTER INDEX APPS.PARTITION_TEST_TAB_N3 NOPARALLEL;
① 일반 테이블
NORMAL_TEST_TAB
---------------
Rows=997,141 Blocks=3,032
Empty Blocks=0 Avg Space=0
Chain Count=0 Avg Row Length=16
Avg Space Freelist Blocks=0 Freelist Blocks=0
Sample Size=54,167 Last Analyze=2008/08/24
Partitioned=NO
Column Name Nullable Column Type Distinct Buckets
-------------------------------- -------- ------------- ---------- ----------
MON_P1 DATE 101 1
GRP_P2 NUMBER 9,999 1
CNT_N1 NUMBER 997,141 1
INDEX
-----------------------------------------------------------------------------
NORMAL_TEST_TAB_N1 : MON_P1
Type=NORMAL, Uniq=No, Distinct=100, Rows=1,000,000, Last Analyze=2008/08/24
NORMAL_TEST_TAB_N2 : MON_P1 + GRP_P2
Type=NORMAL, Uniq=No, Distinct=10,000, Rows=1,000,000, Last Analyze=2008/08/24
NORMAL_TEST_TAB_N3 : CNT_N1
Type=NORMAL, Uniq=No, Distinct=1,000,000, Rows=1,000,000, Last Analyze=2008/08/24
② 파티션 테이블
PARTITION_TEST_TAB
------------------
Rows=998,668 Blocks=74,646
Empty Blocks=0 Avg Space=0
Chain Count=0 Avg Row Length=16
Avg Space Freelist Blocks=0 Freelist Blocks=0
Sample Size=56,777 Last Analyze=2008/08/24
Partitioned=YES
Column Name Nullable Column Type Distinct Buckets
-------------------------------- -------- ------------- ---------- ----------
MON_P1 DATE 101 1
GRP_P2 NUMBER 9,994 1
CNT_N1 NUMBER 998,668 1
INDEX
-----------------------------------------------------------------------------
PARTITION_TEST_TAB_N1 : MON_P1
Partition=LOCAL NON_PREFIXED
Type=NORMAL, Uniq=No, Distinct=8, Rows=1,000,000, Last Analyze=2008/08/24
PARTITION_TEST_TAB_N2 : MON_P1 + GRP_P2
Partition=LOCAL PREFIXED
Type=NORMAL, Uniq=No, Distinct=10,000, Rows=1,000,000, Last Analyze=2008/08/24
PARTITION_TEST_TAB_N3 : CNT_N1
Partition=GLOBAL PREFIXED
Type=NORMAL, Uniq=No, Distinct=1,000,000, Rows=1,000,000, Last Analyze=2008/08/24
① 일반 테이블
SELECT *
FROM NORMAL_TEST_TAB
WHERE MON_P1 = :B1 -- 2007/01/01
AND GRP_P2 = :B2 -- 841000
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 11 0.000 0.000 0 24 0 100
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 13 0.000 0.001 0 24 0 100
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
100 TABLE ACCESS BY INDEX ROWID NORMAL_TEST_TAB (cr=24 pr=0 pw=0 time=36 us)
100 INDEX RANGE SCAN NORMAL_TEST_TAB_N2 (cr=13 pr=0 pw=0 time=621 us)(Object ID 2885525)
SELECT *
FROM NORMAL_TEST_TAB
WHERE CNT_N1 = :B1 -- 900000
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 2 0.000 0.000 0 5 0 1
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 4 0.000 0.000 0 5 0 1
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
1 TABLE ACCESS BY INDEX ROWID NORMAL_TEST_TAB (cr=5 pr=0 pw=0 time=40 us)
1 INDEX RANGE SCAN NORMAL_TEST_TAB_N3 (cr=4 pr=0 pw=0 time=36 us)(Object ID 2885526)
② 파티션 테이블
SELECT *
FROM PARTITION_TEST_TAB
WHERE MON_P1 = :B1 -- 2007/01/01
AND GRP_P2 = :B2 -- 841000
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 11 0.000 0.001 0 23 0 100
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 13 0.000 0.001 0 23 0 100
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
100 PARTITION RANGE SINGLE PARTITION: KEY KEY (cr=23 pr=0 pw=0 time=71 us)
100 PARTITION HASH SINGLE PARTITION: KEY KEY (cr=23 pr=0 pw=0 time=55 us)
100 TABLE ACCESS BY LOCAL INDEX ROWID PARTITION_TEST_TAB PARTITION: KEY KEY (cr=23 pr=0 pw=0 time=46 us)
100 INDEX RANGE SCAN PARTITION_TEST_TAB_N2 PARTITION: KEY KEY (cr=12 pr=0 pw=0 time=826 us)(Object ID 2895022)
-- Global Prefixed Index
SELECT *
FROM PARTITION_TEST_TAB
WHERE CNT_N1 = :B1 -- 900000
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 2 0.000 0.000 0 4 0 1
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 4 0.000 0.000 0 4 0 1
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
1 PARTITION RANGE SINGLE PARTITION: KEY KEY (cr=4 pr=0 pw=0 time=49 us)
1 TABLE ACCESS BY GLOBAL INDEX ROWID PARTITION_TEST_TAB PARTITION: ROW LOCATION ROW LOCATION (cr=4 pr=0 pw=0 time=35 us)
1 INDEX RANGE SCAN PARTITION_TEST_TAB_N3 PARTITION: KEY KEY (cr=3 pr=0 pw=0 time=30 us)(Object ID 2904517)
;
-- Local Non-Prefixed Index
DROP INDEX APPS.PARTITION_TEST_TAB_N3;
CREATE INDEX APPS.PARTITION_TEST_TAB_N3 ON APPS.PARTITION_TEST_TAB (CNT_N1) TABLESPACE APPS_TS_TX_IDX COMPUTE STATISTICS PARALLEL 6 LOCAL;
-- FULL COLUMN
SELECT *
FROM PARTITION_TEST_TAB
WHERE MON_P1 = :B1 -- 2007/01/01
AND GRP_P2 = :B2 -- 841000
AND CNT_N1 = :B3 -- 840936
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 2 0.000 0.000 0 4 0 1
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 4 0.000 0.000 0 4 0 1
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
1 PARTITION RANGE SINGLE PARTITION: KEY KEY (cr=4 pr=0 pw=0 time=99 us)
1 PARTITION HASH SINGLE PARTITION: KEY KEY (cr=4 pr=0 pw=0 time=73 us)
1 TABLE ACCESS BY LOCAL INDEX ROWID PARTITION_TEST_TAB PARTITION: KEY KEY (cr=4 pr=0 pw=0 time=55 us)
1 INDEX RANGE SCAN PARTITION_TEST_TAB_N3 PARTITION: KEY KEY (cr=3 pr=0 pw=0 time=41 us)(Object ID 2904529)
-- 후발 없이(선두키가 없으면 PARALLEL 처리할 ? 보이는 실행계획 나옴)
SELECT *
FROM PARTITION_TEST_TAB
WHERE MON_P1 = :B1 -- 2007/01/01
AND CNT_N1 = :B3 -- 840936
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.018 0 200 0 0
Fetch 2 0.010 0.117 0 0 0 1
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 4 0.010 0.135 0 200 0 1
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
1 PX COORDINATOR (cr=200 pr=0 pw=0 time=37561 us)
0 PX SEND QC (RANDOM) :TQ10000 (cr=0 pr=0 pw=0 time=0 us)
0 PX PARTITION HASH ALL PARTITION: 1 100 (cr=0 pr=0 pw=0 time=0 us)
0 TABLE ACCESS BY LOCAL INDEX ROWID PARTITION_TEST_TAB PARTITION: KEY KEY (cr=0 pr=0 pw=0 time=0 us)
0 INDEX RANGE SCAN PARTITION_TEST_TAB_N3 PARTITION: KEY KEY (cr=0 pr=0 pw=0 time=0 us)(Object ID 2904529)
-- 선두 없이(선두키가 없으면 PARALLEL 처리할 ? 보이는 실행계획 나옴)
SELECT *
FROM PARTITION_TEST_TAB
WHERE GRP_P2 = :B2 -- 841000
AND CNT_N1 = :B3 -- 840936
;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.000 0.000 0 0 0 0
Execute 1 0.000 0.009 0 188 0 0
Fetch 2 0.010 0.135 0 0 0 1
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 4 0.010 0.144 0 188 0 1
Misses in library cache during parse: 0
Optimizer goal: ALL_ROWS
Parsing user: APPS (ID=44)
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
1 PX COORDINATOR (cr=188 pr=0 pw=0 time=46595 us)
0 PX SEND QC (RANDOM) :TQ10000 (cr=0 pr=0 pw=0 time=0 us)
0 PX PARTITION HASH SINGLE PARTITION: KEY KEY (cr=0 pr=0 pw=0 time=0 us)
0 TABLE ACCESS BY LOCAL INDEX ROWID PARTITION_TEST_TAB PARTITION: (cr=0 pr=0 pw=0 time=0 us)
0 INDEX RANGE SCAN PARTITION_TEST_TAB_N3 PARTITION: (cr=0 pr=0 pw=0 time=0 us)(Object ID 2904529)
영업 주문 조회 프로그램에 대해 파티션 테이블 적용 사례
우리 회사에서는 영업에서 주문이 된 내용들을 신속하게 확인하게 위해 '영업 주문 조회'라는 프로그램을 만들었다.
그러나 이 프로그램은 시간이 지나면 지날수록 조회하는 속도가 너무나 느려 사용자들의 클레임이 늘어나고 있는 실정이다.
하여 수행속도가 느린 원인을 분석한 결과 '영업 주문 조회'에 참여하는 테이블 수가 30개나 되어 조인하는데 시간이 너무
많이 걸리고 날짜 조건 또한 너무나 큰 Range(2~3달)를 주어 내부적으로 액세스 하는 로우수가 많은것을 확인하였다.
현재 필수조건으로 들어오는 조건은 사업부와 날짜조건이다. 그 외에 선택조건들이 20개 정도 들어가 있다.
필수조건만 가지고 2달의 범위를 주고 체크한 결과 30분이 넘게 걸려서 문제의 심각성을 인지하였고, 이를 해결하기 위해
우리는 '영업 주문 조회'에서 사용되는 SQL을 30분마다 배치를 수행하여 Temp 테이블에 넣고 이를 조회하도록 하려고 한다.
이를 위해 우리는 테이블 생성 시 파티션으로 구성할 수 있다는 얘기를 들었고 이 기술을 Temp 테이블에 도입하려고 한다.
어떤 고려사항을 가지고 파티션 테이블을 만들어야 할지 모르겠다. 아래는 파티션 테이블을 만들기 위해 고려해야 할
사항들을 미리 뽑아보았다.
1. 필수조건은 사업부, 주문생성일자이다.
2. 모든 사업부에 대해 하루에 발생할 수 있는 건수는 약 30만건 정도로 추정된다.
3. 우리는 2년치 데이터를 이 테이블에 보관하고 1년마다 새롭게 관리를 하고자 한다.
4. 기존에 A 사업부 + 2달치 조건을 주었을 경우 3,000건에 30분이 걸렸다고 가정한다면 이 기술이 도입될 경우 1분 이내에
나올 수 있기를 희망한다.
어떻게 파티션 테이블 및 인덱스를 구성해야 할까?