LP#1630271 - Add Purchase Order Summary View
authorChris Sharp <csharp@georgialibraries.org>
Tue, 20 Jun 2017 13:05:07 +0000 (09:05 -0400)
committerChris Sharp <csharp@georgialibraries.org>
Tue, 14 May 2019 19:15:54 +0000 (15:15 -0400)
The purchase order reporting source contains several fields that are
available in the reporter but are non-functional (because they are
generated on-the-fly within user interfaces).  This view allows a
similar calculation and provides access back to the PO object as well.

Signed-off-by: Chris Sharp <csharp@georgialibraries.org>
Open-ILS/examples/fm_IDL.xml
Open-ILS/src/sql/Pg/example.reporter-extension.sql
Open-ILS/src/sql/Pg/upgrade/XXXX.schema.acq_invoice_reporter_view.sql

index aadb6a0..15af82b 100644 (file)
@@ -10345,6 +10345,34 @@ SELECT  usr,
                        <link field="shipper_id" reltype="might_have" key="id" map="" class="acqpro"/>
                </links>
        </class>
+       <class id="raposv" controller="open-ils.reporter-store" oils_obj:fieldmapper="reporter::acq_purchase_order_summary_view" oils_persist:tablename="reporter.acq_purchase_order_summary_view" reporter:label="Acquisitions Purchase Order Summary">
+               <fields oils_persist:primary="id">
+                       <field reporter:label="Purchase Order ID" name="id" reporter:datatype="link"/>
+                       <field reporter:label="Owner" name="owner" reporter:datatype="link"/>
+                       <field reporter:label="Creator" name="creator" reporter:datatype="link"/>
+                       <field reporter:label="Ordering Agency" name="ordering_agency" reporter:datatype="link"/>
+                       <field reporter:label="Creation Date/Time" name="create_time" reporter:datatype="timestamp"/>
+                       <field reporter:label="Last Edit Date/Time" name="edit_time" reporter:datatype="timestamp"/>
+                       <field reporter:label="Provider" name="provider" reporter:datatype="link"/>
+                       <field reporter:label="State" name="state" reporter:datatype="text"/>
+                       <field reporter:label="Order Date/Time" name="order_date" reporter:datatype="timestamp"/>
+                       <field reporter:label="Purchase Order Name" name="name" reporter:datatype="timestamp"/>
+                       <field reporter:label="Cancel Reason" name="cancel_reason" reporter:datatype="link"/>
+                       <field reporter:label="Pre-Payment Required?" name="prepayment_required" reporter:datatype="bool"/>
+                       <field reporter:label="Lineitem Count" name="lineitem_count" reporter:datatype="int"/>
+                       <field reporter:label="Amount Encumbered" name="amount_encumbered" reporter:datatype="money"/>
+                       <field reporter:label="Amount Spent" name="amount_spent" reporter:datatype="money"/>
+                       <field reporter:label="Amount Estimated" name="amount_estimated" reporter:datatype="money"/>
+               </fields>
+               <links>
+                       <link field="id" reltype="has_a" key="id" map="" class="acqpo"/>
+                       <link field="owner" reltype="has_a" key="id" map="" class="au"/>
+                       <link field="creator" reltype="has_a" key="id" map="" class="au"/>
+                       <link field="ordering_agency" reltype="has_a" key="id" map="" class="aou"/>
+                       <link field="provider" reltype="has_a" key="id" map="" class="acqpro"/>
+                       <link field="cancel_reason" reltype="might_have" key="id" map="" class="acqcr"/>
+               </links>
+       </class>
        <class id="ergbhu" controller="open-ils.reporter-store" oils_obj:fieldmapper="extend_reporter::global_bibs_by_holding_update" oils_persist:tablename="extend_reporter.global_bibs_by_holding_update" reporter:label="Bib IDs by Holding Add/Delete Time (OCLC batch update)">
                <fields oils_persist:primary="id">
                        <field reporter:label="Bib ID" name="id" reporter:datatype="id" />
index 485eb37..3788c31 100644 (file)
@@ -1,5 +1,5 @@
 /*
- * Copyright (C) 2004-2008  Georgia Public Library Service
+ * Copyright (C) 2004-2017  Georgia Public Library Service
  * Copyright (C) 2007-2008  Equinox Software, Inc.
  * Mike Rylander <miker@esilibrary.com> 
  *
@@ -386,7 +386,115 @@ CREATE OR REPLACE VIEW reporter.acq_invoice_summary_view AS
            LEFT OUTER JOIN acq.provider shipper ON (invoice.shipper = shipper.id)
            LEFT OUTER JOIN actor.org_unit receiver ON (invoice.receiver = receiver.id);
 
+CREATE VIEW reporter.acq_purchase_order_summary_view AS
+SELECT  po.id,
+    po.owner,
+    po.creator,
+    po.editor,
+    po.ordering_agency,
+    po.create_time,
+    po.edit_time,
+    po.provider,
+    po.state,
+    po.order_date,
+    po.name,
+    po.cancel_reason,
+    po.prepayment_required,
+    -- lineitem_count
+    (SELECT COALESCE(COUNT(*), 0)
+        FROM acq.lineitem li
+        WHERE li.purchase_order = po.id) AS lineitem_count,
+    -- amount_encumbered
+    (SELECT COALESCE(SUM(amount), '0.00')
+        FROM acq.fund_debit afd
+        WHERE afd.encumbrance = TRUE
+        AND afd.id IN (
+            SELECT fund_debit
+            FROM acq.lineitem_detail lid
+            WHERE lineitem IN (
+                SELECT id
+                FROM acq.lineitem
+                WHERE purchase_order = po.id)
+        ) OR afd.id IN (
+            SELECT fund_debit
+            FROM acq.po_item
+            WHERE purchase_order = po.id
+        ) OR afd.id IN (
+            SELECT fund_debit
+            FROM acq.invoice_item
+            WHERE purchase_order = po.id
+        )) AS amount_encumbered,
+    -- amount_spent
+        (SELECT COALESCE(SUM(amount), '0.00')
+                FROM acq.fund_debit afd
+                WHERE afd.encumbrance = FALSE
+                AND afd.id IN (
+                        SELECT fund_debit
+                        FROM acq.lineitem_detail lid
+                        WHERE lineitem IN (
+                                SELECT id
+                                FROM acq.lineitem
+                                WHERE purchase_order = po.id)
+                ) OR afd.id IN (
+                        SELECT fund_debit
+                        FROM acq.po_item
+                        WHERE purchase_order = po.id
+                ) OR afd.id IN (
+                        SELECT fund_debit
+                        FROM acq.invoice_item
+                        WHERE purchase_order = po.id
+                )) AS amount_spent,
+    -- amount_estimated
+        CASE
+            WHEN (
+                SELECT id
+                FROM acq.fund_debit
+                WHERE id IN (
+                    SELECT fund_debit
+                    FROM acq.lineitem_detail
+                    WHERE lineitem IN (
+                        SELECT id
+                            FROM acq.lineitem
+                        WHERE purchase_order = po.id
+                    )
+                ) OR id IN (
+                SELECT fund_debit
+                FROM acq.po_item
+                WHERE purchase_order = po.id
+                ) OR id IN (
+                SELECT fund_debit
+                FROM acq.invoice_item
+                WHERE purchase_order = po.id
+                ) limit 1
+            ) IS NOT NULL THEN (
+                SELECT COALESCE(SUM(amount), '0.00')
+                                        FROM acq.fund_debit
+                            WHERE id IN (
+                                    SELECT fund_debit
+                                    FROM acq.lineitem_detail
+                                    WHERE lineitem IN (
+                                            SELECT id
+                                            FROM acq.lineitem
+                                            WHERE purchase_order = po.id
+                                    )
+                            ) OR id IN (
+                            SELECT fund_debit
+                            FROM acq.po_item
+                            WHERE purchase_order = po.id
+                            ) OR id IN (
+                            SELECT fund_debit
+                            FROM acq.invoice_item
+                            WHERE purchase_order = po.id
+                            )
+            ) ELSE (
+                SELECT (
+                    COALESCE(SUM(li.estimated_unit_price), '0.00') +
+                    COALESCE(SUM(poi.estimated_cost), '0.00')
+                ) FROM acq.lineitem li
+                LEFT OUTER JOIN acq.lineitem_detail lid ON (li.id = lid.lineitem)
+                LEFT OUTER JOIN acq.po_item poi ON (poi.purchase_order = po.id)
+                WHERE li.purchase_order = po.id
+            ) END AS amount_estimated
+FROM    acq.purchase_order po;
 
 COMMIT;
-
-
index 9aab645..57e2d6a 100644 (file)
@@ -71,4 +71,115 @@ CREATE OR REPLACE VIEW reporter.acq_invoice_summary_view AS
            LEFT OUTER JOIN acq.provider shipper ON (invoice.shipper = shipper.id)
            LEFT OUTER JOIN actor.org_unit receiver ON (invoice.receiver = receiver.id);
 
+CREATE VIEW reporter.acq_purchase_order_summary_view AS
+SELECT  po.id,
+    po.owner,
+    po.creator,
+    po.editor,
+    po.ordering_agency,
+    po.create_time,
+    po.edit_time,
+    po.provider,
+    po.state,
+    po.order_date,
+    po.name,
+    po.cancel_reason,
+    po.prepayment_required,
+    -- lineitem_count
+    (SELECT COALESCE(COUNT(*), 0)
+        FROM acq.lineitem li
+        WHERE li.purchase_order = po.id) AS lineitem_count,
+    -- amount_encumbered
+    (SELECT COALESCE(SUM(amount), '0.00')
+        FROM acq.fund_debit afd
+        WHERE afd.encumbrance = TRUE
+        AND afd.id IN (
+            SELECT fund_debit
+            FROM acq.lineitem_detail lid
+            WHERE lineitem IN (
+                SELECT id
+                FROM acq.lineitem
+                WHERE purchase_order = po.id)
+        ) OR afd.id IN (
+            SELECT fund_debit
+            FROM acq.po_item
+            WHERE purchase_order = po.id
+        ) OR afd.id IN (
+            SELECT fund_debit
+            FROM acq.invoice_item
+            WHERE purchase_order = po.id
+        )) AS amount_encumbered,
+    -- amount_spent
+        (SELECT COALESCE(SUM(amount), '0.00')
+                FROM acq.fund_debit afd
+                WHERE afd.encumbrance = FALSE
+                AND afd.id IN (
+                        SELECT fund_debit
+                        FROM acq.lineitem_detail lid
+                        WHERE lineitem IN (
+                                SELECT id
+                                FROM acq.lineitem
+                                WHERE purchase_order = po.id)
+                ) OR afd.id IN (
+                        SELECT fund_debit
+                        FROM acq.po_item
+                        WHERE purchase_order = po.id
+                ) OR afd.id IN (
+                        SELECT fund_debit
+                        FROM acq.invoice_item
+                        WHERE purchase_order = po.id
+                )) AS amount_spent,
+    -- amount_estimated
+        CASE
+            WHEN (
+                SELECT id
+                FROM acq.fund_debit
+                WHERE id IN (
+                    SELECT fund_debit
+                    FROM acq.lineitem_detail
+                    WHERE lineitem IN (
+                        SELECT id
+                            FROM acq.lineitem
+                        WHERE purchase_order = po.id
+                    )
+                ) OR id IN (
+                SELECT fund_debit
+                FROM acq.po_item
+                WHERE purchase_order = po.id
+                ) OR id IN (
+                SELECT fund_debit
+                FROM acq.invoice_item
+                WHERE purchase_order = po.id
+                ) limit 1
+            ) IS NOT NULL THEN (
+                SELECT COALESCE(SUM(amount), '0.00')
+                                        FROM acq.fund_debit
+                            WHERE id IN (
+                                    SELECT fund_debit
+                                    FROM acq.lineitem_detail
+                                    WHERE lineitem IN (
+                                            SELECT id
+                                            FROM acq.lineitem
+                                            WHERE purchase_order = po.id
+                                    )
+                            ) OR id IN (
+                            SELECT fund_debit
+                            FROM acq.po_item
+                            WHERE purchase_order = po.id
+                            ) OR id IN (
+                            SELECT fund_debit
+                            FROM acq.invoice_item
+                            WHERE purchase_order = po.id
+                            )
+            ) ELSE (
+                SELECT (
+                    COALESCE(SUM(li.estimated_unit_price), '0.00') +
+                    COALESCE(SUM(poi.estimated_cost), '0.00')
+                ) FROM acq.lineitem li
+                LEFT OUTER JOIN acq.lineitem_detail lid ON (li.id = lid.lineitem)
+                LEFT OUTER JOIN acq.po_item poi ON (poi.purchase_order = po.id)
+                WHERE li.purchase_order = po.id
+            ) END AS amount_estimated
+FROM    acq.purchase_order po;
+
 COMMIT;