DROP VIEW Languages_with_descr; DROP VIEW Languages_with_all_descr; DROP VIEW Extlangs_with_descr; DROP VIEW Extlangs_with_all_descr; DROP VIEW Scripts_with_descr; DROP VIEW Scripts_with_all_descr; DROP VIEW Variants_with_descr; DROP VIEW Variants_with_all_descr; DROP VIEW Regions_with_descr; DROP VIEW Regions_with_all_descr; DROP TABLE Descriptions_languages; DROP TABLE Descriptions_extlangs; DROP TABLE Descriptions_scripts; DROP TABLE Descriptions_regions; DROP TABLE Descriptions_variants; --DROP TABLE Descriptions_extensions; DROP TABLE Descriptions; DROP TABLE Prefixes; DROP TABLE Languages; DROP TABLE Extlangs; DROP TABLE Scripts; DROP TABLE Regions; DROP TABLE Variants; DROP TABLE Extensions; DROP AGGREGATE concatenate(text); CREATE TABLE Scripts ( id SERIAL PRIMARY KEY NOT NULL, code TEXT UNIQUE NOT NULL, -- TODO: a length and content constraint? added DATE, deprecated DATE, comments TEXT); CREATE TABLE Languages ( id SERIAL PRIMARY KEY NOT NULL, code TEXT UNIQUE NOT NULL, -- TODO: a length and content constraint? suppressscript TEXT REFERENCES Scripts(code), preferredvalue TEXT, -- Yes, it should REFERENCES Languages(code), but -- there is a chicken-and-egg problem. added DATE, deprecated DATE, comments TEXT); CREATE TABLE Extlangs ( id SERIAL PRIMARY KEY NOT NULL, code TEXT UNIQUE NOT NULL, -- TODO: a length and content constraint? added DATE, prefix TEXT, -- references Languages(code)? Can a prefix be longer (a language and a script, for instance)? comments TEXT); CREATE TABLE Regions ( id SERIAL PRIMARY KEY NOT NULL, code TEXT UNIQUE NOT NULL, -- TODO: a length and content constraint? added DATE, deprecated DATE, comments TEXT); CREATE TABLE Variants ( id SERIAL PRIMARY KEY NOT NULL, code TEXT UNIQUE NOT NULL, -- TODO: a length and content constraint? -- TODO: prefixes added DATE, deprecated DATE, comments TEXT); CREATE TABLE Extensions ( id SERIAL PRIMARY KEY NOT NULL, code TEXT UNIQUE NOT NULL, -- TODO: a length and content constraint? added DATE, comments TEXT); CREATE TABLE Descriptions ( id SERIAL PRIMARY KEY NOT NULL, description TEXT NOT NULL); CREATE TABLE Descriptions_Languages ( description INTEGER NOT NULL REFERENCES Descriptions(id), lang TEXT NOT NULL REFERENCES Languages(code)); CREATE TABLE Descriptions_Extlangs ( description INTEGER NOT NULL REFERENCES Descriptions(id), extlang TEXT NOT NULL REFERENCES Extlangs(code)); CREATE TABLE Descriptions_Scripts ( description INTEGER NOT NULL REFERENCES Descriptions(id), script TEXT NOT NULL REFERENCES Scripts(code)); CREATE TABLE Descriptions_Regions ( description INTEGER NOT NULL REFERENCES Descriptions(id), region TEXT NOT NULL REFERENCES Regions(code)); CREATE TABLE Descriptions_Variants ( description INTEGER NOT NULL REFERENCES Descriptions(id), variant TEXT NOT NULL REFERENCES Variants(code)); CREATE TABLE Prefixes ( variant TEXT NOT NULL REFERENCES Variants(code), prefix TEXT NOT NULL REFERENCES Languages(code) ); CREATE OR REPLACE FUNCTION concat2(text, text) RETURNS text AS ' SELECT CASE WHEN $1 IS NULL OR $1 = '''' THEN $2 WHEN $2 IS NULL OR $2 = '''' THEN $1 ELSE $1 || '' / '' || $2 END; ' LANGUAGE SQL; CREATE AGGREGATE concatenate ( sfunc = concat2, basetype = text, stype = text, initcond = '' ); CREATE VIEW Languages_with_all_descr AS SELECT l.code, l.added, l.suppressscript, d.description FROM languages l,descriptions d,descriptions_languages WHERE descriptions_languages.lang = l.code AND descriptions_languages.description = d.id; CREATE VIEW Languages_with_descr AS SELECT l.code, l.added, l.suppressscript, concatenate(d.description) as description FROM languages l, descriptions d, descriptions_languages WHERE descriptions_languages.lang = l.code AND descriptions_languages.description = d.id GROUP BY l.code, l.added, l.suppressscript; CREATE VIEW Variants_with_all_descr AS SELECT v.code, v.added, d.description FROM variants v,descriptions d,descriptions_variants WHERE descriptions_variants.variant = v.code AND descriptions_variants.description = d.id; CREATE VIEW Variants_with_descr AS SELECT v.code, v.added, concatenate(d.description) as description FROM variants v, descriptions d, descriptions_variants WHERE descriptions_variants.variant = v.code AND descriptions_variants.description = d.id GROUP BY v.code, v.added; CREATE VIEW Scripts_with_all_descr AS SELECT s.code, s.added, d.description FROM scripts s,descriptions d,descriptions_scripts WHERE descriptions_scripts.script = s.code AND descriptions_scripts.description = d.id; CREATE VIEW Scripts_with_descr AS SELECT s.code, s.added, concatenate(d.description) as description FROM scripts s, descriptions d, descriptions_scripts WHERE descriptions_scripts.script = s.code AND descriptions_scripts.description = d.id GROUP BY s.code, s.added; CREATE VIEW Regions_with_all_descr AS SELECT r.code, r.added, d.description FROM regions r,descriptions d,descriptions_regions WHERE descriptions_regions.region = r.code AND descriptions_regions.description = d.id; CREATE VIEW Regions_with_descr AS SELECT r.code, r.added, concatenate(d.description) as description FROM regions r, descriptions d, descriptions_regions WHERE descriptions_regions.region = r.code AND descriptions_regions.description = d.id GROUP BY r.code, r.added; CREATE VIEW Extlangs_with_all_descr AS SELECT l.code, l.added, d.description FROM extlangs l,descriptions d,descriptions_extlangs WHERE descriptions_extlangs.extlang = l.code AND descriptions_extlangs.description = d.id; CREATE VIEW Extlangs_with_descr AS SELECT l.code, l.added, concatenate(d.description) as description FROM extlangs l, descriptions d, descriptions_extlangs WHERE descriptions_extlangs.extlang = l.code AND descriptions_extlangs.description = d.id GROUP BY l.code, l.added; -- You can get all the records with stuff like: -- select 'language', code, added from languages where added > '2005-10-16' union select 'script', code, added from scripts where added > '2005-10-16';