1
0
Fork 0

Add experiments/finmgrsql/ddl.sql

This commit is contained in:
Strix 2025-05-11 23:41:26 +02:00
parent e862655781
commit 20d4c9d3b7

View file

@ -0,0 +1,115 @@
-- Drop table
-- DROP TABLE finance.expenses;
CREATE TABLE finance.expenses (
expense_id bigserial NOT NULL,
"target" varchar(128) NOT NULL,
price int8 DEFAULT 0 NULL,
"interval" int4 DEFAULT 30 NULL,
active bool DEFAULT true NOT NULL,
amount int4 DEFAULT 1 NULL,
CONSTRAINT expenses_pkey PRIMARY KEY (expense_id)
);
-- Drop table
-- DROP TABLE finance.incidents;
CREATE TABLE finance.incidents (
incident_id bigserial NOT NULL,
"target" varchar NULL,
amount int8 NULL,
value_date date NULL,
created_on timestamp DEFAULT now() NULL,
CONSTRAINT incidents_pk PRIMARY KEY (incident_id)
);
-- Drop table
-- DROP TABLE finance.income;
CREATE TABLE finance.income (
income_id serial4 NOT NULL,
"source" varchar(64) NULL,
amount int8 NULL,
"interval" int4 DEFAULT 31 NULL,
active bool DEFAULT true NULL,
CONSTRAINT income_pkey PRIMARY KEY (income_id)
);
CREATE OR REPLACE VIEW finance.daily_overview
AS SELECT name,
type,
id,
amount
FROM ( SELECT e.target AS name,
'expenses'::text AS type,
e.expense_id AS id,
- (e.price * e.amount / e."interval") AS amount
FROM finance.expenses e
UNION ALL
SELECT i.source AS name,
'income'::text AS type,
i.income_id AS id,
i.amount / i."interval" AS amount
FROM finance.income i
UNION ALL
SELECT i.target AS name,
'incident'::text AS type,
i.incident_id AS id,
i.amount / (i.value_date - i.created_on::date) AS amount
FROM finance.incidents i) unnamed_subquery;
-- DROP FUNCTION finance.transaction_log(date, int4);
CREATE OR REPLACE FUNCTION finance.transaction_log(from_date date DEFAULT now(), day_range integer DEFAULT 30)
RETURNS TABLE(date date, type text, id bigint, target text, amount bigint)
LANGUAGE plpgsql
AS $function$
BEGIN
RETURN QUERY
WITH date_range AS (
SELECT generate_series(from_date, from_date + day_range, INTERVAL '1 day')::date AS day
),
recurring_expenses AS (
SELECT
d.day AS date,
'expenses' AS type,
e.expense_id AS id,
e.target::TEXT AS target,
-(e.price * e.amount) AS amount
FROM finance.expenses e
JOIN date_range d ON e.active
AND MOD((d.day - DATE '2024-04-01')::int, e.interval) = 0
),
recurring_income AS (
SELECT
d.day AS date,
'income' AS type,
i.income_id AS id,
i.source::TEXT AS target,
i.amount AS amount
FROM finance.income i
JOIN date_range d ON i.active
AND MOD((d.day - DATE '2024-04-01')::int, i.interval) = 0
),
incident_txns AS (
SELECT
i.value_date AS date,
'incidents' AS type,
i.incident_id AS id,
i.target::TEXT AS target,
i.amount
FROM finance.incidents i
WHERE i.value_date BETWEEN from_date AND from_date + day_range
)
SELECT * FROM recurring_expenses
UNION ALL
SELECT * FROM recurring_income
UNION ALL
SELECT * FROM incident_txns
ORDER BY date, type;
END;
$function$
;