Mohamed Houri’s Oracle Notes

February 26, 2011

Indexing Foreign keys

Filed under: Index — hourim @ 10:34 am

Among the very important Oracle development standards that are worth to follow I can list the following:
(a)    indexing foreign keys (FK)
(b)    using a clear naming standard to name these FK indexes

In this blog article I will try to demonstrate through simple examples the importance of the above standards. I will nevertheless, also present how? when following the (a) standard? we often came to a situation of redundant indexes (duplicate indexes) generating waste of disk space and waste of time during DML statements. Finally, I will present a simple sql script that a developer might use, each time he decides to create an index covering a foreign key, to verify if there already exists such an index or not.

It is not strictly necessary to index all and every foreign key. If you never delete nor update/merge the parent table then you don’t need to index the foreign key for reasons related to locking. Of course you may decide to create your index on the foreign key because you know that this index will give you a high precision access on the child table.

Let’s examine a situation from an existing application. In the below table the couple (cxyz_id, cxyz_dat) represents a foreign key referencing a parent table.

 index name         column name
 ind_cxyz_pk        cxyz_id
 ind_cxyz_pk        cxyz_dat
 ind_cxyz_pk        cxyz_no
 ....
 ....
 ind_px_cx_fk_i     cxyz_id
 ind_px_cx_fk_i     cxyz_dat

The output has been limited only to the indexes we are interested in.
Note how it is easy, thanks to the naming standards followed by the developer, to identify that those two indexes are covering a primary key and a foreign key respectively.

We can point out that we have two indexes starting by the foreign key columns. This is a very nice example of redundant indexes. The ind_px_cx_fk_i index should have never been created. It is already covered by the ind_cxyz_pk primary key index.

In order to beat the “foreign key locking” threat you need only to have an index which starts with the foreign key column.  Moreover, In case of a foreign key with multiple columns, you need only to have an index starting with the combination of those multiple columns but not necessarily in the same order as the order of the foreign key definition.  In other words, imagine that the ind_cxyz_pk  index has been created as follows:

 index name         column name
 ind_cxyz_pk       cxyz_dat
 ind_cxyz_pk       cxyz_id
 ind_cxyz_pk       cxyz_no

Then,  this index will still be able to cover our foreign key and we don’t need to create an extra  index.

Before I finish, I would like to submit a small sql script I wrote in order to test, if it is necessary or not (according to the existing indexes) to create an index to cover the foreign key locking threat.


/*-- ---------------------------------------------------------------------------------
-- script : verify if the fk columns are already indexed or not
--        the purpose of this script is to avoid creating redundant indexes
--        it has been defined to check FKs with up to 3 columns but can easily be updated to
--        handle Fks with more than 3 columns
--        when checking existing indexes for FK with one column then you can simply supply 'none'
--        without cotes ('') for the remaining columns when asked by the script to do so
--
--   author   : Mohamed Houri
--   date     : december 2010
--   version  : v1.0
--   Example 1 sql.world> start index_fk
--                   Enter value for m_table: t1
--                   Enter value for m_column: id
--                   Enter value for m_column2: none
--
--                  table_name      index_name      column_nam  column_pos
--                  --------------- --------------- ---------- ----------
--                   t1              ind_usr_ni      id             1
--
-- the output says that for the table t1 there exists already an index named ind_usr_ni starting
-- with the column id that you want to use as FK. So you don't need to create an extra index
-- to cover the locking threat of non indexed foreign keys
--
-- Example 2 sql.world> start index_fk
--                    Enter value for m_table: t2
--                    Enter value for m_column : col1
--                    Enter value for m_column2: col2
--                    Enter value for m_column3: none
--
--      table_name           index_name            column_nam  column_pos
------------- --- ------------------------- ---------- ------------
--      t2                      t2_usr_ni            col1           1
--
-- the output says that for the table t2 it exists an index named t2_usr_ni
-- starting with the column col1 but the script did not found an index
-- starting by (col1, col2) or (col2, col1).
-- So in this situation you need to create an extra index covering the FK and starting with
--(col1, col2) or (col2, col1) to cover the locking threat of non indexed foreign keys
--
-- Example 3 sql.world> start index_fk
--                    Enter value for m_table: t3
--                    Enter value for m_column:  col1
--                    Enter value for m_column2: col2
--                    Enter value for m_column3: none
-- table_name                index_name             column_nam     column_pos
------------------------- ------------------------------ ---------- ------
-- t3                       t3_ni_1                  col0              1
-- t3                       t3_ni_1                  col1              2
-- t3                       t3_ni_1                  col2              3
-- in this situation there exist an index name t3_ni_1 having (col1, col2)
-- as indexed columns but they are at position 2 and 3 respectively. However in order to
-- cover a FK the index should have (col1, col2) at position 1 or 2 or 2 and 1 respectively
-- Hence it is necessary in this case to create an extra index to cover the FK
-- ---------------------------------------------------------------------------------------*/
define m_table_name    = &m_table
define m_column_name   = &m_column
define m_column_name2  = &m_column2
define m_column_name3  = &m_column3
spool index_col_fk.log
set verify off
set linesize 100
select
     substr(uc1.table_name,1,25)  table_name
    ,substr(uc1.index_name,1,30)  index_name
    ,substr(uc1.column_name,1,10) column_name
    ,uc1.column_position          column_pos
from
     user_ind_columns uc1
where
     uc1.table_name   = upper('&m_table_name')
and  uc1.column_name  in ( upper('&m_column_name')
                          ,upper('&m_column_name2')
                          ,upper('&m_column_name3')
                         )
order by
     uc1.index_name
    ,uc1.column_position
    ,uc1.column_position
;
spool off

February 22, 2011

DML error logging restrictions

Filed under: Oracle — hourim @ 7:05 pm

The DML error logging represents a nice feature introduced with oracle database 10gR2. Unfortunately this feature has several restrictions as described by the Oracle documentation reproduced here below:

The following conditions cause the statement to fail and roll back without invoking the error logging capability:

  • Violated deferred constraints.
  • Any direct-path INSERT or MERGE operation that raises a unique constraint or index violation.
  • Any update operation UPDATE or MERGE that raises a unique constraint or index violation).
  • You cannot track errors in the error logging table for LONG, LOB, or object type columns. However, the table that is the target of the DML operation can contain these types of columns.

However, I have recently experienced a new restriction which is not mentioned in the Oracle documentation. Let’s see what it is about

sql> CREATE TABLE t (ID NUMBER PRIMARY KEY, text VARCHAR2(100));

Table created.

sql> BEGIN
2    DBMS_ERRLOG.create_error_log (dml_table_name => 't');
3  END;
4  /

PL/SQL procedure successfully completed.

sql>> INSERT INTO t
2     SELECT     ROWNUM, 'Test DML'
3           FROM DUAL
4     CONNECT BY LEVEL <= 10
5     LOG ERRORS INTO err$_t REJECT LIMIT UNLIMITED;

10 rows created.

sql> commit;

Commit complete.

I will now create an after statement trigger as follows

</pre>
sql> CREATE OR REPLACE TRIGGER t_trg
2     AFTER INSERT
3     ON t
4  DECLARE
5     my_exception   EXCEPTION;
6  BEGIN
7     NULL;
8     RAISE my_exception;
9  EXCEPTION
10     WHEN my_exception
11     THEN
12        DBMS_OUTPUT.put_line ('Trigger t_trg raised My_exception');
13        RAISE;
14  END;
15  /

Trigger created.

sql> set serveroutput on

sql> INSERT INTO t
2     SELECT     11, 'Test DML after Statement Trigger'
3           FROM DUAL
4     LOG ERRORS INTO err$_t REJECT LIMIT UNLIMITED;

Trigger t_trg raised My_exception
LOG ERRORS INTO err$_t REJECT LIMIT UNLIMITED
*
ERROR at line 4:
ORA-06510: PL/SQL: unhandled user-defined exception
ORA-06512: at "T_TRG", line 10
ORA-04088: error during execution of trigger 'T_TRG'

sql>    select count(1) from err$_t;
COUNT(1)
----------
0

sql> rollback;
Rollback complete.

Woo, the DML error logging stops working correctly and raised an exception. The DML err$_t table is empty.
But let’s change the trigger to be a ‘for each row’ trigger

sql> CREATE OR REPLACE TRIGGER t_trg
2     AFTER INSERT
3     ON t
4     FOR EACH ROW
5  DECLARE
6     my_exception   EXCEPTION;
7  BEGIN
8     NULL;
9     RAISE my_exception;
10  EXCEPTION
11     WHEN my_exception
12     THEN
13        DBMS_OUTPUT.put_line ('Trigger t_trg raised My_exception');
14        RAISE;
15  END;
16  /

Trigger created.

sql> INSERT INTO t
2     SELECT     11, 'Test DML after Statement Trigger'
3           FROM DUAL
4     LOG ERRORS INTO err$_t REJECT LIMIT UNLIMITED;
Trigger t_trg raised My_exception
0 rows created.

sql>> select count(1) from err$_t;
COUNT(1)
----------
1

And this time the DML error logging table worked correctly.

Footnote: DML error logging has another restriction which is not mentioned by the Oracle documentation: it will not work with a statement trigger. It works only with a ‘for each row’ trigger.

February 20, 2011

Back to blogging

Filed under: Oracle — hourim @ 4:35 pm

Two years ago I have decided to stop blogging as far as I have nothing interesting to publish. The decision I have made at that time was to continue reading, learning and experimenting from other valuable blogs instead of spending my time writing items without any added value to the community.

Today, I think I need to be back; not because the stuff I will be writing will bring an added value but because it will force me to phrase my oracle knowledge which ultimately will bring me to test and test before publishing anything. The second reason is that I can access to my stuff very easily because I know that I have already write something about.

Here below is the list of what I will be blogging about in the near feature

  • (a) Understanding the locking threat of unindexed foreign keys will avoid creating redundant indexes
  • (b) cursor_sharing=force and static PL/SQL
  • (c) DML error logging with after statement triggers
  • (d) few words about the method the follow when inserting a large volume of data
  • (e) Indexing  partitioned tables
  • (f) The french translation of Jonathan Lewis Oracle Cost Based Optimizer Book (Clustering Factor Chapter)

See you soon (I hope I am not speaking only to myself ) 🙂

Create a free website or blog at WordPress.com.

Tony's Oracle Tips

Tony Hasler's light hearted approach to learning about Oracle

Richard Foote's Oracle Blog

Focusing Specifically On Oracle Indexes, Database Administration and Some Great Music

Hatem Mahmoud's blog

Just another blog : Databases, Linux and other stuffs

Mohamed Houri’s Oracle Notes

Qui se conçoit bien s’énonce clairement

Oracle Diagnostician

Performance troubleshooting as exact science

Raheel's Blog

Things I have learnt as Oracle DBA

Coskan's Approach to Oracle

What I learned about Oracle

So Many Oracle Manuals, So Little Time

“Books to the ceiling, Books to the sky, My pile of books is a mile high. How I love them! How I need them! I'll have a long beard by the time I read them”—Lobel, Arnold. Whiskers and Rhymes. William Morrow & Co, 1988.

Carlos Sierra's Tools and Tips

Tools and Tips for Oracle Performance and SQL Tuning

Oracle Scratchpad

Just another Oracle weblog

OraStory

Dominic Brooks on Oracle Performance, Tuning, Data Quality & Sensible Design ... (Now with added Sets Appeal)