adding Tiffany's query user/csharp/acq_fund_debit_view_redo
authorChris Sharp <csharp@georgialibraries.org>
Fri, 12 Jun 2020 11:29:37 +0000 (07:29 -0400)
committerChris Sharp <csharp@georgialibraries.org>
Fri, 12 Jun 2020 11:29:37 +0000 (07:29 -0400)
Signed-off-by: Chris Sharp <csharp@georgialibraries.org>
Open-ILS/examples/fm_IDL.xml
Open-ILS/src/sql/Pg/example.reporter-extension.sql

index 560d372..99b2bb5 100644 (file)
@@ -12211,6 +12211,24 @@ SELECT  usr,
                </links>
        </class>
 
+       <class id="rafdv" controller="open-ils.reporter-store open-ils.cstore" oils_obj:fieldmapper="reporter::acq_fund_debit_view" oils_persist:tablename="reporter.acq_fund_debit_view" reporter:label="Acquisitions Fund Debit View">
+               <fields oils_persist:primary="fund_debit_id">
+                       <field reporter:label="Fund Debit ID" name="fund_debit_id" reporter:datatype="link"/>
+                       <field reporter:label="Fund Debit Creation Date/Time" name="debit_creation_time" reporter:datatype="timestamp"/>
+                       <field reporter:label="Fund Debit Amount" name="amount" reporter:datatype="money"/>
+                       <field reporter:label="Fund Debit Encumbrance" name="encumbrance" reporter:datatype="money"/>
+                       <field reporter:label="Fund Database ID" name="fund_id" reporter:datatype="link"/>
+                       <field reporter:label="Fund Code" name="fund_code" reporter:datatype="text"/>
+                       <field reporter:label="Fund Year" name="fund_year" reporter:datatype="int"/>
+                       <field reporter:label="Fund Organizational Unit ID" name="fund_org_id" reporter:datatype="link"/>
+                       <field reporter:label="Fund Organizational Unit Short (Policy) Name" name="fund_org_name" reporter:datatype="text"/>
+                       <field reporter:label="Purchase Order Database ID" name="po_id" reporter:datatype="link"/>
+               </fields>
+               <links>
+                       <link field="owner" reltype="has_a" key="id" map="" class="aou"/>
+               </links>
+       </class>
+
        <class id="rccbs" controller="open-ils.reporter-store" oils_obj:fieldmapper="reporter::classic_current_billing_summary" oils_persist:tablename="reporter.classic_current_billing_summary" reporter:core="true" reporter:label="Classic Open Transaction Summary">
                <fields oils_persist:primary="id">
                        <field reporter:label="Transaction ID" name="id" reporter:datatype="id" />
index 8cee578..fe6546f 100644 (file)
@@ -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;