LP#1630271 - Creating acq purchase order and invoice reports views. user/csharp/lp1630271_acq_po_and_invoice_views
authorChris Sharp <csharp@georgialibraries.org>
Thu, 8 Sep 2016 13:02:25 +0000 (09:02 -0400)
committerChris Sharp <csharp@georgialibraries.org>
Tue, 4 Oct 2016 15:37:58 +0000 (11:37 -0400)
We currently lack several desired linkages in the reporter for
acquisitions data.  I'm creating views for POs and invoices to
hopefully alleviate some of the pain around acq reports.

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

index 7126f16..19f84cd 100644 (file)
@@ -10859,7 +10859,117 @@ SELECT  usr,
                </permacrud>
        </class>
 
-
+       <class id="racqpov" controller="open-ils.reporter-store" oils_obj:fieldmapper="reporter::acq_purchase_order_view" oils_persist:tablename="reporter.acq_purchase_order_view" reporter:core="false" reporter:label="Acquisitions: Purchase Order View">
+               <fields oils_persist:primary="po_id">
+                       <field reporter:label="Purchase Order ID" name="po_id" reporter:datatype="id"/>
+                       <field reporter:label="Purchase Order Name" name="po_name" reporter:datatype="text"/>
+                       <field reporter:label="Purchase Order Date/Time" name="po_order_date" reporter:datatype="timestamp"/>
+                       <field reporter:label="Provider Link" name="provider_id" reporter:datatype="link"/>     
+                       <field reporter:label="Provider Name" name="provider_name" reporter:datatype="text"/>
+                       <field reporter:label="Provider SAN" name="provider_san" reporter:datatype="text"/>
+                       <field reporter:label="Provider Address Link" name="provider_address_id" reporter:datatype="link"/>
+                       <field reporter:label="Ordering Agency Link" name="ordering_agency_id" reporter:datatype="link"/>
+                       <field reporter:label="Ordering Agency Name" name="ordering_agency_name" reporter:datatype="text"/>
+                       <field reporter:label="Ordering Agency Short (Policy) Name" name="ordering_agency_shortname" reporter:datatype="text"/> 
+                       <field reporter:label="Lineitem ID" name="lineitem_id" reporter:datatype="id"/>
+                       <field reporter:label="Lineitem Identifier" name="lineitem_identifier" reporter:datatype="text"/>
+                       <field reporter:label="Lineitem Title" name="lineitem_title" reporter:datatype="text"/>
+                       <field reporter:label="Lineitem Quantity Ordered" name="quantity_ordered" reporter:datatype="int"/>
+                       <field reporter:label="Estimated Unit Price" name="estimated_unit_price" reporter:datatype="money"/>
+                       <field reporter:label="Purchasing Library Link" name="purchasing_lib_id" reporter:datatype="link"/>
+                       <field reporter:label="Purchasing Library Name" name="purchasing_lib_name" reporter:datatype="text"/>
+                       <field reporter:label="Purchasing Library Short (Policy) Name" name="purchasing_lib_shortname" reporter:datatype="text"/>
+                       <field reporter:label="Fund Link" name="fund_id" reporter:datatype="link"/>
+                       <field reporter:label="Fund Name (Year)" name="fund_name" reporter:datatype="text"/>
+                       <field reporter:label="Purchase Order Item Type Code" name="po_item_type_code" reporter:datatype="text"/>
+                       <field reporter:label="Purchase Order Item Type Name" name="po_item_type_name" reporter:datatype="text"/>
+                       <field reporter:label="Purchase Order Item Link" name="po_item_id" reporter:datatype="link"/>
+                       <field reporter:label="Purchase Order Item Title" name="po_item_title" reporter:datatype="text"/>
+                       <field reporter:label="Purchase Order Item Author" name="po_item_author" reporter:datatype="text"/>
+                       <field reporter:label="Purchase Order Item Note" name="po_item_note" reporter:datatype="text"/>
+                       <field reporter:label="Purchase Order Item Estimated Cost" name="po_item_estimated_cost" reporter:datatype="money"/>
+                       <field reporter:label="Purchase Order Item Fund Link" name="po_item_fund_id" reporter:datatype="link"/>
+                       <field reporter:label="Purchase Order Item Fund Name (Year)" name="po_item_fund_name" reporter:datatype="text"/>
+                       <field reporter:label="Lineitem Total" name="lineitem_total_price" reporter:datatype="money"/>
+                       <field reporter:label="Purchase Order Item Total" name="po_item_total_price" reporter:datatype="money"/>
+               </fields>
+               <links>
+                       <link field="po_id" reltype="has_a" key="id" map="" class="acqpo"/>
+                       <link field="provider_id" reltype="has_a" key="id" map="" class="acqpro"/>
+                       <link field="provider_address_id" reltype="has_a" key="id" map="" class="acqpa"/>
+                       <link field="ordering_agency_id" reltype="has_a" key="id" map="" class="aou"/>
+                       <link field="lineitem_id" reltype="might_have" key="id" map="" class="jub"/>
+                       <link field="fund_id" reltype="has_a" key="id" map="" class="acqf"/>
+                       <link field="purchasing_lib_id" reltype="has_a" key="id" map="" class="aou"/>
+                       <link field="po_item_id" reltype="might_have" key="id" map="" class="acqpoi"/>
+                       <link field="po_item_fund_id" reltype="might_have" key="id" map="" class="acqf"/>
+               </links>
+       </class>        
+
+       <class id="racqiv" controller="open-ils.reporter-store" oils_obj:fieldmapper="reporter::acq_invoice_view" oils_persist:tablename="reporter.acq_purchase_order_view" reporter:core="false" reporter:label="Acquisitions: Invoice View">
+               <fields oils_persist:primary="inv_id">
+                       <field reporter:label="Invoice ID" name="inv_id" reporter:datatype="id"/>
+                       <field reporter:label="Invoice Identifier" name="inv_ident" reporter:datatype="text"/>
+                       <field reporter:label="Provider Link" name="provider_id" reporter:datatype="link"/>
+                       <field reporter:label="Provider Name" name="provider_name" reporter:datatype="text"/>
+                       <field reporter:label="Shipper Link" name="shipper_id" reporter:datatype="link"/>
+                       <field reporter:label="Shipper Name" name="shipper_name" reporter:datatype="text"/>
+                       <field reporter:label="Receive Date/Time" name="recv_date" reporter:datatype="timestamp"/>
+                       <field reporter:label="Receiving Org Unit Link" name="receiver_id" reporter:datatype="link"/>
+                       <field reporter:label="Receiving Org Unit Name" name="receiver_name" reporter:datatype="text"/>
+                       <field reporter:label="Receiving Org Unit Short (Policy) Name" name="receiver_shortname" reporter:datatype="text"/>
+                       <field reporter:label="Receiving Method Name" name="recv_method_name" reporter:datatype="text"/>
+                       <field reporter:label="Receiving Method Code" name="recv_method_code" reporter:datatype="text"/>
+                       <field reporter:label="Invoice Type" name="inv_type" reporter:datatype="text"/>
+                       <field reporter:label="Payment Authorization" name="payment_auth" reporter:datatype="text"/>
+                       <field reporter:label="Payment Method" name="payment_method" reporter:datatype="text"/>
+                       <field reporter:label="Invoice Note" name="inv_note" reporter:datatype="text"/>
+                       <field reporter:label="Invoice Is Complete?" name="inv_complete" reporter:datatype="boolean"/>
+                       <field reporter:label="Lineitem Link" name="li_id" reporter:datatype="link"/>
+                       <field reporter:label="Purchase Order Link" name="po_id" reporter:datatype="link"/>
+                       <field reporter:label="Lineitem Identifier" name="li_identifier" reporter:datatype="text"/>
+                       <field reporter:label="Lineitem Title" name="li_title" reporter:datatype="text"/>
+                       <field reporter:label="Lineitem Quantity Ordered" name="quantity_ordered" reporter:datatype="int"/>
+                       <field reporter:label="Estimated Unit Price" name="estimated_unit_price" reporter:datatype="money"/>
+                       <field reporter:label="Billed Per Item?" name="billed_per_item" reporter:datatype="boolean"/>
+                       <field reporter:label="Cost Billed" name="cost_billed" reporter:datatype="money"/>
+                       <field reporter:label="Actual Cost" name="actual_cost" reporter:datatype="money"/>
+                       <field reporter:label="Amount Paid" name="amount_paid" reporter:datatype="money"/>
+                       <field reporter:label="Purchasing Library Link" name="purchasing_lib_id" reporter:datatype="link"/>
+                       <field reporter:label="Purchasing Library Name" name="purchasing_lib_name" reporter:datatype="text"/>
+                       <field reporter:label="Purchasing Library Short (Policy) Name" name="purchasing_lib_shortname" reporter:datatype="text"/>
+                       <field reporter:label="Fund Link" name="fund_id" reporter:datatype="link"/>
+                       <field reporter:label="Fund Name (Year)" name="fund_name" reporter:datatype="text"/>
+                       <field reporter:label="Invoice Item Link" name="inv_item_id" reporter:datatype="link"/>
+                       <field reporter:label="Invoice Item Title" name="inv_item_title" reporter:datatype="text"/>
+                       <field reporter:label="Invoice Item Author" name="inv_item_author" reporter:datatype="text"/>
+                       <field reporter:label="Invoice Item Note" name="inv_item_note" reporter:datatype="text"/>
+                       <field reporter:label="Invoice Item Cost Billed" name="inv_item_cost_billed" reporter:datatype="money"/>
+                       <field reporter:label="Invoice Item Actual Cost" name="inv_item_actual_cost" reporter:datatype="money"/>
+                       <field reporter:label="Invoice Item Amount Paid" name="inv_item_amount_paid" reporter:datatype="money"/>
+                       <field reporter:label="Invoice Item Type Code" name="inv_item_type_code" reporter:datatype="text"/>
+                       <field reporter:label="Invoice Item Type Name" name="inv_item_type_name" reporter:datatype="text"/>
+                       <field reporter:label="Invoice Item Fund Link" name="inv_item_fund_id" reporter:datatype="link"/>
+                       <field reporter:label="Invoice Item Fund Name (Year)" name="inv_item_fund_name" reporter:datatype="text"/>
+                       <field reporter:label="Invoice Item Purchase Order Link" name="inv_item_po_id" reporter:datatype="link"/>
+                       <field reporter:label="Purchase Order Item Link" name="po_item_id" reporter:datatype="link"/>
+                       <field reporter:label="Invoice Item Target" name="inv_item_target" reporter:datatype="int"/>
+               </fields>
+               <links>
+                       <link field="inv_id" reltype="has_a" key="id" map="" class="acqinv"/>
+                       <link field="provider_id" reltype="has_a" key="id" map="" class="acqpro"/>
+                       <link field="shipper_id" reltype="has_a" key="id" map="" class="acqpro"/>
+                       <link field="receiver_id" reltype="has_a" key="id" map="" class="aou"/>
+                       <link field="li_id" reltype="might_have" key="id" map="" class="jub"/>
+                       <link field="po_id" reltype="has_a" key="id" map="" class="acqpo"/>
+                       <link field="purchasing_lib_id" reltype="has_a" key="id" map="" class="aou"/>
+                       <link field="fund_id" reltype="has_a" key="id" map="" class="acqf"/>
+                       <link field="inv_item_id" reltype="might_have" key="id" map="" class="acqii"/>
+                       <link field="inv_item_fund_id" reltype="might_have" key="id" map="" class="acqf"/>
+                       <link field="inv_item_po_id" reltype="has_a" key="id" map="" class="acqpo"/>
+                       <link field="po_item_id" reltype="has_a" key="id" map="" class="acqpoi"/>
+               </links>
+       </class>
        <!-- ********************************************************************************************************************* -->
        <!-- What follows is a set of example extensions that are useful for PINES.  Comment out or remove if you don't want them. -->
        <!-- ********************************************************************************************************************* -->
index 5095aee..8ac49ad 100644 (file)
@@ -5,7 +5,7 @@
  *
  * This program is free software; you can redistribute it and/or
  * modify it under the terms of the GNU General Public License
- * as published by the Free Software Foundation; either version 2
+ * AS published by the Free Software Foundation; either version 2
  * of the License, or (at your option) any later version.
  *
  * This program is distributed in the hope that it will be useful,
@@ -178,7 +178,7 @@ SELECT rmsr.title,
     cp.id,
     cp.price,
     cp.barcode,
-    cn.label as call_number_label,
+    cn.label AS call_number_label,
     CASE
         WHEN call_number_dewey(cn.label) ~  E'^[0-9.]+$'
             THEN
@@ -199,7 +199,7 @@ SELECT rmsr.title,
                 )
         ELSE NULL
     END AS dewey_block_hundreds,
-    erfcc.circ_count as use_count,
+    erfcc.circ_count AS use_count,
     cp.circ_modifier,
     sl.name AS shelving_location,
     sc1.stat_cat_entry AS stat_cat_1,
@@ -222,8 +222,8 @@ SELECT rmsr.title,
     cp.status,
     circ.stop_fines,
     circ.due_date,
-    circ_card.barcode as patron_barcode,
-    circ_u.first_given_name || ' ' || circ_u.family_name as patron_name
+    circ_card.barcode AS patron_barcode,
+    circ_u.first_given_name || ' ' || circ_u.family_name AS patron_name
   FROM  asset.copy cp
     JOIN extend_reporter.full_circ_count erfcc ON (cp.id = erfcc.id)
     JOIN asset.copy_location sl ON (cp.location = sl.id)
@@ -316,6 +316,130 @@ CREATE OR REPLACE VIEW money.open_balance_by_usr_home_and_owning_lib AS
          FROM  money.open_circ_balance_by_usr_home_and_owning_lib x
          GROUP BY 1,2;
 
-COMMIT;
+DROP VIEW IF EXISTS reporter.acq_purchase_order_view;
+
+CREATE VIEW reporter.acq_purchase_order_view AS
+ SELECT  po.id AS po_id,
+        po.name AS po_name,
+        po.order_date AS po_order_date,
+        provider.id AS provider_id,
+        provider.name AS provider_name,
+        provider.san AS provider_san,
+        provider_address.id AS provider_address_id,
+        ord_agency.id AS ordering_agency_id,
+        ord_agency.name AS ordering_agency_name,
+        ord_agency.shortname AS ordering_agency_shortname,
+        li.id AS lineitem_id,
+        li_identifier.attr_value AS lineitem_identifier,
+        li_title.attr_value AS lineitem_title,
+        (SELECT count(*)
+                FROM acq.lineitem_detail acqlid
+                WHERE acqlid.lineitem = li.id
+                AND cancel_reason IS NULL) AS quantity_ordered,
+        li.estimated_unit_price,
+               purchasing_lib.id AS purchasing_lib_id,
+        purchasing_lib.name AS purchasing_lib_name,
+        purchasing_lib.shortname AS purchasing_lib_shortname,
+        fund.id AS fund_id,
+        fund.name || ' (' || fund.year || ')' AS fund_name,
+        inv_item_type.code AS po_item_type_code,
+        inv_item_type.name AS po_item_type_name,
+        po_item.id AS po_item_id,
+        po_item.title AS po_item_title,
+        po_item.author AS po_item_author,
+        po_item.note AS po_item_note,
+        po_item.estimated_cost AS po_item_estimated_cost,
+        po_item_fund.id AS po_item_fund_id,
+        po_item_fund.name || ' (' || po_item_fund.year || ')' AS po_item_fund_name,
+        (SELECT sum(estimated_unit_price)
+                FROM acq.lineitem acqli
+                WHERE acqli.purchase_order = po.id) AS lineitem_total_price,
+        (SELECT sum(estimated_cost)
+                FROM acq.po_item acqpoi
+                WHERE acqpoi.purchase_order = po.id) AS po_item_total_price
+FROM    acq.purchase_order po
+        INNER JOIN acq.provider provider ON (po.provider = provider.id)
+        LEFT OUTER JOIN acq.provider_address provider_address ON (provider_address.provider = provider.id)
+        INNER JOIN actor.org_unit ord_agency ON (po.ordering_agency = ord_agency.id)
+        LEFT OUTER JOIN acq.lineitem li ON (li.purchase_order = po.id)
+        LEFT OUTER JOIN acq.lineitem_attr li_identifier ON (li_identifier.lineitem = li.id AND li_identifier.attr_name = 'identifier')
+        LEFT OUTER JOIN acq.lineitem_attr li_title ON (li_title.lineitem = li.id AND li_title.attr_name = 'title')
+        LEFT OUTER JOIN acq.lineitem_detail lid ON (lid.lineitem = li.id)
+        LEFT OUTER JOIN actor.org_unit purchasing_lib ON (lid.owning_lib = purchasing_lib.id)
+        LEFT OUTER JOIN acq.fund fund ON (lid.fund = fund.id)
+        LEFT OUTER JOIN acq.po_item po_item ON (po_item.purchase_order = po.id)
+        LEFT OUTER JOIN acq.invoice_item_type inv_item_type ON (po_item.inv_item_type = inv_item_type.code)
+        LEFT OUTER JOIN acq.fund po_item_fund ON (po_item.fund = po_item_fund.id);
 
+DROP VIEW IF EXISTS reporter.acq_invoice_view;
 
+CREATE VIEW reporter.acq_invoice_view AS
+ SELECT inv.id AS inv_id,
+        inv.inv_ident AS inv_ident,
+        provider.id AS provider_id,
+        provider.name AS provider_name,
+        shipper.id AS shipper_id,
+        shipper.name AS shipper_name,
+        inv.recv_date AS recv_date,
+        receiver.id AS receiver_id,
+        receiver.name AS receiver_name,
+        receiver.shortname AS receiver_shortname,
+        recv_method.name AS recv_method_name,
+               recv_method.code AS recv_method_code,
+        inv.inv_type AS inv_type,
+        inv.payment_auth AS payment_auth,
+        inv.payment_method AS payment_method,
+        inv.note AS inv_note,
+        inv.complete AS inv_complete,
+        li.id AS li_id,
+        po.id AS po_id,
+        li_identifier.attr_value AS li_identifier,
+        li_title.attr_value AS li_title,
+        (SELECT count(*)
+                FROM acq.lineitem_detail acqlid
+                WHERE acqlid.lineitem = li.id
+                AND cancel_reason IS NULL) AS quantity_ordered,
+        li.estimated_unit_price,
+        inv_entry.billed_per_item,
+        inv_entry.cost_billed,
+        inv_entry.actual_cost,
+        inv_entry.amount_paid,
+               purchasing_lib.id AS purchasing_lib_id,
+        purchasing_lib.name AS purchasing_lib_name,
+        purchasing_lib.shortname AS purchasing_lib_shortname,
+        fund.id AS fund_id,
+        fund.name || ' (' || fund.year || ')' AS fund_name,
+        inv_item.id AS inv_item_id,
+        inv_item.title AS inv_item_title,
+        inv_item.author AS inv_item_author,
+        inv_item.note AS inv_item_note,
+        inv_item.cost_billed AS inv_item_cost_billed,
+        inv_item.actual_cost AS inv_item_actual_cost,
+        inv_item.amount_paid AS inv_item_amount_paid,
+        inv_item_type.code AS inv_item_type_code,
+        inv_item_type.name AS inv_item_type_name,
+        inv_item_fund.id AS inv_item_fund_id,
+        inv_item_fund.name || ' (' || inv_item_fund.year || ')' AS inv_item_fund_name,
+        inv_item_po.id AS inv_item_po_id,
+        po_item.id AS po_item_id,
+        inv_item.target AS inv_item_target
+ FROM   acq.invoice inv
+        INNER JOIN acq.provider provider ON (inv.provider = provider.id)
+        INNER JOIN acq.provider shipper ON (inv.shipper = shipper.id)
+        INNER JOIN actor.org_unit receiver ON (inv.receiver = receiver.id)
+               INNER JOIN acq.invoice_method recv_method ON (inv.recv_method = recv_method.code)
+        LEFT OUTER JOIN acq.invoice_entry inv_entry ON (inv_entry.invoice = inv.id)
+        LEFT OUTER JOIN acq.lineitem li ON (inv_entry.lineitem = li.id)
+        LEFT OUTER JOIN acq.purchase_order po ON (li.purchase_order = po.id)
+        LEFT OUTER JOIN acq.lineitem_attr li_identifier ON (li_identifier.lineitem = li.id AND li_identifier.attr_name = 'identifier')
+        LEFT OUTER JOIN acq.lineitem_attr li_title ON (li_identifier.lineitem = li.id AND li_identifier.attr_name = 'title')
+        LEFT OUTER JOIN acq.lineitem_detail lid ON (lid.lineitem = li.id)
+        LEFT OUTER JOIN actor.org_unit purchasing_lib ON (lid.owning_lib = purchasing_lib.id)
+        LEFT OUTER JOIN acq.fund fund ON (lid.fund = fund.id)
+        LEFT OUTER JOIN acq.invoice_item inv_item ON (inv_item.invoice = inv.id)
+        LEFT OUTER JOIN acq.invoice_item_type inv_item_type ON (inv_item.inv_item_type = inv_item_type.code)
+        LEFT OUTER JOIN acq.fund inv_item_fund ON (inv_item.fund = inv_item_fund.id)
+        LEFT OUTER JOIN acq.po_item po_item ON (inv_item.po_item = po_item.id)
+        LEFT OUTER JOIN acq.purchase_order inv_item_po ON (inv_item.purchase_order = inv_item_po.id);
+
+COMMIT;