Re: Hierarchical queries and indexes

From: --CELKO-- <jcelko212_at_earthlink.net>
Date: 8 Oct 2004 17:31:00 -0700
Message-ID: <18c7b3c2.0410081631.7fe63b84_at_posting.google.com>


>> since Dr. Codd had IMS (a hard-wired hierarchical DB) as current practice, it is odd that the RDBMSs (and SQL) still don't handle them natively. <<

I think that the notion of a PRIMARY KEY in Codd's first papers was from tape files that had to be sorted on a single key for merging. >>

>> for example, assume three generic tables (Mr. Celko, control your blood
pressure); table1, table2, table3. now, the designers (loosely defined) decided that some data in table1 would be joined to some data in either table2 or table3 ... processing these tables with SQL is not, in my estimation, possible. <<

Not a problem; let me "cut & paste":

The classic scenario calls for a root class with all the common attributes and then specialized sub-classes under it. As an example, let's take the class of Vehicles and find an industry standard identifier (VIN), and add two mutually exclusive sub-classes, Sport utility vehicles and sedans ('SUV', 'SED').

CREATE TABLE Vehicles
(vin CHAR(17) NOT NULL PRIMARY KEY,

 vehicle_type CHAR(3) NOT NULL

       CHECK(vehicle_type IN ('SUV', 'SED')),  UNIQUE (vin, vehicle_type),
 ..);

Notice the overlapping candidate keys. I then use a compound candidate key (vin, vehicle_type) and a constraint in each sub-class table to assure that the vehicle_type is locked and agrees with the Vehicles table. Add some DRI actions and you are done:

CREATE TABLE SUV
(vin CHAR(17) NOT NULL PRIMARY KEY,

 vehicle_type CHAR(3) DEFAULT 'SUV' NOT NULL

       CHECK(vehicle_type = 'SUV'),
 UNIQUE (vin, vehicle_type),
 FOREIGN KEY (vin, vehicle_type)
  REFERENCES Vehicles(vin, vehicle_type)   ON UPDATE CASCADE
  ON DELETE CASCADE,
 ..);

CREATE TABLE Sedans
(vin CHAR(17) NOT NULL PRIMARY KEY,

 vehicle_type CHAR(3) DEFAULT 'SED' NOT NULL

       CHECK(vehicle_type = 'SED'),
 UNIQUE (vin, vehicle_type),
 FOREIGN KEY (vin, vehicle_type)
  REFERENCES Vehicles(vin, vehicle_type)   ON UPDATE CASCADE
  ON DELETE CASCADE,
 ..);

I can continue to build a hierarchy like this. For example, if I had a Sedans table that broke down into two-door and four-door sedans, I could a schema like this:  

CREATE TABLE Sedans
(vin CHAR(17) NOT NULL PRIMARY KEY,

 vehicle_type CHAR(3) DEFAULT 'SED' NOT NULL

       CHECK(vehicle_type IN ('2DR', '4DR', 'SED')),  UNIQUE (vin, vehicle_type),
 FOREIGN KEY (vin, vehicle_type)
  REFERENCES Vehicles(vin, vehicle_type)   ON UPDATE CASCADE
  ON DELETE CASCADE,
 ..);

CREATE TABLE TwoDoor
(vin CHAR(17) NOT NULL PRIMARY KEY,

 vehicle_type CHAR(3) DEFAULT '2DR' NOT NULL

       CHECK(vehicle_type = '2DR'),
 UNIQUE (vin, vehicle_type),
 FOREIGN KEY (vin, vehicle_type)
  REFERENCES Sedans(vin, vehicle_type)
  ON UPDATE CASCADE
  ON DELETE CASCADE,
 ..);

CREATE TABLE FourDoor
(vin CHAR(17) NOT NULL PRIMARY KEY,

 vehicle_type CHAR(3) DEFAULT '4DR' NOT NULL

       CHECK(vehicle_type = '4DR'),
 UNIQUE (vin, vehicle_type),
 FOREIGN KEY (vin, vehicle_type)
  REFERENCES Sedans (vin, vehicle_type)
  ON UPDATE CASCADE
  ON DELETE CASCADE,
 ..);

The idea is to build a chain of identifiers and types in a UNIQUE() constraint that go up the tree when you use a REFERENCES constraint. Obviously, you can do variants of this trick to get different class structures.

If an entity doesn't have to be exclusively one subtype, you play with the root of the class hierarchy:

CREATE TABLE Vehicles
(vin CHAR(17) NOT NULL,

 vehicle_type CHAR(3) NOT NULL

       CHECK(vehicle_type IN ('SUV', 'SED')),  PRIMARY KEY (vin, vehicle_type),
 ..);

Now start hiding all this stuff in VIEWs immediately and add an INSTEAD OF trigger to those VIEWs.

>> but antique COBOL programmers, and juvenile java programmers seem to think it's peachy keen. at least those from those groups that i work with. they don't have to do anything but serial select(s). and write a tonne of code to keep it all from falling apart; but, hey, that's their job. <<

Their job *security*, you mean. Received on Sat Oct 09 2004 - 02:31:00 CEST

Original text of this message