Project

General

Profile

1
WITH RECURSIVE fundingtree(id, parent_id, payload, depth) 
2
AS (
3
	SELECT  f.id, 
4
		ff.funding1, 
5
		'{"funding_level_0":{"class":"' || f.semanticclass || '", "id":"' || f.id || '", "description":"' || f.description || '", "name":"' || f.name || '", "parent":{}}}', 
6
		1
7
		FROM fundings f LEFT OUTER JOIN funding_funding ff ON f.id = ff.funding1 
8
		WHERE ff.funding2 IS NULL
9
	UNION 
10
	SELECT  f1.id, 
11
		ff.funding2,
12
		'{"funding_level_'||depth||'":{"class":"' || f1.semanticclass || '", "id":"' || f1.id || '", "description":"' || f1.description || '", "name":"' || f1.name || '", "parent":'|| ft.payload ||'}}',
13
		ft.depth + 1
14
		FROM funding_funding ff, fundingtree ft, fundings f2, fundings f1
15
		WHERE ft.id = ff.funding2 AND f2.id = ft.id AND ff.funding1 = f1.id AND depth <= 10)		
16

    
17
SELECT 	p.id 					                    as projectid,
18
		p.code										as code,
19
		p.websiteurl               					as websiteurl,		
20
		p.acronym                  					as acronym,
21
		p.title                    					as title,
22
		p.startdate									as startdate,
23
		p.enddate                 					as enddate,
24
		p.call_identifier          					as callidentifier,
25
		p.keywords									as keywords,		
26
		p.duration									as duration,
27
		p.ec_sc39				                    as ecsc39,
28
		p.dateofcollection							as dateofcollection,
29
		p.inferred									as inferred,
30
		p.deletedbyinference						as deletedbyinference,
31
		p.trust										as trust,
32
		p.inferenceprovenance						as inferenceprovenance,
33
		dc.id										as collectedfromid,
34
		dc.officialname								as collectedfromname,
35
		
36
		cc.code || '@@@' || cc.name || '@@@' || cs.code || '@@@' || cs.name	as contracttype,
37
		pac.code || '@@@' || pac.name || '@@@' || pas.code || '@@@' || pas.name	as provenanceaction,
38
		
39
		array_agg(DISTINCT i.pid || '###' || idc.code || '@@@' || idc.name || '@@@' || ids.code || '@@@' || ids.name)	as pid,
40
		
41
		array_agg(ft.payload)		as fundingtree
42
	
43
FROM projects p
44
	left outer join class cc on (cc.code = p.contracttypeclass)	
45
	left outer join scheme cs on (cs.code = p.contracttypescheme)
46
	
47
	left outer join class pac on (pac.code = p.provenanceactionclass)	
48
	left outer join scheme pas on (pas.code = p.provenanceactionscheme)		
49
	
50
	left outer join projectpids pp on (pp.project = p.id)
51
	left outer join identities i on (i.pid = pp.pid)
52
	left outer join class idc on (idc.code = i.issuertypeclass)
53
	left outer join scheme ids on (ids.code = i.issuertypescheme)
54
	
55
	left outer join datasources dc on (dc.id = p.collectedfrom)
56
	
57
	left outer join project_funding pf on (pf.project = p.id)
58
	left outer join fundingtree ft on (ft.id = pf.funding)
59
	
60
GROUP BY 	
61
		p.id,
62
		p.code,
63
		p.websiteurl,		
64
		p.acronym,
65
		p.title,
66
		p.startdate,
67
		p.enddate,
68
		p.call_identifier,
69
		p.keywords,		
70
		p.duration,
71
		p.ec_sc39,
72
		p.dateofcollection,
73
		p.inferred,
74
		p.deletedbyinference,
75
		p.trust,
76
		p.inferenceprovenance,
77
		dc.id,
78
		dc.officialname,		
79
		cc.code, cc.name, cs.code, cs.name,
80
		pac.code, pac.name, pas.code, pas.name
81
		
82
		
(18-18/18)