h2.2. 파티션 Pruning
h3.기본 파티션 Pruning
h4.파티션 Pruning 기능에 따른 실행계획 비교
SQL> create table t ( key, no, data )
partition by range(no)(
partition p01 values less than(11)
, partition p02 values less than(21)
, partition p03 values less than(31)
, partition p04 values less than(41)
, partition p05 values less than(51)
, partition p06 values less than(61)
, partition p07 values less than(71)
, partition p08 values less than(81)
, partition p09 values less than(91)
, partition p10 values less than(maxvalue)
)
as
select lpad(rownum, 6, '0'), mod(rownum, 100)+1, lpad(rownum, 10, '0')
from dual
connect by level <= 999999;
-- 상수조건 사용으로 정적 Pruning TEST
SQL> Select count(*) from t Where no between 30 and 50;
--------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
--------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 13 | 287 (14)| 00:00:04 | | |
| 1 | SORT AGGREGATE | | 1 | 13 | | | | |
| 2 | PARTITION RANGE ITERATOR| | 204K| 2590K| 287 (14)| 00:00:04 | 3 | 5 |
| 3 | TABLE ACCESS FULL | T | 204K| 2590K| 287 (14)| 00:00:04 | 3 | 5 |
--------------------------------------------------------------------------------------------------
-- Bind변수로 입력 동적 Pruning TEST
SQL>Select count(*) from t Where no between :a and :b;
---------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
---------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 13 | 876 (7)| 00:00:11 | | |
| 1 | SORT AGGREGATE | | 1 | 13 | | | | |
| 2 | FILTER | | | | | | | |
| 3 | PARTITION RANGE ITERATOR| | 2214 | 28782 | 876 (7)| 00:00:11 | KEY | KEY |
| 4 | TABLE ACCESS FULL | T | 2214 | 28782 | 876 (7)| 00:00:11 | KEY | KEY |
---------------------------------------------------------------------------------------------------
* 'KEY'라고 표시된 것은 하드파싱 시점에 액세스할 파티션을 결정할 수 없기 때문이다.
-- In-List 이용
SQL> Select count(*) from t Where no in (30, 50);
------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 13 | 210 (22)| 00:00:03 | | |
| 1 | SORT AGGREGATE | | 1 | 13 | | | | |
| 2 | PARTITION RANGE INLIST| | 22428 | 284K| 210 (22)| 00:00:03 |KEY(I) |KEY(I) |
| 3 | TABLE ACCESS FULL | T | 22428 | 284K| 210 (22)| 00:00:03 |KEY(I) |KEY(I) |
------------------------------------------------------------------------------------------------
* IN-List 조건을 사용하면 상수 값이더라도 KEY(I)라고 표시된다.
--NL Join Test
SQL> create table n
as
select level no from dual connect by level <=100;
SQL> explain plan for
select /*+ leading(n) use_nl(t) */ *
from n, t
where t.no = n.no;
----------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Pstart| Pstop |
----------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1097K | 48M | | |
| 1 | NESTED LOOPS | | 1097K | 48M | | |
| 2 | TABLE ACCESS FULL | N | 100 | 1300 | | |
| 3 | PARTITION RANGE ITERATOR| | 10975 | 353K | KEY | KEY |
| 4 | TABLE ACCESS FULL | T | 10975 | 353K | KEY | KEY |
----------------------------------------------------------------------------
* NL조인에서도 n테이블로 읽히는 값에 따라 t테이블에 동적 Pruning이 나타남
-- 결합파티션
SQL > create table t ( key, no, data )
partition by range(no) subpartition by hash(key) subpartitions 16 (
partition p01 values less than(11)
, partition p02 values less than(21)
, partition p03 values less than(31)
, partition p04 values less than(41)
, partition p05 values less than(51)
, partition p06 values less than(61)
, partition p07 values less than(71)
, partition p08 values less than(81)
, partition p09 values less than(91)
, partition p10 values less than(maxvalue)
)
as
select lpad(rownum, 6, '0'), mod(rownum, 50)+1, lpad(rownum, 10, '0')
from dual
connect by level <= 999999;
* 테이블을 no 컬럼 기준 Range 파티셔닝, key 컬럼 기준 해시 파티셔닝 함
아래는 상수 조건을 사용해 정적 Pruning을 TEST
SQL> select count(*) from t where no between 30 and 50;
----------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Pstart| Pstop |
----------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 13 | | |
| 1 | SORT AGGREGATE | | 1 | 13 | | |
| 2 | PARTITION RANGE ITERATOR | | 576K | 7323K | 3 | 5 |
| 3 | PARTITION HASH ALL | | 576K | 7323K | 1 | 16 |
| 4 | TABLE ACCESS FULL | T | 576K | 7323K | 33 | 80 |
----------------------------------------------------------------------------
* Range파티션에는 파티션 목록을 확정할 수 없어 'KEY'라고 표시
SQL> select count(*) from t where no between :a and :b;
----------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Pstart| Pstop |
----------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 13 | | |
| 1 | SORT AGGREGATE | | 1 | 13 | | |
|* 2 | FILTER | | | | | |
|* 2 | PARTITION RANGE ITERATOR | | 2226 | 28938 | KEY | KEY |
| 3 | PARTITION HASH ALL | | 2226 | 28938 | 1 | 16 |
|* 4 | TABLE ACCESS FULL | T | 2226 | 28938 | KEY | KEY |
----------------------------------------------------------------------------
h4.파티션 Pruning 기능에 따른 I/O 수행량 비교
-- Partition Pruning 작동
SQL> select * from t where no=1 and key ='000100'
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.062 0.144 0 22 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 2 0.000 0.092 44 50 0 1
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 4 0.062 0.236 44 72 0 1
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
1 PARTITION RANGE SINGLE PARTITION: 1 1 (cr=50 pr=44 pw=0 time=27716 us)
1 PARTITION HASH SINGLE PARTITION: 6 6 (cr=50 pr=44 pw=0 time=27700 us)
1 TABLE ACCESS FULL T PARTITION: 6 6 (cr=50 pr=44 pw=0 time=27685 us)
-- Sub Partition Key Column에 Function을 이용
SQL> select * from t where no=1 and to_number(key) = 100
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.031 0.036 0 121 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 2 0.031 1.051 587 777 0 1
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 4 0.062 1.087 587 898 0 1
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
1 PARTITION RANGE SINGLE PARTITION: 1 1 (cr=777 pr=587 pw=0 time=362513 us)
1 PARTITION HASH ALL PARTITION: 1 16 (cr=777 pr=587 pw=0 time=362497 us)
# TABLE ACCESS FULL T PARTITION: 1 16 (cr=777 pr=587 pw=0 time=1049983 us)
-- 묵시적 형변환이 일어난 경우
SQL>select * from t where no=1 and key = 100;
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.031 0.034 0 121 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 2 0.031 0.037 0 777 0 1
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 4 0.062 0.071 0 898 0 1
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
1 PARTITION RANGE SINGLE PARTITION: 1 1 (cr=777 pr=0 pw=0 time=12688 us)
1 PARTITION HASH ALL PARTITION: 1 16 (cr=777 pr=0 pw=0 time=12665 us)
1 TABLE ACCESS FULL T PARTITION: 1 16 (cr=777 pr=0 pw=0 time=34235 us)
-- 주 Partition Key에 형변환을 사용할 경우
SQL> select * from t where to_char(no)=1 and key = 100
Call Count CPU Time Elapsed Time Disk Query Current Rows
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Parse 1 0.031 0.038 0 166 0 0
Execute 1 0.000 0.000 0 0 0 0
Fetch 2 0.359 4.513 2859 4217 51 1
------- ------ -------- ------------ ---------- ---------- ---------- ----------
Total 4 0.390 4.550 2859 4383 51 1
Rows Row Source Operation
------- ---------------------------------------------------
0 STATEMENT
1 PARTITION RANGE ALL PARTITION: 1 10 (cr=4217 pr=2859 pw=0 time=13718 us)
1 PARTITION HASH ALL PARTITION: 1 16 (cr=4217 pr=2859 pw=0 time=4481997 us)
1 TABLE ACCESS FULL T PARTITION: 1 160 (cr=4217 pr=2859 pw=0 time=4508829 us)
h4.동적 파티션 Pruning 시 테이블 레벨 통계 사용
h3.Sub쿼리 Pruning
Select d.분기, o.주문일자, o.고객ID, o.상품ID, o.주문수량, o.주문금액
From 일자 d, 주문 o
Where o.주문일자 = d.일자
And d.분기 >= 'Q20071';
SQL> select distinct TBL$OR$IDX$PART$NUM(주문, 0,1,0, a.일자)
From (select 일자 from 일자 were 분기 >= 'Q20071') a
Order by 1
P.647 참조
drop table dept;
drop table emp;
create table dept as select * from scott.dept;
create table emp
partition by range (deptno)
(partition p1 values less than (10),
partition p2 values less than (20),
partition p3 values less than (30),
partition p4 values less than (MAXVALUE))
as
select * from scott.emp ;
# 서브쿼리 Pruning이 작동하지 않는 경우
alter session set "_subquery_pruning_cost_factor" = 20; -- default
alter session set "_subquery_pruning_reduction" = 50; -- default
set autotrace traceonly exp;
select /*+ leading(d) use_hash(e) */ *
from dept d, emp e
where d.deptno = e.deptno
and d.loc = 'DALLAS';
---------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
---------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 5 | 585 | 8 (13)| 00:00:01 | | |
|* 1 | HASH JOIN | | 5 | 585 | 8 (13)| 00:00:01 | | |
|* 2 | TABLE ACCESS FULL | DEPT | 1 | 30 | 3 (0)| 00:00:01 | | |
| 3 | PARTITION RANGE ALL| | 14 | 1218 | 4 (0)| 00:00:01 | 1 | 4 |
| 4 | TABLE ACCESS FULL | EMP | 14 | 1218 | 4 (0)| 00:00:01 | 1 | 4 |
---------------------------------------------------------------------------------------------
select /*+ leading(e) use_hash(d) */ *
from dept d, emp e
where d.deptno = e.deptno
and d.loc = 'DALLAS';
---------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
---------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 5 | 585 | 8 (13)| 00:00:01 | | |
|* 1 | HASH JOIN | | 5 | 585 | 8 (13)| 00:00:01 | | |
| 2 | PARTITION RANGE ALL| | 14 | 1218 | 4 (0)| 00:00:01 | 1 | 4 |
| 3 | TABLE ACCESS FULL | EMP | 14 | 1218 | 4 (0)| 00:00:01 | 1 | 4 |
|* 4 | TABLE ACCESS FULL | DEPT | 1 | 30 | 3 (0)| 00:00:01 | | |
---------------------------------------------------------------------------------------------
# 서브쿼리 Pruning이 작동하는 경우
alter session set "_subquery_pruning_cost_factor" = 1;
alter session set "_subquery_pruning_reduction" = 100;
select /*+ leading(d) use_hash(e) */ *
from dept d, emp e
where d.deptno = e.deptno
and d.loc = 'DALLAS';
--------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
--------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 5 | 585 | 8 (13)| 00:00:01 | | |
|* 1 | HASH JOIN | | 5 | 585 | 8 (13)| 00:00:01 | | |
|* 2 | TABLE ACCESS FULL | DEPT | 1 | 30 | 3 (0)| 00:00:01 | | |
| 3 | PARTITION RANGE SUBQUERY| | 14 | 1218 | 4 (0)| 00:00:01 |KEY(SQ)|KEY(SQ)|
| 4 | TABLE ACCESS FULL | EMP | 14 | 1218 | 4 (0)| 00:00:01 |KEY(SQ)|KEY(SQ)|
--------------------------------------------------------------------------------------------------
select /*+ leading(e) use_hash(d) */ *
from dept d, emp e
where d.deptno = e.deptno
and d.loc = 'DALLAS';
--------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time | Pstart| Pstop |
--------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 5 | 585 | 8 (13)| 00:00:01 | | |
|* 1 | HASH JOIN | | 5 | 585 | 8 (13)| 00:00:01 | | |
| 2 | PARTITION RANGE SUBQUERY| | 14 | 1218 | 4 (0)| 00:00:01 |KEY(SQ)|KEY(SQ)|
| 3 | TABLE ACCESS FULL | EMP | 14 | 1218 | 4 (0)| 00:00:01 |KEY(SQ)|KEY(SQ)|
|* 4 | TABLE ACCESS FULL | DEPT | 1 | 30 | 3 (0)| 00:00:01 | | |
--------------------------------------------------------------------------------------------------
h3.조인 필터 Pruning
h4.블룸 필터(Bloom Filter)알고리즘
create or replace function h1(e number) return number
as
begin
return mod(e, 10);
end;
/
create or replace function h2(e number) return number
as
begin
return mod(ceil(e/10), 10);
end;
/
select rownum no, h1(rownum) r1, h2(rownum) r2
from dual
connect by level <= 100;
create or replace function h1(e number) return number
as
begin
return mod(e, 100);
end;
/
create or replace function h2(e number) return number
as
begin
return mod(ceil(e/10), 100);
end;
/
select rownum no, h1(rownum) r1, h2(rownum) r2
from dual
connect by level <= 100;
집합 B(175, 327,432,548)의 각 원소마다 차례로 h1, h2 함수를 적용하고, 리턴된 값 (0~9중 하나)에 해당하는 비트를 모두 확인한다. 하나라도 0으로 설정돼 있으면 그 원소는 집합 A에 없는 값이다. 모두 1로 설정돼 있으면 그 원소는 집합 A에 포함 될 가능성이 있는 값이므로 이때만 집합 A를 찾아가 실제 같은 값을 가진 원소가 있는지 찾아 본다.
h4.볼룸 필터 알고리즘에서 false positive를 줄이는 방법
create or replace function h1(e number) return number
as
begin
return mod(e, 100);
end;
/
create or replace function h2(e number) return number
as
begin
return mod(ceil(e/10), 100);
end;
/
h4.조인 필터(=볼륨 필터) Pruning
Select d.분기, o.주문일자, o.고객ID, o.상품ID, o.주문수량, o.주문금액주문금액
From 일자 d, 주문 o
Where o.주문일자 = d.일자
And d.분기 >= 'Q20071';
Rows Row Source Operation
------- ---------------------------------------------------
480591 HASH JOIN (cr=3827 pr=0 pw=0 time=4946 us cost=655 size=2100270 ...)
12 PART JOIN FILTER CREATE:BF0000 (cr=4 pr=0 pw=0 time=18 us cost=4 ...)
12 TABLE ACCESS FULL 일자 (cr=4 pr=0 pw=0 time=6 us cost=4 size=10388 ...)
480591 PARTITION RANGE JOIN-FILTER PARTITION: :BF0000 :BF0000 (cr=3823 pr=0 ...)
480591 TABLE ACCESS FULL 주문 PARTITION: :BF0000 :BF0000 (cr=3823 pr=0 ...)
h4.SQL 조건절 작성 시 주의사항
create table 고객
partition by range(가입일)
( partition m01 values less than('20090201')
, partition m02 values less than('20090301')
, partition m03 values less than('20090401')
, partition m04 values less than('20090501')
, partition m05 values less than('20090601')
, partition m06 values less than('20090701')
, partition m07 values less than('20090801')
, partition m08 values less than('20090901')
, partition m09 values less than('20091001')
, partition m10 values less than('20091101')
, partition m11 values less than('20091201')
, partition m12 values less than('20100101'))
as
select rownum 고객ID
, dbms_random.string('a', 20) 고객명
, to_char(to_date('20090101', 'yyyymmdd') + (rownum - 1), 'yyyymmdd') 가입일
from dual
connect by level <= 365;
SQL> set autotrace traceonly exp;
SQL> select * from 고객
2 where 가입일 like '200910%';
Execution Plan
----------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Pstart| Pstop |
--------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 31 | 62651 | 2 (0)| | |
| 1 | PARTITION RANGE ITERATOR| | 31 | 62651 | 2 (0)| 9 | 10 |
|* 2 | TABLE ACCESS FULL | 고객 | 31 | 62651 | 2 (0)| 9 | 10 |
--------------------------------------------------------------------------------------
SQL> set pagesize 1000
SQL> set linesize 300
SQL> select * from 고객
2 where 가입일 between '20091001' and '20091031';
Execution Plan
---------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Pstart| Psop |
-----------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 31 | 62651 | 2 (0)| | |
| 1 | PARTITION RANGE SINGLE| | 31 | 62651 | 2 (0)| 10 |10 |
|* 2 | TABLE ACCESS FULL | 고객 | 31 | 62651 | 2 (0)| 10 |10 |
-----------------------------------------------------------------------------------
문서에 대하여
최초작성자 : 꼬챙이
최초작성일 : 2010년 12월 03일
이 문서는 오라클클럽 대용량 데이터베이스 스터디 모임에서 작성하였습니다.
이 문서의 내용은 (주)비투엔컬설팅에서 출간한 '오라클 성능 고도화 원리와 해법II'를 참고하였습니다.