From: Chris Sharp Date: Fri, 12 Jun 2020 11:29:37 +0000 (-0400) Subject: adding Tiffany's query X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=refs%2Fheads%2Fuser%2Fcsharp%2Facq_fund_debit_view_redo;p=working%2FEvergreen.git adding Tiffany's query Signed-off-by: Chris Sharp --- diff --git a/Open-ILS/examples/fm_IDL.xml b/Open-ILS/examples/fm_IDL.xml index 560d372eab..99b2bb5da8 100644 --- a/Open-ILS/examples/fm_IDL.xml +++ b/Open-ILS/examples/fm_IDL.xml @@ -12211,6 +12211,24 @@ SELECT usr, + + + + + + + + + + + + + + + + + + diff --git a/Open-ILS/src/sql/Pg/example.reporter-extension.sql b/Open-ILS/src/sql/Pg/example.reporter-extension.sql index 8cee578cb5..fe6546f631 100644 --- a/Open-ILS/src/sql/Pg/example.reporter-extension.sql +++ b/Open-ILS/src/sql/Pg/example.reporter-extension.sql @@ -173,71 +173,71 @@ SELECT x.id AS id, CREATE OR REPLACE VIEW reporter.classic_item_list AS SELECT rmsr.title, - rmsr.author, - rmsr.pubdate, - cp.id, - cp.price, - cp.barcode, - cn.label as call_number_label, - CASE - WHEN call_number_dewey(cn.label) ~ E'^[0-9.]+$' - THEN - btrim( - to_char( - 10 * floor((call_number_dewey(cn.label)::float) / 10), '000' - ) - ) - ELSE NULL - END AS dewey_block_tens, - CASE - WHEN call_number_dewey(cn.label) ~ E'^[0-9.]+$' - THEN - btrim( - to_char( - 100 * floor((call_number_dewey(cn.label)::float) / 100), '000' - ) - ) - ELSE NULL - END AS dewey_block_hundreds, - erfcc.circ_count as use_count, - cp.circ_modifier, - sl.name AS shelving_location, - sc1.stat_cat_entry AS stat_cat_1, - sc2.stat_cat_entry AS stat_cat_2, - sce1.value AS stat_cat_1_value, - sce2.value AS stat_cat_2_value, - cp.edit_date, - cp.create_date, - ol.shortname AS owning_lib_name, - cn.owning_lib, - cl.shortname AS circ_lib_name, - cl.id AS circ_lib, - cp.creator, - cp.age_protect, - cp.opac_visible, - cp.ref, - cp.deposit_amount, - cp.deleted, - rmsr.tcn_value, - 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 + rmsr.author, + rmsr.pubdate, + cp.id, + cp.price, + cp.barcode, + cn.label as call_number_label, + CASE + WHEN call_number_dewey(cn.label) ~ E'^[0-9.]+$' + THEN + btrim( + to_char( + 10 * floor((call_number_dewey(cn.label)::float) / 10), '000' + ) + ) + ELSE NULL + END AS dewey_block_tens, + CASE + WHEN call_number_dewey(cn.label) ~ E'^[0-9.]+$' + THEN + btrim( + to_char( + 100 * floor((call_number_dewey(cn.label)::float) / 100), '000' + ) + ) + ELSE NULL + END AS dewey_block_hundreds, + erfcc.circ_count as use_count, + cp.circ_modifier, + sl.name AS shelving_location, + sc1.stat_cat_entry AS stat_cat_1, + sc2.stat_cat_entry AS stat_cat_2, + sce1.value AS stat_cat_1_value, + sce2.value AS stat_cat_2_value, + cp.edit_date, + cp.create_date, + ol.shortname AS owning_lib_name, + cn.owning_lib, + cl.shortname AS circ_lib_name, + cl.id AS circ_lib, + cp.creator, + cp.age_protect, + cp.opac_visible, + cp.ref, + cp.deposit_amount, + cp.deleted, + rmsr.tcn_value, + 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 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) - JOIN asset.call_number cn ON (cp.call_number = cn.id) - JOIN actor.org_unit ol ON (cn.owning_lib = ol.id) - JOIN actor.org_unit cl ON (cp.circ_lib = cl.id) - JOIN reporter.materialized_simple_record rmsr ON (cn.record = rmsr.id) - LEFT JOIN action.circulation circ ON (circ.target_copy = cp .id AND circ.checkin_time IS NULL) - LEFT JOIN actor.usr circ_u ON (circ_u.id = circ.usr) - LEFT JOIN actor.card circ_card ON (circ_u.card = circ_card.id) - LEFT JOIN asset.stat_cat_entry_copy_map sc1 ON (sc1.owning_copy = cp.id AND sc1.stat_cat = 1) - LEFT JOIN asset.stat_cat_entry sce1 ON (sce1.id = sc1.stat_cat_entry) - LEFT JOIN asset.stat_cat_entry_copy_map sc2 ON (sc2.owning_copy = cp.id AND sc2.stat_cat = 2) - LEFT JOIN asset.stat_cat_entry sce2 ON (sce2.id = sc2.stat_cat_entry); + JOIN extend_reporter.full_circ_count erfcc ON (cp.id = erfcc.id) + JOIN asset.copy_location sl ON (cp.location = sl.id) + JOIN asset.call_number cn ON (cp.call_number = cn.id) + JOIN actor.org_unit ol ON (cn.owning_lib = ol.id) + JOIN actor.org_unit cl ON (cp.circ_lib = cl.id) + JOIN reporter.materialized_simple_record rmsr ON (cn.record = rmsr.id) + LEFT JOIN action.circulation circ ON (circ.target_copy = cp .id AND circ.checkin_time IS NULL) + LEFT JOIN actor.usr circ_u ON (circ_u.id = circ.usr) + LEFT JOIN actor.card circ_card ON (circ_u.card = circ_card.id) + LEFT JOIN asset.stat_cat_entry_copy_map sc1 ON (sc1.owning_copy = cp.id AND sc1.stat_cat = 1) + LEFT JOIN asset.stat_cat_entry sce1 ON (sce1.id = sc1.stat_cat_entry) + LEFT JOIN asset.stat_cat_entry_copy_map sc2 ON (sc2.owning_copy = cp.id AND sc2.stat_cat = 2) + LEFT JOIN asset.stat_cat_entry sce2 ON (sce2.id = sc2.stat_cat_entry); CREATE OR REPLACE VIEW money.open_circ_balance_by_owning_lib AS @@ -288,10 +288,6 @@ CREATE OR REPLACE VIEW money.open_balance_by_circ_and_owning_lib AS FROM money.open_circ_balance_by_circ_and_owning_lib x GROUP BY 1,2; - - - - CREATE OR REPLACE VIEW money.open_circ_balance_by_usr_home_and_owning_lib AS SELECT circ.id, usr.home_ou, @@ -316,6 +312,41 @@ 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; - +CREATE OR REPLACE VIEW reporter.acq_fund_debit_view AS + SELECT debit.id AS fund_debit_id, + to_char(debit.create_time,'mm-dd-yyyy') AS debit_creation_time, + debit.amount, + debit.encumbrance, + debit.debit_type, + fund.id AS fund_id, + fund.code AS fund_code, + fund.year AS fund_year, + fund_org.id AS fund_org_id, + fund_org.shortname AS fund_org_name, + li.purchase_order AS po_id, + purchases_provider.code AS provider_on_po, + lid.lineitem AS lineitem_id, + lid.id AS lineitem_detail_id, + to_char(invoice.recv_date,'mm-dd-yyyy') AS invoice_date_for_purchases, + invoice.id AS internal_invoice_id_for_purchases, + invoice.inv_ident AS vendor_invoice_id_for_purchases, + podirectcharge.purchase_order AS po_id_for_direct_charge, + podirectcharge.id AS direct_charge_id_on_purchase_order, + to_char(inv2.recv_date,'mm-dd-yyyy') AS invoice_date_for_direct_charge, + invoicedirectcharge.id AS direct_charge_id_on_invoice, + inv2.inv_ident AS vendor_invoice_id_for_direct_charge, + provider.code AS provider_on_invoice_for_direct_charge + FROM acq.fund_debit AS debit + INNER JOIN acq.fund AS fund ON (debit.fund = fund.id) + INNER JOIN actor.org_unit fund_org ON (fund_org.id = fund.org) + LEFT JOIN acq.invoice_entry AS invlineitem ON (debit.invoice_entry = invlineitem.id) + LEFT JOIN acq.invoice AS invoice ON (invlineitem.invoice = invoice.id) + LEFT JOIN acq.lineitem_detail AS lid ON (debit.id = lid.fund_debit) + LEFT JOIN acq.po_item AS podirectcharge ON (debit.id = podirectcharge.fund_debit) + LEFT JOIN acq.invoice_item AS invoicedirectcharge ON (debit.id = invoicedirectcharge.fund_debit) + LEFT JOIN acq.lineitem AS li ON (lid.lineitem = li.id) + LEFT JOIN acq.invoice AS inv2 ON (invoicedirectcharge.invoice = inv2.id) + LEFT JOIN acq.provider AS provider ON (provider.id = inv2.provider) + LEFT JOIN acq.provider AS purchases_provider ON (purchases_provider.id = li.provider); +COMMIT;