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
611eaa8b
"docker/example-compose-ingestion.yaml" did not exist on "41640b0d30b4af38f2651d3a6fb1621841033674"
Commit
611eaa8b
authored
4 years ago
by
Sonia Zorba
Browse files
Options
Downloads
Patches
Plain Diff
Improved view performance
parent
74fd0219
No related branches found
No related tags found
No related merge requests found
Pipeline
#1919
passed
4 years ago
Stage: dockerize
Changes
1
Pipelines
1
Show whitespace changes
Inline
Side-by-side
Showing
1 changed file
02-views.sql
+11
-24
11 additions, 24 deletions
02-views.sql
with
11 additions
and
24 deletions
02-views.sql
+
11
−
24
View file @
611eaa8b
...
...
@@ -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
SELECT
n
.
node_id
,
'/'
||
STRING_AGG
(
j
.
name
,
'/'
ORDER
BY
t
.
ord
)
AS
os_path
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
;
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
SELECT
n
.
node_id
,
COALESCE
(
NULLIF
(
STRING_AGG
(
j
.
name
,
'/'
ORDER
BY
t
.
ord
),
''
),
'/'
)
AS
vos_path
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
;
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
...
...
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