From a2be3ba91a2f196f38c6bd540a8d00c54dcabebd Mon Sep 17 00:00:00 2001
From: wohlgemu <michael.wohlgemuth@slub-dresden.de>
Date: Tue, 20 May 2025 09:14:24 +0000
Subject: [PATCH] add new table finance_institution

---
 script/Create_Table.sql | 84 ++++++++++++++++++++++++++---------------
 1 file changed, 54 insertions(+), 30 deletions(-)

diff --git a/script/Create_Table.sql b/script/Create_Table.sql
index 61b955f..6553c49 100644
--- a/script/Create_Table.sql
+++ b/script/Create_Table.sql
@@ -31,13 +31,16 @@ CREATE TABLE IF NOT EXISTS public.finance_request
     family_name character varying(40) COLLATE pg_catalog."default" NOT NULL,
     orcid character varying(19) COLLATE pg_catalog."default",
     dfg_number character varying(200) COLLATE pg_catalog."default",
-    school character varying(50) COLLATE pg_catalog."default" NOT NULL,
-    faculty character varying(50) COLLATE pg_catalog."default",
-    department character varying(70) COLLATE pg_catalog."default",
-    institute character varying(150) COLLATE pg_catalog."default",
-    center character varying(150) COLLATE pg_catalog."default",
-    chair character varying(150) COLLATE pg_catalog."default",
-    workgroup character varying(150) COLLATE pg_catalog."default",
+    org_id integer NOT NULL,
+    org_comment text COLLATE pg_catalog."default",
+    --institution character varying(70) COLLATE pg_catalog."default" DEFAULT 'TU Dresden'::character varying,
+    --school character varying(50) COLLATE pg_catalog."default" NOT NULL,
+    --faculty character varying(50) COLLATE pg_catalog."default",
+    --department character varying(70) COLLATE pg_catalog."default",
+    --institute character varying(150) COLLATE pg_catalog."default",
+    --center character varying(150) COLLATE pg_catalog."default",
+    --chair character varying(150) COLLATE pg_catalog."default",
+    --workgroup character varying(150) COLLATE pg_catalog."default",
     publisher character varying(150) COLLATE pg_catalog."default" NOT NULL,
     journal character varying(150) COLLATE pg_catalog."default" NOT NULL,
     eissn character varying(9) COLLATE pg_catalog."default" DEFAULT 'XXXX-XXXX'::character varying,
@@ -52,35 +55,30 @@ CREATE TABLE IF NOT EXISTS public.finance_request
     media_type character varying(12) COLLATE pg_catalog."default" NOT NULL,
     issuer character varying(30) COLLATE pg_catalog."default" DEFAULT SESSION_USER,
     issuer_update character varying(30) COLLATE pg_catalog."default" DEFAULT SESSION_USER,
-    institution character varying(70) COLLATE pg_catalog."default" DEFAULT 'TU Dresden'::character varying,
     research_article character varying(1) COLLATE pg_catalog."default" NOT NULL DEFAULT 'o'::character varying,
     postpayment_check character varying(1) COLLATE pg_catalog."default" NOT NULL DEFAULT 'n'::character varying,
     journal_classification character varying(250) COLLATE pg_catalog."default",
     CONSTRAINT finance_request_pkey PRIMARY KEY (oa_id),
-    CONSTRAINT value_check_research_article1 CHECK (research_article::text = ANY (ARRAY['y'::character varying, 'n'::character varying, 'o'::character varying]::text[])),
-    CONSTRAINT value_check_postpayment_check1 CHECK (postpayment_check::text = ANY (ARRAY['y'::character varying, 'n'::character varying, 'o'::character varying]::text[])),
-    CONSTRAINT value_check_decision CHECK (decision::text = ANY (ARRAY['y'::character varying, 'n'::character varying, 'o'::character varying]::text[])),
-    CONSTRAINT blank_check_institution CHECK (btrim(institution::text) = institution::text),
-    CONSTRAINT blank_check_oa_id CHECK (ltrim(oa_id::text) = oa_id::text AND rtrim(oa_id::text) = oa_id::text),
-    CONSTRAINT blank_check_ticket_number CHECK (ltrim(ticket_number::text) = ticket_number::text AND rtrim(ticket_number::text) = ticket_number::text),
-    CONSTRAINT blank_check_first_name CHECK (ltrim(first_name::text) = first_name::text AND rtrim(first_name::text) = first_name::text),
+    CONSTRAINT fk_org_id FOREIGN KEY (org_id)
+        REFERENCES public.finance_institution (pure_id) MATCH SIMPLE
+        ON UPDATE NO ACTION
+        ON DELETE NO ACTION,
+    CONSTRAINT blank_check_article_type CHECK (ltrim(article_type::text) = article_type::text AND rtrim(article_type::text) = article_type::text),
+    CONSTRAINT value_check_postpayment_check1 CHECK (postpayment_check::text = ANY (ARRAY['y'::character varying::text, 'n'::character varying::text, 'o'::character varying::text])),
+    CONSTRAINT blank_check_doi CHECK (ltrim(doi::text) = doi::text AND rtrim(doi::text) = doi::text),
     CONSTRAINT blank_check_family_name CHECK (ltrim(family_name::text) = family_name::text AND rtrim(family_name::text) = family_name::text),
+    CONSTRAINT blank_check_first_name CHECK (ltrim(first_name::text) = first_name::text AND rtrim(first_name::text) = first_name::text),
+    CONSTRAINT value_check_research_article1 CHECK (research_article::text = ANY (ARRAY['y'::character varying::text, 'n'::character varying::text, 'o'::character varying::text])),
+    CONSTRAINT blank_check_journal CHECK (ltrim(journal::text) = journal::text AND rtrim(journal::text) = journal::text),
+    CONSTRAINT blank_check_license CHECK (ltrim(license::text) = license::text AND rtrim(license::text) = license::text),
+    CONSTRAINT blank_check_manuskript_id CHECK (ltrim(manuskript_id::text) = manuskript_id::text AND rtrim(manuskript_id::text) = manuskript_id::text),
+    CONSTRAINT blank_check_media_type CHECK (ltrim(media_type::text) = media_type::text AND rtrim(media_type::text) = media_type::text),
+    CONSTRAINT blank_check_oa_id CHECK (ltrim(oa_id::text) = oa_id::text AND rtrim(oa_id::text) = oa_id::text),
     CONSTRAINT blank_check_orcid CHECK (ltrim(orcid::text) = orcid::text AND rtrim(orcid::text) = orcid::text),
-    CONSTRAINT blank_check_school CHECK (ltrim(school::text) = school::text AND rtrim(school::text) = school::text),
-    CONSTRAINT blank_check_faculty CHECK (ltrim(faculty::text) = faculty::text AND rtrim(faculty::text) = faculty::text),
-    CONSTRAINT blank_check_department CHECK (ltrim(department::text) = department::text AND rtrim(department::text) = department::text),
-    CONSTRAINT blank_check_institute CHECK (ltrim(institute::text) = institute::text AND rtrim(institute::text) = institute::text),
-    CONSTRAINT blank_check_center CHECK (ltrim(center::text) = center::text AND rtrim(center::text) = center::text),
-    CONSTRAINT blank_check_chair CHECK (ltrim(chair::text) = chair::text AND rtrim(chair::text) = chair::text),
-    CONSTRAINT blank_check_workgroup CHECK (ltrim(workgroup::text) = workgroup::text AND rtrim(workgroup::text) = workgroup::text),
     CONSTRAINT blank_check_publisher CHECK (ltrim(publisher::text) = publisher::text AND rtrim(publisher::text) = publisher::text),
-    CONSTRAINT blank_check_journal CHECK (ltrim(journal::text) = journal::text AND rtrim(journal::text) = journal::text),
+    CONSTRAINT blank_check_ticket_number CHECK (ltrim(ticket_number::text) = ticket_number::text AND rtrim(ticket_number::text) = ticket_number::text),
     CONSTRAINT blank_check_title CHECK (ltrim(title::text) = title::text AND rtrim(title::text) = title::text),
-    CONSTRAINT blank_check_article_type CHECK (ltrim(article_type::text) = article_type::text AND rtrim(article_type::text) = article_type::text),
-    CONSTRAINT blank_check_manuskript_id CHECK (ltrim(manuskript_id::text) = manuskript_id::text AND rtrim(manuskript_id::text) = manuskript_id::text),
-    CONSTRAINT blank_check_doi CHECK (ltrim(doi::text) = doi::text AND rtrim(doi::text) = doi::text),
-    CONSTRAINT blank_check_license CHECK (ltrim(license::text) = license::text AND rtrim(license::text) = license::text),
-    CONSTRAINT blank_check_media_type CHECK (ltrim(media_type::text) = media_type::text AND rtrim(media_type::text) = media_type::text)
+    CONSTRAINT value_check_decision CHECK (decision::text = ANY (ARRAY['y'::character varying::text, 'n'::character varying::text, 'o'::character varying::text]))
 )
 WITH (
     OIDS = FALSE
@@ -131,7 +129,7 @@ CREATE TABLE IF NOT EXISTS public.finance_cost
     pk_cost integer NOT NULL GENERATED ALWAYS AS IDENTITY ( INCREMENT 1 START 7070 MINVALUE 1 MAXVALUE 2147483647 CACHE 1 ),
     oa_id character varying(17) COLLATE pg_catalog."default",
     invoice_number character varying(100) COLLATE pg_catalog."default",
-    budget_id character varying(20) COLLATE pg_catalog."default" DEFAULT 'TUD_EL_2025'::character varying,
+    budget_id character varying(20) COLLATE pg_catalog."default" DEFAULT 'SLUB_2025'::character varying,
     cost_type character varying(100) COLLATE pg_catalog."default",
     contract_type character varying(50) COLLATE pg_catalog."default",
     amount_net numeric(8,2),
@@ -280,6 +278,7 @@ CREATE TABLE IF NOT EXISTS public.finance_invoice
     date_invoice_receipt date,
     date_factually_accurate date,
     date_hauptkasse date,
+    date_paragraph70 date,
     comment_invoice character varying(100) COLLATE pg_catalog."default",
     issuer character varying(30) COLLATE pg_catalog."default" DEFAULT SESSION_USER,
     issuer_update character varying(30) COLLATE pg_catalog."default" DEFAULT SESSION_USER,
@@ -345,4 +344,29 @@ CREATE TRIGGER update_issuer_budget
     BEFORE UPDATE 
     ON public.finance_budget
     FOR EACH ROW
-    EXECUTE FUNCTION public.update_issuer();
\ No newline at end of file
+    EXECUTE FUNCTION public.update_issuer();
+
+
+--------------------------------------------------------------------------------------------------------------
+--------------------------------------------------------------------------------------------------------------
+-- Table: public.finance_institution
+
+-- DROP TABLE IF EXISTS public.finance_institution;
+
+CREATE TABLE IF NOT EXISTS public.finance_institution
+(
+    pure_id integer NOT NULL,
+    uuid uuid NOT NULL,
+    name_de text COLLATE pg_catalog."default" NOT NULL,
+    name_en text COLLATE pg_catalog."default",
+    type_de text COLLATE pg_catalog."default" NOT NULL,
+    type_en text COLLATE pg_catalog."default",
+    start_date date,
+    end_date date,
+    www_de text COLLATE pg_catalog."default",
+    www_en text COLLATE pg_catalog."default",
+    parent_uuids uuid,
+    previous_uuids text COLLATE pg_catalog."default",
+    successor_uuid uuid,
+    CONSTRAINT finance_institution_pkey PRIMARY KEY (pure_id)
+)
-- 
GitLab