]> git.evergreen-ils.org Git - Evergreen.git/blob - Open-ILS/src/sql/Pg/upgrade/0174.schema.money.nulls-in-mmbxs-fix.sql
LP#1117808: release notes for New Access points for MARC Overlay
[Evergreen.git] / Open-ILS / src / sql / Pg / upgrade / 0174.schema.money.nulls-in-mmbxs-fix.sql
1 BEGIN;
2
3 INSERT INTO config.upgrade_log (version) VALUES ('0174'); -- miker
4
5 -- The view should supply defaults for numeric (amount) columns
6 CREATE OR REPLACE VIEW money.billable_xact_summary AS
7     SELECT  xact.id,
8         xact.usr,
9         xact.xact_start,
10         xact.xact_finish,
11         COALESCE(credit.amount, 0.0::numeric) AS total_paid,
12         credit.payment_ts AS last_payment_ts,
13         credit.note AS last_payment_note,
14         credit.payment_type AS last_payment_type,
15         COALESCE(debit.amount, 0.0::numeric) AS total_owed,
16         debit.billing_ts AS last_billing_ts,
17         debit.note AS last_billing_note,
18         debit.billing_type AS last_billing_type,
19         COALESCE(debit.amount, 0.0::numeric) - COALESCE(credit.amount, 0.0::numeric) AS balance_owed,
20         p.relname AS xact_type
21       FROM  money.billable_xact xact
22         JOIN pg_class p ON xact.tableoid = p.oid
23         LEFT JOIN (
24             SELECT  billing.xact,
25                 sum(billing.amount) AS amount,
26                 max(billing.billing_ts) AS billing_ts,
27                 last(billing.note) AS note,
28                 last(billing.billing_type) AS billing_type
29               FROM  money.billing
30               WHERE billing.voided IS FALSE
31               GROUP BY billing.xact
32             ) debit ON xact.id = debit.xact
33         LEFT JOIN (
34             SELECT  payment_view.xact,
35                 sum(payment_view.amount) AS amount,
36                 max(payment_view.payment_ts) AS payment_ts,
37                 last(payment_view.note) AS note,
38                 last(payment_view.payment_type) AS payment_type
39               FROM  money.payment_view
40               WHERE payment_view.voided IS FALSE
41               GROUP BY payment_view.xact
42             ) credit ON xact.id = credit.xact
43       ORDER BY debit.billing_ts, credit.payment_ts;
44
45 -- And the "add" trigger functions should protect against existing NULLed values, just in case
46 CREATE OR REPLACE FUNCTION money.materialized_summary_billing_add () RETURNS TRIGGER AS $$
47 BEGIN
48     IF NOT NEW.voided THEN
49         UPDATE  money.materialized_billable_xact_summary
50           SET   total_owed = COALESCE(total_owed, 0.0::numeric) + NEW.amount,
51             last_billing_ts = NEW.billing_ts,
52             last_billing_note = NEW.note,
53             last_billing_type = NEW.billing_type,
54             balance_owed = balance_owed + NEW.amount
55           WHERE id = NEW.xact;
56     END IF;
57
58     RETURN NEW;
59 END;
60 $$ LANGUAGE PLPGSQL;
61
62 CREATE OR REPLACE FUNCTION money.materialized_summary_payment_add () RETURNS TRIGGER AS $$
63 BEGIN
64     IF NOT NEW.voided THEN
65         UPDATE  money.materialized_billable_xact_summary
66           SET   total_paid = COALESCE(total_paid, 0.0::numeric) + NEW.amount,
67             last_payment_ts = NEW.payment_ts,
68             last_payment_note = NEW.note,
69             last_payment_type = TG_ARGV[0],
70             balance_owed = balance_owed - NEW.amount
71           WHERE id = NEW.xact;
72     END IF;
73
74     RETURN NEW;
75 END;
76 $$ LANGUAGE PLPGSQL;
77
78 -- Refresh the mat view with the corrected underlying view
79 TRUNCATE money.materialized_billable_xact_summary;
80 INSERT INTO money.materialized_billable_xact_summary SELECT * FROM money.billable_xact_summary;
81
82 COMMIT;
83
84