19 December 2008

Business Rule: Only One Clerk per Department

During the 7Up workshop, a workshop geared towards experienced developers who want to get up to speed with everything that happened in Oracle since release 7, one of the “tricks” that passes by is how to implement the Business Rule:

Only one Clerk per Department is Allowed

The way we show how to declaratively implement this Business Rule is by using a Unique Function Based Index. Every now and then someone will comment that the implementation is a hack, “'cause an Index is not meant to implement a Business Rule, it’s there to enhance performance.”
I don’t necessarily agree with this, but I do believe that Oracle 11g offers a more elegant solution (be it very similar, but is considered less of a hack).

First let’s take a look at the “hack”, with the Unique Function Based Index. Then we’ll look at the way to do the same in Oracle 11g. Lastly I will show you the similarity between the two.

Unique Function Based Index


First off, the Function Based Index. FBI’s were introduced in Oracle 9i and allow you to create an index using a function.
Especially useful when you have a query like

select *
from emp
where upper (ename) = :ename
;
When the ename column in the example above is indexed (the regular way) you can not use this index because of the UPPER function.
Indexing the ename column with the UPPER function would allow use of the index. Here is the code for this example:
create index upper_name
on emp (upper(ename))
When the index is created this way, it can be used with the first statement.

The way to implement the Business Rule “Only one Clerk per Department”:
create UNIQUE index one_clerk_per_deptno
on emp (case job
when 'CLERK'
then deptno
end
)
Using a simple CASE expression only DEPTNO are used in the index when the JOB is equal to CLERK. Because it is a unique index, there can only be one CLERK in each department.

Virtual Columns


Some might call the implementation of the Business Rule in the previous section a “hack”. Instead of using indexes to increase performance, the index is used to declaratively implement a Business Rule.
Oracle 11g introduced Virtual Columns. I really like Virtual Columns more and more because of the multitude of possibilities. Using Virtual Columns to implement this Business Rule is very straight forward.
Instead of using the simple CASE expression in an index, we will use it in the definition of the Virtual Column:
alter table emp
add one_clerk_per_dept as (case
when job='CLERK'
then deptno
end
)
With the statement above an extra column is added to the EMP table. This Virtual Column, based on the CASE expression, will only show a value when the JOB equals CLERK.
SQL> select job
2 , one_clerk_per_dept
3 from emp
4 /

JOB ONE_CLERK_PER_DEPT
--------- ------------------
CLERK 20
SALESMAN
SALESMAN
MANAGER
SALESMAN
MANAGER
MANAGER
ANALYST
PRESIDENT
SALESMAN
CLERK 20
CLERK 30
ANALYST
CLERK 10

As you can see in the resultset above, the ONE_CLERK_PER_DEPT has a value in its column when the JOB is a CLERK. Because the Business Rule says “Only one Clerk per Department” we need to make this column UNIQUE.
With this data this is not possible, because department has two CLERKS. One has to go…
SQL> update emp
2 set job = 'NOCLERK'
3 where job = 'CLERK'
4 and rownum = 1
5 /

1 row updated.

SQL> alter table emp
2 add constraint one_clerk_uk UNIQUE (one_clerk_per_dept)
3 /

Table altered.

SQL> update emp
2 set job = 'CLERK'
3 where job = 'NOCLERK'
4 /
update emp
*
ERROR at line 1:
ORA-00001: unique constraint (ALEX.ONE_CLERK_UK) violated
And now the Business Rule is implemented in a more “natural” way, without resorting to a “hack”.


The Same Difference…


Both methods implement the same Business Rule. Both implement the Business Rule in a declarative way. To some people the first method feels like a “hack” and find the second method more “natural”. But how different are they really?
Not as much as you might have suspected. When you use the first method (hacking with Function Based Indexes), the USER_IND_COLUMNS datadictionary view reveals the implementation.

SQL> select column_name
2 from user_ind_columns
3 where index_name = 'ONE_CLERK_PER_DEPT'
4 /

COLUMN_NAME
---------------------------------------------------------
SYS_NC00010$

SQL> select job
2 , SYS_NC00010$
3 from emp
4 /

JOB SYS_NC00010$
--------- ------------
NOCLERK
SALESMAN
SALESMAN
MANAGER
SALESMAN
MANAGER
MANAGER
ANALYST
PRESIDENT
SALESMAN
CLERK 20
CLERK 30
ANALYST
CLERK 10
A hidden column is added to the table with a very obscure name. Apparently a Function Based Index is pretty similar to a Virtual Column.

12 December 2008

Business Rule: Only use Active Records

The Business Rule that needed to implemented:

Only "active" records can be used in other tables.

Before Oracle 11g, one way to implement this Business Rule was to Materialized View with a Check Constraint defined on it. However In Oracle 11g you can implement this Business Rule a lot simpler by using a Virtual Column and a Foreign Key.

First let set up the tables that we are going to use in this example:

create table lookup
(id number primary key
,code varchar2(10)
,value varchar2(100)
,ind_active varchar2(1)
);

alter table lookup
add constraint lookup_ind_chk check (ind_active in ('Y', 'N'))
/

This table has the ind_active column which dictates whether the record in this table may be used in other tables. "Y" indicates that we can use it in other tables, "N" indicates that you can not use it (anymore).

Next we need another table to reference our Lookup Table:

create table t
(id number primary key
,lu_id number references lookup
);

Together with some data in both tables:
insert into lookup values (1, 'One', 'First Value', 'Y')
/
insert into lookup values (2, 'Two', 'Second Value', 'Y')
/
insert into t values (1, 1)
/
insert into t values (2, 2)
/

Now to implement the Business Rule, using the Materialized View method. Because the rule needs to be checked whenever someone wants to use a record from the Lookup table, we want to validate the rule as soon as possible. To have the Materialized View refresh when a COMMIT is issued, we need Materialized View Logs on both base tables:

create materialized view log on t with sequence, primary key including new values
/
create materialized view log on lookup with sequence, primary key including new values
/

The Materialized View definition will be

create materialized view t_lookup_mv
build immediate
refresh force on commit
as
select l.ind_active
from t
, lookup l
where l.id = t.lu_id
/

This way we will get a record in the Materialized View whenever the T-table uses a record in our Lookup Table. The final thing we need is a Check Constraint on this Materialized View, because we only want Lookup records with the active_ind is “Y”:
alter materialized view t_lookup_mv
add constraint active_chk check (ind_active = 'Y');

Just to check that the Materialized View does what it is supposed to do:

update lookup
set ind_active = 'N'
where rownum <= 1
/
commit;

ORA-12008: error in materialized view refresh path
ORA-02290: check constraint (ALEX.ACTIVE_CHK) violated

That seems to work. But as you can see, you need quite a lot of code to implement such a simple rule. The same Business Rule can be implemented in Oracle 11g a lot simpler, with less code.

Virtual Columns

This is the way we're going to implement the rule:

  1. Add a Virtual Column to the Lookup table
  2. Create a Foreign Key referencing the Virtual Column
And that's all there is to it. Let's take a look at the code. First of all the Virtual Column.

Virtual Columns are a new feature of the Oracle 11gR1 database. Using this feature you can create an extra column in the table that is based on an expression.
active_fk as (case when ind_active = 'Y' then id end) unique 

The values in this Virtual Column are only shown when the IND_ACTIVE column has the value of "Y". The value that is shown is the primary key of the base table. Querying the LOOKUP table, reveals the content of the ACTIVE_FK Virtual Column:


SQL> select *
2 from lookup
3 /

ID CODE VALUE I ACTIVE_FK
---------- ---------- -------------------- - ----------
1 One First Value Y 1
2 Two Second Value Y 2

Changing the IND_ACTIVE column to "N" will remove the value from the ACTIVE_FK column:

SQL> update lookup
2 set ind_active = 'N'
3 where id = 2
4 /

1 row updated.

SQL> select *
2 from lookup
3 /

ID CODE VALUE I ACTIVE_FK
---------- ---------- -------------------- - ----------
1 One First Value Y 1
2 Two Second Value N

SQL> rollback;


Because we are going to use the Virtual Column as referenced by a Foreign Key we are going to make it UNIQUE as well.

Now for the table which uses the records from our Lookup Table:


create table t
(id number primary key
,lu_id number
);
alter table t
add constraint t_lookup_fk foreign key (lu_id) references lookup (active_fk)
/
The foreign key is this case is not on the primary key, but on the Virtual Column instead.

Let's add some data to the table and try it out.

insert into t values (1, 1);
insert into t values (2, 2);

update lookup
set ind_active = 'N'
where rownum <= 1
/
update lookup
* ERROR at line 1: ORA-02292: integrity constraint (ALEX.T_LOOKUP_FK) violated - child record found

And there you have it. It's not possible to use deactivated records anymore.

Check when you COMMIT?

Note the difference though, the Materialized View method is checked when you commit your transaction. The Virtual Column method checks it immediately. If you want the Virtual Column to have similar to the Materialized View method, change the foreign key:

alter table t
add constraint t_lookup_fk foreign key (lu_id) references lookup (active_fk)
deferrable initially deferred
/
Note the last sentence, deferrable initially deferred, this tells Oracle to not validate the constraint immediately but to postpone it until the transaction is ended.

06 December 2008

On my own

In 2004 I started working for AMIS Services BV, my current employer, and they started with something "new"...blogging.
AMIS is all about sharing knowledge so a Technology Blog was the thing to have.
Everybody in the company was asked to write a contribution for the company blog.
My first entry on the blog was on Tora, an Open Source tool. You can find that entry by clicking here.
It was blog number 119, as you can see in the URL. Yesterday afternoon I wrote another blog on the AMIS Technology site on Subquery Factoring in Oracle 11gR1. The counter is currently at 4252... or it was yesterday afternoon.

Sometimes it is hard to find something that I have written, so I decided to startup my own blog. ....just to keep my notes together.
The other day someone asked me something about a blog I had written, and to be honest I was quite convinced that I haven't written about that subject. He showed me the contrary...
I'm getting older, memory starts to go... Hopefully this will make it easier to remember things. And maybe, just maybe you might find it useful too. If you do, leave a comment. If you don't, leave a comment too. It nice to see someone else actually reading this stuff.