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

23.09.2024

parent ed42219a
No related branches found
No related tags found
No related merge requests found
-- DROP PROCEDURE schema_xyz.create_kb_tables_pg(text, text, text);
CREATE OR REPLACE PROCEDURE schema_xyz.create_kb_tables_pg(input_table_a text, input_table_s text, result_suffix text)
LANGUAGE plpgsql
AS $procedure$
BEGIN
/*
Parameters:
input_table_a: result_VIII_a
input_table_s: result_VIII_s
new structure
- kb_inst
- kb_sectors
- kb_inst_trans
- kb_a_inst_sec
- kb_s_inst_sec
- kb_a_addr_inst_sec
- kb_s_addr_inst_sec
*/
/* Basis */
EXECUTE 'drop table if exists schema_xyz.KB_INST cascade';
EXECUTE 'drop table if exists schema_xyz.KB_SECTORS cascade';
EXECUTE 'drop table if exists schema_xyz.KB_INST_TRANS cascade';
EXECUTE 'drop table if exists schema_xyz.KB_A_INST_SEC cascade';
EXECUTE 'drop table if exists schema_xyz.KB_S_INST_SEC cascade';
/* Assignments */
EXECUTE 'drop table if exists schema_xyz.kb_a_addr_inst_sec cascade';
EXECUTE 'drop table if exists schema_xyz.kb_s_addr_inst_sec cascade';
/************ BASIC-TABLES ****************/
/* KB_INST */
/*
kb_inst_id (= uid_)
name
first_year
last_year
*/
EXECUTE 'create table schema_xyz.kb_inst as (select
uid_ as kb_inst_id,
schema_xyz.get_name_pg(uid_) as name,
extract(year from first_date) as first_year,
extract(year from last_date) as last_year
from schema_xyz.unit
where uid_ in (select uid_1 from schema_xyz.relation where uid_0=0)
and not uid_ in (1,4751,4752))';
commit;
alter table schema_xyz.kb_inst add primary key(kb_inst_id);
commit;
execute 'drop index if exists schema_xyz.i_kb_inst_inst_id';
execute 'create index i_kb_inst_inst_id on schema_xyz.kb_inst(kb_inst_id)';
/* KB_SECTORS */
/*
kb_sectorgroup_id
kb_sector_id
subsector
remarks
*/
EXECUTE 'create table schema_xyz.kb_sectors (
kb_sectorgroup_id varchar(20),
kb_sector_id varchar(20),
sectorgroup_name varchar(500),
sector_name varchar(500),
remarks varchar(500) )';
commit;
alter table schema_xyz.kb_sectors add primary key(kb_sector_id);
commit;
EXECUTE 'insert into schema_xyz.KB_SECTORS
select
"DOMAIN",
subdomain,
domain_long,
subdomain_long,
domain_expl
from schema_xyz.domain';
commit;
/* KB_INST_TRANS */
/*
inst_ante
transition_date
inst_post
type
*/
call schema_xyz.create_kb_inst_trans_pg();
/* KB_S_INST_SEC */
/*
kb_inst_id
kb_sector_id
first_year
last__year
*/
-- in case of existence due to old structure
EXECUTE 'drop sequence if exists schema_xyz.seq_kb_s_inst_sec';
EXECUTE 'create table schema_xyz.kb_s_inst_sec (
kb_inst_id bigint REFERENCES schema_xyz.kb_inst(kb_inst_id) ON DELETE CASCADE,
kb_sector_id varchar REFERENCES schema_xyz.kb_sectors(kb_sector_id) ON DELETE CASCADE,
first_year bigint,
last_year bigint)';
commit;
alter table schema_xyz.kb_s_inst_sec add primary key(kb_inst_id, kb_sector_id, first_year, last_year);
commit;
EXECUTE 'insert into schema_xyz.kb_s_inst_sec (
select kb_inst_id, kb_sector_id, first_year, last_year
from
(select uid_ as kb_inst_id, subdomain as kb_sector_id,
extract(year from first_date) as first_year, extract(year from last_date) as last_year
from schema_xyz.u_sector a
join schema_xyz.domain b
on a.domain_id = b.id
where schema_xyz.is_hi_in_date_pg(uid_,first_date, last_date)=1
group by uid_, subdomain, extract(year from first_date), extract(year from last_date)) as x
where x.kb_inst_id in (select kb_inst_id from schema_xyz.kb_inst)
)';
commit;
/* KB_A_INST_SEC */
/*
kb_inst_id
kb_sector_id
*/
-- in case of existence due to old format
EXECUTE 'drop sequence if exists schema_xyz.seq_kb_a_inst_sec';
EXECUTE 'create table schema_xyz.kb_a_inst_sec (
kb_inst_id bigint REFERENCES schema_xyz.kb_inst(kb_inst_id) ON DELETE CASCADE,
kb_sector_id varchar REFERENCES schema_xyz.kb_sectors(kb_sector_id) ON DELETE CASCADE
)';
alter table schema_xyz.kb_a_inst_sec add primary key(kb_inst_id, kb_sector_id);
commit;
EXECUTE 'insert into schema_xyz.kb_a_inst_sec
(select kb_inst_id, kb_sector_id
from
(
select a.kb_inst_id, a.kb_sector_id,a.first_year, a.last_year
from
(select *
from schema_xyz.kb_s_inst_sec) a
join
(select kb_inst_id, max(last_year) as max_last
from schema_xyz.kb_s_inst_sec
group by kb_inst_id) b
on a.kb_inst_id=b.kb_inst_id
where a.last_year=b.max_last
group by a.kb_inst_id, a.kb_sector_id, a.first_year, a.last_year
) as x
where x.kb_inst_id in (select kb_inst_id from schema_xyz.kb_inst))';
commit;
/**************** ASSIGNMENT TABLES *******************/
/*
Input:
aff_seq_nr
item_id
address_full
city
pubyear
adr_id
top_uid
**/
/* kb_a_addr_inst_sec */
/*
kb_inst_id
item_id
aff_seq_nr
address_full
kb_sector_id
*/
EXECUTE 'create table schema_xyz.kb_a_addr_inst_sec (
kb_inst_id bigint REFERENCES schema_xyz.kb_inst(kb_inst_id) ON DELETE CASCADE,
item_id varchar(100),
aff_seq_nr bigint,
address_full varchar(2000),
kb_sector_id varchar array
)';
--alter table schema_xyz.kb_a_addr_inst_sec add primary key(item_id, aff_seq_nr, kb_inst_id); Switch on again if required!
EXECUTE 'insert into schema_xyz.kb_a_addr_inst_sec
select
top,
item_id,
aff_seq_nr,
address_full,
array_agg(kb_sector_id)
from '||input_table_a||' a
left join
schema_xyz.kb_a_inst_sec b
on a.top=b.kb_inst_id
where top in (select kb_inst_id from schema_xyz.kb_inst)
group by top, item_id, aff_seq_nr, address_full';
commit;
/* kb_s_addr_inst */
/*
kb_inst_id
item_id
aff_seq_nr
address_full
kb_sector_id
*/
-- in case of existence from old structure
EXECUTE 'drop sequence if exists schema_xyz.seq_kb_s_addr_inst';
EXECUTE 'create table schema_xyz.kb_s_addr_inst_sec (
kb_inst_id bigint REFERENCES schema_xyz.kb_inst(kb_inst_id) ON DELETE CASCADE,
item_id varchar(100),
aff_seq_nr bigint,
address_full varchar(2000),
kb_sector_id varchar array
)';
--alter table schema_xyz.kb_s_addr_inst_sec add primary key(item_id, aff_seq_nr, kb_inst_id); Switch on again if required!
EXECUTE 'insert into schema_xyz.kb_s_addr_inst_sec
select
top,
item_id,
aff_seq_nr,
address_full,
array_agg(kb_sector_id)
from '||input_table_s||' a
left join
schema_xyz.kb_s_inst_sec b
on a.top=b.kb_inst_id and schema_xyz.valid_sector_mod_s_pg(a.top, b.kb_sector_id, a.pubyear)=1
where top in (select kb_inst_id from schema_xyz.kb_inst)
group by top, item_id, aff_seq_nr, address_full';
commit;
-- in case of existence due to old structure
EXECUTE 'drop sequence if exists schema_xyz.seq_kb_a_addr_sec';
/* indexes to delete faster */
execute 'drop index if exists schema_xyz.inst_s_addr_inst_sec';
execute 'create index inst_s_addr_inst_sec on schema_xyz.kb_s_addr_inst_sec(kb_inst_id)';
execute 'drop index if exists schema_xyz.inst_a_addr_inst_sec';
execute 'create index inst_a_addr_inst_sec on schema_xyz.kb_a_addr_inst_sec(kb_inst_id)';
/* Delete everything from all tables that does not appear in the assignments (all uids_) */
EXECUTE 'delete from schema_xyz.kb_s_addr_inst_sec where kb_inst_id is null';
EXECUTE 'delete from schema_xyz.kb_a_addr_inst_sec where kb_inst_id is null';
/* Delete what does not occur from KB_INST */
EXECUTE 'delete from schema_xyz.kb_inst
where not kb_inst_id in (select kb_inst_id from schema_xyz.KB_S_ADDR_INST_SEC)
and not kb_inst_id in (select kb_inst_id from schema_xyz.KB_A_ADDR_INST_SEC)
and not kb_inst_id in (select inst_ante from schema_xyz.KB_INST_TRANS)
and not kb_inst_id in (select inst_post from schema_xyz.KB_INST_TRANS)
and not kb_inst_id=3987';
commit;
EXECUTE 'delete from schema_xyz.KB_S_INST_SEC
where not kb_inst_id in (select kb_inst_id from schema_xyz.kb_s_addr_inst_sec)';
EXECUTE 'delete from schema_xyz.KB_A_INST_SEC
where not kb_inst_id in (select kb_inst_id from schema_xyz.kb_a_addr_inst_sec)';
/* Column comments */
EXECUTE 'COMMENT ON COLUMN schema_xyz.kb_inst.name IS ''current name''';
EXECUTE 'COMMENT ON COLUMN schema_xyz.kb_inst.first_year IS ''1000: unknown''';
EXECUTE 'COMMENT ON COLUMN schema_xyz.kb_inst.last_year IS ''9999: unknown''';
EXECUTE 'COMMENT ON COLUMN schema_xyz.kb_inst_trans.inst_ante IS ''precedessor, kb_inst.kb_inst_id''';
EXECUTE 'COMMENT ON COLUMN schema_xyz.kb_inst_trans.inst_post IS ''successor k_inst.kb_inst_id''';
EXECUTE 'COMMENT ON COLUMN schema_xyz.kb_S_INST_SEC.first_year IS ''sector assignment from''';
EXECUTE 'COMMENT ON COLUMN schema_xyz.kb_S_INST_SEC.last_year IS ''sector assignment to''';
commit;
/* add suffix_to_tablenames */
EXECUTE 'DROP TABLE IF EXISTS schema_xyz.kb_inst_trans_'||result_suffix;
EXECUTE 'DROP TABLE IF EXISTS schema_xyz.kb_a_inst_sec_'||result_suffix;
EXECUTE 'DROP TABLE IF EXISTS schema_xyz.kb_s_inst_sec_'||result_suffix;
EXECUTE 'DROP TABLE IF EXISTS schema_xyz.kb_a_addr_inst_sec_'||result_suffix;
EXECUTE 'DROP TABLE IF EXISTS schema_xyz.kb_s_addr_inst_sec_'||result_suffix;
EXECUTE 'DROP TABLE IF EXISTS schema_xyz.kb_inst_'||result_suffix;
EXECUTE 'DROP TABLE IF EXISTS schema_xyz.kb_sectors_'||result_suffix;
execute 'alter table schema_xyz.kb_inst rename to kb_inst_'||result_suffix;
execute 'alter table schema_xyz.kb_sectors rename to kb_sectors_'||result_suffix;
execute 'alter table schema_xyz.kb_inst_trans rename to kb_inst_trans_'||result_suffix;
execute 'alter table schema_xyz.kb_a_inst_sec rename to kb_a_inst_sec_'||result_suffix;
execute 'alter table schema_xyz.kb_s_inst_sec rename to kb_s_inst_sec_'||result_suffix;
execute 'alter table schema_xyz.kb_a_addr_inst_sec rename to kb_a_addr_inst_sec_'||result_suffix;
execute 'alter table schema_xyz.kb_s_addr_inst_sec rename to kb_s_addr_inst_sec_'||result_suffix;
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