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

---
 Procedures/modus_s_holger_pg__.txt | 277 +++++++++++++++++++++++++++++
 1 file changed, 277 insertions(+)
 create mode 100644 Procedures/modus_s_holger_pg__.txt

diff --git a/Procedures/modus_s_holger_pg__.txt b/Procedures/modus_s_holger_pg__.txt
new file mode 100644
index 0000000..a9bf6c1
--- /dev/null
+++ b/Procedures/modus_s_holger_pg__.txt
@@ -0,0 +1,277 @@
+-- DROP PROCEDURE schema_xyz.modus_s_holger_pg();
+
+CREATE OR REPLACE PROCEDURE schema_xyz.modus_s_holger_pg()
+ LANGUAGE plpgsql
+AS $procedure$
+	BEGIN
+
+DECLARE
+
+
+BEGIN
+
+
+EXECUTE 'DROP TABLE IF EXISTS schema_xyz.X_hrch_date_0';
+EXECUTE 'DROP TABLE IF EXISTS schema_xyz.X_hrch_date';
+EXECUTE 'DROP TABLE IF EXISTS schema_xyz.X_top_s3';
+EXECUTE 'DROP TABLE IF EXISTS schema_xyz.X_closed';
+EXECUTE 'DROP TABLE IF EXISTS schema_xyz.X_pre_start';
+EXECUTE 'DROP TABLE IF EXISTS schema_xyz.X_des';
+EXECUTE 'DROP TABLE IF EXISTS schema_xyz.X_d0';
+EXECUTE 'DROP TABLE IF EXISTS schema_xyz.X_HI_uid_s';
+
+
+-- Assignment uid to HI without consideration of structural changes
+EXECUTE 'CREATE TABLE schema_xyz.X_hrch_date_0
+AS
+SELECT (CASE r1.uid_0 WHEN 0 THEN r1.uid_1 ELSE  
+          (CASE r2.uid_0 WHEN 0 THEN r2.uid_1 ELSE
+             (CASE r3.uid_0 WHEN 0 THEN r3.uid_1 ELSE 
+                (CASE r4.uid_0 WHEN 0 THEN r4.uid_1 ELSE 
+                   (CASE r5.uid_0 WHEN 0 THEN r5.uid_1 ELSE
+                      (CASE r6.uid_0 WHEN 0 THEN r6.uid_1 ELSE r6.uid_0 END)END)END)END)END)END) top,
+       r6.uid_0 u6,
+       r6.first_date fd6,
+       r6.last_date ld6,
+       r5.uid_0 u5,
+       r5.first_date fd5,
+       r5.last_date ld5,
+       r4.uid_0 u4,
+       r4.first_date fd4,
+       r4.last_date ld4,
+       r3.uid_0 u3,
+       r3.first_date fd3,
+       r3.last_date ld3,
+       r2.uid_0 u2,
+       r2.first_date fd2,
+       r2.last_date ld2,
+       r1.uid_0 u1,
+       r1.first_date fd1,
+       r1.last_date ld1,
+       r1.uid_1 u_last
+
+FROM schema_xyz.relation r1
+LEFT JOIN schema_xyz.unit u11 ON u11.uid_=r1.uid_1
+LEFT JOIN schema_xyz.unit u10 ON u10.uid_=r1.uid_0
+LEFT JOIN schema_xyz.relation r2 ON  r2.uid_1=r1.uid_0
+                      AND r2.type IN (0,1,7)
+                      AND r2.last_date  >= r1.first_date
+                      AND r2.first_date <= r1.last_date
+LEFT JOIN schema_xyz.unit u2 ON u2.uid_=r2.uid_0
+LEFT JOIN schema_xyz.relation r3 ON  r3.uid_1=r2.uid_0
+                      AND r3.type IN (0,1,7)
+                      AND r3.last_date >= r2.first_date
+                      AND r3.first_date <= r2.last_date
+LEFT JOIN schema_xyz.unit u3 ON u3.uid_=r3.uid_0
+LEFT JOIN schema_xyz.relation r4 ON  r4.uid_1=r3.uid_0
+                      AND r4.type IN (0,1,7)
+                      AND r4.last_date >= r3.first_date
+                      AND r4.first_date <= r3.last_date
+LEFT JOIN schema_xyz.unit u4 ON u4.uid_=r4.uid_0
+LEFT JOIN schema_xyz.relation r5 ON  r5.uid_1=r4.uid_0
+                      AND r5.type IN (0,1,7)
+                      AND r5.last_date >= r4.first_date
+                      AND r5.first_date <= r4.last_date
+LEFT JOIN schema_xyz.unit u5 ON u5.uid_=r5.uid_0
+LEFT JOIN schema_xyz.relation r6 ON  r6.uid_1=r5.uid_0
+                      AND r6.type IN (0,1,7)
+                      AND r6.first_date >= r5.last_date
+                      AND r6.last_date <= r5.first_date
+LEFT JOIN schema_xyz.unit u6 ON u6.uid_=r6.uid_0
+WHERE  (CASE r1.uid_0 WHEN 0 THEN r1.uid_1 ELSE  
+          (CASE r2.uid_0 WHEN 0 THEN r2.uid_1 ELSE
+             (CASE r3.uid_0 WHEN 0 THEN r3.uid_1 ELSE 
+                (CASE r4.uid_0 WHEN 0 THEN r4.uid_1 ELSE 
+                   (CASE r5.uid_0 WHEN 0 THEN r5.uid_1 ELSE
+                      (CASE r6.uid_0 WHEN 0 THEN r6.uid_1 ELSE r6.uid_0 END)END)END)END)END)END)
+       IS NOT NULL
+AND r1.type IN (0,1,7)
+ORDER BY u6 DESC,u5 DESC,u4 DESC,u3 DESC,u2 DESC,u1 DESC';
+
+
+EXECUTE 'create index i_hrch_date_0_top on schema_xyz.X_hrch_date_0 (top)';
+
+
+
+EXECUTE 'CREATE TABLE schema_xyz.X_top_s3 (
+   top    bigint ,
+   first  DATE  DEFAULT to_date(''1000-01-01'',''yyyy-mm-dd''),
+   last   DATE  DEFAULT to_date(''9999-12-31'',''yyyy-mm-dd''),
+   u_last bigint)';
+
+
+EXECUTE 'INSERT INTO  schema_xyz.X_top_s3 (top,first,last,u_last)
+SELECT top,
+       GREATEST(coalesce(fd5,to_date(''1000-01-01'',''YYYY-MM-DD'')),
+                coalesce(fd4,to_date(''1000-01-01'',''YYYY-MM-DD'')),
+                coalesce(fd3,to_date(''1000-01-01'',''YYYY-MM-DD'')),
+                coalesce(fd2,to_date(''1000-01-01'',''YYYY-MM-DD'')),
+                coalesce(fd1,to_date(''1000-01-01'',''YYYY-MM-DD''))) as first,
+       LEAST(coalesce(ld5,to_date(''9999-12-31'',''YYYY-MM-DD'')),
+             coalesce(ld4,to_date(''9999-12-31'',''YYYY-MM-DD'')),
+             coalesce(ld3,to_date(''9999-12-31'',''YYYY-MM-DD'')),
+             coalesce(ld2,to_date(''9999-12-31'',''YYYY-MM-DD'')),
+             coalesce(ld1,to_date(''9999-12-31'',''YYYY-MM-DD''))) as last,
+       u_last
+FROM schema_xyz.X_hrch_date_0';
+
+
+
+EXECUTE 'create index i__top_s3_top on schema_xyz.X_top_s3 (top)';
+EXECUTE 'create index i__top_s3_u_last on schema_xyz.X_top_s3 (u_last)';
+EXECUTE 'create index i__top_s3_first on schema_xyz.X_top_s3 (first)';
+EXECUTE 'create index i__top_s3_last on schema_xyz.X_top_s3 (last)';
+
+
+-- Subunits with end date, without succession
+EXECUTE 'CREATE TABLE schema_xyz.X_closed
+AS
+SELECT t.top,t.u_last
+FROM schema_xyz.X_top_s3 t
+LEFT JOIN schema_xyz.X_top_s3 t2 
+ON t2.u_last=t.u_last AND t2.last>=t.last AND t2.top != t.top
+LEFT JOIN schema_xyz.u_sector s1 
+ON s1.uid_=t.u_last AND s1.first_date<=t.last AND s1.last_date >= t.first
+LEFT JOIN schema_xyz.descent d 
+ON d.parent = t.u_last AND d.type IN (1,3)
+LEFT JOIN schema_xyz.unit u1 
+ON u1.uid_=t.u_last
+--LEFT JOIN schema_xyz.u_name n1 
+--ON n1.id=u1.u_name_id
+WHERE t2.u_last IS NULL
+AND t.last != to_date(''9999-12-31'',''yyyy-mm-dd'')
+AND d.successor IS NULL
+GROUP BY t.top,t.u_last';
+
+
+EXECUTE 'alter table schema_xyz.X_closed add constraint pk_closed primary key(top, u_last)';
+EXECUTE 'create index i_closed_top_u_last on schema_xyz.X_closed(top)';
+EXECUTE 'create index i_closed_u_last on schema_xyz.X_closed(u_last)';
+
+
+-- Subunits with start date > 1000 without predecessor relation or predecessor in descent
+
+EXECUTE 'CREATE TABLE schema_xyz.X_pre_start
+AS
+SELECT t.top,t.u_last
+FROM schema_xyz.X_top_s3 t
+LEFT JOIN schema_xyz.X_top_s3 t2 ON t2.u_last=t.u_last AND t2.first<t.first
+LEFT JOIN schema_xyz.descent d1 ON d1.successor=t.u_last AND type IN (1,3)
+LEFT JOIN schema_xyz.X_top_s3 t3 ON t3.u_last=d1.parent
+WHERE t.first > to_date(''1000-01-01'',''yyyy-mm-dd'')
+AND t2.u_last IS NULL
+AND t.u_last NOT IN
+(SELECT successor
+ FROM schema_xyz.descent d2
+ LEFT JOIN schema_xyz.X_top_s3 t4 
+	ON t4.u_last=d2.parent
+ WHERE t4.first < t.first
+ AND type IN (1,3))
+GROUP BY t.top,t.u_last';
+
+
+
+
+-- Insertion of special cases of institutions with predecessors, 
+-- whose publications should also be considered with PY before start date
+EXECUTE 'INSERT INTO schema_xyz.X_pre_start (top,u_last) VALUES (1101,1101)';
+EXECUTE 'DELETE FROM schema_xyz.X_pre_start WHERE top = 571 AND u_last=571';
+
+
+EXECUTE 'alter table schema_xyz.X_pre_start add constraint pk_pre_start primary key(top, u_last)';
+EXECUTE 'create index i_pre_start_top on schema_xyz.X_pre_start(top)';
+EXECUTE 'create index i_pre_start_u_last on schema_xyz.X_pre_start(u_last)';
+
+
+
+
+-- Representation of the descendants (descent table) as a relation in _top_s3
+------------Units with unique predecessor-successor relationship (descent.type = [1,3])
+EXECUTE 'CREATE TABLE schema_xyz.X_des 
+AS
+SELECT d.successor,d.date_,t.u_last
+FROM schema_xyz.X_top_s3 t
+LEFT JOIN schema_xyz.X_top_s3 t2 ON t2.u_last=t.u_last AND t2.last>=t.last AND t2.top != t.top
+LEFT JOIN schema_xyz.descent d ON d.parent = t.u_last AND d.type IN (1,3)
+WHERE t2.u_last IS NULL
+AND d.successor IS NOT NULL
+GROUP BY d.successor,d.date_,t.u_last
+ORDER BY t.u_last';
+
+
+EXECUTE 'alter table schema_xyz.X_des add constraint pk_des primary key(u_last)';
+
+
+
+---------- Insert the predecessor-successor relation in _top_s3 with last=9999-12-31
+EXECUTE 'CREATE TABLE schema_xyz.X_d0
+AS
+SELECT successor as top,
+       date_ as first,
+       t.last,
+       d.u_last
+FROM schema_xyz.X_des d
+LEFT JOIN schema_xyz.X_top_s3 t  ON t.u_last = d.successor
+                    AND t.first <= d.date_
+                    AND t.last >= d.date_
+                    AND t.top = t.u_last
+WHERE t.u_last IS NOT NULL';
+
+
+---- Consideration of later integrations for successor HI
+EXECUTE 'INSERT INTO schema_xyz.X_d0 (top,first,last,u_last)
+SELECT t.top,
+       date_ as first,
+       t.last,
+       d.u_last
+FROM schema_xyz.X_des d
+LEFT JOIN schema_xyz.X_top_s3 t  ON t.u_last = d.successor
+                    AND t.first > d.date_
+                    AND t.last > d.date_
+                    AND t.top != t.u_last
+WHERE t.u_last IS NOT NULL';
+
+
+--- Successor is sub-unit at the time of transition
+EXECUTE 'INSERT INTO schema_xyz.X_d0 (top,first,last,u_last)
+SELECT t.top,
+       date_,
+       t.last,
+       d.u_last
+FROM schema_xyz.X_des d
+LEFT JOIN schema_xyz.X_top_s3 t  ON t.u_last = d.successor
+                    AND t.first <= d.date_
+                    AND t.last >= d.date_
+                    AND t.top != t.u_last
+WHERE t.u_last IS NOT NULL';
+
+
+
+--- Subunits as successors that later become HI (spin-off)
+EXECUTE 'INSERT INTO schema_xyz.X_d0 (top,first,last,u_last)
+SELECT t.top,
+       date_,
+       t.last,
+       d.u_last
+FROM schema_xyz.X_des d
+LEFT JOIN schema_xyz.X_top_s3 t  ON t.u_last = d.successor
+                    AND t.first > d.date_
+                    AND t.last > d.date_
+                    AND t.top = t.u_last
+WHERE t.u_last IS NOT NULL';
+
+
+
+--- Adding the HI - Partial unit relations
+--- in table schema_xyz.X_top_s3 taking into account
+--- the successor from table schema_xyz.X_d0
+EXECUTE 'INSERT INTO schema_xyz.X_top_s3 (top,first,last,u_last)
+SELECT top,first,last,u_last
+FROM schema_xyz.X_d0';
+
+commit;
+
+END;
+	END;
+$procedure$
+;
-- 
GitLab