comparison flys-artifacts/doc/conf/datacage.sql @ 3818:dc18457b1cef

merged flys-artifacts/pre2.7-2012-03-16
author Thomas Arendsen Hein <thomas@intevation.de>
date Fri, 28 Sep 2012 12:14:59 +0200
parents a007a4368768
children 1071aacd042c
comparison
equal deleted inserted replaced
2456:60ab1054069d 3818:dc18457b1cef
1 BEGIN;
2
3 CREATE SEQUENCE USERS_ID_SEQ;
4
5 CREATE TABLE users (
6 id INT PRIMARY KEY NOT NULL,
7 gid UUID NOT NULL UNIQUE
8 );
9
10 CREATE SEQUENCE COLLECTIONS_ID_SEQ;
11
12 CREATE TABLE collections (
13 id INT PRIMARY KEY NOT NULL,
14 gid UUID NOT NULL UNIQUE,
15 user_id INT NOT NULL REFERENCES users(id) ON DELETE CASCADE,
16 name VARCHAR(256) NOT NULL,
17 creation TIMESTAMP NOT NULL
18 );
19
20 CREATE SEQUENCE ARTIFACTS_ID_SEQ;
21
22 CREATE TABLE artifacts (
23 id INT PRIMARY KEY NOT NULL,
24 gid UUID NOT NULL UNIQUE,
25 state VARCHAR(256) NOT NULL,
26 creation TIMESTAMP NOT NULL
27 );
28
29 CREATE SEQUENCE COLLECTION_ITEMS_ID_SEQ;
30
31 CREATE TABLE collection_items (
32 id INT PRIMARY KEY NOT NULL,
33 collection_id INT NOT NULL REFERENCES collections(id) ON DELETE CASCADE,
34 artifact_id INT NOT NULL REFERENCES artifacts(id) ON DELETE CASCADE
35 );
36
37 CREATE SEQUENCE ARTIFACT_DATA_ID_SEQ;
38
39 CREATE TABLE artifact_data (
40 id INT PRIMARY KEY NOT NULL,
41 artifact_id INT NOT NULL REFERENCES artifacts(id) ON DELETE CASCADE,
42 kind VARCHAR(256) NOT NULL,
43 k VARCHAR(256) NOT NULL,
44 v VARCHAR(256), -- Maybe too short
45 UNIQUE (artifact_id, k)
46 );
47
48 CREATE SEQUENCE OUTS_ID_SEQ;
49
50 CREATE TABLE outs (
51 id INT PRIMARY KEY NOT NULL,
52 artifact_id INT NOT NULL REFERENCES artifacts(id) ON DELETE CASCADE,
53 name VARCHAR(256) NOT NULL,
54 description VARCHAR(256),
55 out_type VARCHAR(256)
56 );
57
58 CREATE SEQUENCE FACETS_ID_SEQ;
59
60 CREATE TABLE facets (
61 id INT PRIMARY KEY NOT NULL,
62 out_id INT NOT NULL REFERENCES outs(id) ON DELETE CASCADE,
63 name VARCHAR(256) NOT NULL,
64 num INT NOT NULL,
65 state VARCHAR(256) NOT NULL,
66 description VARCHAR(256),
67 UNIQUE (out_id, num, name)
68 );
69
70 CREATE VIEW master_artifacts AS
71 SELECT a2.id AS id,
72 a2.gid AS gid,
73 a2.state AS state,
74 a2.creation AS creation,
75 ci2.collection_id AS collection_id
76 FROM collection_items ci2
77 JOIN artifacts a2
78 ON ci2.artifact_id = a2.id
79 JOIN (SELECT ci.collection_id AS c_id,
80 MIN(a.creation) AS oldest_a
81 FROM collection_items ci
82 JOIN artifacts a
83 ON ci.artifact_id = a.id
84 GROUP BY ci.collection_id) o
85 ON o.c_id = ci2.collection_id
86 WHERE a2.creation = o.oldest_a;
87
88 -- DROP VIEW master_artifacts;
89 -- DROP SEQUENCE USERS_ID_SEQ;
90 -- DROP SEQUENCE COLLECTIONS_ID_SEQ;
91 -- DROP SEQUENCE ARTIFACTS_ID_SEQ;
92 -- DROP SEQUENCE COLLECTION_ITEMS_ID_SEQ;
93 -- DROP SEQUENCE ARTIFACT_DATA_ID_SEQ;
94 -- DROP SEQUENCE OUTS_ID_SEQ;
95 -- DROP SEQUENCE FACETS_ID_SEQ;
96 -- DROP TABLE facets;
97 -- DROP TABLE outs;
98 -- DROP TABLE artifact_data;
99 -- DROP TABLE collection_items;
100 -- DROP TABLE collections;
101 -- DROP TABLE artifacts;
102 -- DROP TABLE users;
103
104 COMMIT;

http://dive4elements.wald.intevation.org