[open-ils-commits] r17172 - branches/rel_1_6/Open-ILS/src/sql/Pg (dbs)
svn at svn.open-ils.org
svn at svn.open-ils.org
Wed Aug 11 13:13:30 EDT 2010
Author: dbs
Date: 2010-08-11 13:13:26 -0400 (Wed, 11 Aug 2010)
New Revision: 17172
Modified:
branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.1.1-1.6.1.2-upgrade-db.sql
Log:
Add schema upgrades for r16982, r16996, r17009, r17159 to 1.6.1.2
Modified: branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.1.1-1.6.1.2-upgrade-db.sql
===================================================================
--- branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.1.1-1.6.1.2-upgrade-db.sql 2010-08-11 15:57:14 UTC (rev 17171)
+++ branches/rel_1_6/Open-ILS/src/sql/Pg/1.6.1.1-1.6.1.2-upgrade-db.sql 2010-08-11 17:13:26 UTC (rev 17172)
@@ -171,5 +171,433 @@
LEFT JOIN metabib.full_rec issn ON (r.id = issn.record AND issn.tag = '022' AND issn.subfield = 'a')
GROUP BY 1,2,3,4,5,6;
+CREATE OR REPLACE FUNCTION asset.merge_record_assets( target_record BIGINT, source_record BIGINT ) RETURNS INT AS $func$
+DECLARE
+ moved_objects INT := 0;
+ source_cn asset.call_number%ROWTYPE;
+ target_cn asset.call_number%ROWTYPE;
+ metarec metabib.metarecord%ROWTYPE;
+ hold action.hold_request%ROWTYPE;
+ ser_rec serial.record_entry%ROWTYPE;
+ uri_count INT := 0;
+ counter INT := 0;
+ uri_datafield TEXT;
+ uri_text TEXT := '';
+BEGIN
+ -- move any 856 entries on records that have at least one MARC-mapped URI entry
+ SELECT INTO uri_count COUNT(*)
+ FROM asset.uri_call_number_map m
+ JOIN asset.call_number cn ON (m.call_number = cn.id)
+ WHERE cn.record = source_record;
+
+ IF uri_count > 0 THEN
+
+ SELECT COUNT(*) INTO counter
+ FROM xpath_table(
+ 'id',
+ 'marc',
+ 'biblio.record_entry',
+ '//*[@tag="856"]',
+ 'id=' || source_record
+ ) as t(i int,c text);
+
+ FOR i IN 1 .. counter LOOP
+ SELECT '<datafield xmlns="http://www.loc.gov/MARC21/slim"' ||
+ ' tag="856"' ||
+ ' ind1="' || FIRST(ind1) || '"' ||
+ ' ind2="' || FIRST(ind2) || '">' ||
+ array_to_string(
+ array_accum(
+ '<subfield code="' || subfield || '">' ||
+ regexp_replace(
+ regexp_replace(
+ regexp_replace(data,'&','&','g'),
+ '>', '>', 'g'
+ ),
+ '<', '<', 'g'
+ ) || '</subfield>'
+ ), ''
+ ) || '</datafield>' INTO uri_datafield
+ FROM xpath_table(
+ 'id',
+ 'marc',
+ 'biblio.record_entry',
+ '//*[@tag="856"][position()=' || i || ']/@ind1|' ||
+ '//*[@tag="856"][position()=' || i || ']/@ind2|' ||
+ '//*[@tag="856"][position()=' || i || ']/*/@code|' ||
+ '//*[@tag="856"][position()=' || i || ']/*[@code]',
+ 'id=' || source_record
+ ) as t(id int,ind1 text, ind2 text,subfield text,data text);
+
+ uri_text := uri_text || uri_datafield;
+ END LOOP;
+
+ IF uri_text <> '' THEN
+ UPDATE biblio.record_entry
+ SET marc = regexp_replace(marc,'(</[^>]*record>)', uri_text || E'\\1')
+ WHERE id = target_record;
+ END IF;
+
+ END IF;
+
+ -- Find and move metarecords to the target record
+ SELECT INTO metarec *
+ FROM metabib.metarecord
+ WHERE master_record = source_record;
+
+ IF FOUND THEN
+ UPDATE metabib.metarecord
+ SET master_record = target_record,
+ mods = NULL
+ WHERE id = metarec.id;
+
+ moved_objects := moved_objects + 1;
+ END IF;
+
+ -- Find call numbers attached to the source ...
+ FOR source_cn IN SELECT * FROM asset.call_number WHERE record = source_record LOOP
+
+ SELECT INTO target_cn *
+ FROM asset.call_number
+ WHERE label = source_cn.label
+ AND owning_lib = source_cn.owning_lib
+ AND record = target_record;
+
+ -- ... and if there's a conflicting one on the target ...
+ IF FOUND THEN
+
+ -- ... move the copies to that, and ...
+ UPDATE asset.copy
+ SET call_number = target_cn.id
+ WHERE call_number = source_cn.id;
+
+ -- ... move V holds to the move-target call number
+ FOR hold IN SELECT * FROM action.hold_request WHERE target = source_cn.id AND hold_type = 'V' LOOP
+
+ UPDATE action.hold_request
+ SET target = target_cn.id
+ WHERE id = hold.id;
+
+ moved_objects := moved_objects + 1;
+ END LOOP;
+
+ -- ... if not ...
+ ELSE
+ -- ... just move the call number to the target record
+ UPDATE asset.call_number
+ SET record = target_record
+ WHERE id = source_cn.id;
+ END IF;
+
+ moved_objects := moved_objects + 1;
+ END LOOP;
+
+ -- Find T holds targeting the source record ...
+ FOR hold IN SELECT * FROM action.hold_request WHERE target = source_record AND hold_type = 'T' LOOP
+
+ -- ... and move them to the target record
+ UPDATE action.hold_request
+ SET target = target_record
+ WHERE id = hold.id;
+
+ moved_objects := moved_objects + 1;
+ END LOOP;
+
+ -- Find serial records targeting the source record ...
+ FOR ser_rec IN SELECT * FROM serial.record_entry WHERE record = source_record LOOP
+ -- ... and move them to the target record
+ UPDATE serial.record_entry
+ SET record = target_record
+ WHERE id = ser_rec.id;
+
+ moved_objects := moved_objects + 1;
+ END LOOP;
+
+ -- Finally, "delete" the source record
+ DELETE FROM biblio.record_entry WHERE id = source_record;
+
+ -- That's all, folks!
+ RETURN moved_objects;
+END;
+$func$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION action.find_hold_matrix_matchpoint( pickup_ou INT, request_ou INT, match_item BIGINT, match_user INT, match_requestor INT ) RETURNS INT AS $func$
+DECLARE
+ current_requestor_group permission.grp_tree%ROWTYPE;
+ root_ou actor.org_unit%ROWTYPE;
+ requestor_object actor.usr%ROWTYPE;
+ user_object actor.usr%ROWTYPE;
+ item_object asset.copy%ROWTYPE;
+ item_cn_object asset.call_number%ROWTYPE;
+ rec_descriptor metabib.rec_descriptor%ROWTYPE;
+ current_mp_weight FLOAT;
+ matchpoint_weight FLOAT;
+ tmp_weight FLOAT;
+ current_mp config.hold_matrix_matchpoint%ROWTYPE;
+ matchpoint config.hold_matrix_matchpoint%ROWTYPE;
+BEGIN
+ SELECT INTO root_ou * FROM actor.org_unit WHERE parent_ou IS NULL;
+ SELECT INTO user_object * FROM actor.usr WHERE id = match_user;
+ SELECT INTO requestor_object * FROM actor.usr WHERE id = match_requestor;
+ SELECT INTO item_object * FROM asset.copy WHERE id = match_item;
+ SELECT INTO item_cn_object * FROM asset.call_number WHERE id = item_object.call_number;
+ SELECT INTO rec_descriptor r.* FROM metabib.rec_descriptor r WHERE r.record = item_cn_object.record;
+ SELECT INTO current_requestor_group * FROM permission.grp_tree WHERE id = requestor_object.profile;
+
+ LOOP
+ -- for each potential matchpoint for this ou and group ...
+ FOR current_mp IN
+ SELECT m.*
+ FROM config.hold_matrix_matchpoint m
+ WHERE m.requestor_grp = current_requestor_group.id AND m.active
+ ORDER BY CASE WHEN m.circ_modifier IS NOT NULL THEN 16 ELSE 0 END +
+ CASE WHEN m.juvenile_flag IS NOT NULL THEN 16 ELSE 0 END +
+ CASE WHEN m.marc_type IS NOT NULL THEN 8 ELSE 0 END +
+ CASE WHEN m.marc_form IS NOT NULL THEN 4 ELSE 0 END +
+ CASE WHEN m.marc_vr_format IS NOT NULL THEN 2 ELSE 0 END +
+ CASE WHEN m.ref_flag IS NOT NULL THEN 1 ELSE 0 END DESC LOOP
+
+ current_mp_weight := 5.0;
+
+ IF current_mp.circ_modifier IS NOT NULL THEN
+ CONTINUE WHEN current_mp.circ_modifier <> item_object.circ_modifier OR item_object.circ_modifier IS NULL;
+ END IF;
+
+ IF current_mp.marc_type IS NOT NULL THEN
+ IF item_object.circ_as_type IS NOT NULL THEN
+ CONTINUE WHEN current_mp.marc_type <> item_object.circ_as_type;
+ ELSE
+ CONTINUE WHEN current_mp.marc_type <> rec_descriptor.item_type;
+ END IF;
+ END IF;
+
+ IF current_mp.marc_form IS NOT NULL THEN
+ CONTINUE WHEN current_mp.marc_form <> rec_descriptor.item_form;
+ END IF;
+
+ IF current_mp.marc_vr_format IS NOT NULL THEN
+ CONTINUE WHEN current_mp.marc_vr_format <> rec_descriptor.vr_format;
+ END IF;
+
+ IF current_mp.juvenile_flag IS NOT NULL THEN
+ CONTINUE WHEN current_mp.juvenile_flag <> user_object.juvenile;
+ END IF;
+
+ IF current_mp.ref_flag IS NOT NULL THEN
+ CONTINUE WHEN current_mp.ref_flag <> item_object.ref;
+ END IF;
+
+
+ -- caclulate the rule match weight
+ IF current_mp.item_owning_ou IS NOT NULL AND current_mp.item_owning_ou <> root_ou.id THEN
+ SELECT INTO tmp_weight 1.0 / (actor.org_unit_proximity(current_mp.item_owning_ou, item_cn_object.owning_lib)::FLOAT + 1.0)::FLOAT;
+ current_mp_weight := current_mp_weight - tmp_weight;
+ END IF;
+
+ IF current_mp.item_circ_ou IS NOT NULL AND current_mp.item_circ_ou <> root_ou.id THEN
+ SELECT INTO tmp_weight 1.0 / (actor.org_unit_proximity(current_mp.item_circ_ou, item_object.circ_lib)::FLOAT + 1.0)::FLOAT;
+ current_mp_weight := current_mp_weight - tmp_weight;
+ END IF;
+
+ IF current_mp.pickup_ou IS NOT NULL AND current_mp.pickup_ou <> root_ou.id THEN
+ SELECT INTO tmp_weight 1.0 / (actor.org_unit_proximity(current_mp.pickup_ou, pickup_ou)::FLOAT + 1.0)::FLOAT;
+ current_mp_weight := current_mp_weight - tmp_weight;
+ END IF;
+
+ IF current_mp.request_ou IS NOT NULL AND current_mp.request_ou <> root_ou.id THEN
+ SELECT INTO tmp_weight 1.0 / (actor.org_unit_proximity(current_mp.request_ou, request_ou)::FLOAT + 1.0)::FLOAT;
+ current_mp_weight := current_mp_weight - tmp_weight;
+ END IF;
+
+ IF current_mp.user_home_ou IS NOT NULL AND current_mp.user_home_ou <> root_ou.id THEN
+ SELECT INTO tmp_weight 1.0 / (actor.org_unit_proximity(current_mp.user_home_ou, user_object.home_ou)::FLOAT + 1.0)::FLOAT;
+ current_mp_weight := current_mp_weight - tmp_weight;
+ END IF;
+
+ -- set the matchpoint if we found the best one
+ IF matchpoint_weight IS NULL OR matchpoint_weight > current_mp_weight THEN
+ matchpoint = current_mp;
+ matchpoint_weight = current_mp_weight;
+ END IF;
+
+ END LOOP;
+
+ EXIT WHEN current_requestor_group.parent IS NULL OR matchpoint.id IS NOT NULL;
+
+ SELECT INTO current_requestor_group * FROM permission.grp_tree WHERE id = current_requestor_group.parent;
+ END LOOP;
+
+ RETURN matchpoint.id;
+END;
+$func$ LANGUAGE plpgsql;
+
+
+CREATE OR REPLACE FUNCTION action.hold_request_permit_test( pickup_ou INT, request_ou INT, match_item BIGINT, match_user INT, match_requestor INT ) RETURNS SETOF action.matrix_test_result AS $func$
+DECLARE
+ matchpoint_id INT;
+ user_object actor.usr%ROWTYPE;
+ age_protect_object config.rule_age_hold_protect%ROWTYPE;
+ standing_penalty config.standing_penalty%ROWTYPE;
+ transit_range_ou_type actor.org_unit_type%ROWTYPE;
+ transit_source actor.org_unit%ROWTYPE;
+ item_object asset.copy%ROWTYPE;
+ result action.matrix_test_result;
+ hold_test config.hold_matrix_matchpoint%ROWTYPE;
+ hold_count INT;
+ hold_transit_prox INT;
+ frozen_hold_count INT;
+ context_org_list INT[];
+ done BOOL := FALSE;
+BEGIN
+ SELECT INTO user_object * FROM actor.usr WHERE id = match_user;
+ SELECT INTO context_org_list ARRAY_ACCUM(id) FROM actor.org_unit_full_path( pickup_ou );
+
+ result.success := TRUE;
+
+ -- Fail if we couldn't find a user
+ IF user_object.id IS NULL THEN
+ result.fail_part := 'no_user';
+ result.success := FALSE;
+ done := TRUE;
+ RETURN NEXT result;
+ RETURN;
+ END IF;
+
+ SELECT INTO item_object * FROM asset.copy WHERE id = match_item;
+
+ -- Fail if we couldn't find a copy
+ 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 matchpoint_id action.find_hold_matrix_matchpoint(pickup_ou, request_ou, match_item, match_user, match_requestor);
+ result.matchpoint := matchpoint_id;
+
+ -- Fail if user is barred
+ IF user_object.barred IS TRUE THEN
+ result.fail_part := 'actor.usr.barred';
+ result.success := FALSE;
+ done := TRUE;
+ RETURN NEXT result;
+ RETURN;
+ END IF;
+
+ -- Fail if we couldn't find any matchpoint (requires a default)
+ IF matchpoint_id IS NULL THEN
+ result.fail_part := 'no_matchpoint';
+ result.success := FALSE;
+ done := TRUE;
+ RETURN NEXT result;
+ RETURN;
+ END IF;
+
+ SELECT INTO hold_test * FROM config.hold_matrix_matchpoint WHERE id = matchpoint_id;
+
+ IF hold_test.holdable IS FALSE THEN
+ result.fail_part := 'config.hold_matrix_test.holdable';
+ result.success := FALSE;
+ done := TRUE;
+ RETURN NEXT result;
+ END IF;
+
+ IF hold_test.transit_range IS NOT NULL THEN
+ SELECT INTO transit_range_ou_type * FROM actor.org_unit_type WHERE id = hold_test.transit_range;
+ IF hold_test.distance_is_from_owner THEN
+ SELECT INTO transit_source ou.* FROM actor.org_unit ou JOIN asset.call_number cn ON (cn.owning_lib = ou.id) WHERE cn.id = item_object.call_number;
+ ELSE
+ SELECT INTO transit_source * FROM actor.org_unit WHERE id = item_object.circ_lib;
+ END IF;
+
+ PERFORM * FROM actor.org_unit_descendants( transit_source.id, transit_range_ou_type.depth ) WHERE id = pickup_ou;
+
+ IF NOT FOUND THEN
+ result.fail_part := 'transit_range';
+ result.success := FALSE;
+ done := TRUE;
+ RETURN NEXT result;
+ END IF;
+ 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 explode_array(context_org_list) )
+ AND (usp.stop_date IS NULL or usp.stop_date > NOW())
+ AND csp.block_list LIKE '%HOLD%' LOOP
+
+ result.fail_part := standing_penalty.name;
+ result.success := FALSE;
+ done := TRUE;
+ RETURN NEXT result;
+ END LOOP;
+
+ IF hold_test.stop_blocked_user IS TRUE THEN
+ 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 explode_array(context_org_list) )
+ AND (usp.stop_date IS NULL or usp.stop_date > NOW())
+ AND csp.block_list LIKE '%CIRC%' LOOP
+
+ result.fail_part := standing_penalty.name;
+ result.success := FALSE;
+ done := TRUE;
+ RETURN NEXT result;
+ END LOOP;
+ END IF;
+
+ IF hold_test.max_holds IS NOT NULL THEN
+ SELECT INTO hold_count COUNT(*)
+ FROM action.hold_request
+ WHERE usr = match_user
+ AND fulfillment_time IS NULL
+ AND cancel_time IS NULL
+ AND CASE WHEN hold_test.include_frozen_holds THEN TRUE ELSE frozen IS FALSE END;
+
+ IF hold_count >= hold_test.max_holds THEN
+ result.fail_part := 'config.hold_matrix_test.max_holds';
+ result.success := FALSE;
+ done := TRUE;
+ RETURN NEXT result;
+ END IF;
+ END IF;
+
+ IF item_object.age_protect IS NOT NULL THEN
+ SELECT INTO age_protect_object * FROM config.rule_age_hold_protect WHERE id = item_object.age_protect;
+
+ IF item_object.create_date + age_protect_object.age > NOW() THEN
+ IF hold_test.distance_is_from_owner THEN
+ SELECT INTO hold_transit_prox prox FROM actor.org_unit_proximity WHERE from_org = item_cn_object.owning_lib AND to_org = pickup_ou;
+ ELSE
+ SELECT INTO hold_transit_prox prox FROM actor.org_unit_proximity WHERE from_org = item_object.circ_lib AND to_org = pickup_ou;
+ END IF;
+
+ IF hold_transit_prox > age_protect_object.prox THEN
+ result.fail_part := 'config.rule_age_hold_protect.prox';
+ result.success := FALSE;
+ done := TRUE;
+ RETURN NEXT result;
+ END IF;
+ END IF;
+ END IF;
+
+ IF NOT done THEN
+ RETURN NEXT result;
+ END IF;
+
+ RETURN;
+END;
+$func$ LANGUAGE plpgsql;
+
COMMIT;
+
+CREATE INDEX atev_target_def_idx ON action_trigger.event (target,event_def);
More information about the open-ils-commits
mailing list