Project

General

Profile

1
-- cleanup the unnecessary functions: the following SQL produces the deletion statement list
2
SELECT 'DROP FUNCTION ' || ns.nspname || '.' || proname || '(' || oidvectortypes(proargtypes) || ');'
3
FROM pg_proc
4
	INNER JOIN pg_namespace ns ON (pg_proc.pronamespace = ns.oid)
5
WHERE ns.nspname = 'public'
6
ORDER BY proname;
7

    
8
-- cleanup the unnecessary triggers: the following SQL produces the deletion statement list
9
SELECT 'DROP TRIGGER ' || trg.tgname || ' ON ' || tbl.relname || ';'
10
FROM pg_trigger trg
11
 JOIN pg_class tbl on trg.tgrelid = tbl.oid
12
 JOIN pg_namespace ns ON ns.oid = tbl.relnamespace
13
WHERE trg.tgname like 'notify_%';
14

    
15
-- export the new dnet_dsm schema using
16
--    pg_dump --schema-only -h localhost -U dnet dnet_dsm | gzip -c > /tmp/dnet_dsm.sql.gz
17
-- rename tables and index names in order to include prefix "dsm_"
18
-- import the dsm table schema to the existing openaire database:
19
--    psql -h localhost -U dnet dnet_openaireplus -f dnet_dsm.sql
20

    
21
ALTER TABLE dsm_datasources ALTER COLUMN officialname TYPE VARCHAR(512);
22
ALTER TABLE dsm_datasources ALTER COLUMN englishname TYPE VARCHAR(512);
23
ALTER TABLE dsm_datasources ALTER COLUMN missionstatementurl TYPE VARCHAR(512);
24
ALTER TABLE dsm_datasources ALTER COLUMN citationguidelineurl TYPE VARCHAR(512);
25
ALTER TABLE dsm_datasources ALTER COLUMN languages TYPE text;
26
ALTER TABLE dsm_datasources ALTER COLUMN od_contenttypes TYPE text;
27
ALTER TABLE dsm_datasources ALTER COLUMN subjects TYPE text;
28
ALTER TABLE dsm_datasources ALTER COLUMN description TYPE text;
29
ALTER TABLE dsm_datasources ALTER COLUMN certificates TYPE text;
30
ALTER TABLE dsm_datasources ALTER COLUMN pidsystems TYPE text;
31

    
32
-- insert into the new dsm_* tables picking the information from the old tables
33
insert into dsm_datasources (id, officialname, englishname, websiteurl, logourl, contactemail, latitude, longitude, timezone, namespaceprefix, languages, od_contenttypes, collectedfrom, dateofvalidation,
34
                             typology, provenanceaction, dateofcollection, platform, activationid, description,releasestartdate, releaseenddate, missionstatementurl, dataprovider, serviceprovider,
35
                             databaseaccesstype, datauploadtype,databaseaccessrestriction, datauploadrestriction, versioning, citationguidelineurl, qualitymanagementkind,pidsystems, certificates,
36
                             aggregator, issn, eissn, lissn, registeredby, subjects)
37
select d.id, 
38
	d.officialname, 
39
	d.englishname, 
40
	d.websiteurl, 
41
	d.logourl, 
42
	d.contactemail, 
43
	d.latitude, 
44
	d.longitude, 
45
	d.timezone, 
46
	d.namespaceprefix as namespaceprefix,
47
	ARRAY(select trim(s) from unnest(string_to_array(d.od_languages, ',')) as s) as languages,
48
	ARRAY(select trim(s) from unnest(string_to_array(d.od_contenttypes, '-')) as s) as od_contenttypes,
49
	d.collectedfrom,
50
	d.dateofvalidation,
51
	d.datasourceclass as typology,
52
	d.provenanceactionclass as provenanceaction,
53
	d.dateofcollection,	
54
	d.typology as platform,
55
	d.activationid,
56
	d.description,
57
	d.releasestartdate,
58
	d.releaseenddate,
59
	d.missionstatementurl,
60
	d.dataprovider as dataprovider,
61
	d.serviceprovider as serviceprovider,
62
	d.databaseaccesstype,
63
	d.datauploadtype,
64
	d.databaseaccessrestriction,
65
	d.datauploadrestriction,
66
	d.versioning,
67
	d.citationguidelineurl,
68
	d.qualitymanagementkind,
69
	d.pidsystems,
70
	d.certificates,
71
	d.aggregator,
72
	d.issn,
73
	d.eissn,
74
	d.lissn,
75
	d.registeredby,
76
	ARRAY_AGG(s.name) as subjects
77
from datasources d
78
	left outer join datasource_subject sd on (d.id = sd.datasource)
79
	left outer join subjects s on (sd.subject = s.id)
80
group by
81
	d.id;
82

    
83
insert into dsm_api (id, protocol, datasource, contentdescription, active, removable, typology, compatibility)
84
select a.id,
85
	a.protocolclass as protocol,
86
	a.datasource,
87
	a.contentdescriptionclass as contentdescription,
88
	a.active,
89
	a.removable,
90
	a.typologyclass as typology,
91
	a.compatibilityclass as compatibility
92
from api a;
93

    
94
update dsm_api da set metadata_identifier_path = ac.original from apicollections ac where da.id = ac.api and ac.param = 'metadata_identifier_path' ;
95
update dsm_api da set last_collection_total = ac.original::integer from apicollections ac where da.id = ac.api and ac.param = 'last_collection_total' ;
96
update dsm_api da set last_collection_date = ac.original::date from apicollections ac where da.id = ac.api and ac.param = 'last_collection_date' ;
97
update dsm_api da set last_collection_mdid = ac.original from apicollections ac where da.id = ac.api and ac.param = 'last_collection_mdid' ;
98
update dsm_api da set last_aggregation_total = ac.original::integer from apicollections ac where da.id = ac.api and ac.param = 'last_aggregation_total' ;
99
update dsm_api da set last_aggregation_date = ac.original::date from apicollections ac where da.id = ac.api and ac.param = 'last_aggregation_date' ;
100
update dsm_api da set last_aggregation_mdid = ac.original from apicollections ac where da.id = ac.api and ac.param = 'last_aggregation_mdid' ;
101
update dsm_api da set last_download_total = ac.original::integer from apicollections ac where da.id = ac.api and ac.param = 'last_download_total' ;
102
update dsm_api da set last_download_date = ac.original::date from apicollections ac where da.id = ac.api and ac.param = 'last_download_date' ;
103
update dsm_api da set last_download_objid = ac.original from apicollections ac where da.id = ac.api and ac.param = 'last_download_objid' ;
104
update dsm_api da set last_validation_job = ac.original from apicollections ac where da.id = ac.api and ac.param = 'last_validation_job' ;
105
update dsm_api da set baseurl = CASE WHEN (ac.edited is not null and ac.edited != '') THEN ac.edited ELSE ac.original END from apicollections ac where da.id = ac.api and ac.param = 'baseUrl' ;
106

    
107
insert into dsm_apiparams (param,value, api)
108
select
109
	a.param,
110
	CASE
111
		WHEN (a.edited is not null and a.edited != '') THEN a.edited ELSE a.original
112
	END AS value,
113
	a.api
114
from apicollections a
115
where	param != 'baseUrl' AND accessparam is true;
116

    
117

    
118
ALTER TABLE dsm_organizations ALTER COLUMN websiteurl TYPE text;
119

    
120
INSERT INTO dsm_organizations (id, legalshortname,legalname,websiteurl, logourl,ec_legalbody, ec_legalperson, ec_nonprofit, ec_researchorganization, ec_highereducation, ec_internationalorganizationeurinterests,
121
                               ec_internationalorganization, ec_enterprise, ec_smevalidated, ec_nutscode, country, collectedfrom, dateofcollection, provenanceaction)
122
	SELECT
123
		o.id,
124
		o.legalshortname,
125
		o.legalname,
126
		o.websiteurl,
127
		o.logourl,
128
		o.ec_legalbody,
129
		o.ec_legalperson,
130
		o.ec_nonprofit,
131
		o.ec_researchorganization,
132
		o.ec_highereducation,
133
		o.ec_internationalorganizationeurinterests,
134
		o.ec_internationalorganization,
135
		o.ec_enterprise,
136
		o.ec_smevalidated,
137
		o.ec_nutscode,
138
		o.countryclass          AS country,
139
		o.collectedfrom,
140
		o.dateofcollection,
141
		o.provenanceactionclass AS provenanceaction
142
	FROM organizations o;
143

    
144
INSERT INTO dsm_datasource_organization (datasource, organization)
145
	SELECT
146
		dorg.datasource,
147
		dorg.organization
148
	FROM datasource_organization dorg;
149

    
150

    
151
INSERT INTO dsm_identities (pid, issuertype)
152
	SELECT
153
		i.pid,
154
		i.issuertypeclass AS issuertype
155
	FROM identities i;
156

    
157
INSERT INTO dsm_datasourcepids (datasource, pid)
158
	SELECT
159
		dp.datasource,
160
		dp.pid
161
	FROM datasourcepids dp;
162

    
163
-- is this table needed? --
164
INSERT INTO dsm_organizationpids (organization, pid)
165
	SELECT
166
		op.organization,
167
		op.pid
168
	FROM organizationpids op;
169

    
170
-- !!!!! data insert complete !!!!!
171
-- TODO add below the deletion statements for the old tables.
172

    
173

    
174

    
175

    
176

    
177

    
178

    
179

    
180

    
181

    
182

    
183

    
184

    
185

    
186

    
187

    
188

    
189

    
190

    
(2-2/13)