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
When the ename column in the example above is indexed (the regular way) you can not use this index because of the UPPER function.
select *
from emp
where upper (ename) = :ename
;
Indexing the ename column with the UPPER function would allow use of the index. Here is the code for this example:
create index upper_nameWhen the index is created this way, it can be used with the first statement.
on emp (upper(ename))
The way to implement the Business Rule “Only one Clerk per Department”:
create UNIQUE index one_clerk_per_deptnoUsing 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.
on emp (case job
when 'CLERK'
then deptno
end
)
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 empWith 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.
add one_clerk_per_dept as (case
when job='CLERK'
then deptno
end
)
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 empAnd now the Business Rule is implemented in a more “natural” way, without resorting to a “hack”.
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
The Same Difference…
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.
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.
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