Skip to content
Snippets Groups Projects
Commit 5a904442 authored by wohlgemu's avatar wohlgemu
Browse files

Update file Create_Table.sql

parent 3628d49b
No related branches found
No related tags found
No related merge requests found
...@@ -55,6 +55,7 @@ CREATE TABLE IF NOT EXISTS public.finance_request ...@@ -55,6 +55,7 @@ CREATE TABLE IF NOT EXISTS public.finance_request
institution character varying(70) COLLATE pg_catalog."default" DEFAULT 'TU Dresden'::character varying, 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, 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, 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 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_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_postpayment_check1 CHECK (postpayment_check::text = ANY (ARRAY['y'::character varying, 'n'::character varying, 'o'::character varying]::text[])),
...@@ -110,36 +111,150 @@ CREATE TRIGGER update_issuer_request ...@@ -110,36 +111,150 @@ CREATE TRIGGER update_issuer_request
-------------------------------------------------------------------------------------------------------------- --------------------------------------------------------------------------------------------------------------
-------------------------------------------------------------------------------------------------------------- --------------------------------------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS public.finance_cost -- Table: public.finance_cost
-- DROP TABLE IF EXISTS public.finance_cost;
CREATE TABLE IF NOT EXISTS public.finance_cost
( (
ts_form timestamp without time zone NOT NULL DEFAULT now(), ts_form timestamp without time zone NOT NULL DEFAULT now(),
pk_cost integer NOT NULL GENERATED ALWAYS AS IDENTITY ( INCREMENT 1 START 1 MINVALUE 1 MAXVALUE 2147483647 CACHE 1 ), 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", oa_id character varying(17) COLLATE pg_catalog."default",
invoice_number character varying(100) 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_2023'::character varying, budget_id character varying(20) COLLATE pg_catalog."default" DEFAULT 'TUD_EL_2025'::character varying,
cost_type character varying(100) COLLATE pg_catalog."default", cost_type character varying(100) COLLATE pg_catalog."default",
contract_type character varying(50) COLLATE pg_catalog."default", contract_type character varying(50) COLLATE pg_catalog."default",
amount_net numeric(8,2), amount_net numeric(8,2),
currency character varying(3) COLLATE pg_catalog."default", currency character varying(3) COLLATE pg_catalog."default",
amount_euro_net numeric(8,2), exchange_rate numeric(6,5) DEFAULT 1.00000,
vat_percent numeric(3,2) DEFAULT 1.19, vat_percent numeric(3,2) DEFAULT 1.19,
amount_payment_brut numeric(8,2), amount_payment_brut numeric(8,2),
comment_cost character varying(250) COLLATE pg_catalog."default", comment_cost character varying(250) COLLATE pg_catalog."default",
issuer character varying(30) COLLATE pg_catalog."default" DEFAULT SESSION_USER, issuer character varying(30) COLLATE pg_catalog."default" DEFAULT SESSION_USER,
issuer_update character varying(30) COLLATE pg_catalog."default" DEFAULT SESSION_USER, issuer_update character varying(30) COLLATE pg_catalog."default" DEFAULT SESSION_USER,
CONSTRAINT finance_cost_pkey PRIMARY KEY (pk_cost), beleg_number bigint,
CONSTRAINT blank_check_oa_id CHECK (ltrim(oa_id::text) = oa_id::text AND rtrim(oa_id::text) = oa_id::text), invoice_collective boolean DEFAULT false,
CONSTRAINT blank_check_invoice_number CHECK (ltrim(invoice_number::text) = invoice_number::text AND rtrim(invoice_number::text) = invoice_number::text), CONSTRAINT pk_cost PRIMARY KEY (pk_cost),
CONSTRAINT blank_check_budget_id CHECK (ltrim(budget_id::text) = budget_id::text AND rtrim(budget_id::text) = budget_id::text), CONSTRAINT fk_budget_id FOREIGN KEY (budget_id)
CONSTRAINT blank_check_cost_type CHECK (ltrim(cost_type::text) = cost_type::text AND rtrim(cost_type::text) = cost_type::text), REFERENCES public.finance_budget (budget_id) MATCH SIMPLE
CONSTRAINT blank_check_contract_type CHECK (ltrim(contract_type::text) = contract_type::text AND rtrim(contract_type::text) = contract_type::text), ON UPDATE NO ACTION
CONSTRAINT blank_check_currency CHECK (ltrim(currency::text) = currency::text AND rtrim(currency::text) = currency::text) ON DELETE NO ACTION,
) CONSTRAINT fk_invoice_number FOREIGN KEY (invoice_number)
WITH ( REFERENCES public.finance_invoice (invoice_number) MATCH SIMPLE
OIDS = FALSE ON UPDATE NO ACTION
ON DELETE NO ACTION,
CONSTRAINT fk_oa_id FOREIGN KEY (oa_id)
REFERENCES public.finance_request (oa_id) MATCH SIMPLE
ON UPDATE NO ACTION
ON DELETE NO ACTION,
CONSTRAINT blank_check_contract_type CHECK (TRIM(BOTH FROM contract_type) = contract_type::text),
CONSTRAINT blank_check_cost_type CHECK (TRIM(BOTH FROM cost_type) = cost_type::text),
CONSTRAINT blank_check_currency CHECK (TRIM(BOTH FROM currency) = currency::text)
) )
TABLESPACE pg_default; TABLESPACE pg_default;
-- Trigger: insert_vat
-- DROP TRIGGER IF EXISTS insert_vat ON public.finance_cost;
CREATE OR REPLACE TRIGGER insert_vat
BEFORE INSERT
ON public.finance_cost
FOR EACH ROW
WHEN (new.contract_type::text = 'DEAL'::text AND new.oa_id::text ~~ 'OA2025_%'::text)
EXECUTE FUNCTION public.vat();
-- Trigger: update_issuer_cost
-- DROP TRIGGER IF EXISTS update_issuer_cost ON public.finance_cost;
CREATE OR REPLACE TRIGGER update_issuer_cost
BEFORE UPDATE
ON public.finance_cost
FOR EACH ROW
EXECUTE FUNCTION public.update_issuer();
-- FUNCTION: public.fnct_hybrid_cost()
-- DROP FUNCTION IF EXISTS public.fnct_hybrid_cost();
CREATE OR REPLACE FUNCTION public.fnct_hybrid_cost()
RETURNS trigger
LANGUAGE 'plpgsql'
COST 100
VOLATILE NOT LEAKPROOF
AS $BODY$
BEGIN
CASE WHEN
new.media_type IN ('Hybrid', 'Closed') and new.oa_id like 'OA20%' THEN
CASE
WHEN new.publisher = 'Wiley' and new.journal_classification = 'Tier 1' THEN
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'APC', 'DEAL', 3150, 'EUR', 1.07, true);
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'Betriebskosten', 'DEAL', 100, 'EUR', 1.07, true);
WHEN new.publisher = 'Wiley' and new.journal_classification = 'Tier 2' THEN
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'APC', 'DEAL', 2700, 'EUR', 1.07, true);
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'Betriebskosten', 'DEAL', 100, 'EUR', 1.07, true);
WHEN new.publisher = 'Wiley' and new.journal_classification = 'Tier 3' THEN
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'APC', 'DEAL', 2200, 'EUR', 1.07, true);
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'Betriebskosten', 'DEAL', 100, 'EUR', 1.07, true);
WHEN new.publisher = 'Wiley' and new.journal_classification = 'Tier 4' THEN
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'No APC', 'DEAL', 0, 'EUR', 1.07, true);
WHEN new.publisher = 'Elsevier' and new.journal_classification = 'Core' THEN
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'APC', 'DEAL', 2575, 'EUR', 1.07, true);
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'Betriebskosten', 'DEAL', 100, 'EUR', 1.07, true);
WHEN new.publisher = 'Elsevier' and new.journal_classification = 'CP/TL' THEN
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'APC', 'DEAL', 6708, 'EUR', 1.07, true);
WHEN new.publisher = 'Springer Nature' and new.research_article IN ('y', 'o') THEN
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'APC', 'DEAL', 2600, 'EUR', 1.07, true);
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'Betriebskosten', 'DEAL', 100, 'EUR', 1.07, true);
WHEN new.publisher = 'Springer Nature' and new.research_article = 'n' THEN
INSERT INTO finance_cost (oa_id, COST_TYPE, CONTRACT_TYPE, AMOUNT_NET, CURRENCY, VAT_PERCENT, invoice_collective)
VALUES (NEW.oa_id, 'No APC', 'DEAL', 0, 'EUR', 1.07, true);
ELSE
END CASE;
ELSE
END CASE;
RETURN NEW;
END;
$BODY$;
-- FUNCTION: public.vat()
-- DROP FUNCTION IF EXISTS public.vat();
CREATE OR REPLACE FUNCTION public.vat()
RETURNS trigger
LANGUAGE 'plpgsql'
COST 100
VOLATILE NOT LEAKPROOF
AS $BODY$
BEGIN
NEW.vat_percent := 1.07;
RETURN NEW;
END;
$BODY$;
-- Trigger: update_issuer_cost -- Trigger: update_issuer_cost
-- DROP TRIGGER IF EXISTS update_issuer_cost ON public.finance_cost; -- DROP TRIGGER IF EXISTS update_issuer_cost ON public.finance_cost;
......
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Please register or to comment