Project

General

Profile

1
SELECT d.id 						as datasourceid,
2
		d.officialname				as officialname, 
3
		d.englishname				as englishname,
4

    
5
		CASE 
6
			WHEN (array_agg(DISTINCT tcc.compliance::text) @> ARRAY['driver','openaire2.0']) THEN 
7
				'driver-openaire2.0@@@OpenAIRE 2.0+ (DRIVER OA, EC funding)@@@dnet:datasourceCompatibilityLevel@@@dnet:datasourceCompatibilityLevel'
8
			WHEN (array_agg(DISTINCT tcc.compliance::text) @> ARRAY['driver']) THEN
9
				'driver@@@OpenAIRE Basic (DRIVER OA)@@@dnet:datasourceCompatibilityLevel@@@dnet:datasourceCompatibilityLevel'
10
			WHEN (array_agg(DISTINCT tcc.compliance::text) @> ARRAY['openaire2.0']) THEN
11
				'openaire2.0@@@OpenAIRE 2.0 (EC funding)@@@dnet:datasourceCompatibilityLevel@@@dnet:datasourceCompatibilityLevel'
12
			WHEN (array_agg(DISTINCT tcc.compliance::text) @> ARRAY['openaire3.0']) THEN
13
				'openaire3.0@@@OpenAIRE 3.0 (OA, funding)@@@dnet:datasourceCompatibilityLevel@@@dnet:datasourceCompatibilityLevel'
14
			WHEN (array_agg(DISTINCT tcc.compliance::text) @> ARRAY['native']) THEN
15
				'native@@@native@@@dnet:datasourceCompatibilityLevel@@@dnet:datasourceCompatibilityLevel'
16
			WHEN (array_agg(DISTINCT tcc.compliance::text) @> ARRAY['notCompatible']) THEN
17
				'notCompatible@@@under validation@@@dnet:datasourceCompatibilityLevel@@@dnet:datasourceCompatibilityLevel'
18
			ELSE 
19
				'UNKNOWN@@@not available@@@dnet:datasourceCompatibilityLevel@@@dnet:datasourceCompatibilityLevel'
20
		END as openairecompatibility,
21
		
22
		d.websiteurl				as websiteurl,
23
		d.logourl					as logourl,
24
		d.contactemail				as contactemail,
25
		array_agg(DISTINCT CASE
26
			WHEN apc.param='baseUrl' THEN
27
				CASE WHEN COALESCE(apc.edited, '') = ''  THEN apc.original ELSE apc.edited END
28
			ELSE
29
				NULL
30
		END) as accessinfopackage, -- we need baseUrl param only -when available-, but we can not use WHERE clause on apc.param, otherwise we exclude datasources without a baseUrl param and the returned rows are less than we expect.
31
		d.latitude					as latitude,
32
		d.longitude					as longitude,
33
		d.namespaceprefix			as namespaceprefix,
34
		d.od_numberofitems			as odnumberofitems,          	
35
		d.od_numberofitemsdate		as odnumberofitemsdate,      		
36
		array_agg(DISTINCT s.name || '###' || sc.code || '@@@' || sc.name || '@@@' || ss.code || '@@@' || ss.name) as subjects,
37
		d.description				as description,
38
		d.od_policies				as odpolicies,
39
		ARRAY(select trim(s) from unnest(string_to_array(d.od_languages, ',')) as s)  as odlanguages,
40
		ARRAY(select trim(s) from unnest(string_to_array(d.od_contenttypes, '-')) as s) as odcontenttypes,
41
		d.inferred					as inferred,
42
		d.deletedbyinference		as deletedbyinference,
43
		d.trust						as trust,
44
		d.inferenceprovenance		as inferenceprovenance,
45
		d.dateofcollection			as dateofcollection,
46
		d.dateofvalidation			as dateofvalidation,
47
		
48
		-- re3data fields
49
		d.releasestartdate			as releasestartdate,
50
		d.releaseenddate			as releaseenddate,
51
		d.missionstatementurl		as missionstatementurl,
52
		d.dataprovider				as dataprovider,
53
		d.serviceprovider			as serviceprovider,
54
		d.databaseaccesstype		as databaseaccesstype,
55
		d.datauploadtype			as datauploadtype,
56
		d.databaseaccessrestriction	as databaseaccessrestriction,
57
		d.datauploadrestriction		as datauploadrestriction,
58
		d.versioning				as versioning,
59
		d.citationguidelineurl		as citationguidelineurl,
60
		d.qualitymanagementkind		as qualitymanagementkind,
61
		d.pidsystems				as pidsystems,
62
		d.certificates				as certificates,
63
		array_agg(DISTINCT p.name || '&&&' || p.url) as policies,
64
		-- end of re3data fields
65
		
66
		dc.id					as collectedfromid,
67
		dc.officialname			as collectedfromname,
68
		
69
		tc.code || '@@@' || tc.name || '@@@' || ts.code || '@@@' || ts.name	as datasourcetype,
70
		pac.code || '@@@' || pac.name || '@@@' || pas.code || '@@@' || pas.name	as provenanceaction,
71

    
72
		array_agg(DISTINCT i.pid || '###' || idc.code || '@@@' || idc.name || '@@@' || ids.code || '@@@' || ids.name) as pid
73
		
74

    
75
FROM datasources d
76
	left outer join class tc on (tc.code = d.datasourceclass)	
77
	left outer join scheme ts on (ts.code = d.datasourcescheme)
78
	
79
	left outer join class pac on (pac.code = d.provenanceactionclass)	
80
	left outer join scheme pas on (pas.code = d.provenanceactionscheme)		
81

    
82
	left outer join datasourcepids dps on (dps.datasource = d.id)
83
	left outer join identities i on (i.pid = dps.pid)
84
	
85
	left outer join class idc on (idc.code = i.issuertypeclass)
86
	left outer join scheme ids on (ids.code = i.issuertypescheme)
87
	
88
	left outer join datasources dc on (dc.id = d.collectedfrom)
89
	left outer join api on (api.datasource = d.id)
90
	left outer join apicollections apc on (apc.api = api.id)	
91
	
92
	left outer join temp_compliances tcc on (tcc.api = api.id)	
93
	
94
	left outer join datasource_subject ds on (ds.datasource = d.id)
95
	left outer join subjects s on (s.id = ds.subject) 
96
	
97
	left outer join class sc on (sc.code = s.semanticclass)
98
	left outer join scheme ss on (ss.code = s.semanticscheme)
99
	
100
	left outer join datasource_policy dp on (dp.datasource = d.id)
101
	left outer join policies p on (p.id = dp.policy)
102
	
103
--  These clauses have been commented to allow the import of all the datasource on the index 
104
-- WHERE d.datasourceclass != 'entityregistry'
105
--	AND d.openairecompatibilityclass IS NOT null
106
--	AND d.openairecompatibilityclass != 'UNKNOWN'
107
--	AND d.openairecompatibilityclass != 'notCompatible'
108
	
109
GROUP BY 
110
		d.id,
111
		d.officialname, 
112
		d.englishname,
113
		d.websiteurl,
114
		d.logourl,
115
		d.contactemail,
116
		d.namespaceprefix,
117
		d.description,
118
		d.od_numberofitems,          	
119
		d.od_numberofitemsdate,      		
120
		d.od_policies,
121
		d.od_languages,         		
122
		d.od_contenttypes,
123
		d.latitude,
124
		d.longitude,
125
		d.inferred,
126
		d.deletedbyinference,
127
		d.trust,
128
		d.inferenceprovenance,
129
		d.dateofcollection,
130
		d.dateofvalidation,
131
		dc.id,
132
		d.releasestartdate,
133
		d.releaseenddate,
134
		d.missionstatementurl,
135
		d.dataprovider,
136
		d.serviceprovider,
137
		d.databaseaccesstype,
138
		d.datauploadtype,
139
		d.databaseaccessrestriction,
140
		d.datauploadrestriction,
141
		d.versioning,
142
		d.citationguidelineurl,
143
		d.qualitymanagementkind,
144
		d.pidsystems,
145
		d.certificates,
146
		dc.officialname,
147
		tc.code, tc.name, ts.code, ts.name, 
148
		pac.code, pac.name, pas.code, pas.name,
149
		sc.code, sc.name, ss.code, ss.name
(12-12/18)