study/oracle/oracle编程艺术/chapt11/bitmap_index.sql
2020-02-23 22:23:40 +08:00

99 lines
2.5 KiB
MySQL

/**
* 位图索引
**/
prompt
prompt eoda.emp
declare
row_count number(5);
begin
select count(1) into row_count from user_tables where table_name = upper('emp');
if row_count = 1 then
execute immediate 'drop table eoda.emp ';
end if;
execute immediate '
create table eoda.emp
as
select * from scott.emp
';
end;
/
prompt
prompt eoda.job_idx
declare
row_count number(5);
begin
select count(1) into row_count from user_indexes where index_name = upper('job_jdx') and table_name = upper('emp');
if row_count = 1 then
execute immediate 'drop index eoda.job_idx';
end if;
execute immediate '
create bitmap index eoda.job_idx on eoda.emp(job)
';
end;
/
prompt
prompt eoda.t
declare
row_count number(5);
begin
select count(1) into row_count from user_tables where table_name = upper('t');
if row_count = 1 then
execute immediate 'drop table eoda.t';
end if;
execute immediate '
create table eoda.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,
ceil( 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
';
end;
/
prompt
prompt eoda.gender_idxeoda.location_idxeoda.age_group_idx
declare
row_count_gender number(5);
row_count_location number(5);
row_count_age_group number(5);
begin
select count(1) into row_count_gender from user_indexes where index_name = upper('gender_idx');
select count(1) into row_count_location from user_indexes where index_name = upper('location_idx');
select count(1) into row_count_age_group from user_indexes where index_name = upper('age_group_idx');
if row_count_gender = 1 then
execute immediate 'drop index eoda.gender_idx';
end if;
if row_count_location = 1 then
execute immediate 'drop index eoda.location_idx';
end if;
if row_count_age_group = 1 then
execute immediate 'drop index eoda.age_group_idx';
end if;
execute immediate 'create bitmap index eoda.gender_idx on eoda.t(gender)';
execute immediate 'create bitmap index eoda.location_idx on eoda.t(location)';
execute immediate 'create bitmap index eoda.age_group_idx on eoda.t(age_group)';
end;
/
prompt
prompt edoa.t
exec dbms_stats.gather_table_stats ( user,'T' );
prompt
prompt edoa.t
select count(*)
from eoda.t
where gender = 'M'
and location in (1, 10, 30)
and age_group = '41 and over';