<link field="id" reltype="has_a" key="id" map="" class="acp"/>
</links>
</class>
+ <class id="erccpo" controller="open-ils.reporter-store" oils_obj:fieldmapper="extend_reporter::copy_count_per_org" oils_persist:tablename="extend_reporter.copy_count_per_org" reporter:label="Library Holdings Count with Deleted">
+ <fields oils_persist:primary="bibid">
+ <field reporter:label="Bib Record" name="bibid" reporter:datatype="id" />
+ <field reporter:label="Circulation Library" name="circ_lib" reporter:datatype="id" />
+ <field reporter:label="Last Edit Date" name="last_edit_time" reporter:datatype="timestamp" />
+ <field reporter:label="Has Only Deleted Copies 0/1" name="has_only_deleted_copies" reporter:datatype="int" />
+ <field reporter:label="Total deleted copies" name="deleted_count" reporter:datatype="int" />
+ <field reporter:label="Total visible copies" name="visible_count" reporter:datatype="int" />
+ <field reporter:label="Total copies attached" name="total_count" reporter:datatype="int" />
+ </fields>
+ <links>
+ <link field="bibid" reltype="has_a" key="id" map="" class="bre"/>
+ <link field="circ_lib" reltype="has_a" key="id" map="" class="aou"/>
+ </links>
+ <permacrud xmlns="http://open-ils.org/spec/opensrf/IDL/permacrud/v1">
+ <actions>
+ <retrieve />
+ </actions>
+ </permacrud>
+ </class>
<class id="acqdf" controller="open-ils.cstore open-ils.pcrud" oils_obj:fieldmapper="acq::distribution_formula" oils_persist:tablename="acq.distribution_formula" reporter:label="Distribution Formula">
<fields oils_persist:primary="id" oils_persist:sequence="acq.distribution_formula_id_seq">
<field reporter:label="Formula ID" name="id" reporter:datatype="id" reporter:selector="name" />
AND b.id > 0
GROUP BY b.id)x
ORDER BY id, holding_update;
-
-COMMIT;
+CREATE OR REPLACE VIEW extend_reporter.copy_count_per_org AS
+ SELECT acn.record AS bibid,
+ ac.circ_lib,
+ max(ac.edit_date) AS last_edit_time,
+ min(ac.deleted::integer) AS has_only_deleted_copies,
+ count(
+ CASE
+ WHEN ac.deleted THEN ac.id
+ ELSE NULL::bigint
+ END) AS deleted_count,
+ count(
+ CASE
+ WHEN NOT ac.deleted THEN ac.id
+ ELSE NULL::bigint
+ END) AS visible_count,
+ count(*) AS total_count
+ FROM asset.call_number acn,
+ asset.copy ac
+ WHERE ac.call_number = acn.id
+ GROUP BY acn.record, ac.circ_lib;
+
+COMMIT;
--- /dev/null
+\set ECHO
+\set QUIET 1
+-- Turn off echo and keep things quiet.
+
+-- Format the output for nice TAP.
+\pset format unaligned
+\pset tuples_only true
+\pset pager
+
+-- Revert all changes on failure.
+\set ON_ERROR_ROLLBACK 1
+\set ON_ERROR_STOP true
+\set QUIET 1
+
+-- Load the TAP functions.
+BEGIN;
+
+-- Plan the tests.
+SELECT plan(1);
+
+-- Run the tests.
+-- Check for Lost and Paid copy status.
+SELECT has_view( 'extend_reporter', 'copy_count_per_org', 'VIEW extend_reporter.copy_count_per_org EXISTS' );
+
+-- Finish the tests and clean up.
+SELECT * FROM finish();
+ROLLBACK;
--- /dev/null
+BEGIN;
+
+SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version);
+
+DROP VIEW IF EXISTS extend_reporter.copy_count_per_org;
+
+
+CREATE OR REPLACE VIEW extend_reporter.copy_count_per_org AS
+ SELECT acn.record AS bibid,
+ ac.circ_lib,
+ max(ac.edit_date) AS last_edit_time,
+ min(ac.deleted::integer) AS has_only_deleted_copies,
+ count(
+ CASE
+ WHEN ac.deleted THEN ac.id
+ ELSE NULL::bigint
+ END) AS deleted_count,
+ count(
+ CASE
+ WHEN NOT ac.deleted THEN ac.id
+ ELSE NULL::bigint
+ END) AS visible_count,
+ count(*) AS total_count
+ FROM asset.call_number acn,
+ asset.copy ac
+ WHERE ac.call_number = acn.id
+ GROUP BY acn.record, ac.circ_lib;
+
+
+COMMIT;
--- /dev/null
+New report source table allowing report of "last" deleted copy
+^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^
+
+This source table allows you to construct a clever aggregate report template
+which will report bibliographic ID's where a library or a group of libraries
+no longer have a copy attached but had* a copy attached. This is especially
+useful when a holdings sync is required with an external vendor.
+
+
+Instructions for creating the report template:
+ * Create a new report template using the "Library Holdings Count with Deleted" as the source
+ * Add "Has Only Deleted Copies 0/1" (Min) to the Aggregate Filters -> Change Value to "1"
+ * Add "Last Edit Date" (Max) to Aggregate Filters -> Change Operator to "Between"
+ * Add Circulation Library -> "Organizational Unit ID" Raw Data to Base Filters -> Change Operator to "In list"
+ * Add "Bib ID" to Displayed Fields
+ * Add "Last Edit Date" to Displayed Fields and Change Transform to Max
+ * Add "Has Only Deleted Copies 0/1" to Displayed Fields and Change Transform to Min
+ * Add "Total copies attached" to Displayed Fields and Change Transform to Sum
+
+
+This template will only output bibliographic ID's where all of the copies for the specified branch(es)
+are deleted. Furthermore, it will only output bibs whose copies were edited (deleted) during the
+specified date range. Unfortunatly the user will have to manually type the date range without the date
+picker. This view will also allow you to answer questions like "Show me bibs where I have one visible
+copy and more than two deleted copies."