view flys-artifacts/doc/conf/datacage.sql @ 3785:a5f65e8983be

Merged revisions 5501-5502,5504-5508,5511-5513,5516-5519 via svnmerge from file:///home/clients/bsh/bsh-generischer-viewer/Material/SVN/flys-artifacts/trunk ........ r5501 | felix | 2012-09-18 11:49:45 +0200 (Di, 18 Sep 2012) | 1 line fix issue865 - missing showarea theme prop. ........ r5502 | clins | 2012-09-18 12:18:30 +0200 (Di, 18 Sep 2012) | 1 line Add robustness checks to prevent NPEs ........ r5504 | felix | 2012-09-18 14:03:15 +0200 (Di, 18 Sep 2012) | 1 line i18n for area label (fix issue487). ........ r5505 | clins | 2012-09-18 16:19:59 +0200 (Di, 18 Sep 2012) | 1 line Update themes to show point descriptions ........ r5506 | rrenkert | 2012-09-18 17:00:30 +0200 (Di, 18 Sep 2012) | 3 lines Removed incorrect characteristic diameter. ........ r5507 | rrenkert | 2012-09-18 17:03:20 +0200 (Di, 18 Sep 2012) | 3 lines Fixed some stupid bugs in bed quality data factory and calculation. ........ r5508 | teichmann | 2012-09-18 17:45:49 +0200 (Di, 18 Sep 2012) | 1 line The usual whitespace and import cleanups. ........ r5511 | teichmann | 2012-09-18 18:24:51 +0200 (Di, 18 Sep 2012) | 1 line Use generics aware Collections.emptyList(). ........ r5512 | teichmann | 2012-09-18 20:36:52 +0200 (Di, 18 Sep 2012) | 1 line Some more little steps towards "Auslagerung extremer Wasserspiegellagen". ........ r5513 | clins | 2012-09-18 23:38:19 +0200 (Di, 18 Sep 2012) | 1 line A and B facets of fix analyis are now deactivated by default ........ r5516 | bricks | 2012-09-19 10:45:51 +0200 (Mi, 19 Sep 2012) | 2 lines Add the gauge station to the GaugeOverviewInfoService xml response ........ r5517 | rrenkert | 2012-09-19 10:50:23 +0200 (Mi, 19 Sep 2012) | 3 lines Added CSV export to bed quality calculation. ........ r5518 | bricks | 2012-09-19 11:04:04 +0200 (Mi, 19 Sep 2012) | 2 lines Fix date in changelog entry ........ r5519 | teichmann | 2012-09-19 11:17:14 +0200 (Mi, 19 Sep 2012) | 1 line Removed trailing whitespace. ........ flys-artifacts/tags/2.9.1@5531 c6561f87-3c4e-4783-a992-168aeb5c3f6f
author Ingo Weinzierl <ingo.weinzierl@intevation.de>
date Wed, 19 Sep 2012 14:58:31 +0000
parents a007a4368768
children 1071aacd042c
line wrap: on
line source
BEGIN;

CREATE SEQUENCE USERS_ID_SEQ;

CREATE TABLE users (
    id  INT  PRIMARY KEY NOT NULL,
    gid UUID             NOT NULL UNIQUE
);

CREATE SEQUENCE COLLECTIONS_ID_SEQ;

CREATE TABLE collections (
    id       INT  PRIMARY KEY NOT NULL,
    gid      UUID             NOT NULL UNIQUE,
    user_id  INT              NOT NULL REFERENCES users(id) ON DELETE CASCADE,
    name     VARCHAR(256)     NOT NULL,
    creation TIMESTAMP        NOT NULL
);

CREATE SEQUENCE ARTIFACTS_ID_SEQ;

CREATE TABLE artifacts (
    id       INT  PRIMARY KEY NOT NULL,
    gid      UUID             NOT NULL UNIQUE,
    state    VARCHAR(256)     NOT NULL,
    creation TIMESTAMP        NOT NULL
);

CREATE SEQUENCE COLLECTION_ITEMS_ID_SEQ;

CREATE TABLE collection_items (
    id            INT PRIMARY KEY NOT NULL,
    collection_id INT             NOT NULL REFERENCES collections(id) ON DELETE CASCADE,
    artifact_id   INT             NOT NULL REFERENCES artifacts(id)   ON DELETE CASCADE
);

CREATE SEQUENCE ARTIFACT_DATA_ID_SEQ;

CREATE TABLE artifact_data (
    id          INT PRIMARY KEY NOT NULL,
    artifact_id INT             NOT NULL REFERENCES artifacts(id) ON DELETE CASCADE,
    kind        VARCHAR(256)    NOT NULL,
    k           VARCHAR(256)    NOT NULL,
    v           VARCHAR(256),   -- Maybe too short
    UNIQUE (artifact_id, k)
);

CREATE SEQUENCE OUTS_ID_SEQ;

CREATE TABLE outs (
    id          INT PRIMARY KEY NOT NULL,
    artifact_id INT             NOT NULL REFERENCES artifacts(id) ON DELETE CASCADE,
    name        VARCHAR(256)    NOT NULL,
    description VARCHAR(256),
    out_type    VARCHAR(256)
);

CREATE SEQUENCE FACETS_ID_SEQ;

CREATE TABLE facets (
    id          INT PRIMARY KEY NOT NULL,
    out_id      INT             NOT NULL REFERENCES outs(id) ON DELETE CASCADE,
    name        VARCHAR(256)    NOT NULL,
    num         INT             NOT NULL,
    state       VARCHAR(256)    NOT NULL,
    description VARCHAR(256),
    UNIQUE (out_id, num, name)
);

CREATE VIEW master_artifacts AS
    SELECT a2.id             AS id,
           a2.gid            AS gid,
           a2.state          AS state,
           a2.creation       AS creation,
           ci2.collection_id AS collection_id
    FROM   collection_items ci2 
           JOIN artifacts a2 
             ON ci2.artifact_id = a2.id 
           JOIN (SELECT ci.collection_id AS c_id, 
                        MIN(a.creation)  AS oldest_a 
                 FROM   collection_items ci 
                        JOIN artifacts a 
                          ON ci.artifact_id = a.id 
                 GROUP  BY ci.collection_id) o 
             ON o.c_id = ci2.collection_id 
    WHERE  a2.creation = o.oldest_a;

-- DROP VIEW master_artifacts;
-- DROP SEQUENCE USERS_ID_SEQ;
-- DROP SEQUENCE COLLECTIONS_ID_SEQ;
-- DROP SEQUENCE ARTIFACTS_ID_SEQ;
-- DROP SEQUENCE COLLECTION_ITEMS_ID_SEQ;
-- DROP SEQUENCE ARTIFACT_DATA_ID_SEQ;
-- DROP SEQUENCE OUTS_ID_SEQ;
-- DROP SEQUENCE FACETS_ID_SEQ;
-- DROP TABLE facets;
-- DROP TABLE outs;
-- DROP TABLE artifact_data;
-- DROP TABLE collection_items;
-- DROP TABLE collections;
-- DROP TABLE artifacts;
-- DROP TABLE users;

COMMIT;

http://dive4elements.wald.intevation.org