From: Kathy Lussier Date: Wed, 15 Aug 2018 22:10:08 +0000 (-0400) Subject: LP#1775216: Stamping upgrade script for inconsistent copy counts X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=d967aac09b076d5782047357b5dfcad4b7f1fe9a;p=Evergreen.git LP#1775216: Stamping upgrade script for inconsistent copy counts Signed-off-by: Kathy Lussier --- diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index 728d937a19..e420874cf4 100644 --- a/Open-ILS/src/sql/Pg/002.schema.config.sql +++ b/Open-ILS/src/sql/Pg/002.schema.config.sql @@ -92,7 +92,7 @@ CREATE TRIGGER no_overlapping_deps BEFORE INSERT OR UPDATE ON config.db_patch_dependencies FOR EACH ROW EXECUTE PROCEDURE evergreen.array_overlap_check ('deprecates'); -INSERT INTO config.upgrade_log (version, applied_to) VALUES ('1118', :eg_version); -- gmcharlt/berick +INSERT INTO config.upgrade_log (version, applied_to) VALUES ('1119', :eg_version); -- idjit/kmlussier CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/upgrade/1112.schema.lp1775216_consistent_avail_counts.sql b/Open-ILS/src/sql/Pg/upgrade/1112.schema.lp1775216_consistent_avail_counts.sql deleted file mode 100644 index 2b069f3bc3..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/1112.schema.lp1775216_consistent_avail_counts.sql +++ /dev/null @@ -1,88 +0,0 @@ -CREATE OR REPLACE FUNCTION asset.staff_ou_record_copy_count(org integer, rid bigint) - RETURNS TABLE(depth integer, org_unit integer, visible bigint, available bigint, unshadow bigint, transcendant integer) - LANGUAGE plpgsql -AS $function$ -DECLARE - ans RECORD; - trans INT; -BEGIN - SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; - - FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP - RETURN QUERY - WITH available_statuses AS (SELECT ARRAY_AGG(id) AS ids FROM config.copy_status WHERE is_available), - cp AS( - SELECT cp.id, - (cp.status = ANY (available_statuses.ids))::INT as available, - (cl.opac_visible AND cp.opac_visible)::INT as opac_visible - FROM - available_statuses, - actor.org_unit_descendants(ans.id) d - JOIN asset.copy cp ON (cp.circ_lib = d.id AND NOT cp.deleted) - JOIN asset.copy_location cl ON (cp.location = cl.id AND NOT cl.deleted) - JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number AND NOT cn.deleted) - ), - peer AS ( - SELECT cp.id, - (cp.status = ANY (available_statuses.ids))::INT as available, - (cl.opac_visible AND cp.opac_visible)::INT as opac_visible - FROM - available_statuses, - actor.org_unit_descendants(ans.id) d - JOIN asset.copy cp ON (cp.circ_lib = d.id AND NOT cp.deleted) - JOIN asset.copy_location cl ON (cp.location = cl.id AND NOT cl.deleted) - JOIN biblio.peer_bib_copy_map bp ON (bp.peer_record = rid AND bp.target_copy = cp.id) - ) - SELECT ans.depth, ans.id, count(id), sum(x.available::int), sum(x.opac_visible::int), trans - FROM ((select * from cp) union (select * from peer)) x - GROUP BY 1,2,6; - - IF NOT FOUND THEN - RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; - END IF; - - END LOOP; - RETURN; -END; -$function$; - -CREATE OR REPLACE FUNCTION asset.opac_ou_record_copy_count(org integer, rid bigint) - RETURNS TABLE(depth integer, org_unit integer, visible bigint, available bigint, unshadow bigint, transcendant integer) - LANGUAGE plpgsql -AS $function$ -DECLARE - ans RECORD; - trans INT; -BEGIN - SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; - - FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP - RETURN QUERY - WITH org_list AS (SELECT ARRAY_AGG(id)::BIGINT[] AS orgs FROM actor.org_unit_descendants(ans.id) x), - available_statuses AS (SELECT ARRAY_AGG(id) AS ids FROM config.copy_status WHERE is_available), - mask AS (SELECT c_attrs FROM asset.patron_default_visibility_mask() x) - SELECT ans.depth, - ans.id, - COUNT( av.id ), - SUM( (cp.status = ANY (available_statuses.ids))::INT ), - COUNT( av.id ), - trans - FROM mask, - available_statuses, - org_list, - asset.copy_vis_attr_cache av - JOIN asset.copy cp ON (cp.id = av.target_copy AND av.record = rid) - JOIN asset.call_number cn ON (cp.call_number = cn.id AND not cn.deleted) - WHERE cp.circ_lib = ANY (org_list.orgs) AND av.vis_attr_vector @@ mask.c_attrs::query_int - GROUP BY 1,2,6; - - IF NOT FOUND THEN - RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; - END IF; - - END LOOP; - - RETURN; -END; -$function$; - diff --git a/Open-ILS/src/sql/Pg/upgrade/1119.schema.lp1775216_consistent_avail_counts.sql b/Open-ILS/src/sql/Pg/upgrade/1119.schema.lp1775216_consistent_avail_counts.sql new file mode 100644 index 0000000000..66252ebefc --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/1119.schema.lp1775216_consistent_avail_counts.sql @@ -0,0 +1,90 @@ +SELECT evergreen.upgrade_deps_block_check('1119', :eg_version); + +CREATE OR REPLACE FUNCTION asset.staff_ou_record_copy_count(org integer, rid bigint) + RETURNS TABLE(depth integer, org_unit integer, visible bigint, available bigint, unshadow bigint, transcendant integer) + LANGUAGE plpgsql +AS $function$ +DECLARE + ans RECORD; + trans INT; +BEGIN + SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; + + FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP + RETURN QUERY + WITH available_statuses AS (SELECT ARRAY_AGG(id) AS ids FROM config.copy_status WHERE is_available), + cp AS( + SELECT cp.id, + (cp.status = ANY (available_statuses.ids))::INT as available, + (cl.opac_visible AND cp.opac_visible)::INT as opac_visible + FROM + available_statuses, + actor.org_unit_descendants(ans.id) d + JOIN asset.copy cp ON (cp.circ_lib = d.id AND NOT cp.deleted) + JOIN asset.copy_location cl ON (cp.location = cl.id AND NOT cl.deleted) + JOIN asset.call_number cn ON (cn.record = rid AND cn.id = cp.call_number AND NOT cn.deleted) + ), + peer AS ( + SELECT cp.id, + (cp.status = ANY (available_statuses.ids))::INT as available, + (cl.opac_visible AND cp.opac_visible)::INT as opac_visible + FROM + available_statuses, + actor.org_unit_descendants(ans.id) d + JOIN asset.copy cp ON (cp.circ_lib = d.id AND NOT cp.deleted) + JOIN asset.copy_location cl ON (cp.location = cl.id AND NOT cl.deleted) + JOIN biblio.peer_bib_copy_map bp ON (bp.peer_record = rid AND bp.target_copy = cp.id) + ) + SELECT ans.depth, ans.id, count(id), sum(x.available::int), sum(x.opac_visible::int), trans + FROM ((select * from cp) union (select * from peer)) x + GROUP BY 1,2,6; + + IF NOT FOUND THEN + RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; + END IF; + + END LOOP; + RETURN; +END; +$function$; + +CREATE OR REPLACE FUNCTION asset.opac_ou_record_copy_count(org integer, rid bigint) + RETURNS TABLE(depth integer, org_unit integer, visible bigint, available bigint, unshadow bigint, transcendant integer) + LANGUAGE plpgsql +AS $function$ +DECLARE + ans RECORD; + trans INT; +BEGIN + SELECT 1 INTO trans FROM biblio.record_entry b JOIN config.bib_source src ON (b.source = src.id) WHERE src.transcendant AND b.id = rid; + + FOR ans IN SELECT u.id, t.depth FROM actor.org_unit_ancestors(org) AS u JOIN actor.org_unit_type t ON (u.ou_type = t.id) LOOP + RETURN QUERY + WITH org_list AS (SELECT ARRAY_AGG(id)::BIGINT[] AS orgs FROM actor.org_unit_descendants(ans.id) x), + available_statuses AS (SELECT ARRAY_AGG(id) AS ids FROM config.copy_status WHERE is_available), + mask AS (SELECT c_attrs FROM asset.patron_default_visibility_mask() x) + SELECT ans.depth, + ans.id, + COUNT( av.id ), + SUM( (cp.status = ANY (available_statuses.ids))::INT ), + COUNT( av.id ), + trans + FROM mask, + available_statuses, + org_list, + asset.copy_vis_attr_cache av + JOIN asset.copy cp ON (cp.id = av.target_copy AND av.record = rid) + JOIN asset.call_number cn ON (cp.call_number = cn.id AND not cn.deleted) + WHERE cp.circ_lib = ANY (org_list.orgs) AND av.vis_attr_vector @@ mask.c_attrs::query_int + GROUP BY 1,2,6; + + IF NOT FOUND THEN + RETURN QUERY SELECT ans.depth, ans.id, 0::BIGINT, 0::BIGINT, 0::BIGINT, trans; + END IF; + + END LOOP; + + RETURN; +END; +$function$; +