Project

General

Profile

1
DROP VIEW organizations_view;
2
DROP VIEW organizations_simple_view;
3
DROP VIEW users_view;
4
DROP VIEW warnings_view;
5

    
6
DROP TABLE IF EXISTS other_ids;
7
DROP TABLE IF EXISTS other_names;
8
DROP TABLE IF EXISTS acronyms;
9
DROP TABLE IF EXISTS relationships;
10
DROP TABLE IF EXISTS urls;
11
DROP TABLE IF EXISTS openaire_simrels;
12
DROP TABLE IF EXISTS organizations;
13
DROP TABLE IF EXISTS org_types;
14

    
15
DROP TABLE IF EXISTS user_countries;
16
DROP TABLE IF EXISTS users;
17

    
18
DROP TABLE IF EXISTS user_roles;
19
DROP TABLE IF EXISTS countries;
20
DROP TABLE IF EXISTS id_types;
21
DROP TABLE IF EXISTS languages;
22

    
23
DROP SEQUENCE IF EXISTS organizations_id_seq;
24

    
25
CREATE TABLE org_types (val text PRIMARY KEY);
26
INSERT INTO org_types VALUES ('Archive'), ('Company'), ('Education'), ('Facility'), ('Government'), ('Healthcare'), ('Nonprofit'), ('Other'), ('UNKNOWN');
27

    
28
CREATE TABLE id_types (val text PRIMARY KEY);
29
INSERT INTO id_types VALUES ('CNRS'), ('FundRef'), ('HESA'), ('ISNI'), ('OrgRef'), ('UCAS'), ('UKPRN'), ('Wikidata'), ('grid.ac');
30

    
31
CREATE TABLE languages (val text PRIMARY KEY);
32
INSERT INTO languages VALUES ('UNKNOWN'), ('aa'), ('af'), ('am'), ('ar'), ('as'), ('az'), ('ba'), ('be'), ('bg'), ('bn'), ('br'), ('bs'), ('ca'), ('ch'), ('co'), ('cs'), ('cy'), ('da'),
33
			('de'), ('dv'), ('dz'), ('el'), ('en'), ('eo'), ('es'), ('et'), ('eu'), ('fa'), ('fi'), ('fr'), ('fy'), ('ga'), ('gd'), ('gl'), ('gu'), ('he'), ('hi'), ('hr'), ('hu'), ('hy'), ('id'), ('is'),
34
			('it'), ('iu'), ('ja'), ('jv'), ('ka'), ('kk'), ('kl'), ('km'), ('kn'), ('ko'), ('ku'), ('ky'), ('la'), ('lb'), ('lo'), ('lt'), ('lv'), ('mg'), ('mi'), ('mk'), ('ml'), ('mn'), ('mr'), ('ms'),
35
			('mt'), ('my'), ('nb'), ('ne'), ('nl'), ('nn'), ('no'), ('oc'), ('or'), ('pa'), ('pl'), ('ps'), ('pt'), ('rm'), ('ro'), ('ru'), ('rw'), ('sa'), ('sd'), ('si'), ('sk'), ('sl'), ('so'), ('sq'),
36
			('sr'), ('sv'), ('sw'), ('ta'), ('te'), ('tg'), ('th'), ('tk'), ('tl'), ('tr'), ('tt'), ('ug'), ('uk'), ('ur'), ('uz'), ('vi'), ('xh'), ('yo'), ('zh'), ('zu');
37

    
38
CREATE TABLE countries (val text PRIMARY KEY);
39
INSERT INTO countries VALUES ('UNKNOWN'), ('AD'), ('AE'), ('AF'), ('AG'), ('AL'), ('AM'), ('AO'), ('AR'), ('AT'), ('AU'), ('AW'), ('AX'), ('AZ'), ('BA'), ('BB'), ('BD'), ('BE'), ('BF'), ('BG'), ('BH'), ('BI'),
40
			('BJ'), ('BM'), ('BN'), ('BO'), ('BQ'), ('BR'), ('BS'), ('BT'), ('BW'), ('BY'), ('BZ'), ('CA'), ('CD'), ('CF'), ('CG'), ('CH'), ('CI'), ('CL'), ('CM'), ('CN'), ('CO'), ('CR'),
41
			('CU'), ('CV'), ('CW'), ('CY'), ('CZ'), ('DE'), ('DJ'), ('DK'), ('DM'), ('DO'), ('DZ'), ('EC'), ('EE'), ('EG'), ('EH'), ('ER'), ('ES'), ('ET'), ('FI'), ('FJ'), ('FM'), ('FO'),
42
			('FR'), ('GA'), ('GB'), ('GD'), ('GE'), ('GF'), ('GH'), ('GI'), ('GL'), ('GM'), ('GN'), ('GP'), ('GQ'), ('GR'), ('GT'), ('GW'), ('GY'), ('HN'), ('HR'), ('HT'), ('HU'), ('ID'),
43
			('IE'), ('IL'), ('IM'), ('IN'), ('IQ'), ('IR'), ('IS'), ('IT'), ('JE'), ('JM'), ('JO'), ('JP'), ('KE'), ('KG'), ('KH'), ('KN'), ('KP'), ('KR'), ('KW'), ('KY'), ('KZ'), ('LA'),
44
			('LB'), ('LC'), ('LI'), ('LK'), ('LR'), ('LS'), ('LT'), ('LU'), ('LV'), ('LY'), ('MA'), ('MC'), ('MD'), ('ME'), ('MG'), ('MK'), ('ML'), ('MM'), ('MN'), ('MO'), ('MQ'), ('MR'),
45
			('MS'), ('MT'), ('MU'), ('MV'), ('MW'), ('MX'), ('MY'), ('MZ'), ('NA'), ('NC'), ('NE'), ('NG'), ('NI'), ('NL'), ('NO'), ('NP'), ('NU'), ('NZ'), ('OM'), ('PA'), ('PE'), ('PF'),
46
			('PG'), ('PH'), ('PK'), ('PL'), ('PS'), ('PT'), ('PW'), ('PY'), ('QA'), ('RE'), ('RO'), ('RS'), ('RU'), ('RW'), ('SA'), ('SB'), ('SC'), ('SD'), ('SE'), ('SG'), ('SI'), ('SJ'),
47
			('SK'), ('SL'), ('SM'), ('SN'), ('SO'), ('SR'), ('SS'), ('ST'), ('SV'), ('SX'), ('SY'), ('SZ'), ('TC'), ('TD'), ('TG'), ('TH'), ('TJ'), ('TL'), ('TM'), ('TN'), ('TO'), ('TR'),
48
			('TT'), ('TV'), ('TW'), ('TZ'), ('UA'), ('UG'), ('US'), ('UY'), ('UZ'), ('VA'), ('VC'), ('VE'), ('VG'), ('VN'), ('WS'), ('XK'), ('YE'), ('ZA'), ('ZM'), ('ZW');
49

    
50
CREATE TABLE user_roles(role text PRIMARY KEY);
51
INSERT INTO user_roles VALUES ('USER'), ('SUPERUSER'), ('PENDING');
52

    
53
CREATE TABLE users (
54
	email     text PRIMARY KEY,
55
	password  text NOT NULL,
56
	valid     boolean DEFAULT true,
57
	role      text NOT NULL default 'USER' REFERENCES user_roles(role)
58
);
59

    
60
CREATE TABLE user_countries (
61
	email     text REFERENCES users(email),
62
	country   text  REFERENCES countries(val),
63
	PRIMARY KEY(email, country)	
64
);
65

    
66
CREATE SEQUENCE organizations_id_seq;
67

    
68
CREATE TABLE organizations (
69
    id                text PRIMARY KEY DEFAULT 'openorgs____::'||lpad(nextval('organizations_id_seq')::text,10,'0'),
70
    name              text,
71
   	type              text NOT NULL DEFAULT 'UNKNOWN' REFERENCES org_types(val),
72
    lat               double precision,
73
	lng               double precision,
74
	city              text,
75
	country           text REFERENCES countries(val),
76
	created_by        text,
77
	creation_date     timestamp with time zone DEFAULT now(),
78
	modified_by       text,
79
	modification_date timestamp with time zone DEFAULT now()
80
);
81
CREATE INDEX organizations_type_idx ON organizations(type);
82
CREATE INDEX organizations_country_idx ON organizations(country);
83

    
84
CREATE TABLE other_ids (
85
	id      text REFERENCES organizations(id) ON UPDATE CASCADE,
86
	otherid text,
87
	type    text REFERENCES id_types(val),
88
	PRIMARY KEY (id, otherid, type)
89
);
90
CREATE INDEX other_ids_id_idx ON other_ids(id);
91

    
92
CREATE TABLE other_names (
93
	id    text REFERENCES organizations(id) ON UPDATE CASCADE,
94
	name  text,
95
	lang  text REFERENCES languages(val),
96
	PRIMARY KEY (id, name, lang)
97
);
98
CREATE INDEX other_names_id_idx ON other_names(id);
99

    
100
CREATE TABLE acronyms (
101
	id text  REFERENCES organizations(id) ON UPDATE CASCADE,
102
	acronym text,
103
	PRIMARY KEY (id, acronym)
104
);
105
CREATE INDEX acronyms_id_idx ON acronyms(id);
106

    
107
CREATE TABLE relationships (
108
	id1     text REFERENCES organizations(id) ON UPDATE CASCADE,
109
	reltype text,
110
	id2     text REFERENCES organizations(id) ON UPDATE CASCADE,
111
    PRIMARY KEY (id1, reltype, id2)
112
);
113
CREATE INDEX relationships_id1_idx ON relationships(id1);
114
CREATE INDEX relationships_id2_idx ON relationships(id2);
115

    
116
CREATE TABLE urls (
117
	id  text REFERENCES organizations(id) ON UPDATE CASCADE,
118
	url text,
119
	PRIMARY KEY (id, url)
120
);
121
CREATE INDEX urls_id_idx ON urls(id);
122

    
123
CREATE TABLE openaire_simrels (
124
	local_id         text REFERENCES organizations(id) ON UPDATE CASCADE,
125
	oa_original_id   text NOT NULL,
126
	oa_name          text NOT NULL,
127
	oa_acronym       text,
128
	oa_country       text,
129
	oa_url           text,
130
	oa_collectedfrom text,
131
	reltype          text NOT NULL DEFAULT 'suggested',
132
	PRIMARY KEY (local_id, oa_original_id)
133
);
134
CREATE INDEX openaire_simrels_local_id_idx ON openaire_simrels(local_id);
135

    
136
CREATE VIEW organizations_view AS SELECT
137
    org.id,
138
    org.name,
139
    org.type,
140
    org.lat,
141
	org.lng,
142
	org.city,
143
	org.country,
144
	org.created_by,
145
	org.creation_date,
146
	org.modified_by,
147
	org.modification_date,
148
	COALESCE(jsonb_agg(DISTINCT jsonb_build_object('id', oid.otherid, 'type', oid.type)) FILTER (WHERE oid.otherid IS NOT NULL), '[]') AS other_ids,
149
	COALESCE(jsonb_agg(DISTINCT jsonb_build_object('name', n.name, 'lang', n.lang))      FILTER (WHERE n.name      IS NOT NULL), '[]') AS other_names,
150
	COALESCE(jsonb_agg(DISTINCT a.acronym)                                               FILTER (WHERE a.acronym   IS NOT NULL), '[]') AS acronyms,	
151
	COALESCE(jsonb_agg(DISTINCT u.url)                                                   FILTER (WHERE u.url       IS NOT NULL), '[]') AS urls
152
FROM
153
    organizations org
154
    LEFT OUTER JOIN other_ids oid    ON (org.id = oid.id)
155
    LEFT OUTER JOIN other_names n    ON (org.id = n.id)
156
    LEFT OUTER JOIN acronyms a       ON (org.id = a.id)
157
    LEFT OUTER JOIN urls u           ON (org.id = u.id)
158
GROUP BY
159
    org.id,
160
    org.name,
161
    org.type,
162
    org.lat,
163
	org.lng,
164
	org.city,
165
	org.country,
166
	org.created_by,
167
	org.creation_date,
168
	org.modified_by,
169
	org.modification_date;
170
	
171
CREATE VIEW organizations_simple_view AS SELECT
172
    org.id,
173
    org.name,
174
    org.type,
175
	org.city,
176
	org.country,
177
	array_agg(DISTINCT a.acronym) FILTER (WHERE a.acronym IS NOT NULL) AS acronyms
178
FROM
179
    organizations org
180
    LEFT OUTER JOIN acronyms a ON (org.id = a.id)
181
GROUP BY
182
    org.id,
183
    org.name,
184
    org.type,
185
	org.city,
186
	org.country;
187
	
188
CREATE VIEW	users_view AS SELECT
189
	u.email,
190
	u.valid,
191
	u.role,
192
	array_agg(uc.country) FILTER (WHERE uc.country IS NOT NULL) AS countries
193
FROM
194
	users u
195
	LEFT OUTER JOIN user_countries uc ON (u.email = uc.email)
196
GROUP BY u.email, u.valid, u.role
197
ORDER BY u.email;
198

    
199
CREATE VIEW warnings_view AS SELECT
200
    o1.id      AS id_1,
201
    o1.name    AS name_1,
202
    o1.type    AS type_1,
203
	o1.city    AS city_1,
204
	o1.country AS country_1,
205
    o2.id      AS id_2,
206
    o2.name    AS name_2,
207
    o2.type    AS type_2,
208
	o2.city    AS city_2,
209
	o2.country AS country_2
210
FROM
211
	openaire_simrels s
212
	LEFT OUTER JOIN organizations o1 ON (s.local_id = o1.id)
213
    LEFT OUTER JOIN organizations o2 ON (s.oa_original_id = o2.id)
214
WHERE
215
	s.oa_original_id LIKE 'openorgs____::%' AND o1.id IS NOT NULL AND O2.id IS NOT NULL;
216
	
217

    
218

    
219
	
(4-4/4)