<link field="xact" reltype="might_have" key="id" map="" class="mbt"/>
</links>
</class>
+ <class id="raisv" controller="open-ils.reporter-store" oils_obj:fieldmapper="reporter::acq_invoice_summary_view" oils_persist:tablename="reporter.acq_invoice_summary_view" reporter:label="Acquisitions Invoice Summary">
+ <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="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="Shipper ID" name="shipper_id" reporter:datatype="link"/>
+ <field reporter:label="Shipper Name" name="shipper_name" reporter:datatype="text"/>
+ <field reporter:label="Shipper Code" name="shipper_code" reporter:datatype="text"/>
+ <field reporter:label="Receiving Org Unit ID" name="receiver_id" reporter:datatype="org_unit"/>
+ <field reporter:label="Receiving Org Unit Short (Policy) Name" name="receiver_shortname" reporter:datatype="text"/>
+ <field reporter:label="Receiving Org Unit Name" name="receiver_name" reporter:datatype="text"/>
+ <field reporter:label="Invoice Payment Authorization" name="payment_auth" reporter:datatype="text"/>
+ <field reporter:label="Invoice Payment Method" name="payment_method" 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"/>
+ </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"/>
+ </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" />
SUM(billed) - SUM( COALESCE((SELECT SUM(amount) AS paid FROM money.payment WHERE NOT voided AND xact = x.id), 0::NUMERIC) ) AS balance
FROM money.open_circ_balance_by_usr_home_and_owning_lib x
GROUP BY 1,2;
+CREATE OR REPLACE VIEW reporter.acq_invoice_total_cost_billed AS
+WITH acq_cost_billed (invoice, total_cost_billed) AS
+ (SELECT acqie.invoice,
+ COALESCE(SUM(acqie.cost_billed), '0.00') AS total_cost_billed
+ FROM acq.invoice_entry acqie
+ GROUP BY acqie.invoice
+ UNION ALL
+ SELECT acqii.invoice,
+ COALESCE(SUM(acqii.cost_billed), '0.00') AS total_cost_billed
+ FROM acq.invoice_item acqii
+ GROUP BY acqii.invoice)
+ SELECT invoice, COALESCE(SUM(total_cost_billed), '0.00') AS total_cost_billed
+ FROM acq_cost_billed
+ GROUP BY invoice;
+
+CREATE OR REPLACE VIEW reporter.acq_invoice_total_actual_cost AS
+WITH acq_actual_cost (invoice, total_actual_cost) AS
+ (SELECT acqie.invoice,
+ COALESCE(SUM(acqie.actual_cost), '0.00') AS total_actual_cost
+ FROM acq.invoice_entry acqie
+ GROUP BY acqie.invoice
+ UNION ALL
+ SELECT acqii.invoice,
+ COALESCE(SUM(acqii.actual_cost), '0.00') AS total_actual_cost
+ FROM acq.invoice_item acqii
+ GROUP BY acqii.invoice)
+ SELECT invoice, COALESCE(SUM(total_actual_cost), '0.00') AS total_actual_cost
+ FROM acq_actual_cost
+ GROUP BY invoice;
+
+CREATE OR REPLACE VIEW reporter.acq_invoice_total_amount_paid AS
+WITH acq_amount_paid (invoice, total_amount_paid) AS
+ (SELECT acqie.invoice,
+ COALESCE(SUM(acqie.amount_paid), '0.00') AS total_amount_paid
+ FROM acq.invoice_entry acqie
+ GROUP BY acqie.invoice
+ UNION ALL
+ SELECT acqii.invoice,
+ COALESCE(SUM(acqii.amount_paid), '0.00') AS total_amount_paid
+ FROM acq.invoice_item acqii
+ GROUP BY acqii.invoice)
+ SELECT invoice, COALESCE(SUM(total_amount_paid), '0.00') AS total_amount_paid
+ FROM acq_amount_paid
+ GROUP BY invoice;
+
+CREATE OR REPLACE VIEW reporter.acq_invoice_summary_view AS
+ SELECT invoice.id AS inv_id,
+ invoice.inv_ident AS inv_vendor_ident,
+ invoice.recv_date,
+ provider.id AS provider_id,
+ provider.name AS provider_name,
+ provider.code AS provider_code,
+ shipper.id AS shipper_id,
+ shipper.name AS shipper_name,
+ shipper.code AS shipper_code,
+ receiver.id AS receiver_id,
+ receiver.shortname AS receiver_shortname,
+ receiver.name AS receiver_name,
+ invoice.payment_auth,
+ 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
+ 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);
+
CREATE OR REPLACE VIEW reporter.copy_statistics_view AS
SELECT acp.id as copy_id,
--- /dev/null
+BEGIN;
+
+CREATE OR REPLACE VIEW reporter.acq_invoice_total_cost_billed AS
+WITH acq_cost_billed (invoice, total_cost_billed) AS
+ (SELECT acqie.invoice,
+ COALESCE(SUM(acqie.cost_billed), '0.00') AS total_cost_billed
+ FROM acq.invoice_entry acqie
+ GROUP BY acqie.invoice
+ UNION ALL
+ SELECT acqii.invoice,
+ COALESCE(SUM(acqii.cost_billed), '0.00') AS total_cost_billed
+ FROM acq.invoice_item acqii
+ GROUP BY acqii.invoice)
+ SELECT invoice, COALESCE(SUM(total_cost_billed), '0.00') AS total_cost_billed
+ FROM acq_cost_billed
+ GROUP BY invoice;
+
+CREATE OR REPLACE VIEW reporter.acq_invoice_total_actual_cost AS
+WITH acq_actual_cost (invoice, total_actual_cost) AS
+ (SELECT acqie.invoice,
+ COALESCE(SUM(acqie.actual_cost), '0.00') AS total_actual_cost
+ FROM acq.invoice_entry acqie
+ GROUP BY acqie.invoice
+ UNION ALL
+ SELECT acqii.invoice,
+ COALESCE(SUM(acqii.actual_cost), '0.00') AS total_actual_cost
+ FROM acq.invoice_item acqii
+ GROUP BY acqii.invoice)
+ SELECT invoice, COALESCE(SUM(total_actual_cost), '0.00') AS total_actual_cost
+ FROM acq_actual_cost
+ GROUP BY invoice;
+
+CREATE OR REPLACE VIEW reporter.acq_invoice_total_amount_paid AS
+WITH acq_amount_paid (invoice, total_amount_paid) AS
+ (SELECT acqie.invoice,
+ COALESCE(SUM(acqie.amount_paid), '0.00') AS total_amount_paid
+ FROM acq.invoice_entry acqie
+ GROUP BY acqie.invoice
+ UNION ALL
+ SELECT acqii.invoice,
+ COALESCE(SUM(acqii.amount_paid), '0.00') AS total_amount_paid
+ FROM acq.invoice_item acqii
+ GROUP BY acqii.invoice)
+ SELECT invoice, COALESCE(SUM(total_amount_paid), '0.00') AS total_amount_paid
+ FROM acq_amount_paid
+ GROUP BY invoice;
+
+CREATE OR REPLACE VIEW reporter.acq_invoice_summary_view AS
+ SELECT invoice.id AS inv_id,
+ invoice.inv_ident AS inv_vendor_ident,
+ invoice.recv_date,
+ provider.id AS provider_id,
+ provider.name AS provider_name,
+ provider.code AS provider_code,
+ shipper.id AS shipper_id,
+ shipper.name AS shipper_name,
+ shipper.code AS shipper_code,
+ receiver.id AS receiver_id,
+ receiver.shortname AS receiver_shortname,
+ receiver.name AS receiver_name,
+ invoice.payment_auth,
+ 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
+ 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);
+
+COMMIT;