Skip to Main Content
  • Questions
  • Database without Primary and foreign key

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, gaurav.

Asked: February 13, 2013 - 11:11 am UTC

Last updated: February 13, 2013 - 3:44 pm UTC

Version: 10.2.0.4

Viewed 1000+ times

You Asked

Hi Tom,

In our company we have a database without any primary and foreign keys.
For uniqueness they use unique and not null constraints in both dev and test environment and have delivered the same to all clients.

Example:

Table Tcoy:
Unique and not null constraint on acoycde.

Table TTRD:
Unique and not null constraint on two columns atrdid and acoycde.

Table TTRDLEG:
Unique and not null constraint on two columns atrdid and atrdlegid.

Table TSTT:
Unique and not null constraint on three columns asttid, asttlegid and asttseq.


1) Does absence of Primary and foreign key affect the performance of queries.
2) If yes, can we include them now in our database.
3) Is there any other side effects of not using these keys.

I think our database is not even in the first normal form.


Thanks.



and Tom said...

This seems to be a very very popular topic today! Today must be constraint day :)

Now, your absence of primary keys is bothersome - but not as bad as it could be since a unique constraint + not null is precisely what a primary key constraint is. So - that is good enough, you could have foreign keys to these unique constraints.


The absence of foreign keys is alarming - I'll bet you have orphaned records (especially if your developers think they wrote the application to enforce it - they didn't, they did it wrong, very close to 100% sure on that!).

The database uses constraints to optimize queries. If you don't have constraints - you are missing out on many optimizations.

http://asktom.oracle.com/pls/apex/f?p=100:11:0::::P11_QUESTION_ID:6072457600346531968

http://asktom.oracle.com/pls/apex/z?p_url=ASKTOM%2Edownload_file%3Fp_file%3D8322231124282761811&p_cat=MetadataMatters.ppt&p_company=822925097021874


Rating

  (4 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

How to find orphaned records

gaurav, February 13, 2013 - 2:31 pm UTC

Thanks for your quick response.

In the above case which records will be orphan and how to find them?




Tom Kyte
February 13, 2013 - 2:38 pm UTC

what I'm saying is that if your developers wrote code to enforce referential integrity - they almost certainly DID IT WRONG.

they did it in a way that would work in a single user database - but not in a multi-user database. And they don't know that they did this.

but unless they used LOCK TABLE or judiciously used select for update to serialize operations - they did it wrong.


how to find it?


select * 
  from child left outer join parent on (child.fkey = parent.key)
 where parent.key is null;



do that against every child table for every foreign key.

Constraints in real life

Charlie B, February 13, 2013 - 3:11 pm UTC

Lots of people are thinking about constraints today. Tomorrow is Valentine's Day.

Coincidence?
Tom Kyte
February 13, 2013 - 3:44 pm UTC

bah-doomp-bah, hit cymbal...

Chuck Jolley, February 13, 2013 - 3:23 pm UTC

Every day is constraints day.

Constrains

S, February 14, 2013 - 9:11 am UTC

As long as every day is not a constrained day ...

S