create table t(n number(8) primary key, last_name varchar(100));
insert into t (n,last_name)
select rownum, object_name
from all_objects;
select * from t where upper(last_name) = :ln;
Performs a full table scan to table t.
create index t_last_name_upper on t(upper(last_name));
Performs a full table scan to table t.
create index t_last_name_upper on t(upper(last_name));
select * from t where upper(last_name) = :ln;
And the index is used if the table is big enough.
In DB2 there is no such thing as a function based index. But in a article on IBM site there is described alternatives to do this. Generated columns and index extensions. Generated columns seems like a valid approach. Even though data is duplicated on a row. No need for triggers seems like a good thing and the original query do not need any modifications.
This was about the first time that I am using db2cc Control Center to do things in DB2 environment. Execution plans were found easily from Access Plan page. At least with a small table implementation and tests went ok. Allthough adding a column in a table was not so straight forward because the column was a GENERATED ALLWAYS AS column.
SET INTEGRITY FOR t OFF;
alter table t
add column last_name_u varchar(100)
GENERATED ALWAYS AS ( UPPER(last_name));
SET INTEGRITY FOR t IMMEDIATE CHECKED FORCE GENERATED;
create index t_lastname_upper_idx on t(last_name_u);
How much easier would that have been in Oracle 11g. Just add a virtual column...
alter table t add last_name_u as (upper(last_name));
create index t_last_name_upper on t(last_name_u);
select * from t where upper(last_name) = :ln;
Similarily no need to change the query. Index is used. And the column is virtual, no need for storage. The index extensions approach might be the way to avoid unneeded storing of the data in DB2.
Needed also reduce a size of column and got surpriced how often REORG TABLE is needed in DB2. Or did I miss something in the documentation.
In DB2 there is no such thing as a function based index. But in a article on IBM site there is described alternatives to do this. Generated columns and index extensions. Generated columns seems like a valid approach. Even though data is duplicated on a row. No need for triggers seems like a good thing and the original query do not need any modifications.
This was about the first time that I am using db2cc Control Center to do things in DB2 environment. Execution plans were found easily from Access Plan page. At least with a small table implementation and tests went ok. Allthough adding a column in a table was not so straight forward because the column was a GENERATED ALLWAYS AS column.
SET INTEGRITY FOR t OFF;
alter table t
add column last_name_u varchar(100)
GENERATED ALWAYS AS ( UPPER(last_name));
SET INTEGRITY FOR t IMMEDIATE CHECKED FORCE GENERATED;
create index t_lastname_upper_idx on t(last_name_u);
How much easier would that have been in Oracle 11g. Just add a virtual column...
alter table t add last_name_u as (upper(last_name));
create index t_last_name_upper on t(last_name_u);
select * from t where upper(last_name) = :ln;
Similarily no need to change the query. Index is used. And the column is virtual, no need for storage. The index extensions approach might be the way to avoid unneeded storing of the data in DB2.
Needed also reduce a size of column and got surpriced how often REORG TABLE is needed in DB2. Or did I miss something in the documentation.
No comments:
Post a Comment