diff --git a/03-other-functions.sql b/03-other-functions.sql
index 2cc0048774715baec806bdeb5b9c15f11e1a1823..5d46df315c5212f2dff02e0b58af4c0d6e3d9a14 100644
--- a/03-other-functions.sql
+++ b/03-other-functions.sql
@@ -17,3 +17,20 @@ SELECT array_agg(elements) FROM (
 $func$ LANGUAGE sql;
 
 SELECT update_array('{"group1","group2"}'::VARCHAR[],'{"group2","group3"}'::VARCHAR[],'{"group1"}'::VARCHAR[]) = '{"group2","group3"}' AS test_passed;
+
+-- Returns node_id of a given vos_path. Setting cost to 1 tells the planner to always execute this function before other clauses (100 is the default function cost).
+
+CREATE OR REPLACE FUNCTION id_from_vos_path(vos_path_input VARCHAR) RETURNS BIGINT IMMUTABLE COST 1 AS
+$func$
+WITH RECURSIVE r_vos_path AS (
+    SELECT node_id, path, 1 AS level, STRING_TO_ARRAY(vos_path_input, '/') AS parts, (CASE WHEN vos_path_input = '/' THEN '/' ELSE '' END) AS vos_path
+    FROM node
+    WHERE name = ''
+  UNION ALL
+    SELECT n.node_id, n.path, p.level + 1, p.parts, p.vos_path || '/' || p.parts[p.level + 1]
+    FROM node n
+    JOIN r_vos_path p ON p.path = n.parent_path
+    WHERE n.name = p.parts[p.level + 1]
+)
+SELECT node_id FROM r_vos_path WHERE vos_path = vos_path_input
+$func$ LANGUAGE sql;