<field reporter:label="Peer Records" name="peer_records" oils_persist:virtual="true" reporter:datatype="link"/>
<field reporter:label="Last Captured Hold" name="last_captured_hold" oils_persist:virtual="true" reporter:datatype="link"/>
<field reporter:label="Latest Inventory" name="latest_inventory" oils_persist:virtual="true" reporter:datatype="link"/>
+ <field reporter:label="Copy Inventory" name="copy_inventory" oils_persist:virtual="true" reporter:datatype="link"/>
<field reporter:label="Has Holds" name="holds_count" oils_persist:virtual="true" reporter:datatype="link"/>
<field reporter:label="Copy Tags" name="tags" oils_persist:virtual="true" reporter:datatype="link"/>
<field reporter:label="Copy Alerts" name="copy_alerts" oils_persist:virtual="true" reporter:datatype="link"/>
<link field="peer_records" reltype="has_many" key="target_copy" map="peer_record" class="bpbcm"/>
<link field="last_captured_hold" reltype="has_a" key="current_copy" map="" class="alhr"/>
<link field="latest_inventory" reltype="might_have" key="copy" map="" class="alci"/>
+ <link field="copy_inventory" reltype="might_have" key="copy" map="" class="aci"/>
<link field="floating" reltype="has_a" key="id" map="" class="cfg"/>
<link field="holds_count" reltype="might_have" key="id" map="" class="hasholdscount"/>
<link field="tags" reltype="has_many" key="copy" map="" class="acptcm"/>
</permacrud>
</class>
- <class id="alci" controller="open-ils.cstore open-ils.pcrud" oils_obj:fieldmapper="asset::latest_inventory" oils_persist:tablename="asset.latest_inventory" reporter:core="true" reporter:label="Latest Inventory">
- <fields oils_persist:primary="id" oils_persist:sequence="asset.latest_inventory_id_seq">
+ <class id="aci" controller="open-ils.cstore open-ils.pcrud" oils_obj:fieldmapper="asset::copy_inventory" oils_persist:tablename="asset.copy_inventory" reporter:core="true" reporter:label="Copy Inventory">
+ <fields oils_persist:primary="id" oils_persist:sequence="asset.copy_inventory_id_seq">
+ <field reporter:label="Copy Inventory ID" name="id" reporter:datatype="id"/>
+ <field reporter:label="Copy Inventory Date" name="inventory_date" reporter:datatype="timestamp"/>
+ <field reporter:label="Copy Inventory Workstation" name="inventory_workstation" reporter:datatype="link"/>
+ <field reporter:label="Copy" name="copy" reporter:datatype="link"/>
+ </fields>
+ <links>
+ <link field="inventory_workstation" reltype="has_a" key="id" map="" class="aws"/>
+ <link field="copy" reltype="has_a" key="id" map="" class="acp"/>
+ </links>
+ <permacrud xmlns="http://open-ils.org/spec/opensrf/IDL/permacrud/v1">
+ <actions>
+ <create permission="STAFF_LOGIN"/>
+ <retrieve/>
+ <update permission="STAFF_LOGIN"/>
+ <delete permission="STAFF_LOGIN"/>
+ </actions>
+ </permacrud>
+ </class>
+
+ <class id="alci" controller="open-ils.cstore open-ils.pcrud" oils_obj:fieldmapper="asset::latest_inventory" oils_persist:tablename="asset.latest_inventory" reporter:core="true" reporter:label="Latest Inventory" oils_persist:readonly="true">
+ <fields oils_persist:primary="id" oils_persist:sequence="asset.copy_inventory_id_seq">
<field reporter:label="Latest Inventory ID" name="id" reporter:datatype="id"/>
<field reporter:label="Latest Inventory Date" name="inventory_date" reporter:datatype="timestamp"/>
<field reporter:label="Latest Inventory Workstation" name="inventory_workstation" reporter:datatype="link"/>
</links>
<permacrud xmlns="http://open-ils.org/spec/opensrf/IDL/permacrud/v1">
<actions>
- <create permission="STAFF_LOGIN"/>
<retrieve/>
- <update permission="STAFF_LOGIN"/>
- <delete permission="STAFF_LOGIN"/>
</actions>
</permacrud>
</class>
);
CREATE UNIQUE INDEX copy_part_map_cp_part_idx ON asset.copy_part_map (target_copy, part);
-CREATE TABLE asset.latest_inventory (
+CREATE TABLE asset.copy_inventory (
id SERIAL PRIMARY KEY,
inventory_workstation INTEGER REFERENCES actor.workstation (id) DEFERRABLE INITIALLY DEFERRED,
- inventory_date TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
- copy BIGINT NOT NULL
+ inventory_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
+ copy BIGINT NOT NULL
);
-CREATE INDEX latest_inventory_copy_idx ON asset.latest_inventory (copy);
+CREATE INDEX copy_inventory_copy_idx ON asset.copy_inventory (copy);
+CREATE UNIQUE INDEX asset_copy_inventory_date_once_per_copy ON asset.copy_inventory (inventory_date, copy);
+
+CREATE OR REPLACE FUNCTION asset.copy_may_float_to_inventory_workstation() RETURNS TRIGGER AS $func$
+DECLARE
+ copy asset.copy%ROWTYPE;
+ workstation actor.workstation%ROWTYPE;
+BEGIN
+ SELECT * INTO copy FROM asset.copy WHERE id = NEW.copy;
+ IF FOUND THEN
+ SELECT * INTO workstation FROM actor.workstation WHERE id = NEW.inventory_workstation;
+ IF FOUND THEN
+ IF copy.floating IS NULL THEN
+ IF copy.circ_lib <> workstation.owning_lib THEN
+ RAISE EXCEPTION 'Inventory workstation owning lib (%) does not match copy circ lib (%).',
+ workstation.owning_lib, copy.circ_lib;
+ END IF;
+ ELSE
+ IF NOT evergreen.can_float(copy.floating, copy.circ_lib, workstation.owning_lib) THEN
+ RAISE EXCEPTION 'Copy (%) cannot float to inventory workstation owning lib (%).',
+ copy.id, workstation.owning_lib;
+ END IF;
+ END IF;
+ END IF;
+ END IF;
+ RETURN NEW;
+END;
+$func$ LANGUAGE PLPGSQL VOLATILE COST 50;
+
+CREATE CONSTRAINT TRIGGER asset_copy_inventory_allowed_trig
+ AFTER UPDATE OR INSERT ON asset.copy_inventory
+ DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE asset.copy_may_float_to_inventory_workstation();
+
+CREATE VIEW asset.latest_inventory (id, inventory_workstation, inventory_date, copy) AS
+SELECT DISTINCT ON (copy) id, inventory_workstation, inventory_date, copy
+FROM asset.copy_inventory
+ORDER BY copy, inventory_date DESC;
CREATE OR REPLACE FUNCTION asset.acp_status_changed()
RETURNS TRIGGER AS $$
END;
$f$ LANGUAGE PLPGSQL VOLATILE COST 50;
-CREATE OR REPLACE FUNCTION evergreen.asset_latest_inventory_copy_inh_fkey() RETURNS TRIGGER AS $f$
+CREATE OR REPLACE FUNCTION evergreen.asset_copy_inventory_copy_inh_fkey() RETURNS TRIGGER AS $f$
BEGIN
PERFORM 1 FROM asset.copy WHERE id = NEW.copy;
IF NOT FOUND THEN
AFTER UPDATE OR INSERT ON asset.copy_tag_copy_map
DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE evergreen.asset_copy_tag_copy_map_copy_inh_fkey();
-CREATE CONSTRAINT TRIGGER inherit_asset_latest_inventory_copy_fkey
- AFTER UPDATE OR INSERT ON asset.latest_inventory
- DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE evergreen.asset_latest_inventory_copy_inh_fkey();
+CREATE CONSTRAINT TRIGGER inherit_asset_copy_inventory_copy_fkey
+ AFTER UPDATE OR INSERT ON asset.copy_inventory
+ DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE evergreen.asset_copy_inventory_copy_inh_fkey();
ALTER TABLE asset.copy_note ADD CONSTRAINT asset_copy_note_creator_fkey FOREIGN KEY (creator) REFERENCES actor.usr (id) ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED;
--- /dev/null
+BEGIN;
+
+SELECT plan(9);
+
+-- Workstations to use for tests:
+\set BR1_ws_name 'BR1-lp1883171-pgtap-live_t'
+\set BR4_ws_name 'BR4-lp1883171-pgtap-live_t'
+
+-- Fixed timestamp to check for duplicates:
+\set fixed_ts '2021-10-24 11:52:33.604067-04'
+
+-- Copy from BR1:
+\set BR1_copy_id 1
+-- Copy from BR4
+\set BR4_copy_id 801
+-- Copy from BR3 to test floating.
+\set BR3_copy_id 701
+
+-- A name for a floating group to test floating.
+\set SYS2_floating_group_name 'SYS2 Float Group'
+
+-- Create workstations:
+INSERT INTO actor.workstation
+(name, owning_lib)
+VALUES
+(:'BR1_ws_name', 4),
+(:'BR4_ws_name', 7);
+
+-- Create the floating group and define its members
+INSERT INTO config.floating_group
+(name)
+VALUES (:'SYS2_floating_group_name');
+
+INSERT INTO config.floating_group_member
+(floating_group, org_unit, stop_depth)
+SELECT id, 3, 1
+FROM config.floating_group
+WHERE name = :'SYS2_floating_group_name';
+
+-- Let the copy at BR3 float to SYS2
+UPDATE asset.copy
+SET floating = floating_group.id
+FROM config.floating_group
+WHERE copy.id = :BR3_copy_id
+AND floating_group.name = :'SYS2_floating_group_name';
+
+PREPARE insert_null_all AS INSERT INTO asset.copy_inventory (inventory_workstation, inventory_date, copy)
+VALUES (NULL, :'fixed_ts', :BR1_copy_id),
+(NULL, :'fixed_ts', :BR3_copy_id),
+(NULL, :'fixed_ts', :BR4_copy_id);
+SELECT lives_ok('insert_null_all', 'NULL workstation should succeed');
+
+PREPARE insert_br1_br1 AS INSERT INTO asset.copy_inventory(inventory_workstation, copy)
+SELECT id, :BR1_copy_id
+FROM actor.workstation
+WHERE name = :'BR1_ws_name';
+SELECT lives_ok('insert_br1_br1', 'BR1 at BR1 should succeed');
+
+PREPARE insert_br1_br4 AS INSERT INTO asset.copy_inventory (inventory_workstation, copy)
+SELECT id, :BR1_copy_id
+FROM actor.workstation
+WHERE name = :'BR4_ws_name';
+SELECT throws_ok('insert_br1_br4');
+
+PREPARE insert_br4_br1 AS INSERT INTO asset.copy_inventory (inventory_workstation, copy)
+SELECT id, :BR4_copy_id
+FROM actor.workstation
+WHERE name = :'BR1_ws_name';
+SELECT throws_ok('insert_br4_br1');
+
+PREPARE insert_br3_br1 AS INSERT INTO asset.copy_inventory (inventory_workstation, copy)
+SELECT id, :BR3_copy_id
+FROM actor.workstation
+WHERE name = :'BR1_ws_name';
+SELECT throws_ok('insert_br3_br1');
+
+PREPARE insert_br4_br4 AS INSERT INTO asset.copy_inventory(inventory_workstation, copy)
+SELECT id, :BR4_copy_id
+FROM actor.workstation
+WHERE name = :'BR4_ws_name';
+SELECT lives_ok('insert_br4_br4', 'BR4 at BR4 should succeed');
+
+PREPARE insert_br3_br4 AS INSERT INTO asset.copy_inventory(inventory_workstation, copy)
+SELECT id, :BR3_copy_id
+FROM actor.workstation
+WHERE name = :'BR4_ws_name';
+SELECT lives_ok('insert_br3_br4', 'BR3 at BR4 should succeed');
+
+PREPARE dup_insert_br3_br4 AS INSERT INTO asset.copy_inventory (inventory_workstation, inventory_date, copy)
+SELECT id, :'fixed_ts', :BR3_copy_id
+FROM actor.workstation
+WHERE name = :'BR4_ws_name';
+SELECT throws_ok('dup_insert_br3_br4', 23505);
+
+SELECT throws_ok('insert_null_all', 23505);
+
+SELECT * FROM finish();
+ROLLBACK;
--- /dev/null
+BEGIN;
+
+SELECT plan(11);
+
+SELECT has_table('asset'::name, 'copy_inventory'::name);
+
+SELECT has_index('asset'::name, 'copy_inventory'::name, 'copy_inventory_copy_idx'::name, 'copy'::name);
+
+SELECT has_index('asset'::name, 'copy_inventory'::name, 'asset_copy_inventory_date_once_per_copy'::name,
+ ARRAY[ 'inventory_date', 'copy' ]);
+
+SELECT has_function('evergreen'::name, 'asset_copy_inventory_copy_inh_fkey'::name);
+
+SELECT has_trigger('asset'::name, 'copy_inventory'::name, 'inherit_asset_copy_inventory_copy_fkey'::name);
+
+SELECT has_function('asset'::name, 'copy_may_float_to_inventory_workstation'::name);
+
+SELECT has_trigger('asset'::name, 'copy_inventory'::name, 'asset_copy_inventory_allowed_trig'::name);
+
+SELECT hasnt_function('evergreen'::name, 'asset_latest_inventory_copy_inh_fkey'::name);
+
+SELECT hasnt_trigger('asset'::name, 'latest_inventory'::name, 'inherit_asset_latest_inventory_copy_fkey'::name);
+
+SELECT hasnt_table('asset'::name, 'latest_inventory'::name);
+
+SELECT has_view('asset'::name, 'latest_inventory'::name, 'View latest_inventory should exist');
+
+SELECT * from finish();
+
+ROLLBACK;
--- /dev/null
+BEGIN;
+
+-- SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version);
+
+CREATE TABLE asset.copy_inventory (
+ id SERIAL PRIMARY KEY,
+ inventory_workstation INTEGER REFERENCES actor.workstation (id) DEFERRABLE INITIALLY DEFERRED,
+ inventory_date TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
+ copy BIGINT NOT NULL
+);
+CREATE INDEX copy_inventory_copy_idx ON asset.copy_inventory (copy);
+CREATE UNIQUE INDEX asset_copy_inventory_date_once_per_copy ON asset.copy_inventory (inventory_date, copy);
+
+CREATE OR REPLACE FUNCTION evergreen.asset_copy_inventory_copy_inh_fkey() RETURNS TRIGGER AS $f$
+BEGIN
+ PERFORM 1 FROM asset.copy WHERE id = NEW.copy;
+ IF NOT FOUND THEN
+ RAISE foreign_key_violation USING MESSAGE = FORMAT(
+ $$Referenced asset.copy id not found, copy:%s$$, NEW.copy
+ );
+ END IF;
+ RETURN NEW;
+END;
+$f$ LANGUAGE PLPGSQL VOLATILE COST 50;
+
+CREATE CONSTRAINT TRIGGER inherit_asset_copy_inventory_copy_fkey
+ AFTER UPDATE OR INSERT ON asset.copy_inventory
+ DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE evergreen.asset_copy_inventory_copy_inh_fkey();
+
+CREATE OR REPLACE FUNCTION asset.copy_may_float_to_inventory_workstation() RETURNS TRIGGER AS $func$
+DECLARE
+ copy asset.copy%ROWTYPE;
+ workstation actor.workstation%ROWTYPE;
+BEGIN
+ SELECT * INTO copy FROM asset.copy WHERE id = NEW.copy;
+ IF FOUND THEN
+ SELECT * INTO workstation FROM actor.workstation WHERE id = NEW.inventory_workstation;
+ IF FOUND THEN
+ IF copy.floating IS NULL THEN
+ IF copy.circ_lib <> workstation.owning_lib THEN
+ RAISE EXCEPTION 'Inventory workstation owning lib (%) does not match copy circ lib (%).',
+ workstation.owning_lib, copy.circ_lib;
+ END IF;
+ ELSE
+ IF NOT evergreen.can_float(copy.floating, copy.circ_lib, workstation.owning_lib) THEN
+ RAISE EXCEPTION 'Copy (%) cannot float to inventory workstation owning lib (%).',
+ copy.id, workstation.owning_lib;
+ END IF;
+ END IF;
+ END IF;
+ END IF;
+ RETURN NEW;
+END;
+$func$ LANGUAGE PLPGSQL VOLATILE COST 50;
+
+CREATE CONSTRAINT TRIGGER asset_copy_inventory_allowed_trig
+ AFTER UPDATE OR INSERT ON asset.copy_inventory
+ DEFERRABLE FOR EACH ROW EXECUTE PROCEDURE asset.copy_may_float_to_inventory_workstation();
+
+INSERT INTO asset.copy_inventory
+(inventory_workstation, inventory_date, copy)
+SELECT DISTINCT ON (inventory_date, copy) inventory_workstation, inventory_date, copy
+FROM asset.latest_inventory
+JOIN asset.copy acp ON acp.id = latest_inventory.copy
+JOIN actor.workstation ON workstation.id = latest_inventory.inventory_workstation
+WHERE acp.circ_lib = workstation.owning_lib
+UNION
+SELECT DISTINCT ON (inventory_date, copy) inventory_workstation, inventory_date, copy
+FROM asset.latest_inventory
+JOIN asset.copy acp ON acp.id = latest_inventory.copy
+JOIN actor.workstation ON workstation.id = latest_inventory.inventory_workstation
+WHERE acp.circ_lib <> workstation.owning_lib
+AND acp.floating IS NOT NULL
+AND evergreen.can_float(acp.floating, acp.circ_lib, workstation.owning_lib)
+ORDER by inventory_date;
+
+DROP TABLE asset.latest_inventory;
+
+CREATE VIEW asset.latest_inventory (id, inventory_workstation, inventory_date, copy) AS
+SELECT DISTINCT ON (copy) id, inventory_workstation, inventory_date, copy
+FROM asset.copy_inventory
+ORDER BY copy, inventory_date DESC;
+
+DROP FUNCTION evergreen.asset_latest_inventory_copy_inh_fkey();
+
+COMMIT;