From: Ben Shum Date: Wed, 4 May 2016 16:59:01 +0000 (-0400) Subject: LP#1568046: Stamping upgrade script for changes to permission.grp_ancestors X-Git-Url: https://old-git.evergreen-ils.org/?a=commitdiff_plain;h=463f5358841f1ec668290ad598dc0e83b9e8fc90;p=evergreen%2Fmasslnc.git LP#1568046: Stamping upgrade script for changes to permission.grp_ancestors Signed-off-by: Ben Shum --- diff --git a/Open-ILS/src/sql/Pg/002.schema.config.sql b/Open-ILS/src/sql/Pg/002.schema.config.sql index fc8f13ee63..cad3b82e56 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 ('0978', :eg_version); -- gmcharlt/miker +INSERT INTO config.upgrade_log (version, applied_to) VALUES ('0979', :eg_version); -- miker/dyrcona/bshum CREATE TABLE config.bib_source ( id SERIAL PRIMARY KEY, diff --git a/Open-ILS/src/sql/Pg/upgrade/0979.function.grp-tree-functions-via-cte.sql b/Open-ILS/src/sql/Pg/upgrade/0979.function.grp-tree-functions-via-cte.sql new file mode 100644 index 0000000000..82263bbcfa --- /dev/null +++ b/Open-ILS/src/sql/Pg/upgrade/0979.function.grp-tree-functions-via-cte.sql @@ -0,0 +1,62 @@ +BEGIN; + +SELECT evergreen.upgrade_deps_block_check('0979', :eg_version); + +-- Replace connectby from the tablefunc extension with CTEs + + +CREATE OR REPLACE FUNCTION permission.grp_ancestors( INT ) RETURNS SETOF permission.grp_tree AS $$ + WITH RECURSIVE grp_ancestors_distance(id, distance) AS ( + SELECT $1, 0 + UNION + SELECT ou.parent, ouad.distance+1 + FROM permission.grp_tree ou JOIN grp_ancestors_distance ouad ON (ou.id = ouad.id) + WHERE ou.parent IS NOT NULL + ) + SELECT ou.* FROM permission.grp_tree ou JOIN grp_ancestors_distance ouad USING (id) ORDER BY ouad.distance DESC; +$$ LANGUAGE SQL ROWS 1; + +-- Add a utility function to find descendant groups. + +CREATE OR REPLACE FUNCTION permission.grp_descendants( INT ) RETURNS SETOF permission.grp_tree AS $$ + WITH RECURSIVE descendant_depth AS ( + SELECT gr.id, + gr.parent + FROM permission.grp_tree gr + WHERE gr.id = $1 + UNION ALL + SELECT gr.id, + gr.parent + FROM permission.grp_tree gr + JOIN descendant_depth dd ON (dd.id = gr.parent) + ) SELECT gr.* FROM permission.grp_tree gr JOIN descendant_depth USING (id); +$$ LANGUAGE SQL ROWS 1; + +-- Add utility functions to work with permission groups as general tree-ish sets. + +CREATE OR REPLACE FUNCTION permission.grp_tree_full_path ( INT ) RETURNS SETOF permission.grp_tree AS $$ + SELECT * + FROM permission.grp_ancestors($1) + UNION + SELECT * + FROM permission.grp_descendants($1); +$$ LANGUAGE SQL STABLE ROWS 1; + +CREATE OR REPLACE FUNCTION permission.grp_tree_combined_ancestors ( INT, INT ) RETURNS SETOF permission.grp_tree AS $$ + SELECT * + FROM permission.grp_ancestors($1) + UNION + SELECT * + FROM permission.grp_ancestors($2); +$$ LANGUAGE SQL STABLE ROWS 1; + +CREATE OR REPLACE FUNCTION permission.grp_tree_common_ancestors ( INT, INT ) RETURNS SETOF permission.grp_tree AS $$ + SELECT * + FROM permission.grp_ancestors($1) + INTERSECT + SELECT * + FROM permission.grp_ancestors($2); +$$ LANGUAGE SQL STABLE ROWS 1; + +COMMIT; + diff --git a/Open-ILS/src/sql/Pg/upgrade/XXXX.function.grp-tree-functions-via-cte.sql b/Open-ILS/src/sql/Pg/upgrade/XXXX.function.grp-tree-functions-via-cte.sql deleted file mode 100644 index 28dc0611ab..0000000000 --- a/Open-ILS/src/sql/Pg/upgrade/XXXX.function.grp-tree-functions-via-cte.sql +++ /dev/null @@ -1,60 +0,0 @@ -BEGIN; - --- Replace connectby from the tablefunc extension with CTEs - - -CREATE OR REPLACE FUNCTION permission.grp_ancestors( INT ) RETURNS SETOF permission.grp_tree AS $$ - WITH RECURSIVE grp_ancestors_distance(id, distance) AS ( - SELECT $1, 0 - UNION - SELECT ou.parent, ouad.distance+1 - FROM permission.grp_tree ou JOIN grp_ancestors_distance ouad ON (ou.id = ouad.id) - WHERE ou.parent IS NOT NULL - ) - SELECT ou.* FROM permission.grp_tree ou JOIN grp_ancestors_distance ouad USING (id) ORDER BY ouad.distance DESC; -$$ LANGUAGE SQL ROWS 1; - --- Add a utility function to find descendant groups. - -CREATE OR REPLACE FUNCTION permission.grp_descendants( INT ) RETURNS SETOF permission.grp_tree AS $$ - WITH RECURSIVE descendant_depth AS ( - SELECT gr.id, - gr.parent - FROM permission.grp_tree gr - WHERE gr.id = $1 - UNION ALL - SELECT gr.id, - gr.parent - FROM permission.grp_tree gr - JOIN descendant_depth dd ON (dd.id = gr.parent) - ) SELECT gr.* FROM permission.grp_tree gr JOIN descendant_depth USING (id); -$$ LANGUAGE SQL ROWS 1; - --- Add utility functions to work with permission groups as general tree-ish sets. - -CREATE OR REPLACE FUNCTION permission.grp_tree_full_path ( INT ) RETURNS SETOF permission.grp_tree AS $$ - SELECT * - FROM permission.grp_ancestors($1) - UNION - SELECT * - FROM permission.grp_descendants($1); -$$ LANGUAGE SQL STABLE ROWS 1; - -CREATE OR REPLACE FUNCTION permission.grp_tree_combined_ancestors ( INT, INT ) RETURNS SETOF permission.grp_tree AS $$ - SELECT * - FROM permission.grp_ancestors($1) - UNION - SELECT * - FROM permission.grp_ancestors($2); -$$ LANGUAGE SQL STABLE ROWS 1; - -CREATE OR REPLACE FUNCTION permission.grp_tree_common_ancestors ( INT, INT ) RETURNS SETOF permission.grp_tree AS $$ - SELECT * - FROM permission.grp_ancestors($1) - INTERSECT - SELECT * - FROM permission.grp_ancestors($2); -$$ LANGUAGE SQL STABLE ROWS 1; - -COMMIT; -