-- Evergreen DB patch 0677.schema.circ_limits.sql -- -- FIXME: insert description of change, if needed -- BEGIN; -- check whether patch can be applied SELECT evergreen.upgrade_deps_block_check('0677', :eg_version); -- FIXME: add/check SQL statements to perform the upgrade -- Limit groups for circ counting CREATE TABLE config.circ_limit_group ( id SERIAL PRIMARY KEY, name TEXT UNIQUE NOT NULL, description TEXT ); -- Limit sets CREATE TABLE config.circ_limit_set ( id SERIAL PRIMARY KEY, name TEXT UNIQUE NOT NULL, owning_lib INT NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED, items_out INT NOT NULL, -- Total current active circulations must be less than this. 0 means skip counting (always pass) depth INT NOT NULL DEFAULT 0, -- Depth count starts at global BOOL NOT NULL DEFAULT FALSE, -- If enabled, include everything below depth, otherwise ancestors/descendants only description TEXT ); -- Linkage between matchpoints and limit sets CREATE TABLE config.circ_matrix_limit_set_map ( id SERIAL PRIMARY KEY, matchpoint INT NOT NULL REFERENCES config.circ_matrix_matchpoint (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, limit_set INT NOT NULL REFERENCES config.circ_limit_set (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, fallthrough BOOL NOT NULL DEFAULT FALSE, -- If true fallthrough will grab this rule as it goes along active BOOL NOT NULL DEFAULT TRUE, CONSTRAINT circ_limit_set_once_per_matchpoint UNIQUE (matchpoint, limit_set) ); -- Linkage between limit sets and circ mods CREATE TABLE config.circ_limit_set_circ_mod_map ( id SERIAL PRIMARY KEY, limit_set INT NOT NULL REFERENCES config.circ_limit_set (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, circ_mod TEXT NOT NULL REFERENCES config.circ_modifier (code) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED, CONSTRAINT cm_once_per_set UNIQUE (limit_set, circ_mod) ); -- Linkage between limit sets and limit groups CREATE TABLE config.circ_limit_set_group_map ( id SERIAL PRIMARY KEY, limit_set INT NOT NULL REFERENCES config.circ_limit_set (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, limit_group INT NOT NULL REFERENCES config.circ_limit_group (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, check_only BOOL NOT NULL DEFAULT FALSE, -- If true, don't accumulate this limit_group for storing with the circulation CONSTRAINT clg_once_per_set UNIQUE (limit_set, limit_group) ); -- Linkage between limit groups and circulations CREATE TABLE action.circulation_limit_group_map ( circ BIGINT NOT NULL REFERENCES action.circulation (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, limit_group INT NOT NULL REFERENCES config.circ_limit_group (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, PRIMARY KEY (circ, limit_group) ); -- Function for populating the circ/limit group mappings CREATE OR REPLACE FUNCTION action.link_circ_limit_groups ( BIGINT, INT[] ) RETURNS VOID AS $func$ INSERT INTO action.circulation_limit_group_map(circ, limit_group) SELECT $1, id FROM config.circ_limit_group WHERE id IN (SELECT * FROM UNNEST($2)); $func$ LANGUAGE SQL; DROP TYPE IF EXISTS action.circ_matrix_test_result CASCADE; CREATE TYPE action.circ_matrix_test_result AS ( success BOOL, fail_part TEXT, buildrows INT[], matchpoint INT, circulate BOOL, duration_rule INT, recurring_fine_rule INT, max_fine_rule INT, hard_due_date INT, renewals INT, grace_period INTERVAL, limit_groups INT[] ); CREATE OR REPLACE FUNCTION action.item_user_circ_test( circ_ou INT, match_item BIGINT, match_user INT, renewal BOOL ) RETURNS SETOF action.circ_matrix_test_result AS $func$ DECLARE user_object actor.usr%ROWTYPE; standing_penalty config.standing_penalty%ROWTYPE; item_object asset.copy%ROWTYPE; item_status_object config.copy_status%ROWTYPE; item_location_object asset.copy_location%ROWTYPE; result action.circ_matrix_test_result; circ_test action.found_circ_matrix_matchpoint; circ_matchpoint config.circ_matrix_matchpoint%ROWTYPE; circ_limit_set config.circ_limit_set%ROWTYPE; hold_ratio action.hold_stats%ROWTYPE; penalty_type TEXT; items_out INT; context_org_list INT[]; done BOOL := FALSE; BEGIN -- Assume success unless we hit a failure condition result.success := TRUE; -- Need user info to look up matchpoints SELECT INTO user_object * FROM actor.usr WHERE id = match_user AND NOT deleted; -- (Insta)Fail if we couldn't find the user IF user_object.id IS NULL THEN result.fail_part := 'no_user'; result.success := FALSE; done := TRUE; RETURN NEXT result; RETURN; END IF; -- Need item info to look up matchpoints SELECT INTO item_object * FROM asset.copy WHERE id = match_item AND NOT deleted; -- (Insta)Fail if we couldn't find the item IF item_object.id IS NULL THEN result.fail_part := 'no_item'; result.success := FALSE; done := TRUE; RETURN NEXT result; RETURN; END IF; SELECT INTO circ_test * FROM action.find_circ_matrix_matchpoint(circ_ou, item_object, user_object, renewal); circ_matchpoint := circ_test.matchpoint; result.matchpoint := circ_matchpoint.id; result.circulate := circ_matchpoint.circulate; result.duration_rule := circ_matchpoint.duration_rule; result.recurring_fine_rule := circ_matchpoint.recurring_fine_rule; result.max_fine_rule := circ_matchpoint.max_fine_rule; result.hard_due_date := circ_matchpoint.hard_due_date; result.renewals := circ_matchpoint.renewals; result.grace_period := circ_matchpoint.grace_period; result.buildrows := circ_test.buildrows; -- (Insta)Fail if we couldn't find a matchpoint IF circ_test.success = false THEN result.fail_part := 'no_matchpoint'; result.success := FALSE; done := TRUE; RETURN NEXT result; RETURN; END IF; -- All failures before this point are non-recoverable -- Below this point are possibly overridable failures -- Fail if the user is barred IF user_object.barred IS TRUE THEN result.fail_part := 'actor.usr.barred'; result.success := FALSE; done := TRUE; RETURN NEXT result; END IF; -- Fail if the item can't circulate IF item_object.circulate IS FALSE THEN result.fail_part := 'asset.copy.circulate'; result.success := FALSE; done := TRUE; RETURN NEXT result; END IF; -- Fail if the item isn't in a circulateable status on a non-renewal IF NOT renewal AND item_object.status NOT IN ( 0, 7, 8 ) THEN result.fail_part := 'asset.copy.status'; result.success := FALSE; done := TRUE; RETURN NEXT result; -- Alternately, fail if the item isn't checked out on a renewal ELSIF renewal AND item_object.status <> 1 THEN result.fail_part := 'asset.copy.status'; result.success := FALSE; done := TRUE; RETURN NEXT result; END IF; -- Fail if the item can't circulate because of the shelving location SELECT INTO item_location_object * FROM asset.copy_location WHERE id = item_object.location; IF item_location_object.circulate IS FALSE THEN result.fail_part := 'asset.copy_location.circulate'; result.success := FALSE; done := TRUE; RETURN NEXT result; END IF; -- Use Circ OU for penalties and such SELECT INTO context_org_list ARRAY_AGG(id) FROM actor.org_unit_full_path( circ_ou ); IF renewal THEN penalty_type = '%RENEW%'; ELSE penalty_type = '%CIRC%'; END IF; FOR standing_penalty IN SELECT DISTINCT csp.* FROM actor.usr_standing_penalty usp JOIN config.standing_penalty csp ON (csp.id = usp.standing_penalty) WHERE usr = match_user AND usp.org_unit IN ( SELECT * FROM unnest(context_org_list) ) AND (usp.stop_date IS NULL or usp.stop_date > NOW()) AND csp.block_list LIKE penalty_type LOOP result.fail_part := standing_penalty.name; result.success := FALSE; done := TRUE; RETURN NEXT result; END LOOP; -- Fail if the test is set to hard non-circulating IF circ_matchpoint.circulate IS FALSE THEN result.fail_part := 'config.circ_matrix_test.circulate'; result.success := FALSE; done := TRUE; RETURN NEXT result; END IF; -- Fail if the total copy-hold ratio is too low IF circ_matchpoint.total_copy_hold_ratio IS NOT NULL THEN SELECT INTO hold_ratio * FROM action.copy_related_hold_stats(match_item); IF hold_ratio.total_copy_ratio IS NOT NULL AND hold_ratio.total_copy_ratio < circ_matchpoint.total_copy_hold_ratio THEN result.fail_part := 'config.circ_matrix_test.total_copy_hold_ratio'; result.success := FALSE; done := TRUE; RETURN NEXT result; END IF; END IF; -- Fail if the available copy-hold ratio is too low IF circ_matchpoint.available_copy_hold_ratio IS NOT NULL THEN IF hold_ratio.hold_count IS NULL THEN SELECT INTO hold_ratio * FROM action.copy_related_hold_stats(match_item); END IF; IF hold_ratio.available_copy_ratio IS NOT NULL AND hold_ratio.available_copy_ratio < circ_matchpoint.available_copy_hold_ratio THEN result.fail_part := 'config.circ_matrix_test.available_copy_hold_ratio'; result.success := FALSE; done := TRUE; RETURN NEXT result; END IF; END IF; -- Fail if the user has too many items out by defined limit sets FOR circ_limit_set IN SELECT ccls.* FROM config.circ_limit_set ccls JOIN config.circ_matrix_limit_set_map ccmlsm ON ccmlsm.limit_set = ccls.id WHERE ccmlsm.active AND ( ccmlsm.matchpoint = circ_matchpoint.id OR ( ccmlsm.matchpoint IN (SELECT * FROM unnest(result.buildrows)) AND ccmlsm.fallthrough ) ) LOOP IF circ_limit_set.items_out > 0 AND NOT renewal THEN SELECT INTO context_org_list ARRAY_AGG(aou.id) FROM actor.org_unit_full_path( circ_ou ) aou JOIN actor.org_unit_type aout ON aou.ou_type = aout.id WHERE aout.depth >= circ_limit_set.depth; IF circ_limit_set.global THEN WITH RECURSIVE descendant_depth AS ( SELECT ou.id, ou.parent_ou FROM actor.org_unit ou WHERE ou.id IN (SELECT * FROM unnest(context_org_list)) UNION SELECT ou.id, ou.parent_ou FROM actor.org_unit ou JOIN descendant_depth ot ON (ot.id = ou.parent_ou) ) SELECT INTO context_org_list ARRAY_AGG(ou.id) FROM actor.org_unit ou JOIN descendant_depth USING (id); END IF; SELECT INTO items_out COUNT(DISTINCT circ.id) FROM action.circulation circ JOIN asset.copy copy ON (copy.id = circ.target_copy) LEFT JOIN action.circulation_limit_group_map aclgm ON (circ.id = aclgm.circ) WHERE circ.usr = match_user AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list)) AND circ.checkin_time IS NULL AND (circ.stop_fines IN ('MAXFINES','LONGOVERDUE') OR circ.stop_fines IS NULL) AND (copy.circ_modifier IN (SELECT circ_mod FROM config.circ_limit_set_circ_mod_map WHERE limit_set = circ_limit_set.id) OR aclgm.limit_group IN (SELECT limit_group FROM config.circ_limit_set_group_map WHERE limit_set = circ_limit_set.id) ); IF items_out >= circ_limit_set.items_out THEN result.fail_part := 'config.circ_matrix_circ_mod_test'; result.success := FALSE; done := TRUE; RETURN NEXT result; END IF; END IF; SELECT INTO result.limit_groups result.limit_groups || ARRAY_AGG(limit_group) FROM config.circ_limit_set_group_map WHERE limit_set = circ_limit_set.id AND NOT check_only; END LOOP; -- If we passed everything, return the successful matchpoint IF NOT done THEN RETURN NEXT result; END IF; RETURN; END; $func$ LANGUAGE plpgsql; -- We need to re-create these, as they got dropped with the type above. CREATE OR REPLACE FUNCTION action.item_user_circ_test( INT, BIGINT, INT ) RETURNS SETOF action.circ_matrix_test_result AS $func$ SELECT * FROM action.item_user_circ_test( $1, $2, $3, FALSE ); $func$ LANGUAGE SQL; CREATE OR REPLACE FUNCTION action.item_user_renew_test( INT, BIGINT, INT ) RETURNS SETOF action.circ_matrix_test_result AS $func$ SELECT * FROM action.item_user_circ_test( $1, $2, $3, TRUE ); $func$ LANGUAGE SQL; -- Temp function for migrating circ mod limits. CREATE OR REPLACE FUNCTION evergreen.temp_migrate_circ_mod_limits() RETURNS VOID AS $func$ DECLARE circ_mod_group config.circ_matrix_circ_mod_test%ROWTYPE; current_set INT; circ_mod_count INT; BEGIN FOR circ_mod_group IN SELECT * FROM config.circ_matrix_circ_mod_test LOOP INSERT INTO config.circ_limit_set(name, owning_lib, items_out, depth, global, description) SELECT org_unit || ' : Matchpoint ' || circ_mod_group.matchpoint || ' : Circ Mod Test ' || circ_mod_group.id, org_unit, circ_mod_group.items_out, 0, false, 'Migrated from Circ Mod Test System' FROM config.circ_matrix_matchpoint WHERE id = circ_mod_group.matchpoint RETURNING id INTO current_set; INSERT INTO config.circ_matrix_limit_set_map(matchpoint, limit_set, fallthrough, active) VALUES (circ_mod_group.matchpoint, current_set, false, true); INSERT INTO config.circ_limit_set_circ_mod_map(limit_set, circ_mod) SELECT current_set, circ_mod FROM config.circ_matrix_circ_mod_test_map WHERE circ_mod_test = circ_mod_group.id; SELECT INTO circ_mod_count count(id) FROM config.circ_limit_set_circ_mod_map WHERE limit_set = current_set; RAISE NOTICE 'Created limit set with id % and % circ modifiers attached to matchpoint %', current_set, circ_mod_count, circ_mod_group.matchpoint; END LOOP; END; $func$ LANGUAGE plpgsql; -- Run the temp function SELECT * FROM evergreen.temp_migrate_circ_mod_limits(); -- Drop the temp function DROP FUNCTION evergreen.temp_migrate_circ_mod_limits(); --Drop the old tables --Not sure we want to do this. Keeping them may help "something went wrong" correction. --DROP TABLE IF EXISTS config.circ_matrix_circ_mod_test_map, config.circ_matrix_circ_mod_test; COMMIT;