adding flattened open transaction view for the reporter; splitting cross-schema views...
authormiker <miker@dcc99617-32d9-48b4-a31d-7c20da2025e4>
Wed, 20 Jun 2007 00:22:36 +0000 (00:22 +0000)
committermiker <miker@dcc99617-32d9-48b4-a31d-7c20da2025e4>
Wed, 20 Jun 2007 00:22:36 +0000 (00:22 +0000)
git-svn-id: svn://svn.open-ils.org/ILS/branches/rel_1_0@7453 dcc99617-32d9-48b4-a31d-7c20da2025e4

Open-ILS/examples/fm_IDL.xml
Open-ILS/src/sql/Pg/080.schema.money.sql
Open-ILS/src/sql/Pg/500.view.cross-schema.sql [new file with mode: 0644]
Open-ILS/src/sql/Pg/build-db.sh
Open-ILS/src/sql/Pg/example.reporter-extension.sql

index 644d404..eee8720 100644 (file)
                        <field name="xact" oils_obj:array_position="17" oils_persist:virtual="true" reporter:datatype="link"/>
                        <field name="grocery" oils_obj:array_position="18" oils_persist:virtual="true" reporter:datatype="link"/>
                        <field name="circulation" oils_obj:array_position="19" oils_persist:virtual="true" reporter:datatype="link"/>
+                       <field name="billing_location" oils_obj:array_position="20" oils_persist:virtual="false" reporter:datatype="link"/>
                </fields>
                <links>
                        <link field="usr" reltype="has_a" key="id" map="" class="au"/>
                        <link field="xact" reltype="might_have" key="id" map="" class="mbt"/>
                        <link field="circulation" reltype="might_have" key="id" map="" class="circ"/>
                        <link field="grocery" reltype="might_have" key="id" map="" class="mg"/>
+                       <link field="billing_location" reltype="has_a" key="id" map="" class="aou"/>
                </links>
        </class>
        <class id="au" controller="open-ils.cstore" oils_obj:fieldmapper="actor::user" oils_persist:tablename="actor.usr" reporter:core="true" reporter:label="ILS User">
                        <link field="owner" reltype="has_a" key="id" map="" class="aou"/>
                </links>
        </class>
+
+       <class id="rccbs" controller="open-ils.reporter-store" oils_obj:fieldmapper="reporter::classic_current_billing_summary" oils_persist:tablename="reporter.classic_current_billing_summary" reporter:core="true" reporter:label="Classic Open Transaction Summary">
+               <fields oils_persist:primary="id">
+                       <field name="isnew" oils_obj:array_position="0" oils_persist:virtual="true" />
+                       <field name="ischanged" oils_obj:array_position="1" oils_persist:virtual="true" />
+                       <field name="isdeleted" oils_obj:array_position="2" oils_persist:virtual="true" />
+                       <field reporter:label="Transaction ID" name="id" oils_obj:array_position="3" oils_persist:virtual="false" reporter:datatype="id" />
+
+                       <field reporter:label="Billing Location Short (Policy) Name" name="billing_location_shortname" oils_obj:array_position="4" oils_persist:virtual="false" reporter:datatype="text"/>
+                       <field reporter:label="Billing Location Name" name="billing_location_name" oils_obj:array_position="5" oils_persist:virtual="false" reporter:datatype="text"/>
+                       <field reporter:label="Billing Location Link" name="billing_location" oils_obj:array_position="6" oils_persist:virtual="false" reporter:datatype="org_unit"/>
+
+                       <field reporter:label="User Home Library Short (Policy) Name" name="usr_home_ou_shortname" oils_obj:array_position="7" oils_persist:virtual="false" reporter:datatype="text"/>
+                       <field reporter:label="User Home Library Name" name="usr_home_ou" oils_obj:array_position="8" oils_persist:virtual="false" reporter:datatype="text"/>
+                       <field reporter:label="User Home Library Link" name="usr_home_ou" oils_obj:array_position="9" oils_persist:virtual="false" reporter:datatype="org_unit"/>
+
+                       <field reporter:label="User Barcode" name="barcode" oils_obj:array_position="10" oils_persist:virtual="false" reporter:datatype="text"/>
+                       <field reporter:label="User Link" name="usr" oils_obj:array_position="11" oils_persist:virtual="false" reporter:datatype="link"/>
+
+                       <field reporter:label="Transaction Start Date/Time" name="xact_start" oils_obj:array_position="12" oils_persist:virtual="false" reporter:datatype="timestamp"/>
+                       <field reporter:label="Transaction End Date/Time" name="xact_finish" oils_obj:array_position="13" oils_persist:virtual="false" reporter:datatype="timestamp"/>
+                       <field reporter:label="Transaction Type" name="xact_type" oils_obj:array_position="14" oils_persist:virtual="false" reporter:datatype="text"/>
+
+                       <field reporter:label="Total Paid" name="total_paid" oils_obj:array_position="15" oils_persist:virtual="false" reporter:datatype="money"/>
+                       <field reporter:label="Total Billed" name="total_owed" oils_obj:array_position="16" oils_persist:virtual="false" reporter:datatype="money"/>
+
+                       <field reporter:label="Last Payment Date/Time" name="last_payment_ts" oils_obj:array_position="17" oils_persist:virtual="false" reporter:datatype="timestamp"/>
+                       <field reporter:label="Last Payment Note" name="last_payment_note" oils_obj:array_position="18" oils_persist:virtual="false" reporter:datatype="text"/>
+                       <field reporter:label="Last Payment Type" name="last_payment_type" oils_obj:array_position="19" oils_persist:virtual="false" reporter:datatype="text"/>
+
+                       <field reporter:label="Last Billing Date/Time" name="last_billing_ts" oils_obj:array_position="20" oils_persist:virtual="false" reporter:datatype="timestamp"/>
+                       <field reporter:label="Last Billing Note" name="last_billing_note" oils_obj:array_position="21" oils_persist:virtual="false" reporter:datatype="text"/>
+                       <field reporter:label="Last Billing Type" name="last_billing_type" oils_obj:array_position="22" oils_persist:virtual="false" reporter:datatype="text"/>
+
+                       <field reporter:label="User Age Demographic" name="demographic_general_division" oils_obj:array_position="23" oils_persist:virtual="false" reporter:datatype="text"/>
+                       <field reporter:label="User County" name="patron_county" oils_obj:array_position="24" oils_persist:virtual="false" reporter:datatype="text"/>
+                       <field reporter:label="User City" name="patron_city" oils_obj:array_position="25" oils_persist:virtual="false" reporter:datatype="text"/>
+                       <field reporter:label="User ZIP Code" name="patron_zip" oils_obj:array_position="26" oils_persist:virtual="false" reporter:datatype="text"/>
+
+                       <field reporter:label="Balance Owed" name="balance_owed" oils_obj:array_position="27" oils_persist:virtual="false" reporter:datatype="money"/>
+                       <field reporter:label="User Profile Group" name="profile_group" oils_obj:array_position="28" oils_persist:virtual="false" reporter:datatype="text"/>
+
+               </fields>
+               <links>
+                       <link field="id" reltype="has_a" key="id" map="" class="mbt"/>
+                       <link field="usr" reltype="has_a" key="id" map="" class="au"/>
+                       <link field="billing_location" reltype="has_a" key="id" map="" class="aou"/>
+                       <link field="usr_home_ou" reltype="has_a" key="id" map="" class="aou"/>
+               </links>
+       </class>
+
+
+
        <!-- ********************************************************************************************************************* -->
 
 </IDL>
index fe974c5..19b8994 100644 (file)
@@ -233,47 +233,6 @@ CREATE OR REPLACE VIEW money.billable_xact_summary AS
          GROUP BY 1,2,3,4,14
          ORDER BY MAX(debit.billing_ts), MAX(credit.payment_ts);
 
-CREATE OR REPLACE VIEW money.open_billable_xact_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 AND debit.voided IS FALSE)
-               LEFT JOIN money.payment_view credit ON (xact.id = credit.xact AND credit.voided IS FALSE)
-         WHERE xact.xact_finish IS NULL
-         GROUP BY 1,2,3,4,14
-         ORDER BY MAX(debit.billing_ts), MAX(credit.payment_ts);
-
-
-CREATE OR REPLACE VIEW money.open_usr_summary AS
-       SELECT  usr,
-               SUM(total_paid) AS total_paid,
-               SUM(total_owed) AS total_owed, 
-               SUM(balance_owed) AS balance_owed
-         FROM money.open_billable_xact_summary
-         GROUP BY 1;
-
-CREATE OR REPLACE VIEW money.open_usr_circulation_summary AS
-       SELECT  usr,
-               SUM(total_paid) AS total_paid,
-               SUM(total_owed) AS total_owed, 
-               SUM(balance_owed) AS balance_owed
-         FROM  money.open_billable_xact_summary
-         WHERE xact_type = 'circulation'
-         GROUP BY 1;
-
 CREATE OR REPLACE VIEW money.usr_summary AS
        SELECT  usr,
                SUM(total_paid) AS total_paid,
@@ -323,7 +282,6 @@ CREATE TABLE money.bnm_desk_payment (
 ) INHERITS (money.bnm_payment);
 ALTER TABLE money.bnm_desk_payment ADD PRIMARY KEY (id);
 
-
 CREATE OR REPLACE VIEW money.desk_payment_view AS
        SELECT  p.*,c.relname AS payment_type
          FROM  money.bnm_desk_payment p
diff --git a/Open-ILS/src/sql/Pg/500.view.cross-schema.sql b/Open-ILS/src/sql/Pg/500.view.cross-schema.sql
new file mode 100644 (file)
index 0000000..23c2b2c
--- /dev/null
@@ -0,0 +1,68 @@
+BEGIN;
+
+CREATE OR REPLACE VIEW money.open_billable_xact_summary AS
+       SELECT  xact.id AS id,
+               xact.usr AS usr,
+               COALESCE(circ.circ_lib,groc.billing_location) AS billing_location,
+               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 "action".circulation circ ON (circ.id = xact.id)
+               LEFT JOIN money.grocery groc ON (groc.id = xact.id)
+               LEFT JOIN (
+                       SELECT  billing.xact,
+                               billing.voided,
+                               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, billing.voided
+               ) debit ON (xact.id = debit.xact AND debit.voided IS FALSE)
+               LEFT JOIN (
+                       SELECT  payment_view.xact,
+                               payment_view.voided,
+                               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, payment_view.voided
+               ) credit ON (xact.id = credit.xact AND credit.voided IS FALSE)
+         WHERE xact.xact_finish IS NULL
+         GROUP BY 1,2,3,4,5,15
+         ORDER BY MAX(debit.billing_ts), MAX(credit.payment_ts);
+
+
+CREATE OR REPLACE VIEW money.open_usr_summary AS
+       SELECT  usr,
+               SUM(total_paid) AS total_paid,
+               SUM(total_owed) AS total_owed, 
+               SUM(balance_owed) AS balance_owed
+         FROM money.open_billable_xact_summary
+         GROUP BY 1;
+
+CREATE OR REPLACE VIEW money.open_usr_circulation_summary AS
+       SELECT  usr,
+               SUM(total_paid) AS total_paid,
+               SUM(total_owed) AS total_owed, 
+               SUM(balance_owed) AS balance_owed
+         FROM  money.open_billable_xact_summary
+         WHERE xact_type = 'circulation'
+         GROUP BY 1;
+
+COMMIT;
+
index f52b968..b7f5d98 100755 (executable)
@@ -16,5 +16,7 @@ PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 070.schema.container.sql
 PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 080.schema.money.sql
 PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 090.schema.action.sql
 
+PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 500.view.cross-schema.sql
+
 PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 800.fkeys.sql
 PGUSER=$4 PGHOST=$1 PGPORT=$2 PGDATABASE=$3 psql -f 900.audit-tables.sql
index 6d1e375..88d310e 100644 (file)
@@ -118,5 +118,43 @@ SELECT     id,
   WHERE        stat_cat = 2;
 
 
+CREATE OR REPLACE VIEW reporter.classic_current_billing_summary AS
+SELECT x.id AS id,
+       x.usr AS usr,
+       bl.shortname AS billing_location_shortname,
+       bl.name AS billing_location_name,
+       x.billing_location AS billing_location,
+       c.barcode AS barcode,
+       u.home_ou AS usr_home_ou,
+       ul.shortname AS usr_home_ou_shortname,
+       ul.name AS usr_home_ou_name,
+       x.xact_start AS xact_start,
+       x.xact_finish AS xact_finish,
+       x.xact_type AS xact_type,
+       x.total_paid AS total_paid,
+       x.total_owed AS total_owed,
+       x.balance_owed AS balance_owed,
+       x.last_payment_ts AS last_payment_ts,
+       x.last_payment_note AS last_payment_note,
+       x.last_payment_type AS last_payment_type,
+       x.last_billing_ts AS last_billing_ts,
+       x.last_billing_note AS last_billing_note,
+       x.last_billing_type AS last_billing_type,
+       paddr.county AS patron_county,
+       paddr.city AS patron_city,
+       paddr.post_code AS patron_zip,
+       g.name AS profile_group,
+       dem.general_division AS demographic_general_division
+  FROM money.open_billable_xact_summary x
+       JOIN actor.org_unit bl ON (x.billing_location = bl.id)
+       JOIN actor.usr u ON (u.id = x.usr)
+       JOIN actor.org_unit ul ON (u.home_ou = ul.id)
+       JOIN actor.card c ON (u.card = c.id)
+       JOIN permission.grp_tree g ON (u.profile = g.id)
+       JOIN reporter.demographic dem ON (dem.id = u.id)
+       JOIN actor.usr_address paddr ON (paddr.id = u.billing_address);
+
+
 COMMIT;
 
+