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

23.09.2024

parent 3d31828e
No related branches found
No related tags found
No related merge requests found
-- DROP PROCEDURE schema_xyz.modus_a_connect_pg(text, text);
CREATE OR REPLACE PROCEDURE schema_xyz.modus_a_connect_pg(output_table text, prozess_name text)
LANGUAGE plpgsql
AS $procedure$
BEGIN
DECLARE
cuirc cursor is SELECT uid_ from schema_xyz.unit where schema_xyz.is_TE_plus_7_pg(uid_)=0 and not uid_ in (select parent from schema_xyz.descent);
cuirc2 cursor is SELECT uid_ from schema_xyz.unit where schema_xyz.is_TE_plus_7_pg(uid_)=1 or uid_ in (select parent from schema_xyz.descent);
current_uid RECORD;
BEGIN
/*############################## PROZESS_INFO ###############################*/
EXECUTE 'insert into prozess_info select '''||process_name||''', ''Start modus_a_connect'', '''||current_timestamp::varchar||'''';
commit;
/* Create table decent only 1.3 */
execute 'drop table if exists schema_xyz.descent_1_3';
execute 'CREATE TABLE schema_xyz.descent_1_3 (
id bigint NULL,
parent bigint NULL,
successor bigint NULL
)';
execute 'insert into schema_xyz.descent_1_3 (select id, parent, successor from schema_xyz.descent where type in (1,3))';
commit;
EXECUTE 'drop index if exists schema_xyz.i_desc13_a_1';
EXECUTE 'create index i_desc13_a_1 on schema_xyz.descent_1_3(parent)';
EXECUTE 'drop index if exists schema_xyz.i_desc13_a_2';
EXECUTE 'create index i_desc13_a_2 on schema_xyz.descent_1_3(successor)';
/* Create customised relation table to make it faster */
EXECUTE 'DROP TABLE IF EXISTS schema_xyz.relation_modus_a';
EXECUTE 'create table schema_xyz.relation_modus_a as (
select id, uid_0, uid_1 from schema_xyz.relation where type in (0,1,7)
and (uid_1,last_date) in (select uid_1,max(last_date)
from schema_xyz.relation where type in (0,1,7) group by uid_1))';
execute 'update schema_xyz.relation_modus_a set uid_0 = schema_xyz.next_uid_pg(uid_0)';
commit;
/* Set indices*/
EXECUTE 'drop index if exists schema_xyz.i_rel_a_0';
EXECUTE 'create index i_rel_a_0 on schema_xyz.relation_modus_a(uid_0)';
EXECUTE 'drop index if exists schema_xyz.i_rel_a_1';
EXECUTE 'create index i_rel_a_1 on schema_xyz.relation_modus_a(uid_1)';
/* Build output table */
EXECUTE 'drop table if exists ' ||output_table;
EXECUTE 'create table '||output_table||' (id bigint, TE bigint, HI bigint)';
EXECUTE 'drop sequence if exists schema_xyz.seq_moda_TE_HI';
EXECUTE 'create sequence schema_xyz.seq_moda_TE_HI start with 1 increment by 1';
for current_uid in cuirc
LOOP
EXECUTE 'insert into '||output_table||' (
select nextval(''schema_xyz.seq_moda_TE_HI''), '||current_uid.uid_||', '||current_uid.uid_||')';
END LOOP;
commit;
for current_uid in cuirc2
LOOP
execute 'insert into '||output_table||' (
select nextval(''schema_xyz.seq_moda_TE_HI''), '||current_uid.uid_||', uid_1
from (
SELECT distinct uid_0, uid_1, level
FROM connectby(''schema_xyz.relation_modus_a'', ''uid_0'', ''uid_1'', schema_xyz.next_uid_pg('||current_uid.uid_||')::varchar,0)
AS t(uid_0 bigint, uid_1 bigint, level int)
where uid_0 = 0) as xxx
)';
commit;
END LOOP;
/*############################## PROZESS_INFO ###############################*/
EXECUTE 'insert into prozess_info select '''||process_name||''', ''End modus_a_connect '', '''||current_timestamp::varchar||'''';
end;
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