Skip to content
GitLab
Explore
Sign in
Primary navigation
Search or go to…
Project
V
vospace-file-catalog
Manage
Activity
Members
Labels
Plan
Issues
Issue boards
Milestones
Wiki
Code
Merge requests
Repository
Branches
Commits
Tags
Repository graph
Compare revisions
Snippets
Build
Pipelines
Jobs
Pipeline schedules
Artifacts
Deploy
Releases
Package registry
Container registry
Model registry
Operate
Environments
Terraform modules
Monitor
Incidents
Analyze
Value stream analytics
Contributor analytics
CI/CD analytics
Repository analytics
Model experiments
Help
Help
Support
GitLab documentation
Compare GitLab plans
Community forum
Contribute to GitLab
Provide feedback
Keyboard shortcuts
?
Snippets
Groups
Projects
Show more breadcrumbs
VOSpace INAF
vospace-file-catalog
Commits
9878c1bc
Commit
9878c1bc
authored
3 years ago
by
Sonia Zorba
Browse files
Options
Downloads
Patches
Plain Diff
Added id_from_vos_path() function. Performs much better than joining node_vos_path view
parent
e5264ede
No related branches found
No related tags found
No related merge requests found
Pipeline
#1931
passed
3 years ago
Stage: dockerize
Changes
1
Pipelines
1
Hide whitespace changes
Inline
Side-by-side
Showing
1 changed file
03-other-functions.sql
+17
-0
17 additions, 0 deletions
03-other-functions.sql
with
17 additions
and
0 deletions
03-other-functions.sql
+
17
−
0
View file @
9878c1bc
...
...
@@ -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
;
This diff is collapsed.
Click to expand it.
Preview
0%
Loading
Try again
or
attach a new file
.
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Save comment
Cancel
Please
register
or
sign in
to comment