1
|
--
|
2
|
-- sqoopQL database dump
|
3
|
--
|
4
|
|
5
|
SET statement_timeout = 0;
|
6
|
SET client_encoding = 'UTF8';
|
7
|
SET standard_conforming_strings = on;
|
8
|
SET check_function_bodies = false;
|
9
|
SET client_min_messages = warning;
|
10
|
|
11
|
--
|
12
|
-- Name: shadow; Type: SCHEMA; Schema: -; Owner: sqoop
|
13
|
--
|
14
|
|
15
|
DROP SCHEMA IF EXISTS backup CASCADE;
|
16
|
|
17
|
--
|
18
|
-- Name: shadow; Type: SCHEMA; Schema: -; Owner: sqoop
|
19
|
--
|
20
|
DROP SCHEMA IF EXISTS shadow CASCADE;
|
21
|
CREATE SCHEMA shadow;
|
22
|
|
23
|
--ALTER SCHEMA shadow OWNER TO sqoop;
|
24
|
|
25
|
SET search_path = shadow, pg_catalog;
|
26
|
|
27
|
|
28
|
--
|
29
|
-- Name: concept; Type: TABLE; Schema: public; Owner: dnet; Tablespace:
|
30
|
--
|
31
|
|
32
|
CREATE TABLE shadow.concept (
|
33
|
id text NOT NULL,
|
34
|
name text ,
|
35
|
category text
|
36
|
);
|
37
|
|
38
|
|
39
|
|
40
|
--
|
41
|
-- Name: datasource; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
42
|
--
|
43
|
|
44
|
CREATE TABLE shadow.datasource (
|
45
|
id text NOT NULL,
|
46
|
name text ,
|
47
|
type text,
|
48
|
compatibility text,
|
49
|
latitude text,
|
50
|
longitude text,
|
51
|
dateofvalidation text,
|
52
|
yearofvalidation integer,
|
53
|
harvested TEXT DEFAULT 'false',
|
54
|
piwik_id integer
|
55
|
);
|
56
|
|
57
|
--
|
58
|
-- Name: datasource_languages; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
59
|
--
|
60
|
|
61
|
CREATE TABLE shadow.datasource_languages (
|
62
|
id text NOT NULL,
|
63
|
language text
|
64
|
);
|
65
|
|
66
|
--
|
67
|
-- Name: datasource_websites; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
68
|
--
|
69
|
|
70
|
CREATE TABLE shadow.datasource_websites (
|
71
|
id text NOT NULL,
|
72
|
website text
|
73
|
);
|
74
|
|
75
|
--
|
76
|
-- Name: datasource_organizations; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
77
|
--
|
78
|
|
79
|
--
|
80
|
CREATE TABLE shadow.datasource_organizations (
|
81
|
id text NOT NULL,
|
82
|
organization text NOT NULL
|
83
|
);
|
84
|
|
85
|
|
86
|
|
87
|
--
|
88
|
-- Name: result_datasources; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
89
|
--
|
90
|
|
91
|
CREATE TABLE shadow.result_datasources (
|
92
|
id text NOT NULL,
|
93
|
datasource text NOT NULL
|
94
|
);
|
95
|
|
96
|
|
97
|
|
98
|
--
|
99
|
-- Name: datasource_results; Type: VIEW; Schema: shadow; Owner: sqoop
|
100
|
--
|
101
|
|
102
|
--CREATE VIEW shadow.datasource_results AS
|
103
|
-- SELECT result_datasources.datasource AS id, result_datasources.id AS result FROM result_datasources;
|
104
|
|
105
|
--
|
106
|
-- Name: datasource_topics; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
107
|
-- Name: defaults; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
108
|
--
|
109
|
|
110
|
CREATE TABLE shadow.defaults (
|
111
|
tablename text NOT NULL,
|
112
|
xaxis text,
|
113
|
yaxis text,
|
114
|
agg text,
|
115
|
zaxis text,
|
116
|
type text,
|
117
|
tableorder integer NOT NULL
|
118
|
);
|
119
|
|
120
|
|
121
|
--
|
122
|
-- Name: category; Type: TABLE; Schema: public; Owner: dnet; Tablespace:
|
123
|
--
|
124
|
CREATE TABLE shadow.category (
|
125
|
id text NOT NULL,
|
126
|
name text,
|
127
|
context text
|
128
|
);
|
129
|
|
130
|
--
|
131
|
-- Name: claim; Type: TABLE; Schema: public; Owner: dnet; Tablespace:
|
132
|
--
|
133
|
|
134
|
CREATE TABLE shadow.claim (
|
135
|
id text NOT NULL,
|
136
|
date text ,
|
137
|
userid text
|
138
|
);
|
139
|
|
140
|
|
141
|
--
|
142
|
-- Name: context; Type: TABLE; Schema: public; Owner: dnet; Tablespace:
|
143
|
--
|
144
|
|
145
|
CREATE TABLE shadow.context (
|
146
|
id text NOT NULL,
|
147
|
name text
|
148
|
);
|
149
|
|
150
|
--
|
151
|
-- Name: organization; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
152
|
--
|
153
|
|
154
|
CREATE TABLE shadow.organization (
|
155
|
id text NOT NULL,
|
156
|
name text,
|
157
|
country text
|
158
|
);
|
159
|
|
160
|
|
161
|
|
162
|
--
|
163
|
-- Name: organization_datasources; Type: VIEW; Schema: shadow; Owner: sqoop
|
164
|
--
|
165
|
|
166
|
CREATE VIEW shadow.organization_datasources AS
|
167
|
SELECT datasource_organizations.organization AS id, datasource_organizations.id AS datasource FROM datasource_organizations;
|
168
|
|
169
|
--
|
170
|
-- Name: project_organizations; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
171
|
--
|
172
|
|
173
|
CREATE TABLE shadow.project_organizations (
|
174
|
id text NOT NULL,
|
175
|
organization text NOT NULL
|
176
|
);
|
177
|
|
178
|
|
179
|
--
|
180
|
-- Name: project_organizations; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
181
|
--
|
182
|
|
183
|
CREATE TABLE shadow.result_organizations (
|
184
|
id text NOT NULL,
|
185
|
organization text NOT NULL
|
186
|
);
|
187
|
|
188
|
|
189
|
--
|
190
|
-- Name: organization_projects; Type: VIEW; Schema: shadow; Owner: sqoop
|
191
|
--
|
192
|
|
193
|
CREATE VIEW shadow.organization_projects AS
|
194
|
SELECT project_organizations.id AS project, project_organizations.organization AS id FROM project_organizations;
|
195
|
|
196
|
--
|
197
|
-- Name: project; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
198
|
--
|
199
|
|
200
|
CREATE TABLE shadow.project (
|
201
|
id text NOT NULL,
|
202
|
acronym text ,
|
203
|
title text ,
|
204
|
funder text,
|
205
|
funding_lvl0 text,
|
206
|
funding_lvl1 text,
|
207
|
funding_lvl2 text,
|
208
|
funding_lvl3 text,
|
209
|
sc39 text,
|
210
|
type text,
|
211
|
start_year integer,
|
212
|
end_year integer,
|
213
|
duration integer,
|
214
|
haspubs text DEFAULT 'no'::text,
|
215
|
numpubs integer,
|
216
|
enddate text,
|
217
|
startdate text,
|
218
|
daysforlastpub integer,
|
219
|
delayedpubs integer,
|
220
|
callidentifier text,
|
221
|
code text
|
222
|
);
|
223
|
|
224
|
--
|
225
|
-- Name: result_projects; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
226
|
--
|
227
|
|
228
|
CREATE TABLE shadow.project_oids (
|
229
|
id text NOT NULL,
|
230
|
orid text
|
231
|
);
|
232
|
|
233
|
|
234
|
|
235
|
CREATE TABLE shadow.result_oids (
|
236
|
id text NOT NULL,
|
237
|
orid text
|
238
|
);
|
239
|
|
240
|
|
241
|
CREATE TABLE shadow.organization_oids (
|
242
|
id text NOT NULL,
|
243
|
orid text
|
244
|
);
|
245
|
|
246
|
|
247
|
CREATE TABLE shadow.datasource_oids (
|
248
|
id text NOT NULL,
|
249
|
orid text
|
250
|
);
|
251
|
|
252
|
-- CREATE TABLE shadow.person_oids (
|
253
|
-- id text NOT NULL,
|
254
|
-- orid text
|
255
|
-- );
|
256
|
|
257
|
|
258
|
CREATE TABLE shadow.project_keywords (
|
259
|
id text NOT NULL,
|
260
|
keyword text
|
261
|
);
|
262
|
|
263
|
|
264
|
CREATE TABLE shadow.project_subjects (
|
265
|
id text NOT NULL,
|
266
|
subject text
|
267
|
);
|
268
|
|
269
|
|
270
|
--ALTER TABLE shadow.result_projects OWNER TO sqoop;
|
271
|
|
272
|
CREATE TABLE shadow.project_results (
|
273
|
id text NOT NULL,
|
274
|
result text NOT NULL,
|
275
|
daysfromend integer
|
276
|
);
|
277
|
|
278
|
|
279
|
--
|
280
|
-- Name: result; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
281
|
--
|
282
|
|
283
|
CREATE TABLE shadow.result (
|
284
|
id text NOT NULL,
|
285
|
title text,
|
286
|
publisher text,
|
287
|
journal text,
|
288
|
year integer,
|
289
|
date text ,
|
290
|
-- access_mode text,
|
291
|
bestlicense text,
|
292
|
type text ,
|
293
|
embargo_end_date text,
|
294
|
delayed text,
|
295
|
authors integer,
|
296
|
source text,
|
297
|
abstract text
|
298
|
);
|
299
|
|
300
|
--
|
301
|
-- Name: result_extra; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
302
|
--
|
303
|
|
304
|
CREATE TABLE shadow.result_extra (
|
305
|
id text NOT NULL,
|
306
|
title text,
|
307
|
source text
|
308
|
);
|
309
|
|
310
|
--
|
311
|
-- Name: result_claims; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
312
|
--
|
313
|
|
314
|
CREATE TABLE shadow.result_claims (
|
315
|
id text NOT NULL,
|
316
|
claim text NOT NULL
|
317
|
);
|
318
|
|
319
|
CREATE TABLE shadow.result_citations (
|
320
|
id text NOT NULL,
|
321
|
result text NOT NULL
|
322
|
-- trust text,
|
323
|
-- provenance text,
|
324
|
-- citation text
|
325
|
);
|
326
|
|
327
|
|
328
|
--
|
329
|
-- Name: result_classifications; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
330
|
--
|
331
|
|
332
|
CREATE TABLE shadow.result_classifications (
|
333
|
id text NOT NULL,
|
334
|
type text NOT NULL
|
335
|
);
|
336
|
|
337
|
--
|
338
|
-- Name: result_concepts; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
339
|
--
|
340
|
|
341
|
CREATE TABLE shadow.result_concepts (
|
342
|
id text NOT NULL,
|
343
|
concept text NOT NULL
|
344
|
);
|
345
|
|
346
|
--
|
347
|
-- Name: result_languages; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
348
|
--
|
349
|
|
350
|
CREATE TABLE shadow.result_languages (
|
351
|
id text NOT NULL,
|
352
|
language text NOT NULL
|
353
|
);
|
354
|
|
355
|
|
356
|
--
|
357
|
-- Name: result_results; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
358
|
--
|
359
|
|
360
|
CREATE TABLE shadow.result_results (
|
361
|
id text NOT NULL,
|
362
|
result text NOT NULL
|
363
|
);
|
364
|
|
365
|
|
366
|
|
367
|
--
|
368
|
-- Name: result_topics; Type: TABLE; Schema: shadow; Owner: sqoop; Tablespace:
|
369
|
--
|
370
|
|
371
|
CREATE TABLE shadow.result_topics (
|
372
|
id text NOT NULL,
|
373
|
topic text
|
374
|
);
|
375
|
|
376
|
|
377
|
CREATE TABLE shadow.result_descriptions (
|
378
|
id text NOT NULL,
|
379
|
description text
|
380
|
);
|
381
|
|
382
|
CREATE TABLE shadow.result_pids (
|
383
|
id text NOT NULL,
|
384
|
type text ,
|
385
|
pid text
|
386
|
);
|
387
|
|
388
|
CREATE TABLE shadow.country (
|
389
|
code text NOT NULL,
|
390
|
name text,
|
391
|
continent_code text,
|
392
|
continent_name text
|
393
|
|
394
|
);
|
395
|
|
396
|
-----------
|
397
|
--functions
|
398
|
-----------
|
399
|
CREATE OR REPLACE FUNCTION shadow.extra_defaults_datasource() RETURNS void LANGUAGE plpgsql VOLATILE COST 100 AS $BODY$
|
400
|
BEGIN
|
401
|
|
402
|
INSERT INTO "shadow".datasource (id,name,type,compatibility) (SELECT 'other','Other','Repository','unknown' WHERE NOT EXISTS (SELECT 1 FROM "shadow".datasource WHERE name='Unknown Repository'));
|
403
|
UPDATE "shadow".datasource SET name='Other' where name='Unknown Repository';
|
404
|
UPDATE "shadow".result_datasources SET datasource=(SELECT id FROM "shadow".datasource WHERE name='Other') WHERE datasource NOT IN (SELECT id FROM "shadow".datasource);
|
405
|
|
406
|
TRUNCATE TABLE "shadow".defaults;
|
407
|
INSERT INTO "shadow".defaults VALUES ('result', 'year', 'number', 'count', '', 'column', 1);
|
408
|
INSERT INTO "shadow".defaults VALUES ('project', 'funding_lvl1', 'number', 'count', '', 'column', 2);
|
409
|
INSERT INTO "shadow".defaults VALUES ('organization', 'country', 'number', 'count', '', 'column', 3);
|
410
|
INSERT INTO "shadow".defaults VALUES ('datasource', 'oa_compatible', 'number', 'count', '', 'column', 4);
|
411
|
|
412
|
UPDATE "shadow".datasource SET yearofvalidation=null WHERE yearofvalidation='-1';
|
413
|
UPDATE shadow.datasource set harvested ='true' WHERE datasource.id IN (SELECT DISTINCT d.id FROM datasource d, result_datasources rd where d.id=rd.datasource);
|
414
|
END $BODY$;
|
415
|
|
416
|
ALTER FUNCTION shadow.extra_defaults_datasource() OWNER TO sqoop;
|
417
|
|
418
|
|
419
|
--
|
420
|
-- Project Results Extra Inserts
|
421
|
--
|
422
|
CREATE OR REPLACE FUNCTION shadow.update_project_results() RETURNS void LANGUAGE plpgsql VOLATILE COST 100 AS $BODY$
|
423
|
BEGIN
|
424
|
CREATE OR REPLACE VIEW shadow.project_results_publication AS
|
425
|
SELECT "shadow".result_projects.id AS result, "shadow".result_projects.project AS project_results, "shadow"."result"."date" as resultdate,
|
426
|
"shadow"."project"."enddate" as projectenddate, "shadow".result_projects.daysfromend as daysfromend
|
427
|
FROM "shadow".result_projects, "shadow".result, "shadow".project
|
428
|
where "shadow".result_projects.id="shadow".result.id and "shadow".result.type='publication' and "shadow".project.id= "shadow".result_projects.project;
|
429
|
END $BODY$;
|
430
|
|
431
|
ALTER FUNCTION shadow.update_project_results() OWNER TO sqoop;
|
432
|
|
433
|
|
434
|
|
435
|
--
|
436
|
-- Project Has Publications Extra Inserts
|
437
|
--
|
438
|
CREATE OR REPLACE FUNCTION shadow.project_has_pubs() RETURNS void LANGUAGE plpgsql VOLATILE COST 100 AS $BODY$
|
439
|
BEGIN
|
440
|
UPDATE shadow.project SET haspubs='yes' WHERE id IN (SELECT pr.id FROM shadow.project_results pr, shadow.result r WHERE pr.result=r.id AND r.type='publication');
|
441
|
END $BODY$;
|
442
|
|
443
|
ALTER FUNCTION shadow.project_has_pubs() OWNER TO sqoop;
|
444
|
|
445
|
|
446
|
--
|
447
|
-- Project Publications Count Updates
|
448
|
--
|
449
|
CREATE OR REPLACE FUNCTION shadow.project_pubs_count() RETURNS void LANGUAGE plpgsql VOLATILE COST 100 AS $BODY$
|
450
|
BEGIN
|
451
|
UPDATE shadow.project p SET numpubs=prr.np FROM (SELECT pr.id, count(distinct pr.result) AS np FROM shadow.project_results pr, shadow.result r WHERE pr.result=r.id AND r.type='publication' GROUP BY pr.id) AS prr WHERE prr.id=p.id;
|
452
|
END $BODY$;
|
453
|
|
454
|
ALTER FUNCTION shadow.project_pubs_count() OWNER TO sqoop;
|
455
|
|
456
|
|
457
|
|
458
|
--
|
459
|
-- Project Delayed Publications
|
460
|
--
|
461
|
CREATE OR REPLACE FUNCTION shadow.project_delayedpubs() RETURNS void LANGUAGE plpgsql VOLATILE COST 100 AS $BODY$
|
462
|
BEGIN
|
463
|
UPDATE shadow.project pp SET delayedpubs = prr.dp FROM (SELECT p.id, count(distinct r.id) as dp FROM project p, project_results pr, result r WHERE p.id=pr.id AND pr.result=r.id AND r.type='publication' AND to_date(r.date, 'YYYY-MM-DD')-to_date(p.enddate, 'YYYY-MM-DD') > 0 GROUP BY p.id) AS prr WHERE pp.id=prr.id;
|
464
|
END $BODY$;
|
465
|
|
466
|
ALTER FUNCTION shadow.project_delayedpubs() OWNER TO sqoop;
|
467
|
|
468
|
|
469
|
--
|
470
|
-- Project daysforlastpub
|
471
|
--
|
472
|
CREATE OR REPLACE FUNCTION shadow.project_daysforlastpub() RETURNS void LANGUAGE plpgsql VOLATILE COST 100 AS $BODY$
|
473
|
BEGIN
|
474
|
UPDATE shadow.project pp SET daysforlastpub = prr.dp FROM (SELECT p.id, max(to_date(r.date, 'YYYY-MM-DD')-to_date(p.enddate, 'YYYY-MM-DD')) as dp FROM project p, project_results pr, result r WHERE p.id=pr.id AND pr.result=r.id AND r.type='publication' AND to_date(r.date, 'YYYY-MM-DD')-to_date(p.enddate, 'YYYY-MM-DD') > 0 GROUP BY p.id) AS prr WHERE pp.id=prr.id;
|
475
|
END $BODY$;
|
476
|
|
477
|
ALTER FUNCTION shadow.project_daysforlastpub() OWNER TO sqoop;
|
478
|
|
479
|
--
|
480
|
-- Project delayed
|
481
|
--
|
482
|
CREATE OR REPLACE FUNCTION shadow.project_delayed () RETURNS void LANGUAGE plpgsql VOLATILE COST 100 AS $BODY$
|
483
|
BEGIN
|
484
|
UPDATE shadow.result SET delayed = 'yes' WHERE id IN (SELECT distinct r.id FROM result r, project_results pr, project p WHERE r.id=pr.result AND pr.id=p.id AND to_date(r.date, 'YYYY-MM-DD')-to_date(p.enddate, 'YYYY-MM-DD') > 0);
|
485
|
END $BODY$;
|
486
|
|
487
|
ALTER FUNCTION shadow.project_delayed() OWNER TO sqoop;
|
488
|
|
489
|
--
|
490
|
-- Cleaning Up Temps
|
491
|
--
|
492
|
CREATE OR REPLACE FUNCTION shadow.cleanTemps () RETURNS void LANGUAGE plpgsql VOLATILE COST 100 AS $BODY$
|
493
|
BEGIN
|
494
|
drop view if exists shadow.delayedpubs ;
|
495
|
drop view if exists shadow.project_pub_count ;
|
496
|
drop view if exists shadow.delayedpubs ;
|
497
|
drop view if exists shadow.project_results_publication ;
|
498
|
END $BODY$;
|
499
|
|
500
|
ALTER FUNCTION shadow.cleanTemps() OWNER TO sqoop;
|
501
|
|
502
|
--
|
503
|
-- Name: create_arrays(); Type FUNCTION; Schema: shadow; Owner: sqoop
|
504
|
--
|
505
|
CREATE OR REPLACE FUNCTION shadow.create_arrays() RETURNS void LANGUAGE plpgsql VOLATILE COST 100 AS $BODY$
|
506
|
BEGIN
|
507
|
|
508
|
ALTER TABLE shadow.result ADD COLUMN funders text[], ADD COLUMN funding_lvl0 text[], ADD COLUMN projects text[], ADD COLUMN datasources text[];
|
509
|
UPDATE shadow.result r SET funders = prr.funders FROM (SELECT pr.result AS rid, array_agg(distinct funder) AS funders FROM shadow.project p, shadow.project_results pr WHERE p.id=pr.id GROUP BY pr.result) AS prr WHERE r.id = prr.rid;
|
510
|
UPDATE shadow.result r SET funding_lvl0 = prr.funding_lvl0 FROM (SELECT pr.result AS rid, array_agg(distinct funding_lvl0) AS funding_lvl0 FROM shadow.project p, shadow.project_results pr WHERE p.id=pr.id GROUP BY pr.result) AS prr WHERE r.id = prr.rid;
|
511
|
UPDATE shadow.result r SET projects = prr.ids FROM (SELECT pr.result AS rid, array_agg(distinct pr.id) AS ids FROM shadow.project_results pr GROUP BY pr.result) AS prr WHERE r.id = prr.rid;
|
512
|
|
513
|
-- todo fix this query
|
514
|
-- UPDATE shadow.result r SET datasources = drr.ids FROM (SELECT dr.result AS rid, array_agg(distinct dr.id) AS ids FROM shadow.project_results pr GROUP BY pr.result) AS prr WHERE r.id = prr.rid;
|
515
|
|
516
|
END $BODY$;
|
517
|
|
518
|
ALTER FUNCTION shadow.create_arrays() OWNER TO sqoop;
|
519
|
|
520
|
--
|
521
|
-- Name: create_indexes(); Type: FUNCTION; Schema: shadow; Owner: sqoop
|
522
|
--
|
523
|
|
524
|
CREATE FUNCTION shadow.create_indexes() RETURNS void LANGUAGE plpgsql AS $$
|
525
|
BEGIN
|
526
|
CREATE INDEX datasource_id ON "shadow".datasource USING btree (id);
|
527
|
CREATE INDEX datasource_type ON "shadow".datasource USING btree (type);
|
528
|
CREATE INDEX datasource_name ON "shadow".datasource USING btree (name);
|
529
|
CREATE INDEX datasource_piwik_id ON "shadow".datasource USING btree (piwik_id);
|
530
|
CREATE INDEX dtsrc_type ON shadow.datasource USING btree (type COLLATE pg_catalog."default");
|
531
|
CREATE INDEX dtsrc_name ON shadow.datasource USING btree (name COLLATE pg_catalog."default");
|
532
|
CREATE INDEX dtsrc_compatibility ON shadow.datasource USING btree (compatibility COLLATE pg_catalog."default");
|
533
|
|
534
|
CREATE INDEX datasource_oids_id ON "shadow".datasource_oids USING btree (id COLLATE pg_catalog."default");
|
535
|
CREATE INDEX datasource_oids_orid ON "shadow".datasource_oids USING btree(orid COLLATE pg_catalog."default");
|
536
|
CREATE INDEX datasource_websites_id ON "shadow".datasource_websites USING btree(id COLLATE pg_catalog."default");
|
537
|
CREATE INDEX datasource_lang_id ON shadow.datasource_languages (id ASC NULLS LAST);
|
538
|
CREATE INDEX dtsrc_org_id ON shadow.datasource_organizations USING btree (id COLLATE pg_catalog."default");
|
539
|
CREATE INDEX dtsrc_org_org ON shadow.datasource_organizations USING btree (organization COLLATE pg_catalog."default");
|
540
|
|
541
|
CREATE INDEX result_authors ON "shadow".result USING btree (authors);
|
542
|
CREATE INDEX result_id ON "shadow".result USING btree (id);
|
543
|
CREATE INDEX result_year ON "shadow".result USING btree (year);
|
544
|
CREATE INDEX result_date ON "shadow"."result" USING btree ("date");
|
545
|
CREATE INDEX result_type ON "shadow"."result" USING btree ("type");
|
546
|
CREATE INDEX res_bestlicense ON shadow.result USING btree (bestlicense COLLATE pg_catalog."default");
|
547
|
CREATE INDEX result_funders_idx ON shadow.result USING gin (funders);
|
548
|
CREATE INDEX result_funding_lvl0_idx ON shadow.result USING gin (funding_lvl0);
|
549
|
CREATE INDEX result_projects_idx ON shadow.result USING gin (projects);
|
550
|
-- CREATE INDEX result_datasources_idx ON shadow.result USING gin (datasources);
|
551
|
|
552
|
|
553
|
CREATE INDEX project_acronym ON "shadow"."project" USING btree (acronym);
|
554
|
CREATE INDEX project_enddate ON "shadow"."project" USING btree (enddate);
|
555
|
CREATE INDEX project_id ON "shadow"."project" USING btree (id);
|
556
|
CREATE INDEX proj_funder ON shadow.project USING btree (funder COLLATE pg_catalog."default");
|
557
|
CREATE INDEX proj_title ON shadow.project USING btree (title COLLATE pg_catalog."default");
|
558
|
CREATE INDEX proj_fndlvl0 ON shadow.project USING btree (funding_lvl0 COLLATE pg_catalog."default");
|
559
|
CREATE INDEX proj_fndlvl1 ON shadow.project USING btree (funding_lvl1 COLLATE pg_catalog."default");
|
560
|
CREATE INDEX proj_fndlvl2 ON shadow.project USING btree (funding_lvl2 COLLATE pg_catalog."default");
|
561
|
CREATE INDEX proj_sc39 ON shadow.project USING btree (sc39 COLLATE pg_catalog."default");
|
562
|
CREATE INDEX proj_fndlvl3 ON shadow.project USING btree (funding_lvl3 COLLATE pg_catalog."default");
|
563
|
|
564
|
CREATE INDEX project_results_result ON "shadow"."project_results" USING btree (result);
|
565
|
CREATE INDEX project_results_project ON "shadow"."project_results" USING btree (id);
|
566
|
|
567
|
CREATE INDEX result_oids_id ON "shadow".result_oids USING btree (id COLLATE pg_catalog."default");
|
568
|
CREATE INDEX result_oids_oid ON "shadow".result_oids USING btree(orid COLLATE pg_catalog."default");
|
569
|
|
570
|
CREATE INDEX result_pids_id ON "shadow".result_pids USING btree (id COLLATE pg_catalog."default");
|
571
|
CREATE INDEX result_pids_type ON "shadow".result_pids USING btree (type COLLATE pg_catalog."default");
|
572
|
CREATE INDEX result_pids_pid ON "shadow".result_pids USING btree(pid COLLATE pg_catalog."default");
|
573
|
|
574
|
CREATE INDEX result_extra_id ON "shadow".result_extra USING btree(id COLLATE pg_catalog."default");
|
575
|
|
576
|
CREATE INDEX res_class_type ON shadow.result_classifications USING btree (type COLLATE pg_catalog."default");
|
577
|
CREATE INDEX res_class_id ON shadow.result_classifications USING btree (id COLLATE pg_catalog."default");
|
578
|
|
579
|
CREATE INDEX res_dtsrc_dtsrc ON shadow.result_datasources USING btree (datasource COLLATE pg_catalog."default");
|
580
|
CREATE INDEX res_dtsrc_id ON shadow.result_datasources USING btree (id COLLATE pg_catalog."default");
|
581
|
|
582
|
CREATE INDEX res_lang_lang ON shadow.result_languages USING btree (language COLLATE pg_catalog."default");
|
583
|
|
584
|
CREATE INDEX org_id ON shadow.organization USING btree (id COLLATE pg_catalog."default");
|
585
|
CREATE INDEX org_country ON shadow.organization USING btree (country COLLATE pg_catalog."default");
|
586
|
CREATE INDEX org_name ON shadow.organization USING btree (name COLLATE pg_catalog."default");
|
587
|
|
588
|
CREATE INDEX proj_org_org ON shadow.project_organizations USING btree (organization COLLATE pg_catalog."default");
|
589
|
CREATE INDEX proj_org_id ON shadow.project_organizations USING btree (id COLLATE pg_catalog."default");
|
590
|
|
591
|
CREATE INDEX res_res_id ON shadow.result_results USING btree (id COLLATE pg_catalog."default");
|
592
|
CREATE INDEX res_res_res ON shadow.result_results USING btree (result COLLATE pg_catalog."default");
|
593
|
|
594
|
CREATE INDEX res_lang_id ON shadow.result_languages USING btree (id COLLATE pg_catalog."default");
|
595
|
|
596
|
CREATE INDEX res_conc_id ON shadow.result_concepts USING btree (id COLLATE pg_catalog."default");
|
597
|
CREATE INDEX res_conc_conc ON shadow.result_concepts USING btree (concept COLLATE pg_catalog."default");
|
598
|
END;$$;
|
599
|
|
600
|
ALTER FUNCTION shadow.create_indexes() OWNER TO sqoop;
|
601
|
|
602
|
--
|
603
|
-- Name: create_views(); Type: FUNCTION; Schema: shadow; Owner: sqoop
|
604
|
--
|
605
|
|
606
|
CREATE or replace FUNCTION "shadow".create_views() RETURNS void LANGUAGE plpgsql AS $$
|
607
|
BEGIN
|
608
|
CREATE OR REPLACE VIEW shadow.datasource_results AS SELECT datasource AS id, id AS result FROM shadow.result_datasources;
|
609
|
CREATE OR REPLACE VIEW shadow.organization_datasources AS SELECT organization AS id, id AS datasource FROM shadow.datasource_organizations;
|
610
|
CREATE OR REPLACE VIEW shadow.organization_projects AS SELECT id AS project, organization as id FROM shadow.project_organizations;
|
611
|
|
612
|
CREATE OR REPLACE VIEW shadow.result_projects AS SELECT shadow.project_results.result AS id,
|
613
|
shadow.project_results.id AS project, ( select to_date("shadow"."result"."date", 'YYYY-MM-DD')- to_date("shadow"."project"."enddate", 'YYYY-MM-DD')
|
614
|
from shadow.result, shadow.project where shadow.result.id = shadow.project_results.result
|
615
|
and shadow.project_results.id= shadow.project.id and shadow.result.type='publication' )
|
616
|
as daysfromend FROM shadow.project_results;
|
617
|
|
618
|
CREATE OR REPLACE VIEW "shadow".datasource_topics AS
|
619
|
SELECT distinct "shadow".datasource.id, "shadow".result_topics.topic
|
620
|
FROM "shadow".datasource, "shadow".datasource_results, "shadow".result, "shadow".result_topics
|
621
|
WHERE "shadow".datasource.id = "shadow".datasource_results.id AND "shadow".datasource_results.result = "shadow".result.id AND
|
622
|
"shadow".result_topics.id = "shadow".result.id;
|
623
|
END;$$;
|
624
|
--
|
625
|
-- Name: create_charts(); Type: FUNCTION; Schema: shadow; Owner: sqoop
|
626
|
--
|
627
|
|
628
|
CREATE or replace FUNCTION "shadow".create_charts() RETURNS void LANGUAGE plpgsql AS $$
|
629
|
BEGIN
|
630
|
-- country nums
|
631
|
-- CREATE TABLE "shadow".numbers_country AS SELECT org.country AS country, count(distinct rd.datasource) AS datasources, count(distinct r.id) AS publications FROM "shadow".result r, "shadow".result_datasources rd, "shadow".datasource d, "shadow".datasource_organizations dor, "shadow".organization org WHERE r.id=rd.id AND rd.datasource=d.id AND d.id=dor.id AND dor.organization=org.id AND r.type='publication' AND r.bestlicense='Open Access' GROUP BY org.country;
|
632
|
-- --
|
633
|
-- -- -- country charts
|
634
|
-- CREATE TABLE "shadow".chart_country_year AS SELECT org.country AS country, r.year AS year, count(distinct r.id) AS publications FROM "shadow".result r, "shadow".result_datasources rd, "shadow".datasource d, "shadow".datasource_organizations dor, "shadow".organization org WHERE r.id=rd.id AND rd.datasource=d.id AND rd.datasource=dor.id AND dor.organization=org.id AND r.type='publication' AND r.bestlicense='Open Access' and r.year>='1990' AND r.year<=extract(YEAR from now()) group by org.country, r.year ORDER BY org.country, r.year;
|
635
|
-- CREATE TABLE "shadow".chart_country_datasources AS SELECT org.country AS country, d.name AS datasource, count(distinct r.id) AS publications FROM "shadow".result r, "shadow".result_datasources rd, "shadow".datasource d, "shadow".datasource_organizations dor, "shadow".organization org WHERE r.id=rd.id AND rd.datasource=d.id AND d.id=dor.id AND dor.organization=org.id AND r.type='publication' AND r.bestlicense='Open Access' GROUP BY org.country, d.name ORDER BY org.country, count(distinct r.id) DESC;
|
636
|
-- CREATE TABLE "shadow".chart_country_type AS SELECT org.country AS country, rc.type AS type, count(distinct r.id) AS publications FROM "shadow".result r, "shadow".result_datasources rd, "shadow".datasource d, "shadow".result_classifications rc, "shadow".datasource_organizations dor, "shadow".organization org WHERE r.id=rd.id AND r.id=rc.id AND rd.datasource=d.id AND rd.datasource=dor.id AND dor.organization=org.id AND r.type='publication' AND r.bestlicense='Open Access' GROUP BY org.country, rc.type;
|
637
|
-- CREATE TABLE "shadow".chart_country_fp7 AS SELECT org.country AS country, r.year AS year, count(distinct r.id) AS publications FROM "shadow".result r, "shadow".result_datasources rd, "shadow".datasource d, "shadow".datasource_organizations dor, "shadow".organization org, "shadow".project_results pr, "shadow".project p WHERE r.id=rd.id AND rd.datasource=d.id AND rd.datasource=dor.id AND dor.organization=org.id AND r.id=pr.result AND pr.id=p.id AND p.funding_lvl0='FP7' AND r.type='publication' AND r.year>='1990' AND r.year<=extract(YEAR from now()) GROUP BY org.country, r.year ORDER BY org.country, r.year;
|
638
|
-- --
|
639
|
-- -- -- datasource charts
|
640
|
-- CREATE TABLE "shadow".chart_datasource_type AS SELECT rd.datasource, rc.type, count(distinct rd.id) FROM "shadow".result_datasources rd, "shadow".result_classifications rc WHERE rd.id=rc.id GROUP BY rd.datasource, rc.type;
|
641
|
-- CREATE TABLE "shadow".chart_datasource_year AS SELECT rd.datasource, r.year, count(distinct rd.id) FROM "shadow".result r, "shadow".result_datasources rd WHERE rd.id=r.id GROUP By rd.datasource, r.year;
|
642
|
-- CREATE TABLE "shadow".chart_datasource_funders AS SELECT rd.datasource, p.funder, count(distinct rd.id) FROM "shadow".result_datasources rd, "shadow".project p, "shadow".project_results pr WHERE p.id=pr.id AND pr.result=rd.id GROUP BY rd.datasource, p.funder;
|
643
|
-- CREATE TABLE "shadow".chart_datasource_projects_pubs AS SELECT rd.datasource, p.title, count(distinct rd.id) FROM "shadow".result_datasources rd, "shadow".project p, "shadow".project_results pr, "shadow".result r WHERE p.id=pr.id AND pr.result=rd.id AND pr.result=r.id AND r.type='publication' GROUP BY rd.datasource, p.title;
|
644
|
-- CREATE TABLE "shadow".chart_datasource_projects_data AS SELECT rd.datasource, p.title, count(distinct rd.id) FROM "shadow".result_datasources rd, "shadow".project p, "shadow".project_results pr, "shadow".result r WHERE p.id=pr.id AND pr.result=rd.id AND pr.result=r.id and r.type='dataset' GROUP BY rd.datasource, p.title;
|
645
|
-- --
|
646
|
-- -- project charts
|
647
|
-- CREATE TABLE "shadow".chart_project_year AS SELECT p.id, r.year, count( distinct r.id) FROM "shadow".result r, "shadow".project_results pr, "shadow".project p WHERE r.id=pr.result AND p.id=pr.id AND r.year>=p.start_year GROUP BY p.id, r.year;
|
648
|
-- CREATE TABLE "shadow".chart_project_license AS SELECT pr.id, r.bestlicense, count(distinct r.id) FROM "shadow".result r, "shadow".project_results pr WHERE r.id=pr.result AND r.type='publication' GROUP BY pr.id, r.bestlicense;
|
649
|
-- CREATE TABLE "shadow".chart_project_repos AS SELECT pr.id, d.name, count (distinct r.id) FROM "shadow".result r, "shadow".project_results pr, "shadow".datasource d, "shadow".datasource_results dr WHERE r.id=dr.result AND d.id=dr.id AND r.id=pr.result AND r.type='publication' GROUP BY pr.id, d.name;
|
650
|
END;$$;
|
651
|
|
652
|
--
|
653
|
-- Name: create_charts(); Type: FUNCTION; Schema: shadow; Owner: sqoop
|
654
|
--
|
655
|
CREATE or replace FUNCTION "shadow".create_chart_indexes() RETURNS void LANGUAGE plpgsql AS $$
|
656
|
BEGIN
|
657
|
-- country nums
|
658
|
-- CREATE INDEX numbers_country_country ON "shadow".numbers_country USING btree(country);
|
659
|
|
660
|
-- country charts
|
661
|
-- CREATE INDEX chart_country_year_country ON "shadow".chart_country_year USING btree(country);
|
662
|
-- CREATE INDEX chart_country_datasources_country ON "shadow".chart_country_datasources USING btree(country);
|
663
|
-- CREATE INDEX chart_country_type_country ON "shadow".chart_country_type USING btree(country);
|
664
|
-- CREATE INDEX chart_country_fp7_country ON "shadow".chart_country_fp7 USING btree(country);
|
665
|
|
666
|
-- datasource
|
667
|
-- CREATE INDEX chart_datasource_type_datasource ON "shadow".chart_datasource_type USING btree(datasource);
|
668
|
-- CREATE INDEX chart_datasource_year_datasource ON "shadow".chart_datasource_year USING btree(datasource);
|
669
|
-- CREATE INDEX chart_datasource_funders_datasource ON "shadow".chart_datasource_funders USING btree(datasource);
|
670
|
-- CREATE INDEX chart_datasource_projects_pubs_datasource ON "shadow".chart_datasource_projects_pubs USING btree(datasource);
|
671
|
-- CREATE INDEX chart_datasource_projects_data_datasource ON "shadow".chart_datasource_projects_data USING btree(datasource);
|
672
|
|
673
|
-- project
|
674
|
-- CREATE INDEX chart_project_year_id ON "shadow".chart_project_year USING btree(id);
|
675
|
-- CREATE INDEX chart_project_license_id ON "shadow".chart_project_license USING btree(id);
|
676
|
-- CREATE INDEX chart_project_repos_id ON "shadow".chart_project_repos USING btree(id);
|
677
|
END;$$;
|
678
|
|
679
|
--
|
680
|
-- Name: clean_tables(); Type: FUNCTION; Schema: shadow; Owner: sqoop
|
681
|
--
|
682
|
CREATE or replace FUNCTION "shadow".clean_tables() RETURNS void LANGUAGE plpgsql AS $$
|
683
|
BEGIN
|
684
|
CREATE TABLE "shadow".rd_distinct AS SELECT DISTINCT * FROM "shadow".result_datasources;
|
685
|
|
686
|
DROP TABLE "shadow".result_datasources;
|
687
|
ALTER TABLE "shadow".rd_distinct RENAME TO result_datasources;
|
688
|
|
689
|
-- TRUNCATE "shadow".result_datasources;
|
690
|
-- INSERT INTO "shadow".result_datasources SELECT * FROM "shadow".rd_distinct ORDER BY datasource;
|
691
|
-- DROP TABLE "shadow".rd_distinct;
|
692
|
END;$$;
|
693
|
|
694
|
|
695
|
CREATE OR REPLACE FUNCTION "shadow".insert_countries() RETURNS void LANGUAGE plpgsql AS $$
|
696
|
BEGIN
|
697
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AD', 'Andorra', 'EU', 'Europe');
|
698
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AE', 'United Arab Emirates', 'AS', 'Asia');
|
699
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AF', 'Afghanistan', 'AS', 'Asia');
|
700
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AG', 'Antigua and Barbuda', 'NA', 'North America');
|
701
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AI', 'Anguilla', 'NA', 'North America');
|
702
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AL', 'Albania', 'EU', 'Europe');
|
703
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AM', 'Armenia', 'AS', 'Asia');
|
704
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AO', 'Angola', 'AF', 'Africa');
|
705
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AQ', 'Antarctica', 'AN', 'Antarctica');
|
706
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AR', 'Argentina', 'SA', 'South America');
|
707
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AS', 'American Samoa', 'OC', 'Oceania');
|
708
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AT', 'Austria', 'EU', 'Europe');
|
709
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AU', 'Australia', 'OC', 'Oceania');
|
710
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AW', 'Aruba', 'NA', 'North America');
|
711
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AX', 'Åland Islands', 'EU', 'Europe');
|
712
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('AZ', 'Azerbaijan', 'AS', 'Asia');
|
713
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BA', 'Bosnia and Herzegovina', 'EU', 'Europe');
|
714
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BB', 'Barbados', 'NA', 'North America');
|
715
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BD', 'Bangladesh', 'AS', 'Asia');
|
716
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BE', 'Belgium', 'EU', 'Europe');
|
717
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BF', 'Burkina Faso', 'AF', 'Africa');
|
718
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BG', 'Bulgaria', 'EU', 'Europe');
|
719
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BH', 'Bahrain', 'AS', 'Asia');
|
720
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BI', 'Burundi', 'AF', 'Africa');
|
721
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BJ', 'Benin', 'AF', 'Africa');
|
722
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BL', 'Saint Barthélemy', 'NA', 'North America');
|
723
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BM', 'Bermuda', 'NA', 'North America');
|
724
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BN', 'Brunei Darussalam', 'AS', 'Asia');
|
725
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BO', 'Bolivia, Plurinational State of', 'SA', 'South America');
|
726
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BR', 'Brazil', 'SA', 'South America');
|
727
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BS', 'Bahamas', 'NA', 'North America');
|
728
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BT', 'Bhutan', 'AS', 'Asia');
|
729
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BV', 'Bouvet Island', 'AN', 'Antarctica');
|
730
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BW', 'Botswana', 'AF', 'Africa');
|
731
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BY', 'Belarus', 'EU', 'Europe');
|
732
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('BZ', 'Belize', 'NA', 'North America');
|
733
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CA', 'Canada', 'NA', 'North America');
|
734
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CC', 'Cocos (Keeling) Islands', 'AS', 'Asia');
|
735
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CD', 'Congo, the Democratic Republic of the', 'AF', 'Africa');
|
736
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CF', 'Central African Republic', 'AF', 'Africa');
|
737
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CG', 'Congo', 'AF', 'Africa');
|
738
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CH', 'Switzerland', 'EU', 'Europe');
|
739
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CI', 'Côte d''Ivoire', 'AF', 'Africa');
|
740
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CK', 'Cook Islands', 'OC', 'Oceania');
|
741
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CL', 'Chile', 'SA', 'South America');
|
742
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CM', 'Cameroon', 'AF', 'Africa');
|
743
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CN', 'China', 'AS', 'Asia');
|
744
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CO', 'Colombia', 'SA', 'South America');
|
745
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CR', 'Costa Rica', 'NA', 'North America');
|
746
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CU', 'Cuba', 'NA', 'North America');
|
747
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CV', 'Cape Verde', 'AF', 'Africa');
|
748
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CX', 'Christmas Island', 'AS', 'Asia');
|
749
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CY', 'Cyprus', 'AS', 'Asia');
|
750
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('CZ', 'Czech Republic', 'EU', 'Europe');
|
751
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('DE', 'Germany', 'EU', 'Europe');
|
752
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('DJ', 'Djibouti', 'AF', 'Africa');
|
753
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('DK', 'Denmark', 'EU', 'Europe');
|
754
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('DM', 'Dominica', 'NA', 'North America');
|
755
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('DO', 'Dominican Republic', 'NA', 'North America');
|
756
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('DZ', 'Algeria', 'AF', 'Africa');
|
757
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('EC', 'Ecuador', 'SA', 'South America');
|
758
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('EE', 'Estonia', 'EU', 'Europe');
|
759
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('EG', 'Egypt', 'AF', 'Africa');
|
760
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('EH', 'Western Sahara', 'AF', 'Africa');
|
761
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('ER', 'Eritrea', 'AF', 'Africa');
|
762
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('ES', 'Spain', 'EU', 'Europe');
|
763
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('ET', 'Ethiopia', 'AF', 'Africa');
|
764
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('FI', 'Finland', 'EU', 'Europe');
|
765
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('FJ', 'Fiji', 'OC', 'Oceania');
|
766
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('FK', 'Falkland Islands (Malvinas)', 'SA', 'South America');
|
767
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('FM', 'Micronesia, Federated States of', 'OC', 'Oceania');
|
768
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('FO', 'Faroe Islands', 'EU', 'Europe');
|
769
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('FR', 'France', 'EU', 'Europe');
|
770
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GA', 'Gabon', 'AF', 'Africa');
|
771
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GB', 'United Kingdom', 'EU', 'Europe');
|
772
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GD', 'Grenada', 'NA', 'North America');
|
773
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GE', 'Georgia', 'AS', 'Asia');
|
774
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GF', 'French Guiana', 'SA', 'South America');
|
775
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GG', 'Guernsey', 'EU', 'Europe');
|
776
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GH', 'Ghana', 'AF', 'Africa');
|
777
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GI', 'Gibraltar', 'EU', 'Europe');
|
778
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GL', 'Greenland', 'NA', 'North America');
|
779
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GM', 'Gambia', 'AF', 'Africa');
|
780
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GN', 'Guinea', 'AF', 'Africa');
|
781
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GP', 'Guadeloupe', 'NA', 'North America');
|
782
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GQ', 'Equatorial Guinea', 'AF', 'Africa');
|
783
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GR', 'Greece', 'EU', 'Europe');
|
784
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GS', 'South Georgia and the South Sandwich Islands', 'AN', 'Antarctica');
|
785
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GT', 'Guatemala', 'NA', 'North America');
|
786
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GU', 'Guam', 'OC', 'Oceania');
|
787
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GW', 'Guinea-Bissau', 'AF', 'Africa');
|
788
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('GY', 'Guyana', 'SA', 'South America');
|
789
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('HK', 'Hong Kong', 'AS', 'Asia');
|
790
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('HM', 'Heard Island and McDonald Islands', 'AN', 'Antarctica');
|
791
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('HN', 'Honduras', 'NA', 'North America');
|
792
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('HR', 'Croatia', 'EU', 'Europe');
|
793
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('HT', 'Haiti', 'NA', 'North America');
|
794
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('HU', 'Hungary', 'EU', 'Europe');
|
795
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('ID', 'Indonesia', 'AS', 'Asia');
|
796
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('IE', 'Ireland', 'EU', 'Europe');
|
797
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('IL', 'Israel', 'AS', 'Asia');
|
798
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('IM', 'Isle of Man', 'EU', 'Europe');
|
799
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('IN', 'India', 'AS', 'Asia');
|
800
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('IO', 'British Indian Ocean Territory', 'AS', 'Asia');
|
801
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('IQ', 'Iraq', 'AS', 'Asia');
|
802
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('IR', 'Iran, Islamic Republic of', 'AS', 'Asia');
|
803
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('IS', 'Iceland', 'EU', 'Europe');
|
804
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('IT', 'Italy', 'EU', 'Europe');
|
805
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('JE', 'Jersey', 'EU', 'Europe');
|
806
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('JM', 'Jamaica', 'NA', 'North America');
|
807
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('JO', 'Jordan', 'AS', 'Asia');
|
808
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('JP', 'Japan', 'AS', 'Asia');
|
809
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('KE', 'Kenya', 'AF', 'Africa');
|
810
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('KG', 'Kyrgyzstan', 'AS', 'Asia');
|
811
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('KH', 'Cambodia', 'AS', 'Asia');
|
812
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('KI', 'Kiribati', 'OC', 'Oceania');
|
813
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('KM', 'Comoros', 'AF', 'Africa');
|
814
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('KN', 'Saint Kitts and Nevis', 'NA', 'North America');
|
815
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('KP', 'Korea, Democratic People''s Republic of', 'AS', 'Asia');
|
816
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('KR', 'Korea, Republic of', 'AS', 'Asia');
|
817
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('KW', 'Kuwait', 'AS', 'Asia');
|
818
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('KY', 'Cayman Islands', 'NA', 'North America');
|
819
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('KZ', 'Kazakhstan', 'AS', 'Asia');
|
820
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('LA', 'Lao People''s Democratic Republic', 'AS', 'Asia');
|
821
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('LB', 'Lebanon', 'AS', 'Asia');
|
822
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('LC', 'Saint Lucia', 'NA', 'North America');
|
823
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('LI', 'Liechtenstein', 'EU', 'Europe');
|
824
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('LK', 'Sri Lanka', 'AS', 'Asia');
|
825
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('LR', 'Liberia', 'AF', 'Africa');
|
826
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('LS', 'Lesotho', 'AF', 'Africa');
|
827
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('LT', 'Lithuania', 'EU', 'Europe');
|
828
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('LU', 'Luxembourg', 'EU', 'Europe');
|
829
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('LV', 'Latvia', 'EU', 'Europe');
|
830
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('LY', 'Libya', 'AF', 'Africa');
|
831
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MA', 'Morocco', 'AF', 'Africa');
|
832
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MC', 'Monaco', 'EU', 'Europe');
|
833
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MD', 'Moldova, Republic of', 'EU', 'Europe');
|
834
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('ME', 'Montenegro', 'EU', 'Europe');
|
835
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MF', 'Saint Martin (French part)', 'NA', 'North America');
|
836
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MG', 'Madagascar', 'AF', 'Africa');
|
837
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MH', 'Marshall Islands', 'OC', 'Oceania');
|
838
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MK', 'Macedonia, the Former Yugoslav Republic of', 'EU', 'Europe');
|
839
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('ML', 'Mali', 'AF', 'Africa');
|
840
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MM', 'Myanmar', 'AS', 'Asia');
|
841
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MN', 'Mongolia', 'AS', 'Asia');
|
842
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MO', 'Macao', 'AS', 'Asia');
|
843
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MP', 'Northern Mariana Islands', 'OC', 'Oceania');
|
844
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MQ', 'Martinique', 'NA', 'North America');
|
845
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MR', 'Mauritania', 'AF', 'Africa');
|
846
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MS', 'Montserrat', 'NA', 'North America');
|
847
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MT', 'Malta', 'EU', 'Europe');
|
848
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MU', 'Mauritius', 'AF', 'Africa');
|
849
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MV', 'Maldives', 'AS', 'Asia');
|
850
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MW', 'Malawi', 'AF', 'Africa');
|
851
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MX', 'Mexico', 'NA', 'North America');
|
852
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MY', 'Malaysia', 'AS', 'Asia');
|
853
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('MZ', 'Mozambique', 'AF', 'Africa');
|
854
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NA', 'Namibia', 'AF', 'Africa');
|
855
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NC', 'New Caledonia', 'OC', 'Oceania');
|
856
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NE', 'Niger', 'AF', 'Africa');
|
857
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NF', 'Norfolk Island', 'OC', 'Oceania');
|
858
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NG', 'Nigeria', 'AF', 'Africa');
|
859
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NI', 'Nicaragua', 'NA', 'North America');
|
860
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NL', 'Netherlands', 'EU', 'Europe');
|
861
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NO', 'Norway', 'EU', 'Europe');
|
862
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NP', 'Nepal', 'AS', 'Asia');
|
863
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NR', 'Nauru', 'OC', 'Oceania');
|
864
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NU', 'Niue', 'OC', 'Oceania');
|
865
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('NZ', 'New Zealand', 'OC', 'Oceania');
|
866
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('OM', 'Oman', 'AS', 'Asia');
|
867
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PA', 'Panama', 'NA', 'North America');
|
868
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PE', 'Peru', 'SA', 'South America');
|
869
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PF', 'French Polynesia', 'OC', 'Oceania');
|
870
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PG', 'Papua New Guinea', 'OC', 'Oceania');
|
871
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PH', 'Philippines', 'AS', 'Asia');
|
872
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PK', 'Pakistan', 'AS', 'Asia');
|
873
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PL', 'Poland', 'EU', 'Europe');
|
874
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PM', 'Saint Pierre and Miquelon', 'NA', 'North America');
|
875
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PN', 'Pitcairn', 'OC', 'Oceania');
|
876
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PR', 'Puerto Rico', 'NA', 'North America');
|
877
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PS', 'Palestine, State of', 'AS', 'Asia');
|
878
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PT', 'Portugal', 'EU', 'Europe');
|
879
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PW', 'Palau', 'OC', 'Oceania');
|
880
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('PY', 'Paraguay', 'SA', 'South America');
|
881
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('QA', 'Qatar', 'AS', 'Asia');
|
882
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('RE', 'Réunion', 'AF', 'Africa');
|
883
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('RO', 'Romania', 'EU', 'Europe');
|
884
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('RS', 'Serbia', 'EU', 'Europe');
|
885
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('RU', 'Russian Federation', 'EU', 'Europe');
|
886
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('RW', 'Rwanda', 'AF', 'Africa');
|
887
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SA', 'Saudi Arabia', 'AS', 'Asia');
|
888
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SB', 'Solomon Islands', 'OC', 'Oceania');
|
889
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SC', 'Seychelles', 'AF', 'Africa');
|
890
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SD', 'Sudan', 'AF', 'Africa');
|
891
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SE', 'Sweden', 'EU', 'Europe');
|
892
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SG', 'Singapore', 'AS', 'Asia');
|
893
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SH', 'Saint Helena, Ascension and Tristan da Cunha', 'AF', 'Africa');
|
894
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SI', 'Slovenia', 'EU', 'Europe');
|
895
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SJ', 'Svalbard and Jan Mayen', 'EU', 'Europe');
|
896
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SK', 'Slovakia', 'EU', 'Europe');
|
897
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SL', 'Sierra Leone', 'AF', 'Africa');
|
898
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SM', 'San Marino', 'EU', 'Europe');
|
899
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SN', 'Senegal', 'AF', 'Africa');
|
900
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SO', 'Somalia', 'AF', 'Africa');
|
901
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SR', 'Suriname', 'SA', 'South America');
|
902
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('ST', 'Sao Tome and Principe', 'AF', 'Africa');
|
903
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SV', 'El Salvador', 'NA', 'North America');
|
904
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SY', 'Syrian Arab Republic', 'AS', 'Asia');
|
905
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('SZ', 'Swaziland', 'AF', 'Africa');
|
906
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TC', 'Turks and Caicos Islands', 'NA', 'North America');
|
907
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TD', 'Chad', 'AF', 'Africa');
|
908
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TF', 'French Southern Territories', 'AN', 'Antarctica');
|
909
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TG', 'Togo', 'AF', 'Africa');
|
910
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TH', 'Thailand', 'AS', 'Asia');
|
911
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TJ', 'Tajikistan', 'AS', 'Asia');
|
912
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TK', 'Tokelau', 'OC', 'Oceania');
|
913
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TL', 'Timor-Leste', 'AS', 'Asia');
|
914
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TM', 'Turkmenistan', 'AS', 'Asia');
|
915
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TN', 'Tunisia', 'AF', 'Africa');
|
916
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TO', 'Tonga', 'OC', 'Oceania');
|
917
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TR', 'Turkey', 'EU', 'Europe');
|
918
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TT', 'Trinidad and Tobago', 'NA', 'North America');
|
919
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TV', 'Tuvalu', 'OC', 'Oceania');
|
920
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TW', 'Taiwan, Province of China', 'AS', 'Asia');
|
921
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('TZ', 'Tanzania, United Republic of', 'AF', 'Africa');
|
922
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('UA', 'Ukraine', 'EU', 'Europe');
|
923
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('UG', 'Uganda', 'AF', 'Africa');
|
924
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('UM', 'United States Minor Outlying Islands', 'OC', 'Oceania');
|
925
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('US', 'United States', 'NA', 'North America');
|
926
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('UY', 'Uruguay', 'SA', 'South America');
|
927
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('UZ', 'Uzbekistan', 'AS', 'Asia');
|
928
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('VA', 'Holy See (Vatican City State)', 'EU', 'Europe');
|
929
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('VC', 'Saint Vincent and the Grenadines', 'NA', 'North America');
|
930
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('VE', 'Venezuela, Bolivarian Republic of', 'SA', 'South America');
|
931
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('VG', 'Virgin Islands, British', 'NA', 'North America');
|
932
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('VI', 'Virgin Islands, U.S.', 'NA', 'North America');
|
933
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('VN', 'Viet Nam', 'AS', 'Asia');
|
934
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('VU', 'Vanuatu', 'OC', 'Oceania');
|
935
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('WF', 'Wallis and Futuna', 'OC', 'Oceania');
|
936
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('WS', 'Samoa', 'OC', 'Oceania');
|
937
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('YE', 'Yemen', 'AS', 'Asia');
|
938
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('YT', 'Mayotte', 'AF', 'Africa');
|
939
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('ZA', 'South Africa', 'AF', 'Africa');
|
940
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('ZM', 'Zambia', 'AF', 'Africa');
|
941
|
INSERT INTO shadow.country (code, name, continent_code, continent_name) VALUES ('ZW', 'Zimbabwe', 'AF', 'Africa');
|
942
|
END;$$;
|
943
|
|
944
|
CREATE OR REPLACE FUNCTION "shadow".backwards_compatibility() RETURNS void LANGUAGE plpgsql AS $$
|
945
|
BEGIN
|
946
|
ALTER TABLE "shadow".result RENAME TO tresult;
|
947
|
ALTER TABLE "shadow".datasource RENAME TO tdatasource;
|
948
|
ALTER TABLE "shadow".project RENAME TO tproject;
|
949
|
ALTER TABLE "shadow".organization RENAME TO torganization;
|
950
|
|
951
|
CREATE VIEW "shadow".result AS SELECT tresult.id, tresult.id AS result_projects, tresult.id AS result_datasources, tresult.publisher, tresult.year, tresult.bestlicense, tresult.bestlicense AS access_mode, tresult.type, tresult.embargo_end_date, tresult.delayed, tresult.authors, tresult.funders, tresult.funding_lvl0 AS arfunding_lvl0, tresult.projects, tresult.datasources, 1 AS number, tresult.title as title, tresult.source as source, tresult.abstract as abstract FROM tresult;
|
952
|
CREATE VIEW "shadow".datasource AS SELECT tdatasource.id, tdatasource.name, tdatasource.type, tdatasource.compatibility, tdatasource.dateofvalidation, tdatasource.yearofvalidation, tdatasource.harvested, tdatasource.piwik_id, tdatasource.latitude, tdatasource.longitude, tdatasource.id AS datasource_results, tdatasource.id AS datasource_organizations, 1 AS number FROM tdatasource;
|
953
|
CREATE VIEW "shadow".project AS SELECT tproject.id, tproject.acronym, tproject.title, tproject.funder, tproject.funding_lvl0, tproject.funding_lvl1, tproject.funding_lvl2, tproject.funding_lvl3, tproject.sc39, tproject.type, tproject.start_year, tproject.end_year, tproject.duration, tproject.haspubs, tproject.numpubs, tproject.enddate, tproject.startdate, tproject.daysforlastpub, tproject.delayedpubs, tproject.callidentifier, tproject.code, tproject.id AS project_results, tproject.id AS project_organizations, 1 AS number FROM tproject;
|
954
|
CREATE VIEW "shadow".organization AS SELECT torganization.id, torganization.name, torganization.country, torganization.id AS organization_datasources, torganization.id AS organization_projects, 1 AS number FROM torganization;
|
955
|
|
956
|
-- TODO delete when piwik ids are in place!!!!
|
957
|
update shadow.tdatasource set piwik_id=76 where id='opendoar____::3a20f62a0af1aa152670bab3c602feed';
|
958
|
update shadow.tdatasource set piwik_id=132 where id='opendoar____::f1748d6b0fd9d439f71450117eba2725';
|
959
|
END;$$;
|
960
|
|
961
|
|
962
|
-- sqoopQL database dump complete
|
963
|
--
|