SELECT EMPNO
,ENAME
,JOB
FROM EMP
WHERE HIREDATE BETWEEN :START_DATE AND :END_DATE
%WHERE_SENTENCE%
필요 선택 조건에 따라 쿼리 조건절이 동적으로 추가됨
%WHERE_SENTENCE% = "AND DEPTNO='10' ";
SELECT EMPNO
,ENAME
,JOB
FROM EMP
WHERE HIREDATE BETWEEN :START_DATE AND :END_DATE
AND DEPTNO='10'
SELECT EMPNO
,ENAME
,JOB
FROM EMP
WHERE HIREDATE BETWEEN START_DATE AND END_DATE
AND DEPTNO= NVL(:부서코드, 부서코드)
( 날짜에 제한이 없이 없거나, 데이터의 분포가 적절하지 않으면 인덱스를 못탈 우려가 발생 할수 있음)
SELECT EMPNO
,ENAME
,JOB
FROM EMP
WHERE HIREDATE BETWEEN START_DATE AND END_DATE
AND DEPTNO= :DEPTNO
UNION ALL
SELECT EMPNO
,ENAME
,JOB
FROM EMP
WHERE HIREDATE BETWEEN START_DATE AND END_DATE
AND EMPNO= :EMPNO
개발 기간 내내 SQL마다 최적의 인덱스 구성전략(위의 UNION ALL) 을 고민 하면서 개발 하는데 어려움이 있다.
SQLStmt := 'SELECT ENAME, JOB, SAL, COMM '
|| 'FROM 일별종목거래 '
|| 'WHERE 거래일자 BETWEEN :1 AND :2 ';
IF :EMPNO IS NULL Then
SQLStmt := SQLStmt || 'AND :EMPNO IS NULL ';
Else
SQLStmt := SQLStmt || 'AND EMPNO = :EMPNO ';
End If;
If :DEPTNO IS NULL Then
SQLStmt := SQLStmt || 'AND :DEPTNO IS NULL ';
Else
SQLStmt := SQLStmt || 'AND DEPTNO =:DEPTNO ';
End If;
EXECUTE IMMEDIATE SQLStmt
INTO :A, :B, :C, :D, :E, :F, :G
USING :시작일자, :종료일자, :종목코드, :투자자유형코드;
SQL> CREATE INDEX EMP_ENAME_IDX ON EMP(ENAME);
SQL> SET AUTOTRACE ON;
1) NULL을 사용하지 않는 경우
SQL> VARIABLE ename varchar2(20);
SQL> exec :ename :='SMITH'
SQL> SELECT * FROM EMP WHERE (:ename IS NULL OR ename = :ename);
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 87 | 3 (0)| 00:00:01 |
|* 1 | TABLE ACCESS FULL| EMP | 1 | 87 | 3 (0)| 00:00:01 |
--------------------------------------------------------------------------
2) NULL을 사용한 경우
SQL> exec :ename :=NULL
SQL> SELECT * FROM EMP WHERE (:ename IS NULL OR ename = :ename);
--------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 87 | 3 (0)| 00:00:01 |
|* 1 | TABLE ACCESS FULL| EMP | 1 | 87 | 3 (0)| 00:00:01 |
--------------------------------------------------------------------------
SQL> VARIABLE ename varchar2(20);
SQL> exec :ename :='SMITH'
SQL> SELECT * FROM EMP WHERE ENAME LIKE :ename||'%';
---------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2 | 74 | 2 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| EMP | 2 | 74 | 2 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | EMP_ENAME_IDX | 2 | | 1 (0)| 00:00:01 |
---------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("ENAME" LIKE :ENAME||'%')
filter("ENAME" LIKE :ENAME||'%')
2)NULL을 사용한 경우
SQL> VARIABLE ename varchar2(20);
SQL> exec :ename :=NULL
SQL> SELECT * FROM EMP WHERE ENAME LIKE :ename||'%';
---------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2 | 74 | 2 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| EMP | 2 | 74 | 2 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | EMP_ENAME_IDX | 2 | | 1 (0)| 00:00:01 |
---------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("ENAME" LIKE :ENAME||'%')
filter("ENAME" LIKE :ENAME||'%')
3) ''을 사용 한경우
SQL> VARIABLE ename varchar2(20);
SQL> exec :ename :=''
SQL> SELECT * FROM EMP WHERE ENAME LIKE :ename||'%';
---------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
---------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 2 | 74 | 2 (0)| 00:00:01 |
| 1 | TABLE ACCESS BY INDEX ROWID| EMP | 2 | 74 | 2 (0)| 00:00:01 |
|* 2 | INDEX RANGE SCAN | EMP_ENAME_IDX | 2 | | 1 (0)| 00:00:01 |
---------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - access("ENAME" LIKE :ENAME||'%')
filter("ENAME" LIKE :ENAME||'%')
1) 값이 있는 경우
SQL> VARIABLE ename varchar2(20);
SQL> exec :ename :='SMITH' 한 경우
SQL> SELECT * FROM EMP WHERE ENAME = NVL(:ename, ENAME);
-----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 15 | 555 | 4 (0)| 00:00:01 |
| 1 | CONCATENATION | | | | | |
|* 2 | FILTER | | | | | |
| 3 | TABLE ACCESS BY INDEX ROWID| EMP | 14 | 518 | 2 (0)| 00:00:01 |
|* 4 | INDEX FULL SCAN | EMP_ENAME_IDX | 14 | | 1 (0)| 00:00:01 |
|* 5 | FILTER | | | | | |
| 6 | TABLE ACCESS BY INDEX ROWID| EMP | 1 | 37 | 2 (0)| 00:00:01 |
|* 7 | INDEX RANGE SCAN | EMP_ENAME_IDX | 1 | | 1 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter(:ENAME IS NULL)
4 - filter("ENAME" IS NOT NULL)
5 - filter(:ENAME IS NOT NULL)
7 - access("ENAME"=:ENAME)
2)NULL 값인 경우
SQL> VARIABLE ename varchar2(20);
SQL> exec :ename :=NULL 한 경우
SQL> SELECT * FROM EMP WHERE ENAME = NVL(:ename, ENAME);
-----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 15 | 555 | 4 (0)| 00:00:01 |
| 1 | CONCATENATION | | | | | |
|* 2 | FILTER | | | | | |
| 3 | TABLE ACCESS BY INDEX ROWID| EMP | 14 | 518 | 2 (0)| 00:00:01 |
|* 4 | INDEX FULL SCAN | EMP_ENAME_IDX | 14 | | 1 (0)| 00:00:01 |
|* 5 | FILTER | | | | | |
| 6 | TABLE ACCESS BY INDEX ROWID| EMP | 1 | 37 | 2 (0)| 00:00:01 |
|* 7 | INDEX RANGE SCAN | EMP_ENAME_IDX | 1 | | 1 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter(:ENAME IS NULL)
4 - filter("ENAME" IS NOT NULL)
5 - filter(:ENAME IS NOT NULL)
7 - access("ENAME"=:ENAME)
1) 값이 있는 경우
SQL> VARIABLE ename varchar2(20);
SQL> exec :ename :='SMITH' 한 경우
SQL> SELECT * FROM EMP WHERE ENAME = DECODE(:ename, NULL, ENAME, :ename);
-----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 15 | 555 | 4 (0)| 00:00:01 |
| 1 | CONCATENATION | | | | | |
|* 2 | FILTER | | | | | |
| 3 | TABLE ACCESS BY INDEX ROWID| EMP | 14 | 518 | 2 (0)| 00:00:01 |
|* 4 | INDEX FULL SCAN | EMP_ENAME_IDX | 14 | | 1 (0)| 00:00:01 |
|* 5 | FILTER | | | | | |
| 6 | TABLE ACCESS BY INDEX ROWID| EMP | 1 | 37 | 2 (0)| 00:00:01 |
|* 7 | INDEX RANGE SCAN | EMP_ENAME_IDX | 1 | | 1 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter(:ENAME IS NULL)
4 - filter("ENAME" IS NOT NULL)
5 - filter(:ENAME IS NOT NULL)
7 - access("ENAME"=:ENAME)
2) 값이 NULL 인 경우
SQL> VARIABLE ename varchar2(20);
SQL> exec :ename :=NULL 한 경우
SQL> SELECT * FROM EMP WHERE ENAME = DECODE(:ename, NULL, ENAME, :ename);
-----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
-----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 15 | 555 | 4 (0)| 00:00:01 |
| 1 | CONCATENATION | | | | | |
|* 2 | FILTER | | | | | |
| 3 | TABLE ACCESS BY INDEX ROWID| EMP | 14 | 518 | 2 (0)| 00:00:01 |
|* 4 | INDEX FULL SCAN | EMP_ENAME_IDX | 14 | | 1 (0)| 00:00:01 |
|* 5 | FILTER | | | | | |
| 6 | TABLE ACCESS BY INDEX ROWID| EMP | 1 | 37 | 2 (0)| 00:00:01 |
|* 7 | INDEX RANGE SCAN | EMP_ENAME_IDX | 1 | | 1 (0)| 00:00:01 |
-----------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter(:ENAME IS NULL)
4 - filter("ENAME" IS NOT NULL)
5 - filter(:ENAME IS NOT NULL)
7 - access("ENAME"=:ENAME)
SQL> VARIABLE ename varchar2(20);
SQL> exec :ename :='SMITH' 한 경우
SQL> SELECT * FROM EMP WHERE :ename IS NULL
UNION ALL
SELECT * FROM EMP WHERE ENAME = :ename
----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 15 | 555 | 5 (40)| 00:00:01 |
| 1 | UNION-ALL | | | | | |
|* 2 | FILTER | | | | | |
| 3 | TABLE ACCESS FULL | EMP | 14 | 518 | 3 (0)| 00:00:01 |
| 4 | TABLE ACCESS BY INDEX ROWID| EMP | 1 | 37 | 2 (0)| 00:00:01 |
|* 5 | INDEX RANGE SCAN | EMP_ENAME_IDX | 1 | | 1 (0)| 00:00:01 |
----------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter(:ENAME IS NULL)
5 - access("ENAME"=:ENAME)
SQL> VARIABLE ename varchar2(20);
SQL> exec :ename := NULL 한 경우
SQL> SELECT * FROM EMP WHERE :ename IS NULL
UNION ALL
SELECT * FROM EMP WHERE ENAME = :ename
----------------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 15 | 555 | 5 (40)| 00:00:01 |
| 1 | UNION-ALL | | | | | |
|* 2 | FILTER | | | | | |
| 3 | TABLE ACCESS FULL | EMP | 14 | 518 | 3 (0)| 00:00:01 |
| 4 | TABLE ACCESS BY INDEX ROWID| EMP | 1 | 37 | 2 (0)| 00:00:01 |
|* 5 | INDEX RANGE SCAN | EMP_ENAME_IDX | 1 | | 1 (0)| 00:00:01 |
----------------------------------------------------------------------------------------------
Predicate Information (identified by operation id):
---------------------------------------------------
2 - filter(:ENAME IS NULL)
5 - access("ENAME"=:ENAME)
- 강좌 URL : http://www.gurubee.net/lecture/3105
- 구루비 강좌는 개인의 학습용으로만 사용 할 수 있으며, 다른 웹 페이지에 게재할 경우에는 출처를 꼭 밝혀 주시면 고맙겠습니다.~^^
- 구루비 강좌는 서비스 제공을 위한 목적이나, 학원 홍보, 수익을 얻기 위한 용도로 사용 할 수 없습니다.