diff --git a/02-views.sql b/02-views.sql index b42ade78d5916b8f7792569e0bb3cfe4092289fc..0979a25941bc2bd5cea1552b6fd3890dc1d814ea 100644 --- a/02-views.sql +++ b/02-views.sql @@ -7,34 +7,21 @@ -- View that maps node_id to os_path (relative path of file on disk) CREATE VIEW node_os_path AS -SELECT node_id, '/' AS os_path FROM node WHERE path = '' -UNION -SELECT node_id, '/' || string_agg(name, '/') AS os_path -FROM ( - SELECT (CASE WHEN os_name IS NOT NULL THEN os_name ELSE name END) AS name, p.node_id - FROM node n - JOIN ( - SELECT UNNEST(string_to_array(relative_path::varchar, '.')) AS rel_id, node_id - FROM node - ) AS p ON n.node_id::varchar = p.rel_id - ORDER BY p.node_id, nlevel(n.path) -) AS j GROUP BY node_id; +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; -- View that maps node_id to vos_path (path in VOSpace) CREATE VIEW node_vos_path AS -SELECT node_id, '/' AS vos_path FROM node WHERE path = '' -UNION -SELECT node_id, '/' || string_agg(name, '/') AS os_path -FROM ( - SELECT name, p.node_id - FROM node n - JOIN ( - SELECT UNNEST(string_to_array(path::varchar, '.')) AS rel_id, node_id - FROM node - ) AS p ON n.node_id::varchar = p.rel_id - ORDER BY p.node_id, nlevel(n.path) -) AS j GROUP BY node_id; +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; -- View that combines the two previous views to obtain the os_path from the vos_path and vice versa