Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 

 

 

Temporal Foreign Key Constraint

SQL Tips by Donald Burleson

An audit trail is a database design in which records are never deleted. All data modifications are logged into temporal tables. Every record in a temporal table obtains two timestamp attributes: CREATED and DELETED. The values of the other attributes are valid during the interval starting with CREATED date and ending with DELETED date. Now that the same record of values is scattered into many records, how are constraints enforced? Specifically, given two tables with parent-child relationship, how is referential constraint between their 'temporalized? versions also enforced?

table HistParent (
   id integer,
   ?,
   created date,
   deleted date); 

table HistChild (
   pid integer,   -- foreign key to HistParent.id???
   ?,
   created date,
   deleted date
);


The constraint is formulated, first informally in English, then in SQL. A child record can be created only if its parent record already exists. Likewise, a parent record cannot be deleted until it has at least one child. Informally,

A child lifespan must be contained within the parent lifetime.

The critical issue is defining the parent and child lifetimes.

Since each parent is identified by the id attribute, it is quite easy to define its lifetime. The lifetime of a parent is the longest span of time covered by the chain of [created, deleted] intervals. Now the interval coalesce technique from Chapter 1 can be invoked, and the parent lifetime view obtained:

view ParentLifetime (
   id integer,
   birth date,
   death date
);


Please note that all the attributes marked by ellipsis in the HistParent table are gone. In a way the interval coalesce operation is similar to aggregation, but unlike aggregation, coalesce produces more than one aggregate value.

If a set of attributes identifying the child is present, then its lifetime could simply be defined the same way the parent's lifetime is defined. We don't have to, though! Instead of gluing the smaller [created, deleted] child intervals into the larger [birth, death], we just observe that if each individual [created, deleted] interval is contained in the parent lifetime, so also is the child lifetime.

Now everything is ready for formal constraint expression. The following query enumerates all the child records that violate the temporal referential integrity constraint. Therefore, it should be empty:

select * from HistChild c where not exists
   (select * from ParentLifetime p
    where p.id = c.pid
    and c.created between p.birth and p.death
    and c.deleted between p.birth and p.death
   )

Cardinality Constraint

The materialized view constraint enforcement method is like a hammer looking for a nail to strike. Cardinality constraints, that is, ensuring that a table has certain number of rows, surely fall into the nail category. Sometimes, there is a more ingenious solution.

Consider a table with 3 columns A, B, C, and functional dependency → {A,B,C}. In general, the functional dependency X → Y requires each pair of rows that agree on the columns from the set X to agree on the columns from Y, as well. In other words, there is no couple of rows such that they agree on column set X and disagree on Y. In the case of functional dependency → {A,B,C} this means no two rows unconditionally disagree on values of the columns A, B, C. These are the only columns in the table; therefore, all rows are identical! If duplicates are disallowed by enforcing unique key constraint, then a constraint is effectively enforced limiting table cardinality to 1, at most.

SQL lacks the ability to declare and enforce functional dependency constraints. A unique key is special case of functional dependency constraint X → Y, where Y contains all table columns. Unfortunately, unique keys with the empty set of columns are not allowed in SQL.

In one of the soap boxes in Chapter 1 we had discussed a similar problem with group by operator that did not admit empty sets either. As a workaround, a calculated pseudo column was introduced. Let's amend the table with extra column:

table T (
   A integer,
   B integer,
   C integer,
   dummyCol integer default 0 not null check (dummyCol = 0) unique
)

 

The combination of the check constraint and the uniqueness constraint guarantees that no more than one row is allowed. Elegant solutions always trigger the same reaction: ?Why didn't I think of that??

 

This is an excerpt from the new book SQL Design Patterns: The Expert Guide to SQL Programming by Vadim Tropashko

You can buy it direct from the publisher for 30%-off.


 

 
��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster
 
 
 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2020

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.