Oracle unique constraint and unique index

A constraint and an index are separate logical entities. A unique constraint, for example, is visible in USER_CONSTRAINTS (or ALL_CONSTRAINTS or DBA_CONSTRAINTS). An index is visible in USER_INDEXES (or ALL_INDEXES or DBA_INDEXES).

A unique constraint is enforced by an index though it is possible (and sometimes necessary) to enforce a unique constraint using a non-unique index. A deferrable unique constraint, for example, is enforced using a non-unique index. If you create a non-unique index on a column and subsequently create a unique constraint, you can also use that non-unique index to enforce the unique constraint.

In practice, a unique index acts very much like a unique, non-deferrable constraint in that it raises the same error that a unique constraint raises since the implementation of unique constraints uses the index. But it is not quite the same because there is no constraint. So, as you've seen, there is no unique constraint so you cannot create a foreign key constraint that references the column.

There are cases where you can create a unique index that you cannot create a unique constraint. A function-based index, for example, that enforces conditional uniqueness. If I wanted to create a table that supported logical deletes but ensure that COL1 is unique for all non-deleted rows

SQL> ed
Wrote file afiedt.buf

  1  CREATE TABLE t (
  2    col1 number,
  3    deleted_flag varchar2(1) check( deleted_flag in ('Y','N') )
  4* )
SQL> /

Table created.

SQL> create unique index idx_non_deleted
  2      on t( case when deleted_flag = 'N' then col1 else null end);

Index created.

SQL> insert into t values( 1, 'N' );

1 row created.

SQL> insert into t values( 1, 'N' );
insert into t values( 1, 'N' )
*
ERROR at line 1:
ORA-00001: unique constraint (SCOTT.IDX_NON_DELETED) violated


SQL> insert into t values( 1, 'Y' );

1 row created.

SQL> insert into t values( 1, 'Y' );

1 row created.

But if we're talking about a straight unique non-function based index, there are probably relatively few cases where it really makes more sense to create the index rather than creating the constraint. On the other hand, there are relatively few cases where it makes much difference in practice. You'd almost never want to declare a foreign key constraint that referenced a unique constraint rather than a primary key constraint so you rarely lose something by only creating the index and not creating the constraint.


As was already explained in other answers: constraints and the indexes are different entities. But they lack precise definitions and official comments on the topic. Before we discuss the relationship between these two entities lets take a look at their purpose independent of each other.

Purpose of a constraint1:

Use a constraint to define an integrity constraint-- a rule that restricts the values in a database.

The purposes of an index2:

You can create indexes on columns to speed up queries. Indexes provide faster access to data for operations that return a small portion of a table's rows.

In general, you should create an index on a column in any of the following situations:

  • The column is queried frequently.
  • A referential integrity constraint exists on the column.
  • A UNIQUE key integrity constraint exists on the column.

Now we know what constraints and indexes are, but what is the relationship between them?

The relationship between indexes and constraints is3:

  • a constraint MIGHT create an index or use an existing index to efficient enforce itself. For example, a PRIMARY KEY constraint will either create an index (unique or non-unique depending) or it will find an existing suitable index and use it.

  • an index has nothing to do with a constraint. An index is an index.

So, a constraint MIGHT create/use and index. An INDEX is an INDEX, nothing more, nothing less.

So sum this up and directly address the following sentence from your question:

However, I don't understand the reason for unique index without constraint.

Indexes speed up queries and integrity checks (constraints). Also for conditional uniqueness a unique (functional) index is used as this cannot be achieved with a constraint.

Hopefully this brings a little bit more clarification to the whole topic, but there is one aspect of the original question that remains unanswered:

Why did the following error occur when no constraint existed:

ORA-00001: unique constraint (TEST.IDX_TEST22) violated

The answer is simple: there is no constraint and the error message misnames it!

See the official "Oracle Ask TOM" comment 4 on the same problem:

It isn't a constraint. the error message "misnames" it.
If it were a constraint, you could create a foreign key to it -- but you cannot.

Hope it helps.

Links:

1Oracle 10g Documentation on Constraints

2Oracle 10g Documentation on Selecting an Index Strategy

34"Oracle Ask TOM" answer to a similar problem