LP#1793802 Aged billings and payments
authorBill Erickson <berickxx@gmail.com>
Fri, 21 Sep 2018 18:53:33 +0000 (14:53 -0400)
committerGalen Charlton <gmc@equinoxinitiative.org>
Fri, 6 Sep 2019 21:38:40 +0000 (17:38 -0400)
Creates tables money.aged_billing and money.aged_payment.  When a
circulation is aged, billings/payments linked to the circ are migrated
to the aged_* table.

Upgrade script includes a migration script for migrating existing
billings and payments.

Includes IDL entries for reporting and pcrud access just in case it's
needed.  Note the 'xact' column on these new tables links directly to
the aged circulation instead of the non-existent money.billable_xact.

Signed-off-by: Bill Erickson <berickxx@gmail.com>
Signed-off-by: Chris Sharp <csharp@georgialibraries.org>
Signed-off-by: Galen Charlton <gmc@equinoxinitiative.org>
Open-ILS/examples/fm_IDL.xml
Open-ILS/src/sql/Pg/080.schema.money.sql
Open-ILS/src/sql/Pg/090.schema.action.sql
Open-ILS/src/sql/Pg/upgrade/XXXX.schema.aged-billing-payment.sql [new file with mode: 0644]

index 1a85988..19e65a9 100644 (file)
@@ -8066,6 +8066,30 @@ SELECT  usr,
                        </actions>
                </permacrud>
        </class>
+       <class id="map" controller="open-ils.cstore open-ils.pcrud" 
+               oils_obj:fieldmapper="money::aged_payment" 
+               oils_persist:tablename="money.aged_payment" 
+               reporter:label="Payments: Aged">
+               <fields oils_persist:primary="id" oils_persist:sequence="">
+                       <field reporter:label="Amount" name="amount" reporter:datatype="money" />
+                       <field reporter:label="Payment ID" name="id" reporter:datatype="id" />
+                       <field reporter:label="Note" name="note" reporter:datatype="text"/>
+                       <field reporter:label="Payment Date/Time" name="payment_ts" reporter:datatype="timestamp"/>
+                       <field reporter:label="Payment Type" name="payment_type" reporter:datatype="text"/>
+                       <field reporter:label="Aged Circulation" name="xact" reporter:datatype="link"/>
+                       <field reporter:label="Voided?" name="voided" reporter:datatype="bool"/>
+               </fields>
+               <links>
+                       <link field="xact" reltype="has_a" key="id" map="" class="acirc"/>
+               </links>
+               <permacrud xmlns="http://open-ils.org/spec/opensrf/IDL/permacrud/v1">
+                       <actions>
+                               <retrieve permission="VIEW_USER_TRANSACTIONS">
+                                       <context link="xact" field="usr_home_ou"/>
+                               </retrieve>
+                       </actions>
+               </permacrud>
+       </class>
        <class id="mbp" controller="open-ils.cstore open-ils.pcrud" oils_obj:fieldmapper="money::bnm_payment" oils_persist:tablename="money.bnm_payment_view" reporter:core="true" reporter:label="Payments: Brick-and-mortar">
                <fields oils_persist:primary="id" oils_persist:sequence="">
                        <field reporter:label="Amount" name="amount" reporter:datatype="money" />
@@ -8338,6 +8362,38 @@ SELECT  usr,
                        </actions>
                </permacrud>
        </class>
+       <class id="mab" controller="open-ils.cstore open-ils.pcrud" 
+               oils_obj:fieldmapper="money::aged_billing" 
+               oils_persist:tablename="money.aged_billing" 
+               reporter:label="Aged Billing Line Item">
+               <fields oils_persist:primary="id" oils_persist:sequence="">
+                       <field reporter:label="Amount" name="amount" reporter:datatype="money" />
+                       <field reporter:label="Create Date" name="create_date" reporter:datatype="timestamp"/>
+                       <field reporter:label="Billing Period Start" name="period_start" reporter:datatype="timestamp"/>
+                       <field reporter:label="Billing Period End" name="period_end" reporter:datatype="timestamp"/>
+                       <field reporter:label="Legacy Billing Timestamp" name="billing_ts" reporter:datatype="timestamp"/>
+                       <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="acirc"/>
+                       <link field="voider" reltype="has_a" key="id" map="" class="au"/>
+                       <link field="btype" reltype="has_a" key="id" map="" class="cbt"/>
+               </links>
+               <permacrud xmlns="http://open-ils.org/spec/opensrf/IDL/permacrud/v1">
+                       <actions>
+                               <retrieve permission="VIEW_USER_TRANSACTIONS">
+                                       <context link="xact" field="usr_home_ou"/>
+                               </retrieve>
+                       </actions>
+               </permacrud>
+       </class>
        <class id="pugm" controller="open-ils.cstore" oils_obj:fieldmapper="permission::usr_grp_map" oils_persist:tablename="permission.usr_grp_map" reporter:label="User Group Map">
                <fields oils_persist:primary="id" oils_persist:sequence="permission.usr_grp_map_id_seq">
                        <field name="grp" />
index b5f3b27..85352ab 100644 (file)
@@ -77,7 +77,6 @@ END;
 $$ LANGUAGE PLPGSQL;
 CREATE TRIGGER maintain_billing_ts_tgr BEFORE INSERT OR UPDATE ON money.billing FOR EACH ROW EXECUTE PROCEDURE money.maintain_billing_ts();
 
-
 CREATE TABLE money.payment (
        id              BIGSERIAL                       PRIMARY KEY,
        xact            BIGINT                          NOT NULL, -- money.billable_xact.id
@@ -689,5 +688,10 @@ CREATE OR REPLACE VIEW money.cashdrawer_payment_view AS
                LEFT JOIN money.payment_view t ON (p.id = t.id);
 
 
+-- Create 'aged' clones of billing and payment_view tables
+CREATE TABLE money.aged_payment (LIKE money.payment INCLUDING INDEXES);
+ALTER TABLE money.aged_payment ADD COLUMN payment_type TEXT NOT NULL;
+CREATE TABLE money.aged_billing (LIKE money.billing INCLUDING INDEXES);
+
 COMMIT;
 
index 900c1b3..fe3c78a 100644 (file)
@@ -350,6 +350,17 @@ BEGIN
         max_fine_rule, stop_fines, workstation, checkin_workstation, checkin_scan_time, parent_circ
         FROM action.all_circulation WHERE id = OLD.id;
 
+    -- Migrate billings and payments to aged tables
+
+    INSERT INTO money.aged_billing
+        SELECT * FROM money.billing WHERE xact = OLD.id;
+
+    INSERT INTO money.aged_payment 
+        SELECT * FROM money.payment_view WHERE xact = OLD.id;
+
+    DELETE FROM money.billing WHERE xact = OLD.id;
+    DELETE FROM money.payment WHERE xact = OLD.id;
+
     RETURN OLD;
 END;
 $$ LANGUAGE 'plpgsql';
diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.aged-billing-payment.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.schema.aged-billing-payment.sql
new file mode 100644 (file)
index 0000000..f465411
--- /dev/null
@@ -0,0 +1,82 @@
+
+BEGIN;
+
+--SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version);
+
+\qecho Migrating aged billing and payment data.  This might take a while.
+
+CREATE TABLE money.aged_payment (LIKE money.payment INCLUDING INDEXES);
+ALTER TABLE money.aged_payment ADD COLUMN payment_type TEXT NOT NULL;
+CREATE TABLE money.aged_billing (LIKE money.billing INCLUDING INDEXES);
+
+INSERT INTO money.aged_payment 
+    SELECT  mp.* FROM money.payment_view mp
+    JOIN action.aged_circulation circ ON (circ.id = mp.xact);
+
+INSERT INTO money.aged_billing
+    SELECT mb.* FROM money.billing mb
+    JOIN action.aged_circulation circ ON (circ.id = mb.xact);
+
+DELETE FROM money.payment WHERE id IN (
+    SELECT mp.id FROM money.payment mp
+    JOIN action.aged_circulation circ ON (circ.id = mp.xact)
+);
+
+DELETE FROM money.billing WHERE id IN (
+    SELECT mb.id FROM money.billing mb
+    JOIN action.aged_circulation circ ON (circ.id = mb.xact)
+);
+
+
+CREATE OR REPLACE FUNCTION action.age_circ_on_delete () RETURNS TRIGGER AS $$
+DECLARE
+found char := 'N';
+BEGIN
+
+    -- If there are any renewals for this circulation, don't archive or delete
+    -- it yet.   We'll do so later, when we archive and delete the renewals.
+
+    SELECT 'Y' INTO found
+    FROM action.circulation
+    WHERE parent_circ = OLD.id
+    LIMIT 1;
+
+    IF found = 'Y' THEN
+        RETURN NULL;  -- don't delete
+       END IF;
+
+    -- Archive a copy of the old row to action.aged_circulation
+
+    INSERT INTO action.aged_circulation
+        (id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
+        copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
+        circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, grace_period, due_date,
+        stop_fines_time, checkin_time, create_time, duration, fine_interval, recurring_fine,
+        max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recurring_fine_rule,
+        max_fine_rule, stop_fines, workstation, checkin_workstation, checkin_scan_time, parent_circ)
+      SELECT
+        id,usr_post_code, usr_home_ou, usr_profile, usr_birth_year, copy_call_number, copy_location,
+        copy_owning_lib, copy_circ_lib, copy_bib_record, xact_start, xact_finish, target_copy,
+        circ_lib, circ_staff, checkin_staff, checkin_lib, renewal_remaining, grace_period, due_date,
+        stop_fines_time, checkin_time, create_time, duration, fine_interval, recurring_fine,
+        max_fine, phone_renewal, desk_renewal, opac_renewal, duration_rule, recurring_fine_rule,
+        max_fine_rule, stop_fines, workstation, checkin_workstation, checkin_scan_time, parent_circ
+        FROM action.all_circulation WHERE id = OLD.id;
+
+    -- Migrate billings and payments to aged tables
+
+    INSERT INTO money.aged_billing
+        SELECT * FROM money.billing WHERE xact = OLD.id;
+
+    INSERT INTO money.aged_payment 
+        SELECT * FROM money.payment_view WHERE xact = OLD.id;
+
+    DELETE FROM money.billing WHERE xact = OLD.id;
+    DELETE FROM money.payment WHERE xact = OLD.id;
+
+    RETURN OLD;
+END;
+$$ LANGUAGE 'plpgsql';
+
+COMMIT;
+