Mohamed Houri’s Oracle Notes

April 9, 2011

SQL-Loader direct path and duplicate key

Filed under: direct path — hourim @ 5:10 pm

Very often I see on the OTN site a thread where a poster is wondering why, despite the presence of a primary key on his table, this one contains duplicate key when it is loaded via sqlloader using direct path load.

The answer to this question is that when you direct path load, the unique index supporting the primary key is disabled behind the scene allowing duplicate key to be inserted. Here below is the demonstration of this behaviour :

mhouri.world> create table t1 (id number);

Table created.

mhouri.world> alter table t1 add constraint t1_pk primary key (id);

Table altered.

mhouri.world> select table_name, index_name, status
 2  from user_indexes
 3  where table_name = 'T1';

TABLE_NAME                     INDEX_NAME                     STATUS
------------------------------ ------------------------------ --------
T1                             T1_PK                          VALID

mhouri.world> select count(1) from t1;

 COUNT(1)
----------
 0

The control file and the  sqlloader call are shown here below:

LOAD DATA
INFILE *
REPLACE
INTO TABLE T1
(
 id position(1:1) TERMINATED BY ","
)
BEGINDATA
1;
2;
2;
3;
c:\sqlldr mhouri/mhouri@mhouri control=c.ctl direct=true

mhouri.world> select count(1) from t1;</pre>
COUNT(1)
 ----------
 4

mhouri.world> select * from t1;

ID
 ----------
 1
 2
 2
 3

mhouri.world> select table_name, index_name, status
 2  from user_indexes
 3  where table_name = 'T1';

TABLE_NAME                     INDEX_NAME                     STATUS
 ------------------------------ ------------------------------ --------
 T1                             T1_PK                          UNUSABLE

mhouri.world> alter index t1_pk rebuild;
 alter index t1_pk rebuild
 *
 ERROR at line 1:
 ORA-01452: cannot CREATE UNIQUE INDEX; duplicate keys found

This is one of the thing that we all have to be aware of when using direct path load : uniqueness is ignored.

Advertisements

1 Comment »

  1. […] answer to the first question is easy and I have already blogged about it. He was refreshing the materialized view using a FALSE value for the parameter atomic […]

    Pingback by CBO and unusable unique index | Mohamed Houri’s Oracle Notes — October 23, 2013 @ 6:50 am | Reply


RSS feed for comments on this post. TrackBack URI

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s

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 Oracle's blog

Just another Oracle blog : Database topics and techniques

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.

EU Careers info

Your career in the European Union

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)

%d bloggers like this: