Re: Referential integrity (foreign keys) across multiple tables - Mailing list pgsql-sql

From Aaron Bono
Subject Re: Referential integrity (foreign keys) across multiple tables
Date
Msg-id bf05e51c0607241026y5404fb9do86a2af7f1cde74ac@mail.gmail.com
Whole thread Raw
In response to Referential integrity (foreign keys) across multiple tables  (Richard Jones <rich@annexia.org>)
Responses Re: Referential integrity (foreign keys) across multiple tables  (Richard Jones <rich@annexia.org>)
List pgsql-sql
On 7/22/06, Richard Jones <rich@annexia.org> wrote:

Simplified schema:

  create table hosts (
    id serial primary key,
    hostname text not null
  );

  create table pages (
    id serial primary key,
    hostid int not null references hosts (id),
    url text not null,
    unique (hostid, url)
  );

  create table page_contents (
    pageid int not null references pages (id),
    section text not null
  );

(There are many hosts, many pages per host, and many page_contents
sections per page).

Now I want to add a column to page_contents, say called link_name,
which is going to reference the pages.url column for the particular
host that this page belongs to.

Something like:

  alter table page_contents add link_name text;
  alter table page_contents
    add constraint foo foreign key (p.hostid, link_name)
    references pages (hostid, url)
    where p.id = pageid;

 
The easiest, and not necessarily elegant, way to acomplish this is to create linkid rather than link_name and make it a foreign key to pages.id.  Then add a trigger that checks to make sure the pages you link to from page_contents to pages is for the same host.  If not, raise an exception.

Another option is to do this:

 create table page_contents (
   hostid int not null,
   url text not null,
   linkhostid int,
   linkurl text,
   section text not null,
   foreign key (hostid, url) references pages (hostid, url),
   foreign key (linkhostid, linkurl) references pages (hostid, url)
 );

Or if you really want to restructure things:

 create table hosts (
   id serial primary key,
   hostname text not null
 );

 create table pages (
   id serial primary key,
   url text not null,
   unique (url)
 );

 create table page_contents (
   pageid int not null references pages (id),
   hostsid int not null references hosts (id),
   linkpageid int references pages(id),
   section text not null
 );

That should give you some options to play with.

As a side comment, you should also name your primary key columns more meaningfully.  Use hosts.hostsid and pages.pagesid, not hosts.id and pages.id.  When you begin writing large queries, the use of the column name id all over the place will make your queries more prone to error, harder to read and harder to write.

==================================================================
   Aaron Bono
   Aranya Software Technologies, Inc.
   http://www.aranya.com
==================================================================

pgsql-sql by date:

Previous
From: "Aaron Bono"
Date:
Subject: Re: System catalog table privileges
Next
From: Bruno Wolff III
Date:
Subject: Re: Referential integrity (foreign keys) across multiple tables