diff --git a/Procedures/create_kb_inst_trans_pg.txt b/Procedures/create_kb_inst_trans_pg.txt new file mode 100644 index 0000000000000000000000000000000000000000..00edd48ce559950fbcc54e3112d204287abeb38c --- /dev/null +++ b/Procedures/create_kb_inst_trans_pg.txt @@ -0,0 +1,146 @@ +-- DROP PROCEDURE schema_xyz.create_kb_inst_trans_pg(); + +CREATE OR REPLACE PROCEDURE schema_xyz.create_kb_inst_trans_pg() + LANGUAGE plpgsql +AS $procedure$ + #variable_conflict use_variable +DECLARE + + e RECORD; + a RECORD; +ac cursor is SELECT inst_ante, transition_date from schema_xyz.zzz_kbinsttrans_a; +ec cursor is SELECT inst_post, transition_date from schema_xyz.zzz_kbinsttrans_e; + +BEGIN + +/* Build table */ + +-- in case of existence due to old structure +execute 'drop sequence if exists schema_xyz.seq_kb_inst_trans'; + +execute 'drop table if exists schema_xyz.kb_inst_trans'; + +EXECUTE 'create table schema_xyz.kb_inst_trans ( +inst_ante bigint, +transition_date date, +inst_post bigint, +type varchar +)'; +commit; + +alter table schema_xyz.kb_inst_trans add primary key(inst_ante, inst_post, type); +commit; + +execute 'drop table if exists schema_xyz.zzz_kb_inst_trans'; + +EXECUTE 'create table schema_xyz.zzz_kb_inst_trans ( +inst_ante bigint, +transition_date date, +inst_post bigint, +type bpchar +)'; +commit; + +raise notice 'zzz_kb_inst_trans created'; + +/* Mergers : from descent. */ + +EXECUTE 'insert into schema_xyz.kb_inst_trans ( +select parent, Date_, successor, ''fusion'' +from schema_xyz.descent +where type in (3,1) +and schema_xyz.is_hi_date_neu2_pg(parent,Date_-1)=1 +and schema_xyz.is_hi_date_neu2_pg(successor, Date_)=1)'; +commit; +raise notice 'kb_inst_trans filled'; + + +/* Inclusions */ +EXECUTE 'drop table if exists schema_xyz.zzz_kbinsttrans_e'; + + +EXECUTE 'create table schema_xyz.zzz_kbinsttrans_e as ( +select te_relation.uid_0 as inst_post, hi_relation.uid_1 as inst_ante, te_relation.first_date as transition_date +from schema_xyz.relation hi_relation +join schema_xyz.relation te_relation +on hi_relation.uid_1=te_relation.uid_1 +where hi_relation.uid_0=0 and te_relation.uid_0>0 +and hi_relation.last_date <= te_relation.first_date +and (hi_relation.last_date+1=te_relation.first_date or hi_relation.last_date+2=te_relation.first_date))'; +commit; + +raise notice 'zzz_kbinsttrans_e created'; + +for e in ec + +LOOP +execute 'drop table if exists zzz_tree'; + +CALL schema_xyz.get_hi_tree_for_uid_pg(e.inst_post,e.transition_date,'schema_xyz.zzz_tree'); + +EXECUTE 'insert into schema_xyz.zzz_kb_inst_trans ( +select a.inst_ante, a.transition_date,b.top as inst_post,''inclusion'' +from schema_xyz.zzz_kbinsttrans_e a +join +schema_xyz.zzz_tree b +on a.inst_post=b.u_last) +'; + +execute 'drop table if exists schema_xyz.zzz_tree'; + +END loop; + +/* Outsourcing */ + +EXECUTE 'drop table if exists schema_xyz.zzz_kbinsttrans_a'; + + +EXECUTE 'create table schema_xyz.zzz_kbinsttrans_a as ( +select te_relation.uid_0 as inst_ante, hi_relation.uid_1 as inst_post, hi_relation.first_date as transition_date +from schema_xyz.relation hi_relation +join schema_xyz.relation te_relation +on hi_relation.uid_1=te_relation.uid_1 +where +hi_relation.uid_0=0 and te_relation.uid_0>0 +and hi_relation.first_date >= te_relation.last_date +and (hi_relation.first_date-1=te_relation.last_date or hi_relation.first_date-2=te_relation.last_date))'; + + +for a in ac + +LOOP + +execute 'drop table if exists schema_xyz.zzz_tree'; +CALL schema_xyz.get_hi_tree_for_uid_pg(a.inst_ante, a.transition_date-1,'schema_xyz.zzz_tree'); + +EXECUTE 'insert into schema_xyz.zzz_kb_inst_trans ( +select b.top as inst_ante, a.transition_date, inst_post, ''exclusion'' +from schema_xyz.zzz_kbinsttrans_a a +join +schema_xyz.zzz_tree b +on a.inst_ante=b.u_last +group by b.top, a.transition_date, inst_post)'; + +execute 'drop table if exists schema_xyz.zzz_tree'; + +END LOOP; + + +EXECUTE 'insert into schema_xyz.kb_inst_trans ( +select inst_ante, transition_date, inst_post, type +from +( +select inst_ante, transition_date, inst_post, type +from schema_xyz.zzz_kb_inst_trans +group by inst_ante, transition_date, inst_post, type +) as xxx)'; + +commit; + +execute 'drop table if exists schema_xyz.zzz_kb_inst_trans'; + +end; + + +$procedure$ +;