Project

General

Profile

1
DROP VIEW organizations_view;
2
DROP VIEW organizations_simple_view;
3

    
4
DROP TABLE IF EXISTS other_ids;
5
DROP TABLE IF EXISTS other_names;
6
DROP TABLE IF EXISTS acronyms;
7
DROP TABLE IF EXISTS relationships;
8
DROP TABLE IF EXISTS types;
9
DROP TABLE IF EXISTS urls;
10
DROP TABLE IF EXISTS organizations;
11

    
12
CREATE TABLE organizations (
13
    id      text PRIMARY KEY,
14
    name    text,
15
    lat     double precision,
16
	lng     double precision,
17
	city    text,
18
	country text,
19
	source  text
20
);
21

    
22
CREATE TABLE other_ids (
23
	id      text REFERENCES organizations(id),
24
	otherid text,
25
	type    text,
26
	PRIMARY KEY (id, otherid, type)
27
);
28

    
29
CREATE TABLE other_names (
30
	id    text REFERENCES organizations(id),
31
	name  text,
32
	lang  text DEFAULT '',
33
	PRIMARY KEY (id, name, lang)
34
);
35

    
36
CREATE TABLE acronyms (
37
	id text,
38
	acronym text,
39
	PRIMARY KEY (id, acronym)
40
);
41

    
42
CREATE TABLE relationships (
43
	id1     text REFERENCES organizations(id),
44
	reltype text,
45
	id2     text REFERENCES organizations(id),
46
    PRIMARY KEY (id1, reltype, id2)
47
);
48

    
49
CREATE TABLE types (
50
	id   text REFERENCES organizations(id),
51
	type text,
52
	PRIMARY KEY (id, type)
53
);
54

    
55
CREATE TABLE urls (
56
	id  text REFERENCES organizations(id),
57
	url text,
58
	PRIMARY KEY (id, url)
59
);
60

    
61
CREATE VIEW organizations_view AS SELECT
62
    org.id,
63
    org.name,
64
    org.lat,
65
	org.lng,
66
	org.city,
67
	org.country,
68
	org.source,
69
	COALESCE(jsonb_agg(DISTINCT jsonb_build_object('id', oid.otherid, 'type', oid.type))                                   FILTER (WHERE oid.otherid IS NOT NULL), '[]') AS other_ids,
70
	COALESCE(jsonb_agg(DISTINCT jsonb_build_object('name',          n.name, 'lang', n.lang))                               FILTER (WHERE n.name      IS NOT NULL), '[]') AS other_names,
71
	COALESCE(jsonb_agg(DISTINCT jsonb_build_object('relatedOrgId',  r.id2,  'type', r.reltype, 'relatedOrgName', ro.name)) FILTER (WHERE r.id2       IS NOT NULL), '[]') AS relations,
72
	COALESCE(jsonb_agg(DISTINCT a.acronym)                                                                                 FILTER (WHERE a.acronym   IS NOT NULL), '[]') AS acronyms,	
73
	COALESCE(jsonb_agg(DISTINCT t.type)                                                                                    FILTER (WHERE t.type      IS NOT NULL), '[]') AS types,
74
	COALESCE(jsonb_agg(DISTINCT u.url)                                                                                     FILTER (WHERE u.url       IS NOT NULL), '[]') AS urls
75
FROM
76
    organizations org
77
    LEFT OUTER JOIN other_ids oid    ON (org.id = oid.id)
78
    LEFT OUTER JOIN other_names n    ON (org.id = n.id)
79
    LEFT OUTER JOIN relationships r  ON (org.id = r.id1)
80
    LEFT OUTER JOIN organizations ro ON (ro.id  = r.id2)
81
    LEFT OUTER JOIN acronyms a       ON (org.id = a.id)
82
    LEFT OUTER JOIN types t          ON (org.id = t.id)
83
    LEFT OUTER JOIN urls u           ON (org.id = u.id)
84
GROUP BY
85
    org.id,
86
    org.name,
87
    org.lat,
88
	org.lng,
89
	org.city,
90
	org.country,
91
	org.source;
92
	
93
CREATE VIEW organizations_simple_view AS SELECT
94
    org.id,
95
    org.name,
96
	org.city,
97
	org.country,
98
	array_agg(DISTINCT a.acronym) FILTER (WHERE a.acronym IS NOT NULL) AS acronyms,	
99
	array_agg(DISTINCT t.type)    FILTER (WHERE t.type    IS NOT NULL) AS types
100
FROM
101
    organizations org
102
    LEFT OUTER JOIN acronyms a       ON (org.id = a.id)
103
    LEFT OUTER JOIN types t          ON (org.id = t.id)
104
GROUP BY
105
    org.id,
106
    org.name,
107
	org.city,
108
	org.country;
109
	
110
	
(2-2/2)