BEGIN; -- NOTE: current config.item_type should get sip2_media_type and magnetic_media columns -- New table needed to handle circ modifiers inside the DB. Will still require -- central admin. The circ_modifier column on asset.copy will become an fkey to this table. CREATE TABLE config.circ_modifier ( code TEXT PRIMARY KEY, name TEXT UNIQUE NOT NULL, description TEXT NOT NULL, sip2_media_type TEXT NOT NULL, magnetic_media BOOL NOT NULL DEFAULT TRUE, avg_wait_time INTERVAL ); /* -- for instance ... INSERT INTO config.circ_modifier VALUES ( 'DVD', 'DVD', 'um ... DVDs', '001', FALSE ); INSERT INTO config.circ_modifier VALUES ( 'VIDEO', 'VIDEO', 'Tapes', '001', TRUE ); INSERT INTO config.circ_modifier VALUES ( 'BOOK', 'BOOK', 'Dead tree', '001', FALSE ); INSERT INTO config.circ_modifier VALUES ( 'CRAZY_ARL-ATH_SETTING', 'R2R_TAPE', 'reel2reel tape', '007', TRUE ); */ -- But, just to get us started, use this /* UPDATE asset.copy SET circ_modifier = UPPER(circ_modifier) WHERE circ_modifier IS NOT NULL AND circ_modifier <> ''; UPDATE asset.copy SET circ_modifier = NULL WHERE circ_modifier = ''; INSERT INTO config.circ_modifier (code, name, description, sip2_media_type ) SELECT DISTINCT UPPER(circ_modifier), UPPER(circ_modifier), LOWER(circ_modifier), '001' FROM asset.copy WHERE circ_modifier IS NOT NULL; */ -- add an fkey pointing to the new circ mod table ALTER TABLE asset.copy ADD CONSTRAINT circ_mod_fkey FOREIGN KEY (circ_modifier) REFERENCES config.circ_modifier (code) ON UPDATE CASCADE ON DELETE SET NULL DEFERRABLE INITIALLY DEFERRED; /** ** Here we define the tables that make up the circ matrix. Conceptually, this implements ** the "sparse matrix" that everyone talks about, instead of using traditional rules logic. ** Physically, we cut the matrix up into separate tables (almost 3rd normal form!) that handle ** different portions of the matrix. This wil simplify creation of the UI (I hope), and help the ** developers focus on specific parts of the matrix. **/ CREATE TABLE config.circ_matrix_matchpoint ( id SERIAL PRIMARY KEY, active BOOL NOT NULL DEFAULT TRUE, -- Match Fields org_unit INT NOT NULL REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED, -- Set to the top OU for the matchpoint applicability range; we can use org_unit_prox to choose the "best" grp INT NOT NULL REFERENCES permission.grp_tree (id) DEFERRABLE INITIALLY DEFERRED, -- Set to the top applicable group from the group tree; will need descendents and prox functions for filtering circ_modifier TEXT REFERENCES config.circ_modifier (code) DEFERRABLE INITIALLY DEFERRED, copy_location INT REFERENCES asset.copy_location (id) DEFERRABLE INITIALLY DEFERRED, marc_type TEXT, marc_form TEXT, marc_bib_level TEXT, marc_vr_format TEXT, copy_circ_lib INT REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED, copy_owning_lib INT REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED, user_home_ou INT REFERENCES actor.org_unit (id) DEFERRABLE INITIALLY DEFERRED, ref_flag BOOL, juvenile_flag BOOL, is_renewal BOOL, usr_age_lower_bound INTERVAL, usr_age_upper_bound INTERVAL, item_age INTERVAL, -- "Result" Fields circulate BOOL, -- Hard "can't circ" flag requiring an override duration_rule INT REFERENCES config.rule_circ_duration (id) DEFERRABLE INITIALLY DEFERRED, recurring_fine_rule INT REFERENCES config.rule_recurring_fine (id) DEFERRABLE INITIALLY DEFERRED, max_fine_rule INT REFERENCES config.rule_max_fine (id) DEFERRABLE INITIALLY DEFERRED, hard_due_date INT REFERENCES config.hard_due_date (id) DEFERRABLE INITIALLY DEFERRED, renewals INT, -- Renewal count override grace_period INTERVAL, -- Grace period override script_test TEXT, -- javascript source total_copy_hold_ratio FLOAT, available_copy_hold_ratio FLOAT, description TEXT ); -- Nulls don't count for a constraint match, so we have to coalesce them into something that does. CREATE UNIQUE INDEX ccmm_once_per_paramset ON config.circ_matrix_matchpoint (org_unit, grp, COALESCE(circ_modifier, ''), COALESCE(copy_location::TEXT, ''), COALESCE(marc_type, ''), COALESCE(marc_form, ''), COALESCE(marc_bib_level,''), COALESCE(marc_vr_format, ''), COALESCE(copy_circ_lib::TEXT, ''), COALESCE(copy_owning_lib::TEXT, ''), COALESCE(user_home_ou::TEXT, ''), COALESCE(ref_flag::TEXT, ''), COALESCE(juvenile_flag::TEXT, ''), COALESCE(is_renewal::TEXT, ''), COALESCE(usr_age_lower_bound::TEXT, ''), COALESCE(usr_age_upper_bound::TEXT, ''), COALESCE(item_age::TEXT, '')) WHERE active; -- 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 copy locations CREATE TABLE config.circ_limit_set_copy_loc_map ( id SERIAL PRIMARY KEY, limit_set INT NOT NULL REFERENCES config.circ_limit_set (id) ON DELETE CASCADE DEFERRABLE INITIALLY DEFERRED, copy_loc INT NOT NULL REFERENCES asset.copy_location (id) ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE INITIALLY DEFERRED, CONSTRAINT cl_once_per_set UNIQUE (limit_set, copy_loc) ); -- 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; CREATE TYPE action.found_circ_matrix_matchpoint AS ( success BOOL, matchpoint config.circ_matrix_matchpoint, buildrows INT[] ); CREATE OR REPLACE FUNCTION action.find_circ_matrix_matchpoint( context_ou INT, item_object asset.copy, user_object actor.usr, renewal BOOL ) RETURNS action.found_circ_matrix_matchpoint AS $func$ DECLARE cn_object asset.call_number%ROWTYPE; rec_descriptor metabib.rec_descriptor%ROWTYPE; cur_matchpoint config.circ_matrix_matchpoint%ROWTYPE; matchpoint config.circ_matrix_matchpoint%ROWTYPE; weights config.circ_matrix_weights%ROWTYPE; user_age INTERVAL; my_item_age INTERVAL; denominator NUMERIC(6,2); row_list INT[]; result action.found_circ_matrix_matchpoint; BEGIN -- Assume failure result.success = false; -- Fetch useful data SELECT INTO cn_object * FROM asset.call_number WHERE id = item_object.call_number; SELECT INTO rec_descriptor * FROM metabib.rec_descriptor WHERE record = cn_object.record; -- Pre-generate this so we only calc it once IF user_object.dob IS NOT NULL THEN SELECT INTO user_age age(user_object.dob); END IF; -- Ditto SELECT INTO my_item_age age(coalesce(item_object.active_date, now())); -- Grab the closest set circ weight setting. SELECT INTO weights cw.* FROM config.weight_assoc wa JOIN config.circ_matrix_weights cw ON (cw.id = wa.circ_weights) JOIN actor.org_unit_ancestors_distance( context_ou ) d ON (wa.org_unit = d.id) WHERE active ORDER BY d.distance LIMIT 1; -- No weights? Bad admin! Defaults to handle that anyway. IF weights.id IS NULL THEN weights.grp := 11.0; weights.org_unit := 10.0; weights.circ_modifier := 5.0; weights.copy_location := 5.0; weights.marc_type := 4.0; weights.marc_form := 3.0; weights.marc_bib_level := 2.0; weights.marc_vr_format := 2.0; weights.copy_circ_lib := 8.0; weights.copy_owning_lib := 8.0; weights.user_home_ou := 8.0; weights.ref_flag := 1.0; weights.juvenile_flag := 6.0; weights.is_renewal := 7.0; weights.usr_age_lower_bound := 0.0; weights.usr_age_upper_bound := 0.0; weights.item_age := 0.0; END IF; -- Determine the max (expected) depth (+1) of the org tree and max depth of the permisson tree -- If you break your org tree with funky parenting this may be wrong -- Note: This CTE is duplicated in the find_hold_matrix_matchpoint function, and it may be a good idea to split it off to a function -- We use one denominator for all tree-based checks for when permission groups and org units have the same weighting WITH all_distance(distance) AS ( SELECT depth AS distance FROM actor.org_unit_type UNION SELECT distance AS distance FROM permission.grp_ancestors_distance((SELECT id FROM permission.grp_tree WHERE parent IS NULL)) ) SELECT INTO denominator MAX(distance) + 1 FROM all_distance; -- Loop over all the potential matchpoints FOR cur_matchpoint IN SELECT m.* FROM config.circ_matrix_matchpoint m /*LEFT*/ JOIN permission.grp_ancestors_distance( user_object.profile ) upgad ON m.grp = upgad.id /*LEFT*/ JOIN actor.org_unit_ancestors_distance( context_ou ) ctoua ON m.org_unit = ctoua.id LEFT JOIN actor.org_unit_ancestors_distance( cn_object.owning_lib ) cnoua ON m.copy_owning_lib = cnoua.id LEFT JOIN actor.org_unit_ancestors_distance( item_object.circ_lib ) iooua ON m.copy_circ_lib = iooua.id LEFT JOIN actor.org_unit_ancestors_distance( user_object.home_ou ) uhoua ON m.user_home_ou = uhoua.id WHERE m.active -- Permission Groups -- AND (m.grp IS NULL OR upgad.id IS NOT NULL) -- Optional Permission Group? -- Org Units -- AND (m.org_unit IS NULL OR ctoua.id IS NOT NULL) -- Optional Org Unit? AND (m.copy_owning_lib IS NULL OR cnoua.id IS NOT NULL) AND (m.copy_circ_lib IS NULL OR iooua.id IS NOT NULL) AND (m.user_home_ou IS NULL OR uhoua.id IS NOT NULL) -- Circ Type AND (m.is_renewal IS NULL OR m.is_renewal = renewal) -- Static User Checks AND (m.juvenile_flag IS NULL OR m.juvenile_flag = user_object.juvenile) AND (m.usr_age_lower_bound IS NULL OR (user_age IS NOT NULL AND m.usr_age_lower_bound < user_age)) AND (m.usr_age_upper_bound IS NULL OR (user_age IS NOT NULL AND m.usr_age_upper_bound > user_age)) -- Static Item Checks AND (m.circ_modifier IS NULL OR m.circ_modifier = item_object.circ_modifier) AND (m.copy_location IS NULL OR m.copy_location = item_object.location) AND (m.marc_type IS NULL OR m.marc_type = COALESCE(item_object.circ_as_type, rec_descriptor.item_type)) AND (m.marc_form IS NULL OR m.marc_form = rec_descriptor.item_form) AND (m.marc_bib_level IS NULL OR m.marc_bib_level = rec_descriptor.bib_level) AND (m.marc_vr_format IS NULL OR m.marc_vr_format = rec_descriptor.vr_format) AND (m.ref_flag IS NULL OR m.ref_flag = item_object.ref) AND (m.item_age IS NULL OR (my_item_age IS NOT NULL AND m.item_age > my_item_age)) ORDER BY -- Permission Groups CASE WHEN upgad.distance IS NOT NULL THEN 2^(2*weights.grp - (upgad.distance/denominator)) ELSE 0.0 END + -- Org Units CASE WHEN ctoua.distance IS NOT NULL THEN 2^(2*weights.org_unit - (ctoua.distance/denominator)) ELSE 0.0 END + CASE WHEN cnoua.distance IS NOT NULL THEN 2^(2*weights.copy_owning_lib - (cnoua.distance/denominator)) ELSE 0.0 END + CASE WHEN iooua.distance IS NOT NULL THEN 2^(2*weights.copy_circ_lib - (iooua.distance/denominator)) ELSE 0.0 END + CASE WHEN uhoua.distance IS NOT NULL THEN 2^(2*weights.user_home_ou - (uhoua.distance/denominator)) ELSE 0.0 END + -- Circ Type -- Note: 4^x is equiv to 2^(2*x) CASE WHEN m.is_renewal IS NOT NULL THEN 4^weights.is_renewal ELSE 0.0 END + -- Static User Checks CASE WHEN m.juvenile_flag IS NOT NULL THEN 4^weights.juvenile_flag ELSE 0.0 END + CASE WHEN m.usr_age_lower_bound IS NOT NULL THEN 4^weights.usr_age_lower_bound ELSE 0.0 END + CASE WHEN m.usr_age_upper_bound IS NOT NULL THEN 4^weights.usr_age_upper_bound ELSE 0.0 END + -- Static Item Checks CASE WHEN m.circ_modifier IS NOT NULL THEN 4^weights.circ_modifier ELSE 0.0 END + CASE WHEN m.copy_location IS NOT NULL THEN 4^weights.copy_location ELSE 0.0 END + CASE WHEN m.marc_type IS NOT NULL THEN 4^weights.marc_type ELSE 0.0 END + CASE WHEN m.marc_form IS NOT NULL THEN 4^weights.marc_form ELSE 0.0 END + CASE WHEN m.marc_vr_format IS NOT NULL THEN 4^weights.marc_vr_format ELSE 0.0 END + CASE WHEN m.ref_flag IS NOT NULL THEN 4^weights.ref_flag ELSE 0.0 END + -- Item age has a slight adjustment to weight based on value. -- This should ensure that a shorter age limit comes first when all else is equal. -- NOTE: This assumes that intervals will normally be in days. CASE WHEN m.item_age IS NOT NULL THEN 4^weights.item_age - 1 + 86400/EXTRACT(EPOCH FROM m.item_age) ELSE 0.0 END DESC, -- Final sort on id, so that if two rules have the same sorting in the previous sort they have a defined order -- This prevents "we changed the table order by updating a rule, and we started getting different results" m.id LOOP -- Record the full matching row list row_list := row_list || cur_matchpoint.id; -- No matchpoint yet? IF matchpoint.id IS NULL THEN -- Take the entire matchpoint as a starting point matchpoint := cur_matchpoint; CONTINUE; -- No need to look at this row any more. END IF; -- Incomplete matchpoint? IF matchpoint.circulate IS NULL THEN matchpoint.circulate := cur_matchpoint.circulate; END IF; IF matchpoint.duration_rule IS NULL THEN matchpoint.duration_rule := cur_matchpoint.duration_rule; END IF; IF matchpoint.recurring_fine_rule IS NULL THEN matchpoint.recurring_fine_rule := cur_matchpoint.recurring_fine_rule; END IF; IF matchpoint.max_fine_rule IS NULL THEN matchpoint.max_fine_rule := cur_matchpoint.max_fine_rule; END IF; IF matchpoint.hard_due_date IS NULL THEN matchpoint.hard_due_date := cur_matchpoint.hard_due_date; END IF; IF matchpoint.total_copy_hold_ratio IS NULL THEN matchpoint.total_copy_hold_ratio := cur_matchpoint.total_copy_hold_ratio; END IF; IF matchpoint.available_copy_hold_ratio IS NULL THEN matchpoint.available_copy_hold_ratio := cur_matchpoint.available_copy_hold_ratio; END IF; IF matchpoint.renewals IS NULL THEN matchpoint.renewals := cur_matchpoint.renewals; END IF; IF matchpoint.grace_period IS NULL THEN matchpoint.grace_period := cur_matchpoint.grace_period; END IF; END LOOP; -- Check required fields IF matchpoint.circulate IS NOT NULL AND matchpoint.duration_rule IS NOT NULL AND matchpoint.recurring_fine_rule IS NOT NULL AND matchpoint.max_fine_rule IS NOT NULL THEN -- All there? We have a completed match. result.success := true; END IF; -- Include the assembled matchpoint, even if it isn't complete result.matchpoint := matchpoint; -- Include (for debugging) the full list of matching rows result.buildrows := row_list; -- Hand the result back to caller RETURN result; END; $func$ LANGUAGE plpgsql; -- Helper function - For manual calling, it can be easier to pass in IDs instead of objects CREATE OR REPLACE FUNCTION action.find_circ_matrix_matchpoint( context_ou INT, match_item BIGINT, match_user INT, renewal BOOL ) RETURNS SETOF action.found_circ_matrix_matchpoint AS $func$ DECLARE item_object asset.copy%ROWTYPE; user_object actor.usr%ROWTYPE; BEGIN SELECT INTO item_object * FROM asset.copy WHERE id = match_item; SELECT INTO user_object * FROM actor.usr WHERE id = match_user; RETURN QUERY SELECT * FROM action.find_circ_matrix_matchpoint( context_ou, item_object, user_object, renewal ); END; $func$ LANGUAGE plpgsql; CREATE TYPE action.hold_stats AS ( hold_count INT, copy_count INT, available_count INT, total_copy_ratio FLOAT, available_copy_ratio FLOAT ); CREATE OR REPLACE FUNCTION action.copy_related_hold_stats (copy_id BIGINT) RETURNS action.hold_stats AS $func$ DECLARE output action.hold_stats%ROWTYPE; hold_count INT := 0; copy_count INT := 0; available_count INT := 0; hold_map_data RECORD; BEGIN output.hold_count := 0; output.copy_count := 0; output.available_count := 0; SELECT COUNT( DISTINCT m.hold ) INTO hold_count FROM action.hold_copy_map m JOIN action.hold_request h ON (m.hold = h.id) WHERE m.target_copy = copy_id AND NOT h.frozen; output.hold_count := hold_count; IF output.hold_count > 0 THEN FOR hold_map_data IN SELECT DISTINCT m.target_copy, acp.status FROM action.hold_copy_map m JOIN asset.copy acp ON (m.target_copy = acp.id) JOIN action.hold_request h ON (m.hold = h.id) WHERE m.hold IN ( SELECT DISTINCT hold FROM action.hold_copy_map WHERE target_copy = copy_id ) AND NOT h.frozen LOOP output.copy_count := output.copy_count + 1; IF hold_map_data.status IN (0,7,12) THEN output.available_count := output.available_count + 1; END IF; END LOOP; output.total_copy_ratio = output.copy_count::FLOAT / output.hold_count::FLOAT; output.available_copy_ratio = output.available_count::FLOAT / output.hold_count::FLOAT; END IF; RETURN output; END; $func$ LANGUAGE PLPGSQL; 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; item_prox INT; home_prox INT; 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 <> 8 AND item_object.status NOT IN ( (SELECT id FROM config.copy_status WHERE is_available) ) 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 ); -- Proximity of user's home_ou to circ_ou to see if penalties should be ignored. SELECT INTO home_prox prox FROM actor.org_unit_proximity WHERE from_org = user_object.home_ou AND to_org = circ_ou; -- Proximity of user's home_ou to item circ_lib to see if penalties should be ignored. SELECT INTO item_prox prox FROM actor.org_unit_proximity WHERE from_org = user_object.home_ou AND to_org = item_object.circ_lib; 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.ignore_proximity IS NULL OR csp.ignore_proximity < home_prox OR csp.ignore_proximity < item_prox) 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 copy.location IN (SELECT copy_loc FROM config.circ_limit_set_copy_loc_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; 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; CREATE OR REPLACE FUNCTION actor.calculate_system_penalties( match_user INT, context_org INT ) RETURNS SETOF actor.usr_standing_penalty AS $func$ DECLARE user_object actor.usr%ROWTYPE; new_sp_row actor.usr_standing_penalty%ROWTYPE; existing_sp_row actor.usr_standing_penalty%ROWTYPE; collections_fines permission.grp_penalty_threshold%ROWTYPE; max_fines permission.grp_penalty_threshold%ROWTYPE; max_overdue permission.grp_penalty_threshold%ROWTYPE; max_items_out permission.grp_penalty_threshold%ROWTYPE; max_lost permission.grp_penalty_threshold%ROWTYPE; max_longoverdue permission.grp_penalty_threshold%ROWTYPE; tmp_grp INT; items_overdue INT; items_out INT; items_lost INT; items_longoverdue INT; context_org_list INT[]; current_fines NUMERIC(8,2) := 0.0; tmp_fines NUMERIC(8,2); tmp_groc RECORD; tmp_circ RECORD; tmp_org actor.org_unit%ROWTYPE; tmp_penalty config.standing_penalty%ROWTYPE; tmp_depth INTEGER; BEGIN SELECT INTO user_object * FROM actor.usr WHERE id = match_user; -- Max fines SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org; -- Fail if the user has a high fine balance LOOP tmp_grp := user_object.profile; LOOP SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 1 AND org_unit = tmp_org.id; IF max_fines.threshold IS NULL THEN SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp; ELSE EXIT; END IF; IF tmp_grp IS NULL THEN EXIT; END IF; END LOOP; IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN EXIT; END IF; SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou; END LOOP; IF max_fines.threshold IS NOT NULL THEN RETURN QUERY SELECT * FROM actor.usr_standing_penalty WHERE usr = match_user AND org_unit = max_fines.org_unit AND (stop_date IS NULL or stop_date > NOW()) AND standing_penalty = 1; SELECT INTO context_org_list ARRAY_AGG(id) FROM actor.org_unit_full_path( max_fines.org_unit ); SELECT SUM(f.balance_owed) INTO current_fines FROM money.materialized_billable_xact_summary f JOIN ( SELECT r.id FROM booking.reservation r WHERE r.usr = match_user AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list)) AND xact_finish IS NULL UNION ALL SELECT g.id FROM money.grocery g WHERE g.usr = match_user AND g.billing_location IN (SELECT * FROM unnest(context_org_list)) AND xact_finish IS NULL UNION ALL SELECT circ.id FROM action.circulation circ WHERE circ.usr = match_user AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list)) AND xact_finish IS NULL ) l USING (id); IF current_fines >= max_fines.threshold THEN new_sp_row.usr := match_user; new_sp_row.org_unit := max_fines.org_unit; new_sp_row.standing_penalty := 1; RETURN NEXT new_sp_row; END IF; END IF; -- Start over for max overdue SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org; -- Fail if the user has too many overdue items LOOP tmp_grp := user_object.profile; LOOP SELECT * INTO max_overdue FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 2 AND org_unit = tmp_org.id; IF max_overdue.threshold IS NULL THEN SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp; ELSE EXIT; END IF; IF tmp_grp IS NULL THEN EXIT; END IF; END LOOP; IF max_overdue.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN EXIT; END IF; SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou; END LOOP; IF max_overdue.threshold IS NOT NULL THEN RETURN QUERY SELECT * FROM actor.usr_standing_penalty WHERE usr = match_user AND org_unit = max_overdue.org_unit AND (stop_date IS NULL or stop_date > NOW()) AND standing_penalty = 2; SELECT INTO items_overdue COUNT(*) FROM action.circulation circ JOIN actor.org_unit_full_path( max_overdue.org_unit ) fp ON (circ.circ_lib = fp.id) WHERE circ.usr = match_user AND circ.checkin_time IS NULL AND circ.due_date < NOW() AND (circ.stop_fines = 'MAXFINES' OR circ.stop_fines IS NULL); IF items_overdue >= max_overdue.threshold::INT THEN new_sp_row.usr := match_user; new_sp_row.org_unit := max_overdue.org_unit; new_sp_row.standing_penalty := 2; RETURN NEXT new_sp_row; END IF; END IF; -- Start over for max out SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org; -- Fail if the user has too many checked out items LOOP tmp_grp := user_object.profile; LOOP SELECT * INTO max_items_out FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 3 AND org_unit = tmp_org.id; IF max_items_out.threshold IS NULL THEN SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp; ELSE EXIT; END IF; IF tmp_grp IS NULL THEN EXIT; END IF; END LOOP; IF max_items_out.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN EXIT; END IF; SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou; END LOOP; -- Fail if the user has too many items checked out IF max_items_out.threshold IS NOT NULL THEN RETURN QUERY SELECT * FROM actor.usr_standing_penalty WHERE usr = match_user AND org_unit = max_items_out.org_unit AND (stop_date IS NULL or stop_date > NOW()) AND standing_penalty = 3; SELECT INTO items_out COUNT(*) FROM action.circulation circ JOIN actor.org_unit_full_path( max_items_out.org_unit ) fp ON (circ.circ_lib = fp.id) WHERE circ.usr = match_user AND circ.checkin_time IS NULL AND (circ.stop_fines IN ( SELECT 'MAXFINES'::TEXT UNION ALL SELECT 'LONGOVERDUE'::TEXT UNION ALL SELECT 'LOST'::TEXT WHERE 'true' ILIKE ( SELECT CASE WHEN (SELECT value FROM actor.org_unit_ancestor_setting('circ.tally_lost', circ.circ_lib)) ILIKE 'true' THEN 'true' ELSE 'false' END ) UNION ALL SELECT 'CLAIMSRETURNED'::TEXT WHERE 'false' ILIKE ( SELECT CASE WHEN (SELECT value FROM actor.org_unit_ancestor_setting('circ.do_not_tally_claims_returned', circ.circ_lib)) ILIKE 'true' THEN 'true' ELSE 'false' END ) ) OR circ.stop_fines IS NULL) AND xact_finish IS NULL; IF items_out >= max_items_out.threshold::INT THEN new_sp_row.usr := match_user; new_sp_row.org_unit := max_items_out.org_unit; new_sp_row.standing_penalty := 3; RETURN NEXT new_sp_row; END IF; END IF; -- Start over for max lost SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org; -- Fail if the user has too many lost items LOOP tmp_grp := user_object.profile; LOOP SELECT * INTO max_lost FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 5 AND org_unit = tmp_org.id; IF max_lost.threshold IS NULL THEN SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp; ELSE EXIT; END IF; IF tmp_grp IS NULL THEN EXIT; END IF; END LOOP; IF max_lost.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN EXIT; END IF; SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou; END LOOP; IF max_lost.threshold IS NOT NULL THEN RETURN QUERY SELECT * FROM actor.usr_standing_penalty WHERE usr = match_user AND org_unit = max_lost.org_unit AND (stop_date IS NULL or stop_date > NOW()) AND standing_penalty = 5; SELECT INTO items_lost COUNT(*) FROM action.circulation circ JOIN actor.org_unit_full_path( max_lost.org_unit ) fp ON (circ.circ_lib = fp.id) WHERE circ.usr = match_user AND circ.checkin_time IS NULL AND (circ.stop_fines = 'LOST') AND xact_finish IS NULL; IF items_lost >= max_lost.threshold::INT AND 0 < max_lost.threshold::INT THEN new_sp_row.usr := match_user; new_sp_row.org_unit := max_lost.org_unit; new_sp_row.standing_penalty := 5; RETURN NEXT new_sp_row; END IF; END IF; -- Start over for max longoverdue SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org; -- Fail if the user has too many longoverdue items LOOP tmp_grp := user_object.profile; LOOP SELECT * INTO max_longoverdue FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 35 AND org_unit = tmp_org.id; IF max_longoverdue.threshold IS NULL THEN SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp; ELSE EXIT; END IF; IF tmp_grp IS NULL THEN EXIT; END IF; END LOOP; IF max_longoverdue.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN EXIT; END IF; SELECT INTO tmp_org * FROM actor.org_unit WHERE id = tmp_org.parent_ou; END LOOP; IF max_longoverdue.threshold IS NOT NULL THEN RETURN QUERY SELECT * FROM actor.usr_standing_penalty WHERE usr = match_user AND org_unit = max_longoverdue.org_unit AND (stop_date IS NULL or stop_date > NOW()) AND standing_penalty = 35; SELECT INTO items_longoverdue COUNT(*) FROM action.circulation circ JOIN actor.org_unit_full_path( max_longoverdue.org_unit ) fp ON (circ.circ_lib = fp.id) WHERE circ.usr = match_user AND circ.checkin_time IS NULL AND (circ.stop_fines = 'LONGOVERDUE') AND xact_finish IS NULL; IF items_longoverdue >= max_longoverdue.threshold::INT AND 0 < max_longoverdue.threshold::INT THEN new_sp_row.usr := match_user; new_sp_row.org_unit := max_longoverdue.org_unit; new_sp_row.standing_penalty := 35; RETURN NEXT new_sp_row; END IF; END IF; -- Start over for collections warning SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org; -- Fail if the user has a collections-level fine balance LOOP tmp_grp := user_object.profile; LOOP SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 4 AND org_unit = tmp_org.id; IF max_fines.threshold IS NULL THEN SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp; ELSE EXIT; END IF; IF tmp_grp IS NULL THEN EXIT; END IF; END LOOP; IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN EXIT; END IF; SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou; END LOOP; IF max_fines.threshold IS NOT NULL THEN RETURN QUERY SELECT * FROM actor.usr_standing_penalty WHERE usr = match_user AND org_unit = max_fines.org_unit AND (stop_date IS NULL or stop_date > NOW()) AND standing_penalty = 4; SELECT INTO context_org_list ARRAY_AGG(id) FROM actor.org_unit_full_path( max_fines.org_unit ); SELECT SUM(f.balance_owed) INTO current_fines FROM money.materialized_billable_xact_summary f JOIN ( SELECT r.id FROM booking.reservation r WHERE r.usr = match_user AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list)) AND r.xact_finish IS NULL UNION ALL SELECT g.id FROM money.grocery g WHERE g.usr = match_user AND g.billing_location IN (SELECT * FROM unnest(context_org_list)) AND g.xact_finish IS NULL UNION ALL SELECT circ.id FROM action.circulation circ WHERE circ.usr = match_user AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list)) AND circ.xact_finish IS NULL ) l USING (id); IF current_fines >= max_fines.threshold THEN new_sp_row.usr := match_user; new_sp_row.org_unit := max_fines.org_unit; new_sp_row.standing_penalty := 4; RETURN NEXT new_sp_row; END IF; END IF; -- Start over for in collections SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org; -- Remove the in-collections penalty if the user has paid down enough -- This penalty is different, because this code is not responsible for creating -- new in-collections penalties, only for removing them LOOP tmp_grp := user_object.profile; LOOP SELECT * INTO max_fines FROM permission.grp_penalty_threshold WHERE grp = tmp_grp AND penalty = 30 AND org_unit = tmp_org.id; IF max_fines.threshold IS NULL THEN SELECT parent INTO tmp_grp FROM permission.grp_tree WHERE id = tmp_grp; ELSE EXIT; END IF; IF tmp_grp IS NULL THEN EXIT; END IF; END LOOP; IF max_fines.threshold IS NOT NULL OR tmp_org.parent_ou IS NULL THEN EXIT; END IF; SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou; END LOOP; IF max_fines.threshold IS NOT NULL THEN SELECT INTO context_org_list ARRAY_AGG(id) FROM actor.org_unit_full_path( max_fines.org_unit ); -- first, see if the user had paid down to the threshold SELECT SUM(f.balance_owed) INTO current_fines FROM money.materialized_billable_xact_summary f JOIN ( SELECT r.id FROM booking.reservation r WHERE r.usr = match_user AND r.pickup_lib IN (SELECT * FROM unnest(context_org_list)) AND r.xact_finish IS NULL UNION ALL SELECT g.id FROM money.grocery g WHERE g.usr = match_user AND g.billing_location IN (SELECT * FROM unnest(context_org_list)) AND g.xact_finish IS NULL UNION ALL SELECT circ.id FROM action.circulation circ WHERE circ.usr = match_user AND circ.circ_lib IN (SELECT * FROM unnest(context_org_list)) AND circ.xact_finish IS NULL ) l USING (id); IF current_fines IS NULL OR current_fines <= max_fines.threshold THEN -- patron has paid down enough SELECT INTO tmp_penalty * FROM config.standing_penalty WHERE id = 30; IF tmp_penalty.org_depth IS NOT NULL THEN -- since this code is not responsible for applying the penalty, it can't -- guarantee the current context org will match the org at which the penalty --- was applied. search up the org tree until we hit the configured penalty depth SELECT INTO tmp_org * FROM actor.org_unit WHERE id = context_org; SELECT INTO tmp_depth depth FROM actor.org_unit_type WHERE id = tmp_org.ou_type; WHILE tmp_depth >= tmp_penalty.org_depth LOOP RETURN QUERY SELECT * FROM actor.usr_standing_penalty WHERE usr = match_user AND org_unit = tmp_org.id AND (stop_date IS NULL or stop_date > NOW()) AND standing_penalty = 30; IF tmp_org.parent_ou IS NULL THEN EXIT; END IF; SELECT * INTO tmp_org FROM actor.org_unit WHERE id = tmp_org.parent_ou; SELECT INTO tmp_depth depth FROM actor.org_unit_type WHERE id = tmp_org.ou_type; END LOOP; ELSE -- no penalty depth is defined, look for exact matches RETURN QUERY SELECT * FROM actor.usr_standing_penalty WHERE usr = match_user AND org_unit = max_fines.org_unit AND (stop_date IS NULL or stop_date > NOW()) AND standing_penalty = 30; END IF; END IF; END IF; RETURN; END; $func$ LANGUAGE plpgsql; COMMIT;