h1. 제 4절 데이터베이스 I/O 원리 1. 블록단위 I/O 2. 메모리 I/O vs . 디스크 I/O 3. Sequential I/O vs. Random I/O 4. Single Block I/O vs. MultiBlock I/O 5. I/O 효율화 원리 {panel:title=1.블록단위 I/O | borderColor=#ccc | titleBGColor=#B0C4DE | bgColor=#ffffff} * 데이터 파일에서 dB 버퍼 캐시로 블록을 적재할 때 * 데이터 파일에서 블록을 직접 읽고 쓸 때 * 버퍼 캐시에서 블록을 읽고 쓸 때 * 버퍼 캐시에서 변경된 블록을 다시 데이터 파일에 쓸 때 {panel} {panel:title=2.메모리 I/O vs . 디스크 I/O | borderColor=#ccc | titleBGColor=#B0C4DE | bgColor=#ffffff} |
call count cpu elapsed disk query current rows
------ ----- ----- ------- ---- ----- ------ ----
Parse 15 0.00 0.08 0 0 0 0
Execute 44 0.03 0.03 0 0 0 0
Fetch 44 0.01 0.13 18 822 0 44
------ ----- ----- ------- ---- ----- ------ ----
total 103 0.04 0.25 18 822 0 44
3.Sequential I/O vs. Random I/O
-- 테스트용 테이블 생성
SQL> create table t
2 as
3 select * from all_objects
4 order by dbms_random.value;
-- 테스트용 테이블 데이터 건수 : 49,906
SQL> select count(*) from t;
COUNT(*)
--------
49906
select count(*) from t
where owner like 'SYS%'
Rows Row Source Operation
----- ------------------------------
1 SORT AGGREGATE (cr=691 pr=0 pw=0 time=13037 us)
24613 TABLE ACCESS FULL T (cr=691 pr=0 pw=0 time=98473 us)
select count(*) from t
where owner like 'SYS%'
and object_name = 'ALL_OBJECTS'
Rows Row Source Operation
---- ------------------------------
1 SORT AGGREGATE (cr=691 pr=0 pw=0 time=7191 us)
1 TABLE ACCESS FULL T (cr=691 pr=0 pw=0 time=7150 us)
create index t_idx on t(owner, object_name);
select /*+ index(t t_idx) */ count(*)
from t where owner like 'SYS%'
and object_name = 'ALL_OBJECTS'
Rows Row Source Operation
---- ------------------------------
1 SORT AGGREGATE (cr=76 pr=0 pw=0 time=7009 us)
1 INDEX RANGE SCAN T_IDX (cr=76 pr=0 pw=0 time=6972 us)(Object ID 55337)
create index t_idx on t(object_name,owner );
select /*+ index(t t_idx) */ count(*)
from t where owner like 'SYS%'
and object_name = 'ALL_OBJECTS'
Rows Row Source Operation
---- ------------------------------
1 SORT AGGREGATE (cr=2 pr=0 pw=0 time=44 us)
1 INDEX RANGE SCAN T_IDX (cr=2 pr=0 pw=0 time=23 us)(Object ID 55338)
drop index t_idx;
create index t_idx on t(owner);
select object_id from t
where owner = 'SYS'
and object_name = 'ALL_OBJECTS'
Rows Row Source Operation
---- ------------------------------
1 TABLE ACCESS BY INDEX ROWID T (cr=739 pr=0 pw=0 time=38822 us)
22934 INDEX RANGE SCAN T_IDX (cr=51 pr=0 pw=0 time=115672 us)(Object ID 55339)
drop index t_idx;
create index t_idx on t(owner, object_name);
select object_id from t
where owner = 'SYS'
and object_name = 'ALL_OBJECTS'
Rows Row Source Operation
---- ------------------------------
1 TABLE ACCESS BY INDEX ROWID T (cr=4 pr=0 pw=0 time=67 us)
1 INDEX RANGE SCAN T_IDX (cr=3 pr=0 pw=0 time=51 us)(Object ID 55340)
4. Single Block I/O vs. MultiBlock I/O
create table t
as select * from all_objects;
alter table t add
constraint t_pk primary key(object_id);
select /*+ index(t) */ count(*)
from t
where object_id > 0
call count cpu elapsed disk query current rows
----- ---- ---- ------ ---- ----- ----- ------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.26 0.25 64 65 0 1
----- ---- ---- ------ ---- ----- ----- ------
total 4 0.26 0.25 64 65 0 1
Rows Row Source Operation
----- ------------------------------
1 SORT AGGREGATE (cr=65 r=64 w=0 time=256400 us)
31192 INDEX RANGE SCAN T_PK (cr=65 r=64 w=0 time=134613 us)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
------------------------------- Waited --------- ------------
SQL*Net message to client 2 0.00 0.00
db file sequential read 64 0.00 0.00
SQL*Net message from client 2 0.05 0.05
-- 디스크 I/O가 발생하도록 버퍼 캐시 Flushing
alter system flush buffer_cache;
-- Multiblock I/O 방식으로 인덱스 스캔
select /*+ index_ffs(t) */ count(*)
from t
where object_id > 0
call count cpu elapsed disk query current rows
----- ----- ---- ------- ---- ----- ------- ----
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 2 0.26 0.26 64 69 0 1
----- ----- ---- ------- ---- ----- ------- ----
total 4 0.26 0.26 64 69 0 1
Rows Row Source Operation
----- ------------------------------
1 SORT AGGREGATE (cr=69 r=64 w=0 time=267453 us)
31192 INDEX FAST FULL SCAN T_PK (cr=69 r=64 w=0 time=143781 us)
Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
------------------------------ Waited --------- ------------
SQL*Net message to client 2 0.00 0.00
db file scattered read 9 0.00 0.00
SQL*Net message from client 2 0.35 0.36
5. I/O 효율화 원리
논리적인 I/O 요청 횟수를 최소화 하는것이 I/O 효율화 튜닝의 핵심 원리
select a.카드번호
, a.거래금액 전일_거래금액
, b.거래금액 주간_거래금액
, c.거래금액 전월_거래금액
, d.거래금액 연중_거래금액
from ( -- 전일거래실적
select 카드번호, 거래금액
from 일별카드거래내역
where 거래일자 = to_char(sysdate-1,'yyyymmdd')
) a
, ( -- 전주거래실적
select 카드번호, sum(거래금액) 거래금액
from 일별카드거래내역
where 거래일자 between to_char(sysdate-7,'yyyymmdd') and to_char(sysdate-1,'yyyymmdd')
group by 카드번호
) b
, ( -- 전월거래실적
select 카드번호, sum(거래금액) 거래금액
from 일별카드거래내역
where 거래일자 between to_char(add_months(sysdate,-1),'yyyymm') || '01' and to_char(last_day(add_months(sysdate,-1)),'yyyymmdd')
group by 카드번호
) c
, ( -- 연중거래실적
select 카드번호, sum(거래금액) 거래금액
from 일별카드거래내역
where 거래일자 between to_char(add_months(sysdate,-12),'yyyymmdd') and to_char(sysdate-1,'yyyymmdd')
group by 카드번호
) d
where b.카드번호 (+) = a.카드번호
and c.카드번호 (+) = a.카드번호
and d.카드번호 (+) = a.카드번호
select 카드번호
, sum( case when 거래일자 = to_char(sysdate-1,'yyyymmdd')
then 거래금액
end ) 전일_거래금액
, sum( case when 거래일자 between to_char(sysdate-7,'yyyymmdd') and to_char(sysdate-1,'yyyymmdd')
then 거래금액
end ) 주간_거래금액
, sum( case when 거래일자 between to_char(add_months(sysdate,-1),'yyyymm') || '01' and to_char(last_day(add_months(sysdate,-1)),'yyyymmdd')
then 거래금액
end ) 전월_거래금액
, sum( 거래금액 )연중_거래금액
from 일별카드거래내역
where 거래일자 between to_char(add_months(sysdate,-12),'yyyymmdd') and to_char(sysdate-1,'yyyymmdd')
group by 카드번호
having sum( case when 거래일자 = to_char(sysdate-1,'yyyymmdd') then 거래금액 end ) > 0
예시)
[예제] Oracle
select /*+ leading(d) use_nl(e) index(d dept_loc_idx) */ *
from emp e, dept d
where e.deptno = d.deptno
and d.loc = 'CHICAGO'
[예제] SQL Server
select *
from dept d with (index(dept_loc_idx)), emp e
where e.deptno = d.deptno
and d.loc = 'CHICAGO'
option (force order, loop join)
|