From 271a0d925bf0fddf6a9bc9ad3f2692cb60400f93 Mon Sep 17 00:00:00 2001 From: Moshe Immermam Date: Wed, 19 Jun 2024 18:49:45 +0300 Subject: [PATCH] fix: order relationships by depth --- views/006_config_views.sql | 114 ++++++++++++++++++------------------- 1 file changed, 57 insertions(+), 57 deletions(-) diff --git a/views/006_config_views.sql b/views/006_config_views.sql index e4b76c08..2a4529ed 100644 --- a/views/006_config_views.sql +++ b/views/006_config_views.sql @@ -403,17 +403,17 @@ CREATE OR REPLACE FUNCTION related_config_ids_recursive ( max_depth INT DEFAULT 5, incoming_relation TEXT DEFAULT 'both', -- hard or both (hard & soft) outgoing_relation TEXT DEFAULT 'both' -- hard or both (hard & soft) -) RETURNS TABLE (id UUID, direction TEXT) AS $$ +) RETURNS TABLE (id UUID, direction TEXT, depth INT) AS $$ BEGIN RETURN query WITH edges as ( SELECT * FROM config_relationships_recursive(config_id, type_filter, max_depth, incoming_relation, outgoing_relation) ), all_ids AS ( - SELECT edges.id, edges.direction FROM edges - UNION - SELECT edges.related_id as id, edges.direction FROM edges - ) SELECT DISTINCT all_ids.id, all_ids.direction FROM all_ids; + SELECT edges.id, edges.direction, edges.depth FROM edges + UNION + SELECT edges.related_id as id, edges.direction, edges.depth FROM edges + ) SELECT DISTINCT all_ids.id, all_ids.direction,all_ids.depth FROM all_ids ORDER BY all_ids.depth; END; $$ LANGUAGE plpgsql; @@ -427,60 +427,60 @@ CREATE OR REPLACE FUNCTION config_relationships_recursive ( incoming_relation TEXT DEFAULT 'both', -- hard or both (hard & soft) outgoing_relation TEXT DEFAULT 'both' -- hard or both (hard & soft) ) RETURNS TABLE (id UUID, related_id UUID, relation_type TEXT, direction TEXT, depth INT) AS $$ -BEGIN + BEGIN + + IF type_filter NOT IN ('incoming', 'outgoing', 'all') THEN + RAISE EXCEPTION 'Invalid type_filter value. Allowed values are: ''incoming'', ''outgoing'', ''all'''; + END IF; -IF type_filter NOT IN ('incoming', 'outgoing', 'all') THEN - RAISE EXCEPTION 'Invalid type_filter value. Allowed values are: ''incoming'', ''outgoing'', ''all'''; -END IF; - -IF type_filter = 'outgoing' THEN - RETURN query - WITH RECURSIVE cte (config_id, related_id, relation, direction, depth) AS ( - SELECT parent.config_id, parent.related_id, parent.relation, 'outgoing', 1::int - FROM config_relationships parent - WHERE parent.config_id = config_relationships_recursive.config_id - AND (outgoing_relation = 'both' OR (outgoing_relation = 'hard' AND parent.relation = 'hard')) - AND deleted_at IS NULL - UNION ALL - SELECT - parent.related_id as config_id, child.related_id, child.relation, 'outgoing', parent.depth +1 - FROM config_relationships child, cte parent - WHERE child.config_id = parent.related_id - AND parent.depth <= max_depth - AND (outgoing_relation = 'both' OR (outgoing_relation = 'hard' AND child.relation = 'hard')) + IF type_filter = 'outgoing' THEN + RETURN query + WITH RECURSIVE cte (config_id, related_id, relation, direction, depth) AS ( + SELECT parent.config_id, parent.related_id, parent.relation, 'outgoing', 1::int + FROM config_relationships parent + WHERE parent.config_id = config_relationships_recursive.config_id + AND (outgoing_relation = 'both' OR (outgoing_relation = 'hard' AND parent.relation = 'hard')) AND deleted_at IS NULL - ) CYCLE config_id SET is_cycle USING path - SELECT DISTINCT cte.config_id, cte.related_id, cte.relation as "relation_type", type_filter as "direction", cte.depth - FROM cte - ORDER BY cte.depth asc; -ELSIF type_filter = 'incoming' THEN - RETURN query - WITH RECURSIVE cte (config_id, related_id, relation, direction, depth) AS ( - SELECT parent.config_id, parent.related_id as related_id, parent.relation, 'incoming', 1::int - FROM config_relationships parent - WHERE parent.related_id = config_relationships_recursive.config_id - AND (incoming_relation = 'both' OR (incoming_relation = 'hard' AND parent.relation = 'hard')) - AND deleted_at IS NULL - UNION ALL - SELECT - child.config_id, child.related_id as related_id, child.relation, 'incoming', parent.depth +1 - FROM config_relationships child, cte parent - WHERE child.related_id = parent.config_id - AND parent.depth <= max_depth - AND (incoming_relation = 'both' OR (incoming_relation = 'hard' AND child.relation = 'hard')) + UNION ALL + SELECT + parent.related_id as config_id, child.related_id, child.relation, 'outgoing', parent.depth +1 + FROM config_relationships child, cte parent + WHERE child.config_id = parent.related_id + AND parent.depth <= max_depth + AND (outgoing_relation = 'both' OR (outgoing_relation = 'hard' AND child.relation = 'hard')) + AND deleted_at IS NULL + ) CYCLE config_id SET is_cycle USING path + SELECT DISTINCT cte.config_id, cte.related_id, cte.relation as "relation_type", type_filter as "direction", cte.depth + FROM cte + ORDER BY cte.depth asc; + ELSIF type_filter = 'incoming' THEN + RETURN query + WITH RECURSIVE cte (config_id, related_id, relation, direction, depth) AS ( + SELECT parent.config_id, parent.related_id as related_id, parent.relation, 'incoming', 1::int + FROM config_relationships parent + WHERE parent.related_id = config_relationships_recursive.config_id + AND (incoming_relation = 'both' OR (incoming_relation = 'hard' AND parent.relation = 'hard')) AND deleted_at IS NULL - ) CYCLE config_id SET is_cycle USING path - SELECT DISTINCT cte.config_id, cte.related_id, cte.relation AS "relation_type", type_filter as "direction", cte.depth - FROM cte - ORDER BY cte.depth asc; -ELSE - RETURN query - SELECT * FROM config_relationships_recursive(config_id, 'incoming', max_depth, incoming_relation, outgoing_relation) - UNION - SELECT * FROM config_relationships_recursive(config_id, 'outgoing', max_depth, incoming_relation, outgoing_relation); -END IF; + UNION ALL + SELECT + child.config_id, child.related_id as related_id, child.relation, 'incoming', parent.depth +1 + FROM config_relationships child, cte parent + WHERE child.related_id = parent.config_id + AND parent.depth <= max_depth + AND (incoming_relation = 'both' OR (incoming_relation = 'hard' AND child.relation = 'hard')) + AND deleted_at IS NULL + ) CYCLE config_id SET is_cycle USING path + SELECT DISTINCT cte.config_id, cte.related_id, cte.relation AS "relation_type", type_filter as "direction", cte.depth + FROM cte + ORDER BY cte.depth asc; + ELSE + RETURN query + SELECT * FROM config_relationships_recursive(config_id, 'incoming', max_depth, incoming_relation, outgoing_relation) + UNION + SELECT * FROM config_relationships_recursive(config_id, 'outgoing', max_depth, incoming_relation, outgoing_relation); + END IF; -END; + END; $$ LANGUAGE plpgsql; -- related configs recursively @@ -524,7 +524,7 @@ BEGIN LEFT JOIN edges ON edges.id = all_ids.id GROUP BY all_ids.id ) - SELECT + SELECT configs.id, configs.name, configs.type, @@ -542,7 +542,7 @@ BEGIN configs.health, configs.ready, configs.status - FROM configs + FROM configs LEFT JOIN grouped_related_ids ON configs.id = grouped_related_ids.id WHERE configs.id IN (SELECT DISTINCT all_ids.id FROM all_ids); END;