2009-09-28

Not overlapping

Lets have a validity period in a table and a rule not to have overlapping periods. The correct solution is to have an another table having the concurrency lock and a combound trigger to handle the overlapping check. Or might there be an alternative way? A way that does not force us to rely that all code modifying the table remember to use the concurrency lock table before modifying the periods. Here it comes. A great abuse of the "bad hack" function based indexes. No need for the concurrency table or triggers.



drop table z cascade constraints purge;

create table z(z number(16) not null
, validfrom number(4) not null
, validtill number(4) not null
, constraint fro2000 check (2000 < validfrom)
, constraint til2050 check (validtill <= 2050)
, constraint frotil check (validfrom <= validtill)
);

create or replace function f(fro number,til number)
return number
deterministic
as
n number(16);
begin
n:=0;
for i in fro..(til-1) loop
n:= n + power(2,i-2001);
end loop;
return n;
end;
/


create unique index z1 on z (case when bitand(1,f(validfrom,validtill)) = 1 then z else null end);

create unique index z2 on z (case when bitand(2,f(validfrom,validtill)) = 2 then z else null end);

create unique index z3 on z (case when bitand(4,f(validfrom,validtill)) = 4 then z else null end);

create unique index z4 on z (case when bitand(8,f(validfrom,validtill)) = 8 then z else null end);

create unique index z5 on z (case when bitand(16,f(validfrom,validtill)) = 16 then z else null end);

create unique index z6 on z (case when bitand(32,f(validfrom,validtill)) = 32 then z else null end);

create unique index z7 on z (case when bitand(64,f(validfrom,validtill)) = 64 then z else null end);

create unique index z8 on z (case when bitand(128,f(validfrom,validtill)) = 128 then z else null end);

create unique index z9 on z (case when bitand(256,f(validfrom,validtill)) = 256 then z else null end);

create unique index z10 on z (case when bitand(512,f(validfrom,validtill)) = 512 then z else null end);

--You maybe got the idea. Left out indexes z11-z46 ...

create unique index z47 on z (case when bitand(70368744177664,f(validfrom,validtill)) = 70368744177664 then z else null end);

create unique index z48 on z (case when bitand(140737488355328,f(validfrom,validtill)) = 140737488355328 then z else null end);

create unique index z49 on z (case when bitand(281474976710656,f(validfrom,validtill)) = 281474976710656 then z else null end);

SQL> insert into z values(1,2001,2011);

1 row created.

SQL> insert into z values(1,2011,2011);

1 row created.

SQL> insert into z values(1,2010,2012);
insert into z values(1,2010,2012)
*
ERROR at line 1:
ORA-00001: unique constraint (RAFU.Z10) violated

SQL> insert into z values(2,2049,2050);

1 row created.

SQL> insert into z values(2,2049,2050);
insert into z values(2,2049,2050)
*
ERROR at line 1:
ORA-00001: unique constraint (RAFU.Z49) violated

SQL> insert into z values(2,2010,2012);

1 row created.

SQL> insert into z values(2,2001,2049);
insert into z values(2,2001,2049)
*
ERROR at line 1:
ORA-00001: unique constraint (RAFU.Z10) violated

SQL> insert into z values(2,2014,2017);

1 row created.

2009-09-21

Denormalize safely

For some reason there is a need to denormalize values from p table to c table.
How to ensure that denormalized values are the same that original values in p?


drop table c cascade constraints purge;

drop table p cascade constraints purge;

create table p(p_id number(10) primary key
, p_name varchar2(200) not null);

create table c(c_id number(10) primary key
, p_id constraint c_p_fk references p
, c_value varchar2(200) not null);


The denormalization.



alter table c add (p_name varchar2(200) not null);

alter table p add unique (p_name,p_id);

alter table c add constraint c_p_2fk foreign key(p_name,p_id) references p(p_name,p_id);



Make the c_p_2fk deferrable if there is a need to update the denormalized values. To satisfy unindex:

create index c_p_2fk_idx on c(p_id,p_name);

2009-09-11

Only one (is_current)

Kimball writes in The Date Warehouse Toolkit about slowly changing dimension type 6. Seen such structures with marked current values in a separate attribute. Like in wikipedia. If the dimension is storing transaction time as durations then the current indicator column might as well be a virtual column in 11g, evaluated to Y if the end day is set to end_date value. No need to update the current indicator column when populating new values for a dimension.

There should be at most one current indicator = Y row for each supplier. To satisfy this requirement it is possible to create a unique constraint to a virtual column. Actually I would replace the Y value with the supplier_key if the end of days is set in the row. And put the unique key to that column as show earlier. Adding such a column to an existing model might be problematic because the ETL or mainetenance software might populate new rows before updating the old ones. Should there exist atomic multi table merge? With 11g and virtual columns this is quite easy to overcome by setting the newly created unique constraint deferrable initially deferred.

But how about 10.2 without virtual columns. Lets dig into the only one, insert first and update then problem with an example without durations.


drop table di purge;

drop materialized view di_mv;

create table di(di_id number(4) primary key
, sour number(4) not null
, val number(4) not null
, is_current number(1) not null);



Each sour should have only one current. This can be acheaved by creating a bad hack function based index.


create unique index d_only_one_u on di(case when is_current = 1 then sour end);

insert into di (di_id,sour,val,is_current) values (1,1,0,0);

insert into di (di_id,sour,val,is_current) values (2,1,1,1);

insert into di (di_id,sour,val,is_current) values (3,2,2,1);



Problematic ETL prosess might want to populate new values first and update the current status at the end of transaction.


insert into di (di_id,sour,val,is_current) values (4,2,3,1);
insert into di (di_id,sour,val,is_current) values (4,2,3,1)
*
ERROR at line 1:
ORA-00001: unique constraint (RAFU.D_ONLY_ONE_U) violated


Unique index is checked immediately and now row is allowed to be inserted.
Glue on commit refreshable materialized view to the model.


drop index d_only_one_u;

create materialized view log on di with rowid;

create materialized view di_mv refresh on commit as
select sour,is_current, rowid drid
from di
where is_current = 1
;

alter table di_mv
add constraint sour_u unique (sour);

insert into di (di_id,sour,val,is_current) values (5,2,3,1);

commit;
commit
*
ERROR at line 1:
ORA-12008: error in materialized view refresh path
ORA-00001: unique constraint (RAFU.SOUR_U) violated


And it behaves like an deferrable initially deferred unique constraint. Uniquenes check is done at the end of a transaction.


insert into di (di_id,sour,val,is_current) values (6,2,3,1);

update di set is_current = 0 where di_id = 3;

commit;


Ok. The downside is that di_mv is using space. May be worth using, if your data population is beeing coded by humans.

2009-09-01

Only one (alternative 2)

10g friendly approach to store primary currencies. No virtual column used. Structure seems a lot like Tom Kyte suggested. Difference is that all country currencies are here populated in the same table and the materialized view replaced with a foreign key constraint.


create table country(country varchar2(2) constraint country_pk primary key
, primary_currency varchar(3) not null
)
;

create table currency(country references country
, currency varchar(3)
, constraint currency_pk primary key (currency,country)
)
;

alter table country
add constraint primary_curr_in_country_curr
foreign key(primary_currency,country)
references currency(currency,country)
deferrable initially deferred
;


Populating


insert into country (country,primary_currency) values ('US','USS');

insert into currency (country,currency) values ('US','USD');

insert into currency (country,currency) values ('US','USN');

insert into currency (country,currency) values ('US','USS');

commit;

insert into country (country,primary_currency) values ('FI','EUR');

insert into currency (country,currency) values ('FI','EUR');

insert into currency (country,currency) values ('FI','FIM');

commit;


Changing the default. Easier than before. Less code


update country set primary_currency='USD' where country='US';

commit;

select * from country;
country primary_currency
US USD
FI EUR

select * from currency;
country currency
FI EUR
FI FIM
US USD
US USN
US USS


Testing the model:



update country set primary_currency='USD' where country='FI';

commit;

ORA-02091: transaction rolled back
ORA-02291: integrity constraint (RAFU.PRIMARY_CURR_IN_COUNTRY_CURR) violated -
parent key not found

insert into country (country, primary_currency) values ('SW','SEK');

commit;

ORA-02091: transaction rolled back
ORA-02291: integrity constraint (RAFU.PRIMARY_CURR_IN_COUNTRY_CURR) violated -
parent key not found



There is only one default currency per country, should be obvious.

Be sure to run unindex on your production model.

About Me

My photo
I am Timo Raitalaakso. I have been working since 2001 at Solita Oy as a Senior Database Specialist. My main focus is on projects involving Oracle database. Oracle ACE alumni 2012-2018. In this Rafu on db blog I write some interesting issues that evolves from my interaction with databases. Mainly Oracle.