create BITMAP index job_idx on emp(job);
select count(*) from emp where job = 'CLERK' or job = 'MANGER';
Plan hash value: 3446200557
-----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 8 | 1 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 8 | | |
| 2 | BITMAP CONVERSION COUNT | | 6 | 48 | 1 (0)| 00:00:01 |
|* 3 | BITMAP INDEX FAST FULL SCAN| JOB_IDX | | | | |
-----------------------------------------------------------------------------------------
select * from emp where job = 'CLERK' or job = 'MANGER'
Plan hash value: 3956160932
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 6 | 228 | 3 (0)| 00:00:01 |
|* 1 | TABLE ACCESS FULL| EMP | 6 | 228 | 3 (0)| 00:00:01 |
--------------------------------------------------------------------------
Select count(*)
from T
where gender = 'M'
and location in ( 1, 10, 30 )
and age_group = '41 and over';
select *
from t
where ( (gender = 'M ' and location = 20 )
or ( gender = 'F' and location = 22 ))
and age_group = '18 and under';
select count(*) from t where location in (11 ,20,30);
select count(*) from t where age_group = '41 and over' and gender = 'F';
drop table t ;
create table t
(gender not null,
location not null,
age_group not null,
data
)
as
select decode( round(dbms_random.value(1,2)) ,
1, 'M' ,
2, 'F' ) gender,
round(dbms_random.value(1 ,50)) location,
decode( round(dbms_random.value(1, 5)),
1, '18 and under' ,
2, '19-25' ,
3, '26-30' ,
4, '31-40' ,
5, '41 and over') ,
rpad( '*' ,20,'*')
from dual connect by level <= 100000 ;
create bitmap index gender_idx on t(gender);
create bitmap index location_idx on t(location);
create bitmap index age_group_idx on t(age_group);
exec dbms_stats.gather_table_stats( user, 'T' )
Select count(*)
from T
where gender = 'M'
and location in ( 1, 10, 30 )
and age_group = '41 and over';
Plan hash value: 2919078855
-----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 13 | 7 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 13 | | |
| 2 | BITMAP CONVERSION COUNT | | 308 | 4004 | 7 (0)| 00:00:01 |
| 3 | BITMAP AND | | | | | |
|* 4 | BITMAP INDEX SINGLE VALUE | AGE_GROUP_IDX | | | | |
| 5 | BITMAP OR | | | | | |
|* 6 | BITMAP INDEX SINGLE VALUE| LOCATION_IDX | | | | |
|* 7 | BITMAP INDEX SINGLE VALUE| LOCATION_IDX | | | | |
|* 8 | BITMAP INDEX SINGLE VALUE| LOCATION_IDX | | | | |
|* 9 | BITMAP INDEX SINGLE VALUE | GENDER_IDX | | | | |
-----------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
4 - access("AGE_GROUP"='41 and over')
6 - access("LOCATION"=1)
7 - access("LOCATION"=10)
8 - access("LOCATION"=30)
9 - access("GENDER"='M')
select *
from t
where ( (gender = 'M' and location = 20 )
or ( gender = 'F' and location = 22 ))
and age_group = '18 and under';
Plan hash value: 1064409070
------------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 276 | 9384 | 52 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID | T | 276 | 9384 | 52 (0)| 00:00:01 |
| 2 | BITMAP CONVERSION TO ROWIDS | | | | | |
| 3 | BITMAP AND | | | | | |
|* 4 | BITMAP INDEX SINGLE VALUE | AGE_GROUP_IDX | | | | |
| 5 | BITMAP OR | | | | | |
| 6 | BITMAP AND | | | | | |
|* 7 | BITMAP INDEX SINGLE VALUE| LOCATION_IDX | | | | |
|* 8 | BITMAP INDEX SINGLE VALUE| GENDER_IDX | | | | |
| 9 | BITMAP AND | | | | | |
|* 10 | BITMAP INDEX SINGLE VALUE| LOCATION_IDX | | | | |
|* 11 | BITMAP INDEX SINGLE VALUE| GENDER_IDX | | | | |
------------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
4 - access("AGE_GROUP"='18 and under')
7 - access("LOCATION"=22)
8 - access("GENDER"='F')
10 - access("LOCATION"=20)
11 - access("GENDER"='M')
-- 일반적인 쿼리
select count(*)
from emp, dept
where emp.deptno = dept.deptno
and dept.dname = 'SALES'
/
select emp.*
from emp, dept
where emp.deptno = dept.deptno
and dept.dname = 'SALES'
/
create bitmap index emp_bm_idx
on emp( d.dname )
from emp e, dept d
where e.deptno = d.deptno
begin
dbms_stats.set_table_stats( user, 'EMP' , numrows => 1000000, numblks => 300000 ) ;
dbms_stats.set_table_stats( user, 'DEPT' , numrows => 100000, numblks => 30000 );
dbms_stats.delete_index_stats( user, 'EMP_BM_IDX');
end;
select count (*)
from emp, dept
where emp.deptno = dept.deptno
and dept.dname = 'SALES'
------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 3 | 1 (0)| 00:00:01 |
| 1 | SORT AGGREGATE | | 1 | 3 | | |
| 2 | BITMAP CONVERSION COUNT | | 333K| 976K| 1 (0)| 00:00:01 |
|* 3 | BITMAP INDEX SINGLE VALUE| EMP_BM_IDX | | | | |
------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
3 - access("EMP"."SYS_NC00010$"='SALES')
-- 아래 예제는 bitmap index를 타야하는데 해쉬조인로 되버림
select emp.*
from emp, dept
where emp.deptno = dept.deptno
and dept.dname = 'SALES'
---------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 6250M| 296G| 133K (34)| 00:26:43 |
|* 1 | HASH JOIN | | 6250M| 296G| 133K (34)| 00:26:43 |
|* 2 | TABLE ACCESS FULL| DEPT | 25000 | 317K| 8143 (1)| 00:01:38 |
| 3 | TABLE ACCESS FULL| EMP | 1000K| 36M| 81422 (1)| 00:16:18 |
---------------------------------------------------------------------------
1 - access("EMP"."DEPTNO"="DEPT"."DEPTNO")
2 - filter("DEPT"."DNAME"='SALES')
- 강좌 URL : http://www.gurubee.net/lecture/4044
- 구루비 강좌는 개인의 학습용으로만 사용 할 수 있으며, 다른 웹 페이지에 게재할 경우에는 출처를 꼭 밝혀 주시면 고맙겠습니다.~^^
- 구루비 강좌는 서비스 제공을 위한 목적이나, 학원 홍보, 수익을 얻기 위한 용도로 사용 할 수 없습니다.