Project

General

Profile

1
DROP VIEW organizations_view;
2

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

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

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

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

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

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

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

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

    
60
CREATE VIEW organizations_view AS SELECT
61
    org.id,
62
    org.name,
63
    org.lat,
64
	org.lng,
65
	org.city,
66
	org.country,
67
	org.source,
68
	COALESCE(jsonb_agg(DISTINCT jsonb_build_object('id', oid.otherid, 'type', oid.type))                                    FILTER (WHERE oid.otherid IS NOT NULL), '[]') AS other_ids,
69
	COALESCE(jsonb_agg(DISTINCT jsonb_build_object('name',          n.name, 'lang', n.lang))                                FILTER (WHERE n.name      IS NOT NULL), '[]') AS other_names,
70
	COALESCE(jsonb_agg(DISTINCT jsonb_build_object('related_to_id', r.id2,  'type', r.reltype, 'related_to_name', ro.name)) FILTER (WHERE r.id2       IS NOT NULL), '[]') AS relations,
71
	COALESCE(jsonb_agg(DISTINCT a.acronym)                                                                                  FILTER (WHERE a.acronym   IS NOT NULL), '[]') AS acronyms,	
72
	COALESCE(jsonb_agg(DISTINCT t.type)                                                                                     FILTER (WHERE t.type      IS NOT NULL), '[]') AS types,
73
	COALESCE(jsonb_agg(DISTINCT u.url)                                                                                      FILTER (WHERE u.url       IS NOT NULL), '[]') AS urls
74
FROM
75
    organizations org
76
    LEFT OUTER JOIN other_ids oid    ON (org.id = oid.id)
77
    LEFT OUTER JOIN other_names n    ON (org.id = n.id)
78
    LEFT OUTER JOIN relationships r  ON (org.id = r.id1)
79
    LEFT OUTER JOIN organizations ro ON (ro.id  = r.id2)
80
    LEFT OUTER JOIN acronyms a       ON (org.id = a.id)
81
    LEFT OUTER JOIN types t          ON (org.id = t.id)
82
    LEFT OUTER JOIN urls u           ON (org.id = u.id)
83
GROUP BY
84
    org.id,
85
    org.name,
86
    org.lat,
87
	org.lng,
88
	org.city,
89
	org.country,
90
	org.source;
91
	
92
	
(2-2/2)