CREATE BITMAP INDEX <index_name>
ON <tablename> (<index-expression-list>)
<index-expression-list> -> 【 <column_name> | <column_expression> 】
GRANT QUERY REWRITE TO SCOTT;
CREATE INDEX EMP_NAME_INDEX ON EMP (UPPER(ENAME));
CREATE INDEX EMP_SAL_INDEX ON EMP( SAL + COMM, empno);
CREATE INDEX sales_margin_idx ON sales(revenue - cost) ;
ALTER SESSION SET QUERY_REWRITE_ENABLED = TRUE ;
SELECT ordid FROM sales WHERE (revenue - cost) > 1000 ;
ALTER SESSION SET QUERY_REWRITE_ENABLED = FALSE ;
select index_name, table_name, FUNCIDX_STATUS from user_indexes;
SELECT INDEX_NAME, COLUMN_NAME, DESCEND
FROM DBA_IND_COLUMNS
WHERE INDEX_OWNER = 'SCOTT';
conn scott/loveora
show parameter query_rewrite
NAME TYPE VALUE
------------------------------------ ----------- ----------
query_rewrite_enabled string TRUE
query_rewrite_integrity string enforced
show parameter comp
NAME TYPE VALUE
------------------------------------ ----------- -------------------------
compatible string 10.2.0.1.0
nls_comp string
plsql_compiler_flags string INTERPRETED, NON_DEBUG
plsql_v2_compatibility boolean FALSE
alter session set query_rewrite_integrity=trusted;
Session altered.
create table t as select 'Y' processed_flag, a.* from all_objects a;
Table created.
create or replace view v
as
select t.*,
case when processed_flag='N' then 'N'
else NULL
end processed_flag_indexed
from t;
View created.
create index t_idx on
t(case when processed_flag = 'N' then 'N'
else NULL
end);
Index created.
analyze index t_idx validate structure;
Index analyzed.
SQL> col name for a10
SQL> col del_lf_rorws for 999
SQL> col lf_rows for 99999
SQL> col lf_blks for 99999
SQL> select name, del_lf_rows,lf_rows,lf_blks from index_stats;
NAME DEL_LF_ROWS LF_ROWS LF_BLKS
---------- ----------- ------- -------
T_IDX 0 0 1
SQL> update t set processed_flag='N' where rownum <= 100;
100 rows updated.
SQL> analyze index t_idx validate structure;
Index analyzed.
SQL> select name, del_lf_rows,lf_rows,lf_blks from index_stats;
NAME DEL_LF_ROWS LF_ROWS LF_BLKS
---------- ----------- ------- -------
T_IDX 0 100 1
analyze table t compute statistics
for table
for all indexes
for all indexed columns
SQL> /
Table analyzed.
column rowid new_val r
select rowid,object_name from v
where processed_flag_indexed='N' and rownum=1;
ROWID OBJECT_NAME
------------------ ------------------------------
AAAM+vAAEAAAxkkAAA DUAL
SQL> update v.processed_flag = 'Y'
2 set processed_flag='Y'
3 where rowid='&R';
old 3: where rowid='&R'
new 3: where rowid='AAAM+vAAEAAAxkkAAA'
1 row updated.
set timing on
set time on
set autotrace on
select rowid, object_name
from v
where processed_flag_indexed='N'
and rownum=1;
ROWID OBJECT_NAME
------------------ ------------------------------
AAAM+vAAEAAAxkkAAB DUAL
Elapsed: 00:00:00.03
--------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
--------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 1 | 32 | 2 (0)| 00:00:01 |
|* 1 | COUNT STOPKEY | | | | | |
| 2 | TABLE ACCESS BY INDEX ROWID| T | 1 | 32 | 2 (0)| 00:00:01 |
|* 3 | INDEX RANGE SCAN | T_IDX | 99 | | 1 (0)| 00:00:01 |
--------------------------------------------------------------------------------------
update v set processed_flag='Y' where rowid='&R';
old 3: where rowid='&R'
new 3: where rowid='AAAM+vAAEAAAxkkAAB'
1 row updated.
analyze index t_idx validate structure;
Index analyzed.
select name,del_lf_rows,lf_rows,lf_blks from index_stats;
NAME DEL_LF_ROWS LF_ROWS LF_BLKS
---------- ----------- ------- -------
T_IDX 2 100 1
insert into t
select 'N' processed_flag, a.* from all_objects a
where rownum <=2;
2 rows created.
analyze index t_idx validate structure;
Index analyzed.
select name,del_lf_rows,lf_rows,lf_blks from index_stats;
NAME DEL_LF_ROWS LF_ROWS LF_BLKS
---------- ----------- ------- -------
T_IDX 0 100 1
set autotrace on
select rowid, object_name from v where processed_flag_indexed='N' and rownum=1;
ROWID OBJECT_NAME
------------------ ------------------------------
AAAM+vAAEAAAxkkAAC SYSTEM_PRIVILEGE_MAP
create table project
(project_ID number primary key, teamid number,
job varchar2(100), status varchar2(20)
check(status in ('ACTIVE','INACTIVE')));
Table created.
create unique index
job_unique_in_teamid on project
(case when status = 'ACTIVE' then teamid else null end,
case when status = 'ACTIVE' then job else null end)
/
Index created.
insert into project(project_id,teamid,job,status) values(1,10,'a','ACTIVE');
1 row created.
insert into project(project_id,teamid,job,status) values(2,10,'a','ACTIVE');
insert into project(project_id,teamid,job,status) values(2,10,'a','ACTIVE')
*
ERROR at line 1:
ORA-00001: unique constraint (SCOTT.JOB_UNIQUE_IN_TEAMID) violated
update project set status = 'INACTIVE'
where project_id=1
and teamid=10 and status='ACTIVE';
1 row updated.
insert into project(project_id,teamid,job,status) values(2,10,'a','ACTIVE');
1 row created.
create index idx_emp_lower_ename on emp ( lower(ename) ) ;
Index created.
analyze table emp compute statistics ;
Table analyzed.
show parameter optimizer_mode
NAME VALUE
=============== ==========
optimizer_mode ALL_ROWS
if) optimizer_mode가 ALL_ROWS or FIRST_ROWS로 설정되어 있지 않을 경우
alter session set optimizer_mode = FIRST_ROWS;
alter session set optimizer_mode = ALL_ROWS;
@/u01/app/oracle/product/10.2.0/db_1/rdbms/admin/utlxplan.sql
explain plan set statement_id='qry1' FOR
select empno, ename from emp where lower(ename) = 'ford' ;
SELECT LPAD(' ',2*level-2)||operation||' '||options||' '||object_name query_plan
FROM plan_table
WHERE statement_id='qry1'
CONNECT BY prior id = parent_id
START WITH id = 0 order by id ;
QUERY_PLAN
--------------------------------------------------------------------------------
SELECT STATEMENT
TABLE ACCESS BY INDEX ROWID EMP
INDEX RANGE SCAN IDX_EMP_LOWER_ENAME
explain plan set statement_id='qry2' FOR
select rowid, object_name from v where processed_flag_indexed='N' and rownum=1
Explained.
SELECT LPAD(' ',2*level-2)||operation||' '||options||' '||object_name query_plan
FROM plan_table
WHERE statement_id='qry2'
CONNECT BY prior id = parent_id
START WITH id = 0 order by id
QUERY_PLAN
--------------------------------------------------------------------------------
SELECT STATEMENT
COUNT STOPKEY
COUNT STOPKEY
TABLE ACCESS BY INDEX ROWID T
TABLE ACCESS BY INDEX ROWID T
TABLE ACCESS BY INDEX ROWID T
TABLE ACCESS BY INDEX ROWID T
INDEX RANGE SCAN T_IDX
INDEX RANGE SCAN T_IDX
INDEX RANGE SCAN T_IDX
INDEX RANGE SCAN T_IDX
INDEX RANGE SCAN T_IDX
INDEX RANGE SCAN T_IDX
INDEX RANGE SCAN T_IDX
INDEX RANGE SCAN T_IDX
15 rows selected.