diff --git a/Procedures/address_to_top_uid_pg_text__text__text__text__text__text_.txt b/Procedures/address_to_top_uid_pg_text__text__text__text__text__text_.txt new file mode 100644 index 0000000000000000000000000000000000000000..97260f16e5aee7015edc98348da9ff542ed54eb0 --- /dev/null +++ b/Procedures/address_to_top_uid_pg_text__text__text__text__text__text_.txt @@ -0,0 +1,265 @@ +-- DROP PROCEDURE schema_xyz.address_to_top_uid_pg(text, text, text, text, text, text); + +CREATE OR REPLACE PROCEDURE schema_xyz.address_to_top_uid_pg(ursprungstabelle text, input_table text, output_table_str text, output_table_str_ii text, modus text, process_name text) + LANGUAGE plpgsql +AS $procedure$ + BEGIN + +DECLARE + + +output_table varchar(500); +output_table_II varchar(500); +input_table_without_schema character varying:= split_part(input_table,'.',2); +output_table_without_schema character varying:= split_part(output_table_str,'.',2); +output_table_II_without_schema character varying:= split_part(output_table_str_ii,'.',2); +ursprungstabelle_without_schema character varying:= split_part(ursprungstabelle ,'.',2); +ursprungstabelle_schema character varying := split_part(ursprungstabelle ,'.',1); + + +BEGIN + + +/************************************* Modus S *****************************************************/ +RAISE NOTICE 'output_table: %s', output_table ; +RAISE NOTICE 'output_table_without_schema: %s', output_table_without_schema ; + +RAISE NOTICE 'ursprungstabelle: %s', ursprungstabelle ; + +EXECUTE 'drop index if exists '||ursprungstabelle_schema ||'.i_'||ursprungstabelle_without_schema ||'_adrid'; +EXECUTE 'create index i_'||ursprungstabelle_without_schema||'_adrid on '||ursprungstabelle||' (adr_id)'; + +if upper(modus)='S' THEN + +output_table:=output_table_str||'_S'; +output_table_II:=output_table_str_II||'_S'; + +execute 'drop table if exists '||output_table; +EXECUTE 'create table '||output_table||' +as +select +c.adr_id, +c.aff_seq_nr,a.address_full,a.city, c.pubyear, a.uid_, b.top +from +schema_xyz.result_VI a +join +'||ursprungstabelle||' c +on a.adr_id=c.adr_id +left join +schema_xyz.X_TOP_S3 b +on a.uid_=b.u_last +WHERE c.pubyear >= 1000 +AND ( (c.pubyear >= extract(YEAR from b.first) AND extract(MONTH from b.first) = 01 AND extract(DAY from b.first) = 01) + OR (c.pubyear > extract(YEAR from b.first) AND (extract(MONTH from b.first) != 01 OR extract(DAY from b.first)!= 01) AND extract(YEAR from b.first) != extract(YEAR from b.last)) + OR (c.pubyear >= extract(YEAR from b.first) AND (extract(MONTH from b.first) != 01 OR extract(DAY from b.first)!= 01) AND extract(YEAR from b.first) = extract(YEAR from b.last)) + ) +AND c.pubyear <= extract(YEAR from b.last) +group by c.adr_id, +c.aff_seq_nr, a.address_full,a.city, c.pubyear, a.uid_, b.top +'; +commit; + +execute 'insert into schema_xyz.process_info select '''||process_name||''', ''....substep 1'', '''||current_timestamp::varchar||''' '; +commit; + +EXECUTE 'insert into '||output_table||' +select +a.adr_id, ac.aff_seq_nr,a.address_full,a.city, ac.pubyear, a.uid_, b.top +from +schema_xyz.result_VI a +join +'||ursprungstabelle||' ac +on a.adr_id=ac.adr_id +left join +schema_xyz.X_TOP_S3 b +on a.uid_=b.u_last +LEFT JOIN +schema_xyz.X_closed c +ON c.u_last = b.u_last AND c.top=b.top +WHERE ac.pubyear >= 1000 +AND ac.pubyear > extract(YEAR from b.last) +AND ac.pubyear <= extract(YEAR from b.last) +2 +AND c.u_last IS NOT NULL +group by a.adr_id, ac.aff_seq_nr,a.address_full,a.city, ac.pubyear, a.uid_, b.top +'; +commit; + +execute 'insert into schema_xyz.process_info select '''||process_name||''', ''....substep 2'', '''||current_timestamp::varchar||''' '; +commit; + + +EXECUTE 'insert into '||output_table||' +select +a.adr_id, ac.aff_seq_nr,a.address_full,a.city, ac.pubyear, a.uid_, b.top +from +schema_xyz.result_VI a +join +'||ursprungstabelle||' ac +on a.adr_id=ac.adr_id +left join +schema_xyz.X_TOP_S3 b +on a.uid_=b.u_last +LEFT JOIN +schema_xyz.X_closed c +ON c.u_last = b.u_last AND c.top=b.top +WHERE ac.pubyear >= 1000 +AND ac.pubyear > extract(YEAR from b.last) +AND ac.pubyear > extract(YEAR from b.last) +2 +AND c.u_last IS NOT NULL +group by a.adr_id, ac.aff_seq_nr,a.address_full,a.city, ac.pubyear, a.uid_, b.top '; +commit; + +execute 'insert into schema_xyz.process_info select '''||process_name||''', ''....substep 3'', '''||current_timestamp::varchar||''' '; +commit; + + +EXECUTE 'insert into '||output_table||' +select +a.adr_id, ac.aff_seq_nr,a.address_full,a.city, ac.pubyear, a.uid_, b.top +from +schema_xyz.result_VI a +join +'||ursprungstabelle||' ac +on a.adr_id=ac.adr_id +left join +schema_xyz.X_TOP_S3 b +on a.uid_=b.u_last +LEFT JOIN +schema_xyz.X_PRE_START c +ON c.u_last = b.u_last AND c.top=b.top +WHERE ac.pubyear >= 1000 +AND ac.pubyear < extract(YEAR from b.first) +AND c.u_last IS NOT NULL +group by a.adr_id, ac.aff_seq_nr,a.address_full,a.city, ac.pubyear, a.uid_, b.top '; +commit; + +execute 'insert into schema_xyz.process_info select '''||process_name||''', ''....substep 4'', '''||current_timestamp::varchar||''' '; +commit; + +raise notice 'output_table_without_schema: %s', output_table_without_schema; + +EXECUTE 'drop index if exists schema_xyz.i_'||output_table_without_schema ||'_top'; +EXECUTE 'drop index if exists schema_xyz.i_'||output_table_without_schema ||'_adr_id'; +EXECUTE 'drop index if exists schema_xyz.i_'||output_table_without_schema ||'_pubyear'; +EXECUTE 'drop index if exists schema_xyz.i_'||output_table_without_schema ||'_uid_'; + +EXECUTE 'create index i_'||output_table_without_schema ||'_top on '||output_table||' (top)'; +EXECUTE 'create index i_'||output_table_without_schema ||'_adr_id on '||output_table||' (adr_id)'; +EXECUTE 'create index i_'||output_table_without_schema ||'_pubyear on '||output_table||' (pubyear)'; +EXECUTE 'create index i_'||output_table_without_schema ||'_uid_ on '||output_table||' (uid_)'; + + +execute 'insert into schema_xyz.process_info select '''||process_name||''', ''....substep 5 (index creation)'', '''||current_timestamp::varchar||''' '; +commit; + + +/*********************** Attaching to the original input table ************************************/ + +EXECUTE 'drop table if exists '||output_table_II; +EXECUTE 'create table '||output_table_II||' +as +select b.top, a.item_id, a.aff_seq_nr, a.address_full, a.city, a.pubyear, b.adr_id +from +'||ursprungstabelle||' a +join +'||output_table||' b +on a.adr_id=b.adr_id and a.pubyear=b.pubyear and a.aff_seq_nr=b.aff_seq_nr +group by b.top, a.item_id, a.aff_seq_nr, a.address_full, a.city, a.pubyear, b.adr_id +'; + +execute 'insert into schema_xyz.process_info select '''||process_name||''', ''....substep 6'', '''||current_timestamp::varchar||''' '; +commit; + + +execute 'drop index if exists schema_xyz.i_'||output_table_II_without_schema ||'_adr_id'; +EXECUTE 'create index i_'||output_table_II_without_schema ||'_adr_id on '||output_table_II||' (adr_id)'; + + +end if; + +/******************************************************************************************************************************************************************/ + +if upper(modus)='A' THEN + + RAISE NOTICE 'Start Modus A Connect '; + RAISE NOTICE '%', LOCALTIMESTAMP; + RAISE NOTICE '~~~~~~~~~~~~~~~~~~~~~~~~~~~~'; + + +output_table:=output_table_str||'_A'; +output_table_II:=output_table_str_II||'_A'; + + +EXECUTE 'drop table if exists '||output_table; +EXECUTE 'create table '||output_table||' +as +select +a.adr_id, c2.aff_seq_nr, c2.address_full, c2.city, c2.pubyear, a.uid_, b.HI as top, c2.item_id +from +schema_xyz.result_VI a +join +'||ursprungstabelle||' c2 +on a.adr_id=c2.adr_id +join +schema_xyz.modus_a_connect_plus_7 b +on a.uid_=b.TE +where a.uid_ is not null +GROUP BY a.adr_id, c2.aff_seq_nr,c2.address_full,c2.city, c2.pubyear, a.uid_, b.HI, c2.item_id '; +commit; + +execute 'insert into schema_xyz.process_info select '''||process_name||''', ''....substep 7'', '''||current_timestamp::varchar||''' '; +commit; + + +execute 'drop index if exists schema_xyz.i_'||output_table_without_schema ||'_adr_id'; +execute 'drop index if exists schema_xyz.i_'||output_table_without_schema ||'_top'; +execute 'drop index if exists schema_xyz.i_'||output_table_without_schema ||'_address_full'; +execute 'drop index if exists schema_xyz.i_'||output_table_without_schema ||'_city'; +execute 'drop index if exists schema_xyz.i_'||output_table_without_schema ||'_pk_inst'; + +EXECUTE 'create index i_'||output_table_without_schema ||'_adr_id on '||output_table||' (adr_id)'; +EXECUTE 'create index i_'||output_table_without_schema ||'_top on '||output_table||' (top)'; +EXECUTE 'create index i_'||output_table_without_schema ||'_address_full on '||output_table||' (address_full)'; +EXECUTE 'create index i_'||output_table_without_schema ||'_city on '||output_table||' (city)'; +EXECUTE 'create index i_'||output_table_without_schema ||'_pk_inst on '||output_table||' (aff_seq_nr)'; + +execute 'insert into schema_xyz.process_info select '''||process_name||''', ''....substep 8'', '''||current_timestamp::varchar||''' '; +commit; + + +execute 'drop table if exists '||output_table_II; +EXECUTE 'create table '||output_table_II||' +as +select top, item_id, aff_seq_nr, address_full, city, pubyear, adr_id +from +'||output_table||' +group by top, item_id, aff_seq_nr, address_full, city, pubyear, adr_id +'; + +execute 'insert into schema_xyz.process_info select '''||process_name||''', ''....substep 9'', '''||current_timestamp::varchar||''' '; +commit; + + +execute 'drop index if exists schema_xyz.i_'||output_table_II_without_schema ||'_adr_id'; +EXECUTE 'create index i_'||output_table_II_without_schema ||'_adr_id on '||output_table_II||' (adr_id)'; + +end if; + + +/* +Exclusion of some HI +*/ +EXECUTE 'DELETE FROM '||output_table||' +WHERE +top = 1 +OR top = 230 +OR top = 4233 +OR top = 4751 +OR top = 4752'; + +commit; + +END; +end; +$procedure$ +;