From 25a4241a0816cd2484672bc955f2a46156c2a408 Mon Sep 17 00:00:00 2001 From: Sonia Zorba <sonia.zorba@inaf.it> Date: Fri, 4 Jun 2021 12:37:45 +0200 Subject: [PATCH] Used only recursive queries to map ltree paths to vos paths and added custom functions (performs better) --- 02-views.sql | 34 ++++++++++++++++++++++------------ 03-other-functions.sql | 35 +++++++++++++++++++++++++++++++++++ 2 files changed, 57 insertions(+), 12 deletions(-) diff --git a/02-views.sql b/02-views.sql index 0979a25..a368d3e 100644 --- a/02-views.sql +++ b/02-views.sql @@ -6,22 +6,32 @@ -- View that maps node_id to os_path (relative path of file on disk) -CREATE VIEW node_os_path AS -SELECT n.node_id, '/' || STRING_AGG(j.name, '/' ORDER BY t.ord) AS os_path -FROM node n -JOIN REGEXP_SPLIT_TO_TABLE((CASE WHEN relative_path = '' THEN '1' ELSE '1.' || path::text END), '[.]') WITH ORDINALITY t(node_id, ord) ON true -JOIN node j ON j.node_id = t.node_id::int -WHERE j.relative_path IS NOT NULL AND j.relative_path <> '' -GROUP BY n.node_id; +CREATE VIEW node_os_path AS +WITH RECURSIVE r_os_path AS ( + SELECT node_id, relative_path, COALESCE(os_name, name) AS os_path + FROM node + WHERE name = '' + UNION ALL + SELECT n.node_id, n.relative_path, p.os_path || '/' || COALESCE(os_name, name) + FROM node n + JOIN r_os_path p ON p.relative_path = n.parent_relative_path + WHERE n.parent_relative_path IS NOT NULL +) +SELECT node_id, (CASE WHEN os_path = '' THEN '/' ELSE os_path END) AS os_path FROM r_os_path; -- View that maps node_id to vos_path (path in VOSpace) CREATE VIEW node_vos_path AS -SELECT n.node_id, COALESCE(NULLIF(STRING_AGG(j.name, '/' ORDER BY t.ord), ''), '/') AS vos_path -FROM node n -JOIN REGEXP_SPLIT_TO_TABLE((CASE WHEN path = '' THEN '1' ELSE '1.' || path::text END), '[.]') WITH ORDINALITY t(node_id, ord) ON true -JOIN node j ON j.node_id = t.node_id::int -GROUP BY n.node_id; +WITH RECURSIVE r_vos_path AS ( + SELECT node_id, path, name AS vos_path + FROM node + WHERE name = '' + UNION ALL + SELECT n.node_id, n.path, p.vos_path || '/' || name + FROM node n + JOIN r_vos_path p ON p.path = n.parent_path +) +SELECT node_id, (CASE WHEN path = '' THEN '/' ELSE vos_path END) AS vos_path FROM r_vos_path; -- View that combines the two previous views to obtain the os_path from the vos_path and vice versa diff --git a/03-other-functions.sql b/03-other-functions.sql index 5d46df3..42b9105 100644 --- a/03-other-functions.sql +++ b/03-other-functions.sql @@ -34,3 +34,38 @@ WITH RECURSIVE r_vos_path AS ( ) SELECT node_id FROM r_vos_path WHERE vos_path = vos_path_input $func$ LANGUAGE sql; + +-- Returns vos_path from node_id + +CREATE OR REPLACE FUNCTION get_vos_path(input_id BIGINT) RETURNS VARCHAR AS +$func$ +SELECT string_agg(name, '/') FROM ( + WITH RECURSIVE paths AS ( + SELECT node_id, name, path, parent_path, 1 AS level + FROM node + WHERE node_id = input_id + UNION ALL + SELECT f.node_id, f.name, f.path, f.parent_path, p.level + 1 + FROM node f + INNER JOIN paths p ON p.parent_path = f.path + ) SELECT name FROM paths ORDER BY LEVEL DESC +) AS names +$func$ LANGUAGE sql; + +-- Returns os_path from node_id + +CREATE OR REPLACE FUNCTION get_os_path(input_id BIGINT) RETURNS VARCHAR AS +$func$ +SELECT '/' || string_agg(name, '/') FROM ( + WITH RECURSIVE paths AS ( + SELECT node_id, COALESCE(os_name, name) AS name, relative_path, parent_relative_path, 1 AS level + FROM node + WHERE node_id = input_id + UNION ALL + SELECT f.node_id, COALESCE(f.os_name, f.name) AS name, f.relative_path, f.parent_relative_path, p.level + 1 + FROM node f + INNER JOIN paths p ON p.parent_relative_path = f.relative_path + WHERE f.parent_relative_path IS NOT NULL + ) SELECT name FROM paths ORDER BY LEVEL DESC +) AS names +$func$ LANGUAGE sql; -- GitLab