From: Mike Rylander Date: Wed, 24 Aug 2016 15:58:56 +0000 (-0400) Subject: Stamping upgrade script for ranked-volumes update X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=51759b283ca19b15a252faa830c2e4b4a3199695;p=evergreen%2Fmasslnc.git Stamping upgrade script for ranked-volumes update Signed-off-by: Mike Rylander --- diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index 976361cf6f..6b4b998611 100644 --- a/Open-ILS/src/sql/Pg/002.schema.config.sql +++ b/Open-ILS/src/sql/Pg/002.schema.config.sql @@ -91,7 +91,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 ('0990', :eg_version); -- miker/kmlussier +INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0991', :eg_version); -- dbwells/miker CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/upgrade/0991.function.unapi.ranked_volumes.sql b/Open-ILS/src/sql/Pg/upgrade/0991.function.unapi.ranked_volumes.sql new file mode 100644 index 0000000000..fad90979d7 --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/0991.function.unapi.ranked_volumes.sql @@ -0,0 +1,98 @@ +BEGIN; + +SELECT evergreen.upgrade_deps_block_check('0991', :eg_version); + +CREATE OR REPLACE FUNCTION evergreen.ranked_volumes( + bibid BIGINT[], + ouid INT, + depth INT DEFAULT NULL, + slimit HSTORE DEFAULT NULL, + soffset HSTORE DEFAULT NULL, + pref_lib INT DEFAULT NULL, + includes TEXT[] DEFAULT NULL::TEXT[] +) RETURNS TABLE(id BIGINT, name TEXT, label_sortkey TEXT, rank BIGINT) AS $$ + WITH RECURSIVE ou_depth AS ( + SELECT COALESCE( + $3, + ( + SELECT depth + FROM actor.org_unit_type aout + INNER JOIN actor.org_unit ou ON ou_type = aout.id + WHERE ou.id = $2 + ) + ) AS depth + ), descendant_depth AS ( + SELECT ou.id, + ou.parent_ou, + out.depth + FROM actor.org_unit ou + JOIN actor.org_unit_type out ON (out.id = ou.ou_type) + JOIN anscestor_depth ad ON (ad.id = ou.id), + ou_depth + WHERE ad.depth = ou_depth.depth + UNION ALL + SELECT ou.id, + ou.parent_ou, + out.depth + FROM actor.org_unit ou + JOIN actor.org_unit_type out ON (out.id = ou.ou_type) + JOIN descendant_depth ot ON (ot.id = ou.parent_ou) + ), anscestor_depth AS ( + SELECT ou.id, + ou.parent_ou, + out.depth + FROM actor.org_unit ou + JOIN actor.org_unit_type out ON (out.id = ou.ou_type) + WHERE ou.id = $2 + UNION ALL + SELECT ou.id, + ou.parent_ou, + out.depth + FROM actor.org_unit ou + JOIN actor.org_unit_type out ON (out.id = ou.ou_type) + JOIN anscestor_depth ot ON (ot.parent_ou = ou.id) + ), descendants as ( + SELECT ou.* FROM actor.org_unit ou JOIN descendant_depth USING (id) + ) + + SELECT ua.id, ua.name, ua.label_sortkey, MIN(ua.rank) AS rank FROM ( + SELECT acn.id, owning_lib.name, acn.label_sortkey, + evergreen.rank_cp(acp), + RANK() OVER w + FROM asset.call_number acn + JOIN asset.copy acp ON (acn.id = acp.call_number) + JOIN descendants AS aou ON (acp.circ_lib = aou.id) + JOIN actor.org_unit AS owning_lib ON (acn.owning_lib = owning_lib.id) + WHERE acn.record = ANY ($1) + AND acn.deleted IS FALSE + AND acp.deleted IS FALSE + AND CASE WHEN ('exclude_invisible_acn' = ANY($7)) THEN + EXISTS ( + SELECT 1 + FROM asset.opac_visible_copies + WHERE copy_id = acp.id AND record = acn.record + ) ELSE TRUE END + GROUP BY acn.id, evergreen.rank_cp(acp), owning_lib.name, acn.label_sortkey, aou.id + WINDOW w AS ( + ORDER BY + COALESCE( + CASE WHEN aou.id = $2 THEN -20000 END, + CASE WHEN aou.id = $6 THEN -10000 END, + (SELECT distance - 5000 + FROM actor.org_unit_descendants_distance($6) as x + WHERE x.id = aou.id AND $6 IN ( + SELECT q.id FROM actor.org_unit_descendants($2) as q)), + (SELECT e.distance FROM actor.org_unit_descendants_distance($2) as e WHERE e.id = aou.id), + 1000 + ), + evergreen.rank_cp(acp) + ) + ) AS ua + GROUP BY ua.id, ua.name, ua.label_sortkey + ORDER BY rank, ua.name, ua.label_sortkey + LIMIT ($4 -> 'acn')::INT + OFFSET ($5 -> 'acn')::INT; +$$ LANGUAGE SQL STABLE ROWS 10; + +COMMIT; + diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.function.unapi.ranked_volumes.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.function.unapi.ranked_volumes.sql deleted file mode 100644 index 223224aab1..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/XXXX.function.unapi.ranked_volumes.sql +++ /dev/null @@ -1,98 +0,0 @@ -BEGIN; - ---SELECT evergreen.upgrade_deps_block_check('XXXX', :eg_version); - -CREATE OR REPLACE FUNCTION evergreen.ranked_volumes( - bibid BIGINT[], - ouid INT, - depth INT DEFAULT NULL, - slimit HSTORE DEFAULT NULL, - soffset HSTORE DEFAULT NULL, - pref_lib INT DEFAULT NULL, - includes TEXT[] DEFAULT NULL::TEXT[] -) RETURNS TABLE(id BIGINT, name TEXT, label_sortkey TEXT, rank BIGINT) AS $$ - WITH RECURSIVE ou_depth AS ( - SELECT COALESCE( - $3, - ( - SELECT depth - FROM actor.org_unit_type aout - INNER JOIN actor.org_unit ou ON ou_type = aout.id - WHERE ou.id = $2 - ) - ) AS depth - ), descendant_depth AS ( - SELECT ou.id, - ou.parent_ou, - out.depth - FROM actor.org_unit ou - JOIN actor.org_unit_type out ON (out.id = ou.ou_type) - JOIN anscestor_depth ad ON (ad.id = ou.id), - ou_depth - WHERE ad.depth = ou_depth.depth - UNION ALL - SELECT ou.id, - ou.parent_ou, - out.depth - FROM actor.org_unit ou - JOIN actor.org_unit_type out ON (out.id = ou.ou_type) - JOIN descendant_depth ot ON (ot.id = ou.parent_ou) - ), anscestor_depth AS ( - SELECT ou.id, - ou.parent_ou, - out.depth - FROM actor.org_unit ou - JOIN actor.org_unit_type out ON (out.id = ou.ou_type) - WHERE ou.id = $2 - UNION ALL - SELECT ou.id, - ou.parent_ou, - out.depth - FROM actor.org_unit ou - JOIN actor.org_unit_type out ON (out.id = ou.ou_type) - JOIN anscestor_depth ot ON (ot.parent_ou = ou.id) - ), descendants as ( - SELECT ou.* FROM actor.org_unit ou JOIN descendant_depth USING (id) - ) - - SELECT ua.id, ua.name, ua.label_sortkey, MIN(ua.rank) AS rank FROM ( - SELECT acn.id, owning_lib.name, acn.label_sortkey, - evergreen.rank_cp(acp), - RANK() OVER w - FROM asset.call_number acn - JOIN asset.copy acp ON (acn.id = acp.call_number) - JOIN descendants AS aou ON (acp.circ_lib = aou.id) - JOIN actor.org_unit AS owning_lib ON (acn.owning_lib = owning_lib.id) - WHERE acn.record = ANY ($1) - AND acn.deleted IS FALSE - AND acp.deleted IS FALSE - AND CASE WHEN ('exclude_invisible_acn' = ANY($7)) THEN - EXISTS ( - SELECT 1 - FROM asset.opac_visible_copies - WHERE copy_id = acp.id AND record = acn.record - ) ELSE TRUE END - GROUP BY acn.id, evergreen.rank_cp(acp), owning_lib.name, acn.label_sortkey, aou.id - WINDOW w AS ( - ORDER BY - COALESCE( - CASE WHEN aou.id = $2 THEN -20000 END, - CASE WHEN aou.id = $6 THEN -10000 END, - (SELECT distance - 5000 - FROM actor.org_unit_descendants_distance($6) as x - WHERE x.id = aou.id AND $6 IN ( - SELECT q.id FROM actor.org_unit_descendants($2) as q)), - (SELECT e.distance FROM actor.org_unit_descendants_distance($2) as e WHERE e.id = aou.id), - 1000 - ), - evergreen.rank_cp(acp) - ) - ) AS ua - GROUP BY ua.id, ua.name, ua.label_sortkey - ORDER BY rank, ua.name, ua.label_sortkey - LIMIT ($4 -> 'acn')::INT - OFFSET ($5 -> 'acn')::INT; -$$ LANGUAGE SQL STABLE ROWS 10; - -COMMIT; -