From dc5cc28103b5e485aeacfa6068e8be97feae3ba9 Mon Sep 17 00:00:00 2001
From: Christopher Lenke <christopher.lenke@uni-bielefeld.de>
Date: Mon, 23 Sep 2024 18:39:28 +0200
Subject: [PATCH] 23.09.2024

---
 ...ng_b_iii_pg_varchar__varchar__varchar_.txt | 101 ++++++++++++++++++
 1 file changed, 101 insertions(+)
 create mode 100644 Procedures/pattern_matching_b_iii_pg_varchar__varchar__varchar_.txt

diff --git a/Procedures/pattern_matching_b_iii_pg_varchar__varchar__varchar_.txt b/Procedures/pattern_matching_b_iii_pg_varchar__varchar__varchar_.txt
new file mode 100644
index 0000000..999af83
--- /dev/null
+++ b/Procedures/pattern_matching_b_iii_pg_varchar__varchar__varchar_.txt
@@ -0,0 +1,101 @@
+-- DROP PROCEDURE schema_xyz.pattern_matching_b_iii_pg(varchar, varchar, varchar);
+
+CREATE OR REPLACE PROCEDURE schema_xyz.pattern_matching_b_iii_pg(input_table character varying, output_table character varying, process_name character varying)
+ LANGUAGE plpgsql
+AS $procedure$
+#variable_conflict use_variable
+
+	Declare
+
+/*
+
+Assignment on lowest level.
+
+input_table: result_V
+output_table: result_VI 
+
+*/
+
+my_uid RECORD;
+publ RECORD;
+input_table_without_schema character varying:= split_part(input_table,'.',2);
+
+BEGIN
+
+execute 'drop table if exists schema_xyz.relation_017';
+execute 'create table schema_xyz.relation_017 as (select * from schema_xyz.relation where type in (0,1,7))';
+
+execute 'drop index if exists schema_xyz.i_rel_017_1';	
+execute 'drop index if exists schema_xyz.i_rel_017_2';	
+execute 'create index i_rel_017_1 on schema_xyz.relation_017(uid_0)';	
+execute 'create index i_rel_017_2 on schema_xyz.relation_017(uid_1)';	
+
+/*
+PRIORITY: Lowest level assignment.
+*/
+	
+execute 'alter table '||input_table||' add column lowest_level bigint';
+execute 'update '||input_table||' set lowest_level=uid_';
+commit;
+
+EXECUTE 'drop index if exists schema_xyz.i_'||input_table_without_schema||'_ll';
+
+for my_uid in (select distinct uid_ from schema_xyz.result_V) 
+
+LOOP 
+
+/* RAISE NOTICE 'loop step:% ', my_uid.uid_; */
+execute 'update '||input_table||' set is_TE=schema_xyz.is_TE_pg(uid_) where uid_='||my_uid.uid_;
+commit;
+
+END LOOP;
+
+
+EXECUTE 'drop index if exists schema_xyz.i_'||input_table_without_schema ||'_isTE';
+execute 'create index i_'||input_table_without_schema ||'_isTE on '||input_table||' (is_TE)';
+EXECUTE 'drop index if exists schema_xyz.i_'||input_table_without_schema ||'_llev';
+execute 'create index i_'||input_table_without_schema ||'_llev on '||input_table||' (lowest_level)';
+
+
+
+for publ in (select /*+ parallel(6) */ adr_id, uid_ 
+from schema_xyz.result_V 
+where is_TE=1 and adr_id in (
+select adr_id 
+from schema_xyz.result_V 
+group by adr_id 
+having count(distinct uid_)>1) 
+group by adr_id, uid_)
+
+LOOP
+
+
+execute 'update /*+parallel(6) */ '||input_table||' 
+set lowest_level='||publ.uid_||'
+where lowest_level in (
+(select uid_0
+from (
+ SELECT uid_0, uid_1, level as l1 
+ FROM connectby(''schema_xyz.relation_017'', ''uid_0'', ''uid_1'', '''||publ.uid_||''',0)
+ AS t(uid_1 bigint, uid_0 bigint, level int)
+) as xyz
+ where not uid_0=0 and not uid_0='||publ.uid_||') 
+ )
+ and adr_id='||publ.adr_id;  
+ 
+
+END LOOP;      
+
+commit;
+
+
+execute 'drop table if exists '||output_table;
+execute 'create table '||output_table||' as (
+select adr_id, address_full, city, lowest_level as uid_
+from '||input_table||' 
+group by adr_id, address_full, city, lowest_level)';
+
+END
+
+$procedure$
+;
-- 
GitLab