Skip to content
Snippets Groups Projects
Commit 34d48ebb authored by Christopher Lenke's avatar Christopher Lenke
Browse files

23.09.2024

parent 58225e54
No related branches found
No related tags found
No related merge requests found
-- DROP PROCEDURE schema_xyz.create_download_pg_ii(varchar, varchar, varchar, varchar, varchar, varchar, int8);
CREATE OR REPLACE PROCEDURE schema_xyz.create_download_pg_ii(source_schema_name character varying, source_item_tablename character varying, source_affiliation_tablename character varying, target_schema character varying, desired_tablename character varying, data_format character varying, limit_size bigint)
LANGUAGE plpgsql
AS $procedure$
DECLARE
create_string varchar(2000);
source_item_tab varchar(100);
source_aff_tab varchar(100);
desired_tab varchar(300);
BEGIN
/*
data format has to be wos or scp
restriction to countrycode 'DEU'
limit_size of 0 means no limitation, all deu addresses
no random sampling
**/
source_item_tab = source_schema_name || '.' || source_item_tablename;
source_aff_tab = source_schema_name || '.' || source_affiliation_tablename;
desired_tab = target_schema || '.' || desired_tablename;
EXECUTE 'drop table if exists '||desired_tab;
EXECUTE 'drop table if exists '||desired_tab||'_ztab_1';
if (lower(data_format) = 'wos') then
if (limit_size = '0') then
execute 'create table '||desired_tab||'_ztab_1 as (
SELECT item_id, aff_seq_nr, city, organization, wos_suborganization,
wos_street, postal_code, country
FROM '||source_aff_tab||'
where countrycode=''DEU'')';
commit;
else
execute 'create table '||desired_tab||'_ztab_1 as (
SELECT item_id, aff_seq_nr, city, organization, wos_suborganization,
wos_street, postal_code, country
FROM '||source_aff_tab||'
where countrycode=''DEU''
limit '||limit_size||')';
commit;
end if;
raise notice 'Step 1 done: ztab 1 created';
execute 'drop index if exists ' || target_schema || '.i_' ||desired_tablename||'_ztab_1';
execute 'create index i_' ||desired_tablename||'_ztab_1 on '|| desired_tab ||'_ztab_1(item_id)';
commit;
raise notice 'Step 2 done: Index creation.';
execute 'create table '||desired_tab||' as (
SELECT a.item_id, a.aff_seq_nr, a.city, a.organization, a.wos_suborganization,
a.wos_street, a.postal_code, a.country, b.pubyear
FROM '||desired_tab||'_ztab_1 a
join '||source_item_tab||' b
on a.item_id=b.item_id)';
commit;
execute 'alter table '||desired_tab||' add column address_full varchar(2000)';
commit;
raise notice 'Step 3 done: Table creation done with pubyear.';
execute 'update '||desired_tab||' set city = trim(both from city)';
commit;
execute 'update '||desired_tab||' set wos_street = trim(both from wos_street)';
commit;
execute 'update '||desired_tab||' set postal_code = trim(both from postal_code)';
commit;
execute 'update '||desired_tab||' set country = trim(both from country)';
commit;
raise notice 'Step 4 done: trim done.';
execute 'update '||desired_tab||' set address_full=array_to_string(organization || wos_suborganization ||
trim(both from wos_street) ||
trim(both from postal_code|| '' '' ||city) ||
trim(both from country)
, '', '')';
commit;
raise notice 'Step 5 done: address full creation done.';
elsif (lower(data_format) = 'scp') then
if (limit_size <> '0') then
execute 'create table '||desired_tab||'_ztab_1 as (
SELECT item_id, aff_seq_nr, scopus_city_group as city, organization,
scopus_address_part, country, countrycode
FROM '||source_aff_tab||'
where countrycode=''DEU''
limit '||limit_size ||')';
else
execute 'create table '||desired_tab||'_ztab_1 as (
SELECT item_id, aff_seq_nr, scopus_city_group as city, organization,
scopus_address_part, country, countrycode
FROM '||source_aff_tab||'
where countrycode=''DEU'')';
end if;
raise notice 'Step 1 done: ztab 1 created';
execute 'drop index if exists ' || target_schema || '.i_' ||desired_tablename||'_ztab_1';
execute 'create index i_' ||desired_tablename||'_ztab_1 on '|| desired_tab ||'_ztab_1(item_id)';
commit;
raise notice 'Step 2 done: Index creation.';
execute 'create table '||desired_tab||' as (
SELECT a.item_id, a.aff_seq_nr, a.city, a.organization,
a.scopus_address_part, a.country, a.countrycode, b.pubyear
FROM '||desired_tab||'_ztab_1 a
join '||source_item_tab||' b
on a.item_id=b.item_id)';
commit;
execute 'alter table '||desired_tab||' add column address_full varchar(2000)';
commit;
raise notice 'Step 3 done: Table creation done with pubyear.';
execute 'update '||desired_tab||' set city = trim(both from city)';
commit;
execute 'update '||desired_tab||' set scopus_address_part = trim(both from scopus_address_part)';
commit;
execute 'update '||desired_tab||' set country = trim(both from country)';
commit;
raise notice 'Step 4 done: trim done.';
execute 'update '||desired_tab||' set address_full=array_to_string(organization ||
trim(both from scopus_address_part) ||
trim(both from city) ||
trim(both from country) ||
trim(both from countrycode)
, '', '') ';
commit;
raise notice 'Step 5 done: address full creation done.';
else
RAISE EXCEPTION 'unknown data format, has to be wos or scp';
end if;
-- cleanup
execute 'update '||desired_tab||'
set address_full = regexp_replace(address_full, ''(, ){2,}'', '', '')
where address_full like ''%, , %'' ';
execute 'drop table if exists '||desired_tab||'_ztab_1';
commit;
END;
$procedure$
;
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment