<fields oils_persist:primary="inv_id">
<field reporter:label="Internal Invoice ID" name="inv_id" reporter:datatype="link"/>
<field reporter:label="Vendor Invoice ID" name="inv_vendor_ident" reporter:datatype="text"/>
- <field reporter:label="Receive Date/Time" name="recv_date" reporter:datatype="timestamp"/>
+ <field reporter:label="Invoice Date/Time" name="recv_date" reporter:datatype="timestamp"/>
<field reporter:label="Provider ID" name="provider_id" reporter:datatype="link"/>
<field reporter:label="Provider Name" name="provider_name" reporter:datatype="text"/>
<field reporter:label="Provider Code" name="provider_code" reporter:datatype="text"/>
<field reporter:label="Total Cost Billed" name="total_cost_billed" reporter:datatype="money"/>
<field reporter:label="Total Actual Cost" name="total_actual_cost" reporter:datatype="money"/>
<field reporter:label="Total Amount Paid" name="total_amount_paid" reporter:datatype="money"/>
+ <field reporter:label="Close Date" name="close_date" reporter:datatype="timestamp"/>
+ <field reporter:label="Closing Staff Member (Link)" name="closed_by" reporter:datatype="link"/>
+ <field reporter:label="Closing Staff Member Username" name="closed_by_usrname" reporter:datatype="text"/>
</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="might_have" key="id" map="" class="acqpro"/>
+ <link field="closed_by" reltype="might_have" key="id" map="" class="au"/>
+ </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)">
/*
- * 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>
*
invoice.payment_method,
raitcb.total_cost_billed AS total_cost_billed,
raitac.total_actual_cost AS total_actual_cost,
- raitap.total_amount_paid AS total_amount_paid
+ raitap.total_amount_paid AS total_amount_paid,
+ invoice.close_date,
+ invoice.closed_by,
+ closer.usrname AS closed_by_usrname
FROM acq.invoice invoice
JOIN reporter.acq_invoice_total_cost_billed raitcb ON (raitcb.invoice = invoice.id)
JOIN reporter.acq_invoice_total_actual_cost raitac ON (raitac.invoice = invoice.id)
JOIN reporter.acq_invoice_total_amount_paid raitap ON (raitap.invoice = invoice.id)
JOIN acq.provider provider ON (invoice.provider = provider.id)
LEFT OUTER JOIN acq.provider shipper ON (invoice.shipper = shipper.id)
- LEFT OUTER JOIN actor.org_unit receiver ON (invoice.receiver = receiver.id);
+ LEFT OUTER JOIN actor.org_unit receiver ON (invoice.receiver = receiver.id)
+ LEFT OUTER JOIN actor.usr closer ON (invoice.closed_by = closer.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;
CREATE OR REPLACE VIEW reporter.copy_statistics_view AS
SELECT acp.id as copy_id,
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;