From b5e9f73eb194b5c909567e7ca5cadc0c801f0783 Mon Sep 17 00:00:00 2001 From: dimitrispie Date: Thu, 3 Nov 2022 13:00:01 +0200 Subject: [PATCH] Changes for result__country in observatory step --- .../graph/stats/oozie_app/config-default.xml | 2 +- .../graph/stats/oozie_app/scripts/step13.sql | 7 +- .../scripts/step21-createObservatoryDB.sql | 70 ++++++++----------- .../dhp/oa/graph/stats/oozie_app/workflow.xml | 4 +- 4 files changed, 37 insertions(+), 46 deletions(-) diff --git a/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/config-default.xml b/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/config-default.xml index 9331d4ac5..63fc84d75 100644 --- a/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/config-default.xml +++ b/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/config-default.xml @@ -21,7 +21,7 @@ hive_jdbc_url - jdbc:hive2://iis-cdh5-test-m3.ocean.icm.edu.pl:10000 + jdbc:hive2://iis-cdh5-test-m3.ocean.icm.edu.pl:10000/;UseNativeQuery=1;?spark.executor.memory=19166291558;spark.yarn.executor.memoryOverhead=3225;spark.driver.memory=11596411699;spark.yarn.driver.memoryOverhead=1228 oozie.wf.workflow.notification.url diff --git a/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/scripts/step13.sql b/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/scripts/step13.sql index 24e1a1355..86251ea2e 100644 --- a/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/scripts/step13.sql +++ b/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/scripts/step13.sql @@ -110,4 +110,9 @@ where relClass='Cites' and rel.datainfo.provenanceaction.classid = 'sysimport:cr and r1.resulttype.classname != 'other' and r2.resulttype.classname != 'other' and rel.datainfo.deletedbyinference=false and rel.datainfo.invisible = FALSE -group by substr(source, 4); \ No newline at end of file +group by substr(source, 4); + +CREATE TABLE IF NOT EXISTS ${stats_db_name}.result_country stored as parquet as +SELECT DISTINCT substr(res.id, 4) as id, code as code FROM ${openaire_db_name}.result res +LATERAL VIEW explode(res.country.classid) country as code +WHERE res.datainfo.deletedbyinference = FALSE and res.datainfo.invisible = FALSE; \ No newline at end of file diff --git a/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/scripts/step21-createObservatoryDB.sql b/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/scripts/step21-createObservatoryDB.sql index e24370e7d..342d60aaa 100644 --- a/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/scripts/step21-createObservatoryDB.sql +++ b/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/scripts/step21-createObservatoryDB.sql @@ -25,9 +25,8 @@ select r.type, c.code as ccode, c.name as cname from ${stats_db_name}.result r - join ${stats_db_name}.result_organization ro on ro.id=r.id - join ${stats_db_name}.organization o on o.id=ro.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id left outer join ${stats_db_name}.result_pids pids on pids.id=r.id left outer join ${observatory_db_name}.result_cc_licence rln on rln.id=r.id @@ -54,9 +53,8 @@ select r.type, r.year from ${stats_db_name}.result r - join ${stats_db_name}.result_organization ro on ro.id=r.id - join ${stats_db_name}.organization o on o.id=ro.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id left outer join ${stats_db_name}.result_pids pids on pids.id=r.id left outer join ${observatory_db_name}.result_cc_licence rln on rln.id=r.id @@ -83,9 +81,8 @@ select r.type, r.year, c.code as ccode, c.name as cname from ${stats_db_name}.result r - join ${stats_db_name}.result_organization ro on ro.id=r.id - join ${stats_db_name}.organization o on o.id=ro.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id left outer join ${stats_db_name}.result_pids pids on pids.id=r.id left outer join ${observatory_db_name}.result_cc_licence rln on rln.id=r.id @@ -112,9 +109,8 @@ select r.type, d.name as dname from ${stats_db_name}.result r - join ${stats_db_name}.result_organization ro on ro.id=r.id - join ${stats_db_name}.organization o on o.id=ro.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' left outer join ${stats_db_name}.result_datasources rd on rd.id=r.id left outer join ${stats_db_name}.datasource d on d.id=rd.datasource left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id @@ -143,9 +139,8 @@ select r.type, d.name as dname, c.code as ccode, c.name as cname from ${stats_db_name}.result r - join ${stats_db_name}.result_organization ro on ro.id=r.id - join ${stats_db_name}.organization o on o.id=ro.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' left outer join ${stats_db_name}.result_datasources rd on rd.id=r.id left outer join ${stats_db_name}.datasource d on d.id=rd.datasource left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id @@ -232,9 +227,8 @@ select r.type, p.funder as pfunder from ${stats_db_name}.result r - join ${stats_db_name}.result_organization ro on ro.id=r.id - join ${stats_db_name}.organization o on o.id=ro.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' join ${stats_db_name}.result_projects rp on rp.id=r.id join ${stats_db_name}.project p on p.id=rp.project left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id @@ -263,9 +257,8 @@ select r.type, p.funder as pfunder, c.code as ccode, c.name as cname from ${stats_db_name}.result r - join ${stats_db_name}.result_organization ro on ro.id=r.id - join ${stats_db_name}.organization o on o.id=ro.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' join ${stats_db_name}.result_projects rp on rp.id=r.id join ${stats_db_name}.project p on p.id=rp.project left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id @@ -296,9 +289,8 @@ select from ${stats_db_name}.result r join ${stats_db_name}.result_datasources rd on rd.id=r.id join ${stats_db_name}.datasource d on d.id=rd.datasource and d.type in ('Institutional Repository','Data Repository', 'Repository', 'Publication Repository') - join ${stats_db_name}.datasource_organizations dor on dor.id=d.id - join ${stats_db_name}.organization o on o.id=dor.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id left outer join ${stats_db_name}.result_pids pids on pids.id=r.id left outer join ${observatory_db_name}.result_cc_licence rln on rln.id=r.id @@ -327,9 +319,8 @@ select from ${stats_db_name}.result r join ${stats_db_name}.result_datasources rd on rd.id=r.id join ${stats_db_name}.datasource d on d.id=rd.datasource and d.type in ('Institutional Repository','Data Repository', 'Repository', 'Publication Repository') - join ${stats_db_name}.datasource_organizations dor on dor.id=d.id - join ${stats_db_name}.organization o on o.id=dor.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id left outer join ${stats_db_name}.result_pids pids on pids.id=r.id left outer join ${observatory_db_name}.result_cc_licence rln on rln.id=r.id @@ -358,9 +349,8 @@ select from ${stats_db_name}.result r join ${stats_db_name}.result_datasources rd on rd.id=r.id join ${stats_db_name}.datasource d on d.id=rd.datasource and d.type in ('Institutional Repository','Data Repository', 'Repository', 'Publication Repository') - join ${stats_db_name}.datasource_organizations dor on dor.id=d.id - join ${stats_db_name}.organization o on o.id=dor.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id left outer join ${stats_db_name}.result_pids pids on pids.id=r.id left outer join ${observatory_db_name}.result_cc_licence rln on rln.id=r.id @@ -389,9 +379,8 @@ select from ${stats_db_name}.result r join ${stats_db_name}.result_datasources rd on rd.id=r.id join ${stats_db_name}.datasource d on d.id=rd.datasource and d.type in ('Institutional Repository','Data Repository', 'Repository', 'Publication Repository') - join ${stats_db_name}.datasource_organizations dor on dor.id=d.id - join ${stats_db_name}.organization o on o.id=dor.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id left outer join ${stats_db_name}.result_pids pids on pids.id=r.id left outer join ${observatory_db_name}.result_cc_licence rln on rln.id=r.id @@ -420,9 +409,8 @@ select from ${stats_db_name}.result r join ${stats_db_name}.result_datasources rd on rd.id=r.id join ${stats_db_name}.datasource d on d.id=rd.datasource and d.type in ('Institutional Repository','Data Repository', 'Repository', 'Publication Repository') - join ${stats_db_name}.datasource_organizations dor on dor.id=d.id - join ${stats_db_name}.organization o on o.id=dor.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id left outer join ${stats_db_name}.result_pids pids on pids.id=r.id left outer join ${observatory_db_name}.result_cc_licence rln on rln.id=r.id @@ -513,9 +501,8 @@ select from ${stats_db_name}.result r join ${stats_db_name}.result_datasources rd on rd.id=r.id join ${stats_db_name}.datasource d on d.id=rd.datasource and d.type in ('Institutional Repository','Data Repository', 'Repository', 'Publication Repository') - join ${stats_db_name}.datasource_organizations dor on dor.id=d.id - join ${stats_db_name}.organization o on o.id=dor.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' join ${stats_db_name}.result_projects rp on rp.id=r.id join ${stats_db_name}.project p on p.id=rp.project left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id @@ -546,9 +533,8 @@ select from ${stats_db_name}.result r join ${stats_db_name}.result_datasources rd on rd.id=r.id join ${stats_db_name}.datasource d on d.id=rd.datasource and d.type in ('Institutional Repository','Data Repository', 'Repository', 'Publication Repository') - join ${stats_db_name}.datasource_organizations dor on dor.id=d.id - join ${stats_db_name}.organization o on o.id=dor.organization - join ${stats_db_name}.country c on c.code=o.country and c.continent_name='Europe' + join ${stats_db_name}.result_country rc on rc.id=r.id + join ${stats_db_name}.country c on c.code=rc.code and c.continent_name='Europe' join ${stats_db_name}.result_projects rp on rp.id=r.id join ${stats_db_name}.project p on p.id=rp.project left outer join ${stats_db_name}.result_licenses rl on rl.id=r.id diff --git a/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/workflow.xml b/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/workflow.xml index 08d33f4e8..d8ec4cbb5 100644 --- a/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/workflow.xml +++ b/dhp-workflows/dhp-stats-update/src/main/resources/eu/dnetlib/dhp/oa/graph/stats/oozie_app/workflow.xml @@ -1,4 +1,4 @@ - + stats_db_name @@ -70,7 +70,7 @@ - + Action failed, error message[${wf:errorMessage(wf:lastErrorNode())}]