[open-ils-commits] r15666 - in trunk/Open-ILS/src/sql/Pg: . upgrade (miker)
svn at svn.open-ils.org
svn at svn.open-ils.org
Tue Mar 2 17:36:45 EST 2010
Author: miker
Date: 2010-03-02 17:36:39 -0500 (Tue, 02 Mar 2010)
New Revision: 15666
Added:
trunk/Open-ILS/src/sql/Pg/upgrade/0174.schema.money.nulls-in-mmbxs-fix.sql
Modified:
trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
trunk/Open-ILS/src/sql/Pg/080.schema.money.sql
Log:
forward-porting r15664: protect mmbxs mat view from NULLs
Modified: trunk/Open-ILS/src/sql/Pg/002.schema.config.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/002.schema.config.sql 2010-03-02 22:33:18 UTC (rev 15665)
+++ trunk/Open-ILS/src/sql/Pg/002.schema.config.sql 2010-03-02 22:36:39 UTC (rev 15666)
@@ -51,7 +51,7 @@
install_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
);
-INSERT INTO config.upgrade_log (version) VALUES ('0173'); -- Scott McKellar
+INSERT INTO config.upgrade_log (version) VALUES ('0174'); -- miker
CREATE TABLE config.bib_source (
id SERIAL PRIMARY KEY,
Modified: trunk/Open-ILS/src/sql/Pg/080.schema.money.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/080.schema.money.sql 2010-03-02 22:33:18 UTC (rev 15665)
+++ trunk/Open-ILS/src/sql/Pg/080.schema.money.sql 2010-03-02 22:36:39 UTC (rev 15666)
@@ -217,15 +217,15 @@
xact.usr,
xact.xact_start,
xact.xact_finish,
- credit.amount AS total_paid,
+ COALESCE(credit.amount, 0.0::numeric) AS total_paid,
credit.payment_ts AS last_payment_ts,
credit.note AS last_payment_note,
credit.payment_type AS last_payment_type,
- debit.amount AS total_owed,
+ COALESCE(debit.amount, 0.0::numeric) AS total_owed,
debit.billing_ts AS last_billing_ts,
debit.note AS last_billing_note,
debit.billing_type AS last_billing_type,
- COALESCE(debit.amount, 0::numeric) - COALESCE(credit.amount, 0::numeric) AS balance_owed,
+ COALESCE(debit.amount, 0.0::numeric) - COALESCE(credit.amount, 0.0::numeric) AS balance_owed,
p.relname AS xact_type
FROM money.billable_xact xact
JOIN pg_class p ON xact.tableoid = p.oid
@@ -303,7 +303,7 @@
BEGIN
IF NOT NEW.voided THEN
UPDATE money.materialized_billable_xact_summary
- SET total_owed = total_owed + NEW.amount,
+ SET total_owed = COALESCE(total_owed, 0.0::numeric) + NEW.amount,
last_billing_ts = NEW.billing_ts,
last_billing_note = NEW.note,
last_billing_type = NEW.billing_type,
@@ -403,7 +403,7 @@
BEGIN
IF NOT NEW.voided THEN
UPDATE money.materialized_billable_xact_summary
- SET total_paid = total_paid + NEW.amount,
+ SET total_paid = COALESCE(total_paid, 0.0::numeric) + NEW.amount,
last_payment_ts = NEW.payment_ts,
last_payment_note = NEW.note,
last_payment_type = TG_ARGV[0],
Added: trunk/Open-ILS/src/sql/Pg/upgrade/0174.schema.money.nulls-in-mmbxs-fix.sql
===================================================================
--- trunk/Open-ILS/src/sql/Pg/upgrade/0174.schema.money.nulls-in-mmbxs-fix.sql (rev 0)
+++ trunk/Open-ILS/src/sql/Pg/upgrade/0174.schema.money.nulls-in-mmbxs-fix.sql 2010-03-02 22:36:39 UTC (rev 15666)
@@ -0,0 +1,84 @@
+BEGIN;
+
+INSERT INTO config.upgrade_log (version) VALUES ('0174'); -- miker
+
+-- The view should supply defaults for numeric (amount) columns
+CREATE OR REPLACE VIEW money.billable_xact_summary AS
+ SELECT xact.id,
+ xact.usr,
+ xact.xact_start,
+ xact.xact_finish,
+ COALESCE(credit.amount, 0.0::numeric) AS total_paid,
+ credit.payment_ts AS last_payment_ts,
+ credit.note AS last_payment_note,
+ credit.payment_type AS last_payment_type,
+ COALESCE(debit.amount, 0.0::numeric) AS total_owed,
+ debit.billing_ts AS last_billing_ts,
+ debit.note AS last_billing_note,
+ debit.billing_type AS last_billing_type,
+ COALESCE(debit.amount, 0.0::numeric) - COALESCE(credit.amount, 0.0::numeric) AS balance_owed,
+ p.relname AS xact_type
+ FROM money.billable_xact xact
+ JOIN pg_class p ON xact.tableoid = p.oid
+ LEFT JOIN (
+ SELECT billing.xact,
+ sum(billing.amount) AS amount,
+ max(billing.billing_ts) AS billing_ts,
+ last(billing.note) AS note,
+ last(billing.billing_type) AS billing_type
+ FROM money.billing
+ WHERE billing.voided IS FALSE
+ GROUP BY billing.xact
+ ) debit ON xact.id = debit.xact
+ LEFT JOIN (
+ SELECT payment_view.xact,
+ sum(payment_view.amount) AS amount,
+ max(payment_view.payment_ts) AS payment_ts,
+ last(payment_view.note) AS note,
+ last(payment_view.payment_type) AS payment_type
+ FROM money.payment_view
+ WHERE payment_view.voided IS FALSE
+ GROUP BY payment_view.xact
+ ) credit ON xact.id = credit.xact
+ ORDER BY debit.billing_ts, credit.payment_ts;
+
+-- And the "add" trigger functions should protect against existing NULLed values, just in case
+CREATE OR REPLACE FUNCTION money.materialized_summary_billing_add () RETURNS TRIGGER AS $$
+BEGIN
+ IF NOT NEW.voided THEN
+ UPDATE money.materialized_billable_xact_summary
+ SET total_owed = COALESCE(total_owed, 0.0::numeric) + NEW.amount,
+ last_billing_ts = NEW.billing_ts,
+ last_billing_note = NEW.note,
+ last_billing_type = NEW.billing_type,
+ balance_owed = balance_owed + NEW.amount
+ WHERE id = NEW.xact;
+ END IF;
+
+ RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+CREATE OR REPLACE FUNCTION money.materialized_summary_payment_add () RETURNS TRIGGER AS $$
+BEGIN
+ IF NOT NEW.voided THEN
+ UPDATE money.materialized_billable_xact_summary
+ SET total_paid = COALESCE(total_paid, 0.0::numeric) + NEW.amount,
+ last_payment_ts = NEW.payment_ts,
+ last_payment_note = NEW.note,
+ last_payment_type = TG_ARGV[0],
+ balance_owed = balance_owed - NEW.amount
+ WHERE id = NEW.xact;
+ END IF;
+
+ RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+-- Refresh the mat view with the corrected underlying view
+TRUNCATE money.materialized_billable_xact_summary;
+INSERT INTO money.materialized_billable_xact_summary SELECT * FROM money.billable_xact_summary;
+
+COMMIT;
+
+
More information about the open-ils-commits
mailing list