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
     nextval('projects_tsv_ids') AS rowid,
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
    p.contactfullname AS contactfullname,
36
    p.contactemail AS contactemail,
37
    org.legalname AS legalname,
38
    org.country AS country,
39
    (array_agg(f.id))[1] AS fundingpathid,
40
    (array_agg(f.description))[1] AS description,
41
    (array_agg(CASE WHEN po.participantnumber = 1
42
      THEN 'coordinator'
43
    ELSE '' END))[1] AS role
44

    
45
  FROM projects p
46
    LEFT OUTER JOIN project_organization po ON (p.id = po.project)
47
    LEFT OUTER JOIN dsm_organizations org ON (po.resporganization = org.id)
48
    LEFT OUTER JOIN project_fundingpath pf ON (p.id = pf.project)
49
    LEFT OUTER JOIN fundingpaths f ON (pf.funding = f.id)
50
  GROUP BY
51
  	p.code,
52
  	p.acronym,
53
    p.title,
54
    p.call_identifier,
55
    p.startdate,
56
    p.enddate,
57
    p.ec_sc39,
58
    p.oa_mandate_for_publications,
59
    p.ec_article29_3,
60
    p.contactfullname,
61
    p.contactemail,
62
    org.legalname,
63
    org.country
64
  ORDER BY p.acronym
65
);
66

    
67
CREATE INDEX projects_tsv_fundingpathid_idx ON projects_tsv (fundingpathid);
68
CREATE INDEX projects_tsv_oa_mandate_for_datasets_idx ON projects_tsv (oa_mandate_for_datasets);
69
GRANT SELECT ON projects_tsv TO dnetapi;
70

    
71
-- used to serve queries from dspace and eprints exporter
72
DROP TABLE projects_api;
73
CREATE TABLE projects_api AS (
74
	SELECT
75
		p.id,
76
		p.acronym          AS acronym,
77
		p.title            AS title,
78
		p.code             AS code,
79
		p.startdate        AS startdate,
80
		p.enddate          AS enddate,
81
		(array_agg(org.legalshortname))[1] AS funder,
82
		(array_agg(fp.jurisdiction))[1]    AS jurisdiction,
83
		(array_agg(fp.id))[1]              AS fundingpathid
84
	FROM projects p
85
		LEFT OUTER JOIN project_fundingpath pfp ON (p.id = pfp.project)
86
		LEFT OUTER JOIN fundingpaths fp ON (pfp.funding = fp.id)
87
		LEFT OUTER JOIN dsm_organizations org ON (org.id = fp.funder)
88
	GROUP BY p.id);
89

    
90
CREATE INDEX projects_api_fundingpathid_idx ON projects_api (fundingpathid);
91
CREATE INDEX projects_api_startdate_idx ON projects_api (startdate);
92
CREATE INDEX projects_api_enddate_idx ON projects_api (enddate);
93
GRANT SELECT ON projects_api TO dnetapi;
94

    
95

    
96
DROP MATERIALIZED VIEW projects_mv;
97
CREATE MATERIALIZED VIEW projects_mv AS (
98
	SELECT
99
		p.id                                                                                                       AS projectid,
100
		p.code                                                                                                     AS code,
101
		p.websiteurl                                                                                               AS websiteurl,
102
		p.acronym                                                                                                  AS acronym,
103
		p.title                                                                                                    AS title,
104
		p.startdate                                                                                                AS startdate,
105
		p.enddate                                                                                                  AS enddate,
106
		p.call_identifier                                                                                          AS callidentifier,
107
		p.keywords                                                                                                 AS keywords,
108
		p.duration                                                                                                 AS duration,
109
		p.ec_sc39                                                                                                  AS ecsc39,
110
		p.oa_mandate_for_publications                                                                              AS oamandatepublications,
111
		p.ec_article29_3                                                                                           AS ecarticle29_3,
112
		p.dateofcollection                                                                                         AS dateofcollection,
113
		p.lastupdate                                                                                               AS dateoftransformation,
114
		p.inferred                                                                                                 AS inferred,
115
		p.deletedbyinference                                                                                       AS deletedbyinference,
116
		p.trust                                                                                                    AS trust,
117
		p.inferenceprovenance                                                                                      AS inferenceprovenance,
118
		p.optional1                                                                                                AS optional1,
119
		p.optional2                                                                                                AS optional2,
120
		p.jsonextrainfo                                                                                            AS jsonextrainfo,
121
		p.contactfullname                                                                                          AS contactfullname,
122
		p.contactfax                                                                                               AS contactfax,
123
		p.contactphone                                                                                             AS contactphone,
124
		p.contactemail                                                                                             AS contactemail,
125
		dc.id                                                                                                      AS collectedfromid,
126
		dc.officialname                                                                                            AS collectedfromname,
127
		cc.code || '@@@' || cc.name || '@@@' || cs.code || '@@@' || cs.name                                        AS contracttype,
128
		pac.code || '@@@' || pac.name || '@@@' || pas.code || '@@@' || pas.name                                    AS provenanceaction,
129
		array_agg(DISTINCT i.pid || '###' || i.issuertype)                                                         AS pid,
130
		array_agg(DISTINCT s.name || '###' || sc.code || '@@@' || sc.name || '@@@' || ss.code || '@@@' || ss.name) AS subjects,
131
		array_agg(DISTINCT fp.path)                                                                                AS fundingtree
132
	FROM projects p
133
		LEFT OUTER JOIN class cc ON (cc.code = p.contracttypeclass)
134
		LEFT OUTER JOIN scheme cs ON (cs.code = p.contracttypescheme)
135

    
136
		LEFT OUTER JOIN class pac ON (pac.code = p.provenanceactionclass)
137
		LEFT OUTER JOIN scheme pas ON (pas.code = p.provenanceactionscheme)
138

    
139
		LEFT OUTER JOIN projectpids pp ON (pp.project = p.id)
140
		LEFT OUTER JOIN dsm_identities i ON (i.pid = pp.pid)
141

    
142
		LEFT OUTER JOIN dsm_datasources dc ON (dc.id = p.collectedfrom)
143

    
144
		LEFT OUTER JOIN project_fundingpath pf ON (pf.project = p.id)
145
		LEFT OUTER JOIN fundingpaths fp ON (fp.id = pf.funding)
146

    
147
		LEFT OUTER JOIN project_subject ps ON (ps.project = p.id)
148
		LEFT OUTER JOIN subjects s ON (s.id = ps.subject)
149

    
150
		LEFT OUTER JOIN class sc ON (sc.code = s.semanticclass)
151
		LEFT OUTER JOIN scheme ss ON (ss.code = s.semanticscheme)
152

    
153
	GROUP BY
154
		p.id,
155
		p.code,
156
		p.websiteurl,
157
		p.acronym,
158
		p.title,
159
		p.startdate,
160
		p.enddate,
161
		p.call_identifier,
162
		p.keywords,
163
		p.duration,
164
		p.ec_sc39,
165
		p.oa_mandate_for_publications,
166
		p.ec_article29_3,
167
		p.dateofcollection,
168
		p.inferred,
169
		p.deletedbyinference,
170
		p.trust,
171
		p.inferenceprovenance,
172
		p.contactfullname,
173
		p.contactfax,
174
		p.contactphone,
175
		p.contactemail,
176
		dc.id,
177
		dc.officialname,
178
		cc.code, cc.name, cs.code, cs.name,
179
		pac.code, pac.name, pas.code, pas.name
180
);
181
CREATE INDEX projects_mv_id_idx	ON projects_mv (projectid);
182

    
183
GRANT SELECT ON fundingpaths TO dnetapi;
184

    
185

    
(3-3/19)