Re: Eliminating Combinatorial Relationship Multiplication
Date: 4 Jul 2004 15:27:00 -0700
Message-ID: <dc6c1ff0.0407041427.25962a6d_at_posting.google.com>
Daniel Morgan <damorgan_at_x.washington.edu> wrote in message news:<1088831855.922891_at_yasure>...
> --CELKO-- wrote:
>
> > Here is the link on Amazon.com for my new book on "Trees & Hierarchies
> > in SQL"
> >
> > http://www.amazon.com/exec/obidos/tg/detail/-/1558609202/qid=1080772873/sr=1-1/ref=sr_1_1/102-7683601-6345721?v=glance&s=books#product-details
> >
> > Separate the tree structure from the nodes. Ilike the nested sets
> > model for the structure, but you can pick whatever works best for your
> > situation. Then the nodes can go into another table.
> >
> > 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.
>
> Joe ... sorry ... but integrity demands that I write the following:
>
> We have a usenet group named comp.databases.oracle.marketplace
> specifically designated for promotions. In the future it would be
> appreciated if you posted book, or any other, promotions there.
>
> Thanks.
>
> For everyone else ... I recommend Joe's books to my students and
> highly recommend them.