Add code for void payments to void bills and partial balances.
authorJason Stephenson <jason@sigio.com>
Sat, 20 Jul 2013 15:41:52 +0000 (11:41 -0400)
committerKathy Lussier <klussier@masslnc.org>
Thu, 13 Feb 2014 05:31:04 +0000 (00:31 -0500)
This new payment type replaces the current void logic that simply flags
bills as voided.  There is an upgrade script to remove the void-related
fields from the billing tables, to remove or modify the views of voided
billings, and to convert voided billing amounts into void payments.

The void payment completely replaces the workings of voiding bills in
the backend Evergreen code.  This is a non-optional replacement.  Also,
the void payments are exposed in the staff client so that staff may
apply a void of a partial amount to a given billing.  Voiding an entire
bill or all bills for a given transaction will still function as it does
in the staff client prior to this change. However, instead of marking
the bills as voided, void payments will be applied in the amount of the
voided billings.

This new payment type is needed because the current way that Evergreen
voids bills requires that all voids happen in the same increment as the
bills themselves.  This prevents voiding of a partial bill or a bill
that has had a partial payment applied. For more on the rationale for
this change see:

    http://www.sigio.com/evergreen/billing2013.html#voidpayment

Signed-off-by: Jason Stephenson <jason@sigio.com>
Signed-off-by: Kathy Lussier <klussier@masslnc.org>
Open-ILS/examples/fm_IDL.xml
Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/CircCommon.pm
Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Circulate.pm
Open-ILS/src/perlmods/lib/OpenILS/Application/Circ/Money.pm
Open-ILS/src/sql/Pg/080.schema.money.sql
Open-ILS/src/sql/Pg/reporter-schema.sql
Open-ILS/src/sql/Pg/upgrade/XXXX.schema.money.void_payment.sql [new file with mode: 0644]
Open-ILS/web/opac/locale/en-US/lang.dtd
Open-ILS/xul/staff_client/server/patron/bill2.xul

index 3e82953..daa9807 100644 (file)
@@ -81,6 +81,7 @@ Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA  02110-1301, USA
                        <field name="work_payment" oils_persist:virtual="true" />
                        <field name="credit_payment" oils_persist:virtual="true" />
                        <field name="goods_payment" oils_persist:virtual="true" />
+                       <field name="void_payment" oils_persist:virtual="true" />
                </fields>
                <links>
                        <link field="usr" reltype="has_a" key="id" map="" class="au"/>
@@ -3420,6 +3421,26 @@ Foundation, Inc., 51 Franklin Street, Fifth Floor, Boston, MA  02110-1301, USA
                        <link field="xact" reltype="has_a" key="id" map="" class="mbt"/>
                </links>
        </class>
+       <class id="mvp" controller="open-ils.cstore" oils_obj:fieldmapper="money::void_payment" oils_persist:tablename="money.void_payment" reporter:label="Void Payment">
+               <fields oils_persist:primary="id" oils_persist:sequence="money.payment_id_seq">
+                       <field name="accepting_usr" reporter:datatype="link"/>
+                       <field name="amount" reporter:datatype="money" />
+                       <field name="amount_collected" reporter:datatype="money" />
+                       <field name="id" reporter:datatype="id" />
+                       <field name="note"  reporter:datatype="text"/>
+                       <field name="payment_ts" reporter:datatype="timestamp"/>
+                       <field name="xact" reporter:datatype="link"/>
+                       <field name="billing" reporter:datatype="link"/>
+                       <field name="payment_type" oils_persist:virtual="true"  reporter:datatype="text"/>
+                       <field name="payment" oils_persist:virtual="true" reporter:datatype="link"/>
+               </fields>
+               <links>
+                       <link field="payment" reltype="might_have" key="id" map="" class="mp"/>
+                       <link field="accepting_usr" reltype="has_a" key="id" map="" class="au"/>
+                       <link field="xact" reltype="has_a" key="id" map="" class="mbt"/>
+                       <link field="billing" reltype="might_have" key="id" class="mb"/>
+               </links>
+       </class>
        <class id="mrd" controller="open-ils.cstore" oils_obj:fieldmapper="metabib::record_descriptor" oils_persist:tablename="metabib.rec_descriptor" reporter:label="Basic Record Descriptor">
                <fields oils_persist:primary="id" oils_persist:sequence="metabib.rec_descriptor_id_seq">
                        <field reporter:label="Audn" name="audience" oils_persist:primitive="string"  reporter:datatype="text"/>
@@ -6653,6 +6674,7 @@ SELECT  usr,
                        <field reporter:label="Work Payment Detail" name="work_payment" oils_persist:virtual="true" reporter:datatype="link"/>
                        <field reporter:label="Forgive Payment Detail" name="forgive_payment" oils_persist:virtual="true" reporter:datatype="link"/>
                        <field reporter:label="Goods Payment Detail" name="goods_payment" oils_persist:virtual="true" reporter:datatype="link"/>
+                       <field reporter:label="Void Payment Detail" name="void_payment" oils_persist:virtual="true" reporter:datatype="link"/>
                </fields>
                <links>
                        <link field="cash_payment" reltype="might_have" key="id" map="" class="mcp"/>
@@ -6662,6 +6684,7 @@ SELECT  usr,
                        <link field="work_payment" reltype="might_have" key="id" map="" class="mwp"/>
                        <link field="forgive_payment" reltype="might_have" key="id" map="" class="mfp"/>
                        <link field="goods_payment" reltype="might_have" key="id" map="" class="mgp"/>
+                       <link field="void_payment" reltype="might_have" key="id" map="" class="mvp"/>
                        <link field="xact" reltype="has_a" key="id" map="" class="mbt"/>
                </links>
        </class>
@@ -6682,6 +6705,7 @@ SELECT  usr,
                        <field reporter:label="Work Payment Detail" name="work_payment" oils_persist:virtual="true" reporter:datatype="link"/>
                        <field reporter:label="Forgive Payment Detail" name="forgive_payment" oils_persist:virtual="true" reporter:datatype="link"/>
                        <field reporter:label="Goods Payment Detail" name="goods_payment" oils_persist:virtual="true" reporter:datatype="link"/>
+                       <field reporter:label="Void Payment Detail" name="void_payment" oils_persist:virtual="true" reporter:datatype="link"/>
                </fields>
                <links>
                        <link field="cash_payment" reltype="might_have" key="id" map="" class="mcp"/>
@@ -6691,6 +6715,7 @@ SELECT  usr,
                        <link field="work_payment" reltype="might_have" key="id" map="" class="mwp"/>
                        <link field="forgive_payment" reltype="might_have" key="id" map="" class="mfp"/>
                        <link field="goods_payment" reltype="might_have" key="id" map="" class="mgp"/>
+                       <link field="void_payment" reltype="might_have" key="id" map="" class="mvp"/>
                        <link field="xact" reltype="has_a" key="id" map="" class="mbt"/>
                        <link field="accepting_usr" reltype="has_a" key="id" map="" class="au"/>
                </links>
@@ -6708,12 +6733,14 @@ SELECT  usr,
                        <field reporter:label="Forgive Payment Detail" name="forgive_payment" oils_persist:virtual="true" reporter:datatype="link"/>
                        <field reporter:label="Goods Payment Detail" name="goods_payment" oils_persist:virtual="true" reporter:datatype="link"/>
                        <field reporter:label="Credit Payment Detail" name="credit_payment" oils_persist:virtual="true" reporter:datatype="link"/>
+                       <field reporter:label="Void Payment Detail" name="void_payment" oils_persist:virtual="true" reporter:datatype="link"/>
                </fields>
                <links>
                        <link field="work_payment" reltype="might_have" key="id" map="" class="mwp"/>
                        <link field="forgive_payment" reltype="might_have" key="id" map="" class="mfp"/>
                        <link field="goods_payment" reltype="might_have" key="id" map="" class="mgp"/>
                        <link field="credit_payment" reltype="might_have" key="id" map="" class="mcrp"/>
+                       <link field="void_payment" reltype="might_have" key="id" map="" class="mvp"/>
                        <link field="xact" reltype="has_a" key="id" map="" class="mbt"/>
                </links>
        </class>
@@ -6888,15 +6915,11 @@ SELECT  usr,
                        <field reporter:label="Legacy Billing Type" name="billing_type" reporter:datatype="text"/>
                        <field reporter:label="Billing ID" name="id" reporter:datatype="id" />
                        <field reporter:label="Note" name="note" reporter:datatype="text"/>
-                       <field reporter:label="Void Timestamp" name="void_time" reporter:datatype="timestamp"/>
-                       <field reporter:label="Voided?" name="voided" reporter:datatype="bool"/>
-                       <field reporter:label="Voiding Staff Member" name="voider" reporter:datatype="link"/>
                        <field reporter:label="Transaction" name="xact" reporter:datatype="link"/>
                        <field reporter:label="Type" name="btype" reporter:datatype="link"/>
                </fields>
                <links>
                        <link field="xact" reltype="has_a" key="id" map="" class="mbt"/>
-                       <link field="voider" reltype="has_a" key="id" map="" class="au"/>
                        <link field="btype" reltype="has_a" key="id" map="" class="cbt"/>
                </links>
        </class>
@@ -8699,17 +8722,6 @@ SELECT  usr,
                        <link field="bib_record" reltype="has_a" key="id" map="" class="bre"/>
                </links>
        </class>
-       <class id="rxbt" controller="open-ils.reporter-store" oils_obj:fieldmapper="reporter::xact_billing_totals" oils_persist:tablename="reporter.xact_billing_totals" reporter:label="Transaction Billing Totals">
-               <fields oils_persist:primary="xact">
-                       <field reporter:label="Transaction ID" name="xact" reporter:datatype="int" />
-                       <field reporter:label="Unvoided Billing Amount" name="unvoided" reporter:datatype="int" />
-                       <field reporter:label="Voided Billing Amount" name="voided" reporter:datatype="money"/>
-                       <field reporter:label="Total Billing Amount" name="total" reporter:datatype="money"/>
-               </fields>
-               <links>
-                       <link field="xact" reltype="might_have" key="id" map="" class="mbt"/>
-               </links>
-       </class>
        <class id="rxpt" controller="open-ils.reporter-store" oils_obj:fieldmapper="reporter::xact_paid_totals" oils_persist:tablename="reporter.xact_paid_totals" reporter:label="Transaction Paid Totals">
                <fields oils_persist:primary="xact">
                        <field reporter:label="Transaction ID" name="xact" reporter:datatype="int" />
index 2901ec5..d958778 100644 (file)
@@ -56,17 +56,25 @@ sub void_overdues {
         }
     }
 
-    my $bills = $e->search_money_billing($bill_search);
+    my $bills = $class->oustanding_bills_for_xact($e, $circ, $bill_search);
+
+    # Sum any outstanding overdue billings
+    my $outstanding_overdues = 0;
+
+    foreach my $bill (@$bills) {
+        $outstanding_overdues = ($outstanding_overdues*100 + $bill->amount*100)/100;
+    }
+
+    if ($outstanding_overdues >= 0.01) {
+        # Make void payment
+        my $payobj = Fieldmapper::money::void_payment->new;
+        $payobj->amount($outstanding_overdues);
+        $payobj->amount_collected($outstanding_overdues);
+        $payobj->xact($circ->id);
+        $payobj->note($note);
+        $payobj->accepting_usr($e->requestor->id);
     
-    for my $bill (@$bills) {
-        next if $U->is_true($bill->voided);
-        $logger->info("voiding overdue bill ".$bill->id);
-        $bill->voided('t');
-        $bill->void_time('now');
-        $bill->voider($e->requestor->id);
-        my $n = ($bill->note) ? sprintf("%s\n", $bill->note) : "";
-        $bill->note(sprintf("$n%s", ($note) ? $note : "System: VOIDED FOR BACKDATE"));
-        $e->update_money_billing($bill) or return $e->die_event;
+        $e->create_money_void_payment($payobj) or return $e->die_event;
     }
 
     return undef;
@@ -254,4 +262,67 @@ sub can_close_circ {
     return $can_close;
 }
 
+# -----------------------------------------------------------------
+# Given an editor and a xact, return a reference to an array of
+# billing objects which are outstanding (unpaid, not voided).
+# If a bill is partially paid, change the amount of the bill
+# to reflect the unpaid amount, not the original amount.
+#
+# It also takes an optional last parameter as a bill search predicate
+# filter.
+#
+# This function is adapted from code written by Jeff Godin of Traverse
+# Area District Library and submitted on LaunchPad bug #1009049.
+# -----------------------------------------------------------------
+sub outstanding_bills_for_xact {
+    my ($class, $e, $xact, $bill_predicate) = @_;
+
+    # A little defensive coding never hurts.
+    unless ($bill_predicate) {
+        $bill_predicate = {xact => $xact->id};
+    } else {
+        $bill_predicate->{xact} = $xact->id unless ($bill_predicate->{xact});
+    }
+
+    # find all unvoided bills in order
+    my $bill_search = [
+        $bill_predicate,
+        { order_by => { mb => { billing_ts => { direction => 'asc' } } } },
+    ];
+
+    # find all unvoided payments in order
+    my $payment_search = [
+        { xact => $xact->id, voided=>'f' },
+        { order_by => { mp => { payment_ts => { direction => 'asc' } } } },
+    ];
+
+    my $bills = $e->search_money_billing($bill_search);
+
+    my $payments = $e->search_money_payment($payment_search);
+
+    # "Pay" the bills, removing fully paid bills and
+    # adjusting the amount for partially paid bills
+    map {
+        my $payment = $_;
+        my $paybal = $payment->amount;
+
+        while ($paybal > 0) {
+            # get next billing
+            my $bill = shift @{$bills};
+            my $newbal = (($paybal*100) - ($bill->amount*100))/100;
+            if ($newbal < 0) {
+                $newbal = 0;
+                my $new_bill_amount = (($bill->amount*100) - ($paybal*100))/100;
+                $bill->amount($new_bill_amount);
+                unshift(@{$bills}, $bill); # put the partially-paid bill back on top of the stack
+            }
+            $paybal = $newbal;
+        }
+
+    } @$payments;
+
+    return $bills;
+
+}
+
 1;
index b390688..6e1289b 100644 (file)
@@ -2805,9 +2805,8 @@ sub check_circ_deposit {
     my $self = shift;
     return unless $self->circ;
     my $deposit = $self->editor->search_money_billing(
-        {   btype => 5, 
-            xact => $self->circ->id, 
-            voided => 'f'
+        {   btype => 5,
+            xact => $self->circ->id
         }, {idlist => 1})->[0];
 
     $self->push_events(OpenILS::Event->new(
index a6220ed..41227fc 100644 (file)
@@ -766,20 +766,33 @@ sub void_bill {
         my $xact = $e->retrieve_money_billable_transaction($bill->xact)
             or return $e->die_event;
 
-        if($U->is_true($bill->voided)) {
+        my $amount_to_void = $bill->amount;
+        my $open_amount = 0;
+        my $open_bills = OpenILS::Application::Circ::CircCommon->outstanding_bills_for_xact($e, $xact);
+        for my $open_bill (@$open_bills) {
+            $open_amount = ($open_amount*100 + $open_bill->amount*100)/100;
+        }
+
+        if($open_amount == 0) {
             $e->rollback;
             return OpenILS::Event->new('BILL_ALREADY_VOIDED', payload => $bill);
+        } else {
+            # Void the lesser of $amount_to_void or $open_amount:
+            $amount_to_void = ($amount_to_void < $open_amount) ? $amount_to_void : $open_amount;
+            # Make a void payment in the amount of $amount_to_void
+            my $payobj = Fieldmapper::money::void_payment->new;
+            $payobj->amount($amount_to_void);
+            $payobj->amount_collected($amount_to_void);
+            $payobj->xact($bill->xact);
+            $payobj->accepting_usr($e->requestor->id);
+
+            $e->create_money_void_payment($payobj) or return $e->die_event;
         }
 
         my $org = $U->xact_org($bill->xact, $e);
         $users{$xact->usr} = {} unless $users{$xact->usr};
         $users{$xact->usr}->{$org} = 1;
 
-        $bill->voided('t');
-        $bill->voider($e->requestor->id);
-        $bill->void_time('now');
-    
-        $e->update_money_billing($bill) or return $e->die_event;
         my $evt = $U->check_open_xact($e, $bill->xact, $xact);
         return $evt if $evt;
     }
index 5004f00..9db5188 100644 (file)
@@ -52,9 +52,6 @@ CREATE TABLE money.billing (
        id              BIGSERIAL                       PRIMARY KEY,
        xact            BIGINT                          NOT NULL, -- money.billable_xact.id
        billing_ts      TIMESTAMP WITH TIME ZONE        NOT NULL DEFAULT NOW(),
-       voided          BOOL                            NOT NULL DEFAULT FALSE,
-       voider          INT,
-       void_time       TIMESTAMP WITH TIME ZONE,
        amount          NUMERIC(6,2)                    NOT NULL,
        billing_type    TEXT                            NOT NULL,
        btype           INT                             NOT NULL REFERENCES config.billing_type (id) ON DELETE RESTRICT DEFERRABLE INITIALLY DEFERRED,
@@ -89,7 +86,6 @@ CREATE OR REPLACE VIEW money.transaction_billing_type_summary AS
                MAX(billing_ts) AS last_billing_ts,
                SUM(COALESCE(amount,0)) AS total_owed
          FROM  money.billing
-         WHERE voided IS FALSE
          GROUP BY xact,billing_type
          ORDER BY MAX(billing_ts);
 
@@ -100,7 +96,6 @@ CREATE OR REPLACE VIEW money.transaction_billing_summary AS
                MAX(billing_ts) AS last_billing_ts,
                SUM(COALESCE(amount,0)) AS total_owed
          FROM  money.billing
-         WHERE voided IS FALSE
          GROUP BY xact
          ORDER BY MAX(billing_ts);
 
@@ -115,26 +110,6 @@ CREATE OR REPLACE VIEW money.transaction_payment_summary AS
          GROUP BY xact
          ORDER BY MAX(payment_ts);
 
-CREATE OR REPLACE VIEW money.transaction_billing_with_void_summary AS
-       SELECT  xact,
-               LAST(billing_type) AS last_billing_type,
-               LAST(note) AS last_billing_note,
-               MAX(billing_ts) AS last_billing_ts,
-               SUM(CASE WHEN voided THEN 0 ELSE COALESCE(amount,0) END) AS total_owed
-         FROM  money.billing
-         GROUP BY xact
-         ORDER BY MAX(billing_ts);
-
-CREATE OR REPLACE VIEW money.transaction_payment_with_void_summary AS
-       SELECT  xact,
-               LAST(payment_type) AS last_payment_type,
-               LAST(note) AS last_payment_note,
-               MAX(payment_ts) as last_payment_ts,
-               SUM(CASE WHEN voided THEN 0 ELSE COALESCE(amount,0) END) AS total_paid
-         FROM  money.payment_view
-         GROUP BY xact
-         ORDER BY MAX(payment_ts);
-
 CREATE OR REPLACE VIEW money.open_transaction_billing_type_summary AS
        SELECT  xact,
                billing_type AS last_billing_type,
@@ -142,7 +117,6 @@ CREATE OR REPLACE VIEW money.open_transaction_billing_type_summary AS
                MAX(billing_ts) AS last_billing_ts,
                SUM(COALESCE(amount,0)) AS total_owed
          FROM  money.billing
-         WHERE voided IS FALSE
          GROUP BY xact,billing_type
          ORDER BY MAX(billing_ts);
 
@@ -153,7 +127,6 @@ CREATE OR REPLACE VIEW money.open_transaction_billing_summary AS
                MAX(billing_ts) AS last_billing_ts,
                SUM(COALESCE(amount,0)) AS total_owed
          FROM  money.billing
-         WHERE voided IS FALSE
          GROUP BY xact
          ORDER BY MAX(billing_ts);
 
@@ -168,49 +141,6 @@ CREATE OR REPLACE VIEW money.open_transaction_payment_summary AS
          GROUP BY xact
          ORDER BY MAX(payment_ts);
 
-/* Replacing with the one below.
-CREATE OR REPLACE VIEW money.billable_xact_with_void_summary AS
-       SELECT  xact.id AS id,
-               xact.usr AS usr,
-               xact.xact_start AS xact_start,
-               xact.xact_finish AS xact_finish,
-               credit.total_paid,
-               credit.last_payment_ts,
-               credit.last_payment_note,
-               credit.last_payment_type,
-               debit.total_owed,
-               debit.last_billing_ts,
-               debit.last_billing_note,
-               debit.last_billing_type,
-               COALESCE(debit.total_owed,0) - COALESCE(credit.total_paid,0) AS balance_owed,
-               p.relname AS xact_type
-         FROM  money.billable_xact xact
-               JOIN pg_class p ON (xact.tableoid = p.oid)
-               LEFT JOIN money.transaction_billing_with_void_summary debit ON (xact.id = debit.xact)
-               LEFT JOIN money.transaction_payment_with_void_summary credit ON (xact.id = credit.xact);
-*/
-
-CREATE OR REPLACE VIEW money.billable_xact_with_void_summary AS
-       SELECT  xact.id AS id,
-               xact.usr AS usr,
-               xact.xact_start AS xact_start,
-               xact.xact_finish AS xact_finish,
-               SUM(credit.amount) AS total_paid,
-               MAX(credit.payment_ts) AS last_payment_ts,
-               LAST(credit.note) AS last_payment_note,
-               LAST(credit.payment_type) AS last_payment_type,
-               SUM(debit.amount) AS total_owed,
-               MAX(debit.billing_ts) AS last_billing_ts,
-               LAST(debit.note) AS last_billing_note,
-               LAST(debit.billing_type) AS last_billing_type,
-               COALESCE(SUM(debit.amount),0) - COALESCE(SUM(credit.amount),0) AS balance_owed,
-               p.relname AS xact_type
-         FROM  money.billable_xact xact
-               JOIN pg_class p ON (xact.tableoid = p.oid)
-               LEFT JOIN money.billing debit ON (xact.id = debit.xact)
-               LEFT JOIN money.payment_view credit ON (xact.id = credit.xact)
-         GROUP BY 1,2,3,4,14
-         ORDER BY MAX(debit.billing_ts), MAX(credit.payment_ts);
 
 CREATE OR REPLACE VIEW money.billable_xact_summary AS
        SELECT  xact.id,
@@ -236,7 +166,6 @@ CREATE OR REPLACE VIEW money.billable_xact_summary AS
                                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 (
@@ -297,12 +226,9 @@ CREATE TRIGGER mat_summary_create_tgr AFTER INSERT ON money.grocery FOR EACH ROW
 CREATE TRIGGER mat_summary_change_tgr AFTER UPDATE ON money.grocery FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_update ();
 CREATE TRIGGER mat_summary_remove_tgr AFTER DELETE ON money.grocery FOR EACH ROW EXECUTE PROCEDURE money.mat_summary_delete ();
 
-
-
 /* BEFORE or AFTER trigger */
 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,
@@ -310,7 +236,6 @@ BEGIN
                        last_billing_type = NEW.billing_type,
                        balance_owed = balance_owed + NEW.amount
                  WHERE id = NEW.xact;
-       END IF;
 
        RETURN NEW;
 END;
@@ -323,44 +248,12 @@ DECLARE
        old_voided      money.billing%ROWTYPE;
 BEGIN
 
-       SELECT * INTO old_billing FROM money.billing WHERE xact = NEW.xact AND NOT voided ORDER BY billing_ts DESC LIMIT 1;
-       SELECT * INTO old_voided FROM money.billing WHERE xact = NEW.xact ORDER BY billing_ts DESC LIMIT 1;
-
-       IF NEW.voided AND NOT OLD.voided THEN
-               IF OLD.id = old_voided.id THEN
-                       UPDATE  money.materialized_billable_xact_summary
-                         SET   last_billing_ts = old_billing.billing_ts,
-                               last_billing_note = old_billing.note,
-                               last_billing_type = old_billing.billing_type
-                         WHERE id = OLD.xact;
-               END IF;
+       SELECT * INTO old_billing FROM money.billing WHERE xact = NEW.xact ORDER BY billing_ts DESC LIMIT 1;
 
                UPDATE  money.materialized_billable_xact_summary
-                 SET   total_owed = total_owed - NEW.amount,
-                       balance_owed = balance_owed - NEW.amount
-                 WHERE id = NEW.xact;
-
-       ELSIF NOT NEW.voided AND OLD.voided THEN
-
-               IF OLD.id = old_billing.id THEN
-                       UPDATE  money.materialized_billable_xact_summary
-                         SET   last_billing_ts = old_billing.billing_ts,
-                               last_billing_note = old_billing.note,
-                               last_billing_type = old_billing.billing_type
-                         WHERE id = OLD.xact;
-               END IF;
-
-               UPDATE  money.materialized_billable_xact_summary
-                 SET   total_owed = total_owed + NEW.amount,
-                       balance_owed = balance_owed + NEW.amount
-                 WHERE id = NEW.xact;
-
-       ELSE
-               UPDATE  money.materialized_billable_xact_summary
                  SET   total_owed = total_owed - (OLD.amount - NEW.amount),
                        balance_owed = balance_owed - (OLD.amount - NEW.amount)
                  WHERE id = NEW.xact;
-       END IF;
 
        RETURN NEW;
 END;
@@ -372,8 +265,8 @@ DECLARE
        prev_billing    money.billing%ROWTYPE;
        old_billing     money.billing%ROWTYPE;
 BEGIN
-       SELECT * INTO prev_billing FROM money.billing WHERE xact = OLD.xact AND NOT voided ORDER BY billing_ts DESC LIMIT 1 OFFSET 1;
-       SELECT * INTO old_billing FROM money.billing WHERE xact = OLD.xact AND NOT voided ORDER BY billing_ts DESC LIMIT 1;
+       SELECT * INTO prev_billing FROM money.billing WHERE xact = OLD.xact ORDER BY billing_ts DESC LIMIT 1 OFFSET 1;
+       SELECT * INTO old_billing FROM money.billing WHERE xact = OLD.xact ORDER BY billing_ts DESC LIMIT 1;
 
        IF OLD.id = old_billing.id THEN
                UPDATE  money.materialized_billable_xact_summary
@@ -383,12 +276,10 @@ BEGIN
                  WHERE id = OLD.xact;
        END IF;
 
-       IF NOT OLD.voided THEN
                UPDATE  money.materialized_billable_xact_summary
                  SET   total_owed = total_owed - OLD.amount,
                        balance_owed = balance_owed + OLD.amount
                  WHERE id = OLD.xact;
-       END IF;
 
        RETURN OLD;
 END;
@@ -539,6 +430,20 @@ CREATE TRIGGER mat_summary_add_tgr AFTER INSERT ON money.forgive_payment FOR EAC
 CREATE TRIGGER mat_summary_upd_tgr AFTER UPDATE ON money.forgive_payment FOR EACH ROW EXECUTE PROCEDURE money.materialized_summary_payment_update ('forgive_payment');
 CREATE TRIGGER mat_summary_del_tgr BEFORE DELETE ON money.forgive_payment FOR EACH ROW EXECUTE PROCEDURE money.materialized_summary_payment_del ('forgive_payment');
 
+CREATE TABLE money.void_payment (
+    billing BIGINT REFERENCES money.billing (id) ON DELETE SET NULL
+) INHERITS (money.bnm_payment);
+ALTER TABLE money.void_payment ADD PRIMARY KEY (id);
+CREATE INDEX money_void_id_idx ON money.void_payment (id);
+CREATE INDEX money_void_payment_xact_idx ON money.void_payment (xact);
+CREATE INDEX money_void_payment_bill_idx ON money.void_payment (billing);
+CREATE INDEX money_void_payment_payment_ts_idx ON money.void_payment (payment_ts);
+CREATE INDEX money_void_payment_accepting_usr_idx ON money.void_payment (accepting_usr);
+
+CREATE TRIGGER mat_summary_add_tgr AFTER INSERT ON money.void_payment FOR EACH ROW EXECUTE PROCEDURE money.materialized_summary_payment_add ('void_payment');
+CREATE TRIGGER mat_summary_upd_tgr AFTER UPDATE ON money.void_payment FOR EACH ROW EXECUTE PROCEDURE money.materialized_summary_payment_update ('void_payment');
+CREATE TRIGGER mat_summary_del_tgr BEFORE DELETE ON money.void_payment FOR EACH ROW EXECUTE PROCEDURE money.materialized_summary_payment_del ('void_payment');
+
 
 CREATE TABLE money.work_payment () INHERITS (money.bnm_payment);
 ALTER TABLE money.work_payment ADD PRIMARY KEY (id);
index e8a3e55..1d73a02 100644 (file)
@@ -277,14 +277,6 @@ SELECT     id,
        END AS bib_record
   FROM action.hold_request ahr;
 
-CREATE OR REPLACE VIEW reporter.xact_billing_totals AS
-SELECT b.xact,
-       SUM( CASE WHEN b.voided THEN 0 ELSE amount END ) as unvoided,
-       SUM( CASE WHEN b.voided THEN amount ELSE 0 END ) as voided,
-       SUM( amount ) as total
-  FROM money.billing b
-  GROUP BY 1;
-
 CREATE OR REPLACE VIEW reporter.xact_paid_totals AS
 SELECT b.xact,
        SUM( CASE WHEN b.voided THEN 0 ELSE amount END ) as unvoided,
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.money.void_payment.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.money.void_payment.sql
new file mode 100644 (file)
index 0000000..dbfe0f2
--- /dev/null
@@ -0,0 +1,196 @@
+-- Add table and triggers for the new void payment type.
+
+BEGIN;
+
+-- SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version);
+
+-- Create the money.void_payment table and associated triggers.
+CREATE TABLE money.void_payment (
+    billing BIGINT REFERENCES money.billing (id) ON DELETE SET NULL
+) INHERITS (money.bnm_payment);
+ALTER TABLE money.void_payment ADD PRIMARY KEY (id);
+CREATE INDEX money_void_payment_xact_idx ON money.void_payment (xact);
+CREATE INDEX money_void_payment_bill_idx ON money.void_payment (billing);
+CREATE INDEX money_void_payment_payment_ts_idx ON money.void_payment (payment_ts);
+CREATE INDEX money_void_payment_accepting_usr_idx ON money.void_payment (accepting_usr);
+
+CREATE TRIGGER mat_summary_add_tgr AFTER INSERT ON money.void_payment FOR EACH ROW EXECUTE PROCEDURE money.materialized_summary_payment_add ('void_payment');
+CREATE TRIGGER mat_summary_upd_tgr AFTER UPDATE ON money.void_payment FOR EACH ROW EXECUTE PROCEDURE money.materialized_summary_payment_update ('void_payment');
+CREATE TRIGGER mat_summary_del_tgr BEFORE DELETE ON money.void_payment FOR EACH ROW EXECUTE PROCEDURE money.materialized_summary_payment_del ('void_payment');
+
+-- Create money.void_payment entries for the existing voided bills.
+INSERT INTO money.void_payment
+(xact, billing, payment_ts, amount, amount_collected, note, accepting_usr)
+SELECT xact, id, COALESCE(void_time, billing_ts), amount, amount,
+       'Converted from voided billing.', COALESCE(voider, 1)
+FROM money.billing
+WHERE voided = TRUE;
+
+-- Drop the voided, void_time and voider columns from money.billing.
+ALTER TABLE money.billing DROP COLUMN voided CASCADE;
+ALTER TABLE money.billing DROP COLUMN void_time CASCADE;
+ALTER TABLE money.billing DROP COLUMN voider CASCADE;
+
+-- Recreate billing summary views now that voided is out of the picture.
+CREATE OR REPLACE VIEW money.transaction_billing_type_summary AS
+       SELECT  xact,
+               billing_type AS last_billing_type,
+               LAST(note) AS last_billing_note,
+               MAX(billing_ts) AS last_billing_ts,
+               SUM(COALESCE(amount,0)) AS total_owed
+         FROM  money.billing
+         GROUP BY xact,billing_type
+         ORDER BY MAX(billing_ts);
+
+CREATE OR REPLACE VIEW money.transaction_billing_summary AS
+       SELECT  xact,
+               LAST(billing_type) AS last_billing_type,
+               LAST(note) AS last_billing_note,
+               MAX(billing_ts) AS last_billing_ts,
+               SUM(COALESCE(amount,0)) AS total_owed
+         FROM  money.billing
+         GROUP BY xact
+         ORDER BY MAX(billing_ts);
+
+CREATE OR REPLACE VIEW money.open_transaction_billing_type_summary AS
+       SELECT  xact,
+               billing_type AS last_billing_type,
+               LAST(note) AS last_billing_note,
+               MAX(billing_ts) AS last_billing_ts,
+               SUM(COALESCE(amount,0)) AS total_owed
+         FROM  money.billing
+         GROUP BY xact,billing_type
+         ORDER BY MAX(billing_ts);
+
+CREATE OR REPLACE VIEW money.open_transaction_billing_summary AS
+       SELECT  xact,
+               LAST(billing_type) AS last_billing_type,
+               LAST(note) AS last_billing_note,
+               MAX(billing_ts) AS last_billing_ts,
+               SUM(COALESCE(amount,0)) AS total_owed
+         FROM  money.billing
+         GROUP BY xact
+         ORDER BY MAX(billing_ts);
+
+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
+                         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;
+
+-- Drop billable_xact_with_void_summary since billable_xact_summary
+-- now takes its place.
+DROP VIEW money.billable_xact_with_void_summary;
+
+-- Alter trigger functions as necessary.
+/* BEFORE or AFTER trigger */
+CREATE OR REPLACE FUNCTION money.materialized_summary_billing_add () RETURNS TRIGGER AS $$
+BEGIN
+   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;
+
+       RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+/* AFTER trigger only! */
+CREATE OR REPLACE FUNCTION money.materialized_summary_billing_update () RETURNS TRIGGER AS $$
+DECLARE
+       old_billing     money.billing%ROWTYPE;
+       old_voided      money.billing%ROWTYPE;
+BEGIN
+
+       SELECT * INTO old_billing FROM money.billing WHERE xact = NEW.xact ORDER BY billing_ts DESC LIMIT 1;
+
+       UPDATE  money.materialized_billable_xact_summary
+      SET      total_owed = total_owed - (OLD.amount - NEW.amount),
+                       balance_owed = balance_owed - (OLD.amount - NEW.amount)
+      WHERE    id = NEW.xact;
+
+       RETURN NEW;
+END;
+$$ LANGUAGE PLPGSQL;
+
+/* BEFORE trigger only! */
+CREATE OR REPLACE FUNCTION money.materialized_summary_billing_del () RETURNS TRIGGER AS $$
+DECLARE
+       prev_billing    money.billing%ROWTYPE;
+       old_billing     money.billing%ROWTYPE;
+BEGIN
+       SELECT * INTO prev_billing FROM money.billing WHERE xact = OLD.xact ORDER BY billing_ts DESC LIMIT 1 OFFSET 1;
+       SELECT * INTO old_billing FROM money.billing WHERE xact = OLD.xact ORDER BY billing_ts DESC LIMIT 1;
+
+       IF OLD.id = old_billing.id THEN
+               UPDATE  money.materialized_billable_xact_summary
+                 SET   last_billing_ts = prev_billing.billing_ts,
+                       last_billing_note = prev_billing.note,
+                       last_billing_type = prev_billing.billing_type
+                 WHERE id = OLD.xact;
+       END IF;
+
+       UPDATE  money.materialized_billable_xact_summary
+         SET   total_owed = total_owed - OLD.amount,
+               balance_owed = balance_owed + OLD.amount
+         WHERE id = OLD.xact;
+
+       RETURN OLD;
+END;
+$$ LANGUAGE PLPGSQL;
+
+-- Update money.materialized_billable_xact_summary for changes in bills and payments.
+-- Dyrcona had some lame DO thing, and tsbere sped it up with the below:
+WITH xact_billing AS (
+SELECT xact, SUM(amount) AS total FROM money.billing GROUP BY xact
+),
+xact_payment AS (
+SELECT xact, SUM(amount) AS total FROM money.payment GROUP BY xact
+),
+xact_summary AS (
+SELECT xact, mb.total AS billing, mp.total AS payment, mb.total - mp.total AS balance
+FROM xact_billing mb JOIN xact_payment mp USING (xact)
+)
+UPDATE money.materialized_billable_xact_summary
+SET total_paid = xs.payment,
+    total_owed = xs.billing,
+    balance_owed = xs.balance
+FROM xact_summary xs
+WHERE xs.xact = id;
+
+COMMIT;
index c3c6cf0..d787753 100644 (file)
 <!ENTITY staff.patron.bills_overlay.patron_credit.label "Patron Credit">
 <!ENTITY staff.patron.bills_overlay.word.label "Work">
 <!ENTITY staff.patron.bills_overlay.forgive.label "Forgive">
+<!ENTITY staff.patron.bills_overlay.void.label "Void">
 <!ENTITY staff.patron.bills_overlay.goods.label "Goods">
 <!ENTITY staff.patron.bills_overlay.payment_received.value "Payment received">
 <!ENTITY staff.patron.bills_overlay.payment_received.accesskey "a">
index 2889b7b..4b9e128 100644 (file)
                                         <menuitem id="payment_type_menuitem4" class="hide_patron_credit" label="&staff.patron.bills_overlay.patron_credit.label;" value="credit_payment" />
                                         <menuitem id="payment_type_menuitem5" class="hide_patron_work" label="&staff.patron.bills_overlay.word.label;" value="work_payment"/>
                                         <menuitem id="payment_type_menuitem6" class="hide_patron_forgive" label="&staff.patron.bills_overlay.forgive.label;" value="forgive_payment"/>
-                                        <menuitem id="payment_type_menuitem7" class="hide_patron_goods" label="&staff.patron.bills_overlay.goods.label;" value="goods_payment"/>
+                                        <menuitem id="payment_type_menuitem7" class="hide_patron_void" label="&staff.patron.bills_overlay.void.label;" value="void_payment"/>
+                                        <menuitem id="payment_type_menuitem8" class="hide_patron_goods" label="&staff.patron.bills_overlay.goods.label;" value="goods_payment"/>
                                     </menupopup>
                                 </menulist>
                             </row>