Project

General

Profile

1
-- query performed by IIS to bulk load project details
2
DROP TABLE project_details;
3
CREATE TABLE project_details AS (
4
	SELECT
5
		p.id               AS projectid,
6
		p.acronym          AS acronym,
7
		p.code             AS code,
8
		p.optional1        AS optional1,
9
		p.optional2        AS optional2,
10
		p.jsonextrainfo    AS jsonextrainfo,
11
		array_agg(fp.path) AS fundingpath
12
	FROM projects p
13
		LEFT OUTER JOIN project_fundingpath pf ON (pf.project = p.id)
14
		LEFT OUTER JOIN fundingpaths fp ON (fp.id = pf.funding)
15
	GROUP BY p.id
16
);
17

    
18
GRANT SELECT ON project_details TO dnetapi;
19

    
20

    
21
-- used to serve queries from api tsv exporter
22
DROP TABLE projects_tsv;
23
CREATE TABLE projects_tsv AS (
24
	SELECT
25
		p.id,
26
		p.code,
27
		p.acronym,
28
		p.title,
29
		p.call_identifier,
30
		p.startdate,
31
		p.enddate,
32
		p.ec_sc39,
33
		p.oa_mandate_for_publications,
34
		p.ec_article29_3 AS oa_mandate_for_datasets,
35
		(array_agg(f.id))[1] AS fundingpathid,
36
		(array_agg(f.description))[1] AS description,
37
		(array_agg(org.legalname))[1] AS legalname,
38
		(array_agg(org.countryclass))[1] AS country,
39
		(array_agg(CASE WHEN po.participantnumber = 1
40
			THEN 'coordinator'
41
		ELSE '' END))[1] AS role,
42
		(array_agg(pe.firstname))[1] AS firstname,
43
		(array_agg(pe.secondnames))[1] AS secondnames,
44
		(array_agg(pe.email))[1] AS email
45
	FROM projects p
46
		LEFT OUTER JOIN project_organization po ON (p.id = po.project)
47
		LEFT OUTER JOIN persons pe ON (po.contactperson = pe.id)
48
		LEFT OUTER JOIN organizations org ON (po.resporganization = org.id)
49
		LEFT OUTER JOIN project_fundingpath pf ON (p.id = pf.project)
50
		LEFT OUTER JOIN fundingpaths f ON (pf.funding = f.id)
51
	GROUP BY p.id
52
	ORDER BY p.acronym
53
);
54

    
55
CREATE INDEX projects_tsv_fundingpathid_idx ON projects_tsv (fundingpathid);
56
CREATE INDEX projects_tsv_oa_mandate_for_datasets_idx ON projects_tsv (oa_mandate_for_datasets);
57
GRANT SELECT ON projects_tsv TO dnetapi;
58

    
59
-- used to serve queries from dspace and eprints exporter
60
DROP TABLE projects_api;
61
CREATE TABLE projects_api AS (
62
	SELECT
63
		p.id,
64
		p.acronym          AS acronym,
65
		p.title            AS title,
66
		p.code             AS code,
67
		p.startdate        AS startdate,
68
		p.enddate          AS enddate,
69
		(array_agg(org.legalshortname))[1] AS funder,
70
		(array_agg(fp.jurisdiction))[1]    AS jurisdiction,
71
		(array_agg(fp.id))[1]              AS fundingpathid
72
	FROM projects p
73
		LEFT OUTER JOIN project_fundingpath pfp ON (p.id = pfp.project)
74
		LEFT OUTER JOIN fundingpaths fp ON (pfp.funding = fp.id)
75
		LEFT OUTER JOIN organizations org ON (org.id = fp.funder)
76
	GROUP BY p.id);
77

    
78
CREATE INDEX projects_api_fundingpathid_idx ON projects_api (fundingpathid);
79
CREATE INDEX projects_api_startdate_idx ON projects_api (startdate);
80
CREATE INDEX projects_api_enddate_idx ON projects_api (enddate);
81
GRANT SELECT ON projects_api TO dnetapi;
82

    
83
-- used to serve queries from the repo admin dashboard
84
DROP MATERIALIZED VIEW dashboard_ds;
85
CREATE MATERIALIZED VIEW dashboard_ds AS (
86
	SELECT
87
		ds.id,
88
		ds.officialname,
89
		ds.englishname,
90
		ds.websiteurl,
91
		ds.logourl,
92
		ds.contactemail,
93
		ds.latitude,
94
		ds.longitude,
95
		ds.timezone,
96
		ds.namespaceprefix,
97
		ds.collectedfrom,
98
		ds.dateofvalidation,
99
		ds.registeredby,
100
		ds.datasourceclass,
101
		ds.provenanceactionclass,
102
		ds.dateofcollection,
103
		ds.typology,
104
		ds.activationid,
105
		ds.description,
106
		ds.missionstatementurl,
107
		ds.aggregator,
108
		ds.issn,
109
		ds.eissn,
110
		ds.lissn,
111
		(array_agg(o.legalname)) [1]             AS organization,
112
		(array_agg(ccl.code)) [1]                AS countrycode,
113
		(array_agg(ccl.name)) [1]                AS countryname,
114
		array_agg(DISTINCT ag.accessinfopackage) AS accessinfopackage,
115
		to_char(now(), 'YYYY-MM-DDThh24:mi:ssZ') AS now
116

    
117
	FROM datasources ds
118
		LEFT OUTER JOIN datasource_organization dso ON ds.id = dso.datasource
119
		LEFT OUTER JOIN organizations o ON dso.organization = o.id
120
		LEFT OUTER JOIN class ccl ON ccl.code = o.countryclass
121
		LEFT OUTER JOIN (
122
			                SELECT
123
				                api.datasource,
124
				                api.contentdescriptionclass,
125
				                api.compatibilityclass,
126
				                COALESCE(api.id, '') || '<==1==>' ||
127
				                COALESCE(api.typologyclass, '') || '<==2==>' ||
128
				                COALESCE(api.compatibilityclass, '') || '<==3==>' ||
129
				                COALESCE(api.contentdescriptionclass, '') || '<==4==>' ||
130
				                COALESCE(api.protocolclass, '') || '<==5==>' ||
131
				                COALESCE(api.active, FALSE) || '<==6==>' ||
132
				                COALESCE(api.removable, FALSE) || '<==7==>' ||
133
				                array_to_string(
134
						                array_agg(DISTINCT
135
								                COALESCE(ac.accessparam, TRUE) || '###' ||
136
								                COALESCE(ac.param, '') || '###' ||
137
								                COALESCE(ac.value, '') || '###'), '@@@') AS accessinfopackage
138
			                FROM api
139
				                LEFT OUTER JOIN (
140
					                                SELECT
141
						                                api,
142
						                                param,
143
						                                accessparam,
144
						                                CASE WHEN edited IS NULL
145
							                                THEN original
146
						                                ELSE edited END AS value
147
					                                FROM apicollections
148
				                                ) AS ac ON (ac.api = api.id)
149
			                GROUP BY
150
				                api.id,
151
				                api.datasource,
152
				                api.contentdescriptionclass,
153
				                api.typologyclass,
154
				                api.compatibilityclass,
155
				                api.protocolclass,
156
				                api.active,
157
				                api.removable
158
		                ) AS ag ON (ag.datasource = ds.id)
159
	GROUP BY
160
		ds.id,
161
		ds.officialname,
162
		ds.englishname,
163
		ds.websiteurl,
164
		ds.logourl,
165
		ds.contactemail,
166
		ds.latitude,
167
		ds.longitude,
168
		ds.timezone,
169
		ds.namespaceprefix,
170
		ds.collectedfrom,
171
		ds.dateofvalidation,
172
		ds.registeredby,
173
		ds.datasourceclass,
174
		ds.provenanceactionclass,
175
		ds.dateofcollection,
176
		ds.typology,
177
		ds.activationid,
178
		ds.description,
179
		ds.aggregator,
180
		ds.issn,
181
		ds.eissn,
182
		ds.lissn
183
);
184
CREATE INDEX dashboard_ds_id_idx ON dashboard_ds (id);
185

    
186
DROP MATERIALIZED VIEW projects_mv;
187
CREATE MATERIALIZED VIEW projects_mv AS (
188
	SELECT
189
		p.id                                                                                                       AS projectid,
190
		p.code                                                                                                     AS code,
191
		p.websiteurl                                                                                               AS websiteurl,
192
		p.acronym                                                                                                  AS acronym,
193
		p.title                                                                                                    AS title,
194
		p.startdate                                                                                                AS startdate,
195
		p.enddate                                                                                                  AS enddate,
196
		p.call_identifier                                                                                          AS callidentifier,
197
		p.keywords                                                                                                 AS keywords,
198
		p.duration                                                                                                 AS duration,
199
		p.ec_sc39                                                                                                  AS ecsc39,
200
		p.oa_mandate_for_publications                                                                              AS oamandatepublications,
201
		p.ec_article29_3                                                                                           AS ecarticle29_3,
202
		p.dateofcollection                                                                                         AS dateofcollection,
203
		p.inferred                                                                                                 AS inferred,
204
		p.deletedbyinference                                                                                       AS deletedbyinference,
205
		p.trust                                                                                                    AS trust,
206
		p.inferenceprovenance                                                                                      AS inferenceprovenance,
207
		p.optional1                                                                                                AS optional1,
208
		p.optional2                                                                                                AS optional2,
209
		p.jsonextrainfo                                                                                            AS jsonextrainfo,
210
		p.contactfullname                                                                                          AS contactfullname,
211
		p.contactfax                                                                                               AS contactfax,
212
		p.contactphone                                                                                             AS contactphone,
213
		p.contactemail                                                                                             AS contactemail,
214
		dc.id                                                                                                      AS collectedfromid,
215
		dc.officialname                                                                                            AS collectedfromname,
216
		cc.code || '@@@' || cc.name || '@@@' || cs.code || '@@@' || cs.name                                        AS contracttype,
217
		pac.code || '@@@' || pac.name || '@@@' || pas.code || '@@@' || pas.name                                    AS provenanceaction,
218
		array_agg(DISTINCT i.pid || '###' || i.issuertypeclass)                                                    AS pid,
219
		array_agg(DISTINCT s.name || '###' || sc.code || '@@@' || sc.name || '@@@' || ss.code || '@@@' || ss.name) AS subjects,
220
		array_agg(fp.path)                                                                                         AS fundingtree
221
	FROM projects p
222
		LEFT OUTER JOIN class cc ON (cc.code = p.contracttypeclass)
223
		LEFT OUTER JOIN scheme cs ON (cs.code = p.contracttypescheme)
224

    
225
		LEFT OUTER JOIN class pac ON (pac.code = p.provenanceactionclass)
226
		LEFT OUTER JOIN scheme pas ON (pas.code = p.provenanceactionscheme)
227

    
228
		LEFT OUTER JOIN projectpids pp ON (pp.project = p.id)
229
		LEFT OUTER JOIN identities i ON (i.pid = pp.pid)
230

    
231
		LEFT OUTER JOIN datasources dc ON (dc.id = p.collectedfrom)
232

    
233
		LEFT OUTER JOIN project_fundingpath pf ON (pf.project = p.id)
234
		LEFT OUTER JOIN fundingpaths fp ON (fp.id = pf.funding)
235

    
236
		LEFT OUTER JOIN project_subject ps ON (ps.project = p.id)
237
		LEFT OUTER JOIN subjects s ON (s.id = ps.subject)
238

    
239
		LEFT OUTER JOIN class sc ON (sc.code = s.semanticclass)
240
		LEFT OUTER JOIN scheme ss ON (ss.code = s.semanticscheme)
241

    
242
	GROUP BY
243
		p.id,
244
		p.code,
245
		p.websiteurl,
246
		p.acronym,
247
		p.title,
248
		p.startdate,
249
		p.enddate,
250
		p.call_identifier,
251
		p.keywords,
252
		p.duration,
253
		p.ec_sc39,
254
		p.oa_mandate_for_publications,
255
		p.ec_article29_3,
256
		p.dateofcollection,
257
		p.inferred,
258
		p.deletedbyinference,
259
		p.trust,
260
		p.inferenceprovenance,
261
		p.contactfullname,
262
		p.contactfax,
263
		p.contactphone,
264
		p.contactemail,
265
		dc.id,
266
		dc.officialname,
267
		cc.code, cc.name, cs.code, cs.name,
268
		pac.code, pac.name, pas.code, pas.name
269
);
270
CREATE INDEX projects_mv_id_idx	ON projects_mv (projectid);
271

    
272
GRANT SELECT ON dashboard_ds TO dnetapi;
273
GRANT SELECT ON fundingpaths TO dnetapi;
(1-1/14)