SQL> CREATE TABLE partitioned_table
( a int,
b int,
data char(20)
)
PARTITION BY RANGE (a)
(
PARTITION part_1 VALUES LESS THAN (2) tablespace p1 ,
PARTITION part_2 VALUES LESS THAN (3) tablespace p2
)
/
Table created.
-- 로컬 prefixed 인덱스 생성
SQL> create index local_prefixed on partitioned_table (a,b) local ;
Index created.
-- 로컬 non-prefixed 인덱스 생성
SQL> create index local_nonprefixed on partitioned_table (b) local ;
Index created.
SQL> insert into partitioned_table
select mod(rownum-1,2)+1, rownum, 'x'
from all_objects ;
39868 rows created.
SQL> begin
dbms_stats.gather_table_stats
( user,
'PARTITIONED_TABLE' ,
cascade=>TRUE ) ;
end;
/
PL/SQL procedure successfully completed.
SQL> alter tablespace p2 offline;
Tablespace altered.
select * from partitioned_table where a=1 and b=1 ;
A B DATA
---------- ---------- --------------------
1 1 x
-- 쿼리 실행계획 확인
SQL> explain plan for
select * from partitioned_table where a =1 and b=1 ;
Explained.
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
---------------------------------------------------------------------------------------------------------------------
Plan hash value: 1622054381
------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 29 | 2 (0)| 00:00:01 | | |
| 1 | PARTITION RANGE SINGLE | | 1 | 29 | 2 (0)| 00:00:01 | 1 | 1 |
| 2 | TABLE ACCESS BY LOCAL INDEX ROWID| PARTITIONED_TABLE | 1 | 29 | 2 (0)| 00:00:01 | 1 | 1 |
|* 3 | INDEX RANGE SCAN | LOCAL_PREFIXED | 1 | | 1 (0)| 00:00:01 | 1 | 1 |
------------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("A"=1 AND "B"=1)
15 rows selected.
SQL> select * from partitioned_table where b=1;
ERROR:
ORA-00376: file 13 cannot be read at this time
ORA-01110: data file 13: '/data/data02.dbf'
no rows selected
select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------
Plan hash value: 440752652
------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 29 | 4 (0)| 00:00:01 | | |
| 1 | PARTITION RANGE ALL | | 1 | 29 | 4 (0)| 00:00:01 | 1 | 2 |
| 2 | TABLE ACCESS BY LOCAL INDEX ROWID| PARTITIONED_TABLE | 1 | 29 | 4 (0)| 00:00:01 | 1 | 2 |
|* 3 | INDEX RANGE SCAN | LOCAL_NONPREFIXED | 1 | | 3 (0)| 00:00:01 | 1 | 2 |
------------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("B"=1)
SQL> drop index local_prefixed ;
Index dropped.
SQL> select * from partitioned_table where a = 1 and b =1 ;
A B DATA
---------- ---------- --------------------
1 1 x
-- 실행계획 확인
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 904532382
------------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
------------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 29 | 2 (0)| 00:00:01 | | |
| 1 | PARTITION RANGE SINGLE | | 1 | 29 | 2 (0)| 00:00:01 | 1 | 1 |
|* 2 | TABLE ACCESS BY LOCAL INDEX ROWID| PARTITIONED_TABLE | 1 | 29 | 2 (0)| 00:00:01 | 1 | 1 |
|* 3 | INDEX RANGE SCAN | LOCAL_NONPREFIXED | 1 | | 1 (0)| 00:00:01 | 1 | 1 |
------------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter("A"=1)
3 - access("B"=1)
SQL> CREATE TABLE partitioned
( load_date date,
id int,
constraint partitioned_pk primary key(id)
)
PARTITION BY RANGE (load_date)
(
PARTITION part_1 VALUES LESS THAN
(to_date( '01/01/2000', 'dd/mm/yyyy' )) ,
PARTITION part_2 VALUES LESS THAN
(to_date( '01/01/2001','dd/mm/yyyy'))
)
/
Table created.
SQL> select segment_name, partition_name, segment_type from user_segments ;
SEGMENT_NAME PARTITION_NAME SEGMENT_TYPE
-------------------------------- -------------------- ------------------
PARTITIONED_PK INDEX
PARTITIONED_TABLE PART_1 TABLE PARTITION
PARTITIONED_TABLE PART_2 TABLE PARTITION
SQL> CREATE TABLE partitioned
( timestamp date,
id int
)
PARTITION BY RANGE (timestamp)
(
PARTITION part_1 VALUES LESS THAN
( to_date ('01-jan-2000','dd-mon-yyyy') ),
PARTITION part_2 VALUES LESS THAN
( to_date ('01-jan-2001','dd-mon-yyyy') )
)
;
Table created.
SQL> create index partition_idx on partitioned (id) local ;
cndex created.
SEGMENT_NAME PARTITION_NAME SEGMENT_TYPE
-------------------------------- -------------------- ------------------
PARTITIONED PART_1 TABLE PARTITION
PARTITIONED PART_2 TABLE PARTITION
PARTITION_IDX PART_2 INDEX PARTITION
PARTITION_IDX PART_1 INDEX PARTITION
-- 위 상태에서 primary key 제약조건을 추가하면 이미 인덱스 존재하여 에러발생.
SQL> alter table partitioned add constraint partitioned_pk primary key (id ) ;
alter table partitioned add constraint partitioned_pk primary key (id )
*
ERROR at line 1:
ORA-01408: such column list already indexed
SQL> CREATE TABLE partitioned
( timestamp date,
id int
)
PARTITION BY RANGE ( timestamp )
(
PARTITION part_1 VALUES LESS THAN
( to_date('01-jan-2000','dd-mon-yyyy') ),
PARTITION part_2 VALUES LESS THAN
( to_date('01-jan-2001','dd-mon-yyyy') )
)
;
Table created.
SQL> CREATE INDEX partitioned_index on partitioned (id) global
PARTITION BY RANGE(id)
(
partition part_1 values less than (1000),
partition part_2 values less than (MAXVALUE)
);
Index created.
-- 테이블에 기본키를 추가
SQL> alter table partitioned add constraint partitioned_pk primary key (id) ;
Table altered.
-- 오라클이 기본키를 강제하기 위해 이미 생성한 인덱스를 사용한다.
-- 제약조건을 걸어두면 index drop이 되지 않는다.
SQL> drop index partitioned_index ;
drop index partitioned_index
*
ERROR at line 1:
ORA-02429: cannot drop index used for enforcement of unique/primary key
SQL> CREATE TABLE partitioned
( timestamp date,
id int
)
PARTITION BY RANGE (timestamp)
(
PARTITION fy_2004 VALUES LESS THAN
( to_date('01-jan-2005','dd-mon-yyyy') ),
PARTITION fy_2005 VALUES LESS THAN
( to_date('01-jan-2006','dd-mon-yyyy') )
)
;
Table created.
SQL> insert into partitioned partition (fy_2004)
select to_date('31-dec-2004','dd-mon-yyyy')-mod(rownum,360), object_id
from all_objects ;
39885 rows created.
SQL> insert into partitioned partition (fy_2005)
select to_date('31-dec-2005','dd-mon-yyyy')-mod(rownum,360), object_id
from all_objects ;
39885 rows created.
SQL> create index partitioned_idx_local on partitioned (id) LOCAL ;
Index created.
SQL> create index partition_idx_global on partitioned (timestamp) GLOBAL ;
Index created.
SQL> create table fy_2004 (timestamp date, id int );
Table created.
SQL> create index fy_2004_idx on fy_2004 (id) ;
Index created.
SQL> create table fy_2006 (timestamp date, id int );
Table created.
SQL> insert into fy_2006 select to_date('31-dec-2006','dd-mon-yyyy')-mod(rownum,360), object_id
from all_objects ;
39892 rows created.
SQL> create index fy_2006_idx on fy_2006(id) nologging ;
Index created.
SQL> alter table partitioned exchange partition fy_2004
with table fy_2004
including indexes
without validation ;
Table altered.
SQL> alter table partitioned drop partition fy_2004 ;
Table altered.
-- 오래된 파티션 삭제 완료
-- 신규 파티션 추가
SQL> alter table partitioned add partition fy_2006 values less than (to_date('01-jan-2007','dd-mon-yyyy'));
Table altered.
SQL> alter table partitioned exchange partition fy_2006
with table fy_2006
including indexes
without validation
;
Table altered.
select index_name, status from user_indexes ;
INDEX_NAME STATUS
------------------------------ --------
FY_2004_IDX VALID
PARTITION_IDX_GLOBAL UNUSABLE
PARTITIONED_IDX_LOCAL N/A
FY_2006_IDX VALID
=> exchange 작업 이후 글로벌인덱스는 UNUSABLE 상태로 됨.
=> 가용성, 쿼리 성능에 부정적인 영향을 준다.
SQL> select /*+ index (partitioned PARTITION_IDX_GLOBAL) */ count(*)
from partitioned
where timestamp between to_date ('01-mar-2006','dd-mon-yyyy')
and to_date('31-mar-2006','dd-mon-yyyy') ;
*
ERROR at line 1:
ORA-01502: index 'HONG.PARTITION_IDX_GLOBAL' or partition of such index is in unusable state
SQL> alter table partitioned exchange partition fy_2004
with table fy_2004
including indexes
without validation
UPDATE GLOBAL INDEXES ;
Table altered.
SQL> alter table partitioned
drop partition fy_2004
UPDATE GLOBAL INDEXES ;
Table altered.
SQL> alter table partitioned add partition fy_2006 values less than ( to_date('01-jan-2007','dd-mon-yyyy') ) ;
Table altered.
SQL> alter table partitioned exchange partition fy_2006 with table fy_2006 including indexes
with validation UPDATE GLOBAL INDEXES ;
Table altered.
SQL> select index_name, status from user_indexes;
INDEX_NAME STATUS
------------------------------ --------
PARTITION_IDX_GLOBAL VALID
FY_2004_IDX VALID
FY_2006_IDX VALID
PARTITIONED_IDX_LOCAL N/A
select /*+ INDEX(PARTITIONED PARTITION_IDX_GLOBAL) */ count(*) from partitioned
where timestamp between to_date ('01-mar-2006','dd-mon-yyyy') and to_date('31-mar-2006','dd-mon-yyyy') ;
Execution Plan
----------------------------------------------------------
Plan hash value: 1223142522
------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 9 | 2 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 9 | | |
|* 2 | INDEX RANGE SCAN| PARTITION_IDX_GLOBAL | 1 | 9 | 2 (0)| 00:00:01 |
------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("TIMESTAMP">=TO_DATE(' 2006-03-01 00:00:00', 'syyyy-mm-dd
hh24:mi:ss') AND "TIMESTAMP"<=TO_DATE(' 2006-03-31 00:00:00', 'syyyy-mm-dd
hh24:mi:ss'))
SQL> create table emp
(
EMPNO NUMBER(4) NOT NULL,
ENAME VARCHAR2(10),
JOB VARCHAR2(9),
MGR NUMBER(4),
HIREDATE DATE,
SAL NUMBER(7,2),
COMM NUMBER(7,2),
DEPTNO NUMBER(2) NOT NULL,
LOC VARCHAR2(13) NOT NULL
)
PARTITION BY RANGE (LOC)
(
PARTITION P1 VALUES LESS THAN ('C') TABLESPACE P1,
PARTITION P2 VALUES LESS THAN ('D') TABLESPACE P2,
PARTITION P3 VALUES LESS THAN ('N') TABLESPACE P3,
PARTITION P4 VALUES LESS THAN ('Z') TABLESPACE P4
)
Table created.
SQL> alter table emp add constraint emp_pk primary key (empno) ;
Table altered.
SQL> create index emp_job_idx on emp(job) global ;
Index created.
SQL> create index emp_dept_idx on emp(deptno) global ;
Index created.
SQL> insert into emp
select e.* , d.loc
from scott.emp e, scott.dept d
where e.deptno = d.deptno
;
14 rows created.
SQL> break on pname skip 1
SQL> select 'p1' pname, empno, job, loc from emp partition(p1)
union all
select 'p2' pname, empno, job, loc from emp partition(p2)
union all
select 'p3' pname, empno, job, loc from emp partition(p3)
union all
select 'p4' pname, empno, job, loc from emp partition(p4)
;
PN EMPNO JOB LOC
-- ---------- --------- -------------
p2 7521 SALESMAN CHICAGO
7844 SALESMAN CHICAGO
7499 SALESMAN CHICAGO
7900 CLERK CHICAGO
7698 MANAGER CHICAGO
7654 SALESMAN CHICAGO
p3 7566 MANAGER DALLAS
7902 ANALYST DALLAS
7876 CLERK DALLAS
7369 CLERK DALLAS
7788 ANALYST DALLAS
p4 7782 MANAGER NEW YORK
7839 PRESIDENT NEW YORK
7934 CLERK NEW YORK
14 rows selected.
--> LOC 컬럼으로 개별 파티션됨
variable x varchar2(30);
begin
dbms_stats.set_table_stats ( user, 'EMP', numrows=>100000, numblks=>10000 );
end;
/
PL/SQL procedure successfully completed.
SQL> delete from plan_table ;
SQL> explain plan for
select empno, job, loc from emp where empno = :x ;
Explained.
SQL> select * from table(dbms_xplan.display);
PLAN_TABLE_OUTPUT
------------------------------------------------------------------------------------------------------------------------------------------------------
Plan hash value: 3656192650
-------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
-------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 27 | 2 (0)| 00:00:01 | | |
| 1 | TABLE ACCESS BY GLOBAL INDEX ROWID| EMP | 1 | 27 | 2 (0)| 00:00:01 | ROWID | ROWID |
|* 2 | INDEX UNIQUE SCAN | EMP_PK | 1 | | 1 (0)| 00:00:01 | | |
-------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("EMPNO"=TO_NUMBER(:X))
SQL> delete from plan_table ;
3 rows deleted.
SQL> explain plan for
select empno, job, loc from emp where job = :x ;
Explained.
SQL> select * from table(dbms_xplan.display);
------------------------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
------------------------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1000 | 27000 | 5 (0)| 00:00:01 | | |
| 1 | TABLE ACCESS BY GLOBAL INDEX ROWID| EMP | 1000 | 27000 | 5 (0)| 00:00:01 | ROWID | ROWID |
|* 2 | INDEX RANGE SCAN | EMP_JOB_IDX | 400 | | 1 (0)| 00:00:01 | | |
------------------------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("JOB"=:X)
SQL> alter tablespace p1 offline ;
Tablespace altered.
SQL> alter tablespace p2 offline ;
Tablespace altered.
SQL> alter tablespace p3 offline ;
Tablespace altered.
-- empno로 생성된 global index를 사용하여 TABLE ACCESS BY ROWID 로 데이터 조회 가능
SQL> select empno, job, loc from emp where empno = 7782 ;
EMPNO JOB LOC
---------- --------- -------------
7782 MANAGER NEW YORK
-- job 으로 파티셔닝 되지 않은 상태에서, empno 를 조회하여 데이터 조회 불가
SQL> select empno, job, loc from emp where job = 'CLERK';
select empno, job, loc from emp where job = 'CLERK'
*
ERROR at line 1:
ORA-00376: file 12 cannot be read at this time
ORA-01110: data file 12: '/data/data01.dbf'
-- 쿼리가 인덱스만 사용하여 TABLE ACCESS BY ROWID 가 발생하지 않는다면 데이터 조회가 가능
SQL> select count(*) from emp where job = 'CLERK' ;
COUNT(*)
----------
4