Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Submit feedback
Contribute to GitLab
Sign in
Toggle navigation
haskell-gargantext
Project
Project
Details
Activity
Releases
Cycle Analytics
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Charts
Issues
153
Issues
153
List
Board
Labels
Milestones
Merge Requests
9
Merge Requests
9
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Charts
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Charts
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
gargantext
haskell-gargantext
Commits
058222ef
Commit
058222ef
authored
Jun 14, 2023
by
Alexandre Delanoë
Browse files
Options
Browse Files
Download
Email Patches
Plain Diff
[FIX] SQL
parent
1af015a5
Changes
2
Hide whitespace changes
Inline
Side-by-side
Showing
2 changed files
with
131 additions
and
0 deletions
+131
-0
0.0.6.9.9.6.3._check.sql
devops/postgres/upgrade/0.0.6.9.9.6.3._check.sql
+23
-0
0.0.6.9.9.6.3.sql
devops/postgres/upgrade/0.0.6.9.9.6.3.sql
+108
-0
No files found.
devops/postgres/upgrade/0.0.6.9.9.6.3._check.sql
0 → 100644
View file @
058222ef
with
child_ngrams
as
(
select
jsonb_array_elements_text
(
ngrams_repo_element
->
'children'
)
as
term
from
node_stories
),
parent_ngrams
as
(
select
ngrams_repo_element
->>
'root'
as
term
from
node_stories
)
(
select
child_ngrams
.
term
,
ngrams
.
terms
from
child_ngrams
left
join
ngrams
on
child_ngrams
.
term
=
ngrams
.
terms
where
ngrams
.
terms
is
null
union
select
parent_ngrams
.
term
,
ngrams
.
terms
from
parent_ngrams
left
join
ngrams
on
parent_ngrams
.
term
=
ngrams
.
terms
where
ngrams
.
terms
is
null
and
parent_ngrams
.
term
is
not
null
)
order
by
term
;
devops/postgres/upgrade/0.0.6.9.9.6.3.sql
0 → 100644
View file @
058222ef
-- Remove unused old materialized view
drop
materialized
view
context_node_ngrams_view
;
-- FIX NGRAMS Parents
with
query
as
(
with
child_ngrams
as
(
select
jsonb_array_elements_text
(
ngrams_repo_element
->
'children'
)
as
term
from
node_stories
),
parent_ngrams
as
(
select
ngrams_repo_element
->>
'root'
as
term
from
node_stories
)
(
select
child_ngrams
.
term
,
ngrams
.
terms
from
child_ngrams
left
join
ngrams
on
child_ngrams
.
term
=
ngrams
.
terms
where
ngrams
.
terms
is
null
union
select
parent_ngrams
.
term
,
ngrams
.
terms
from
parent_ngrams
left
join
ngrams
on
parent_ngrams
.
term
=
ngrams
.
terms
where
ngrams
.
terms
is
null
and
parent_ngrams
.
term
is
not
null
)
order
by
term
)
INSERT
INTO
ngrams
(
terms
)
select
term
from
query
;
-- ADD triggers
CREATE
OR
REPLACE
FUNCTION
check_node_stories_json
()
RETURNS
TRIGGER
AS
$$
DECLARE
missing_ngrams_exist
boolean
;
BEGIN
WITH
child_ngrams
as
(
SELECT
jsonb_array_elements_text
(
NEW
.
ngrams_repo_element
->
'children'
)
AS
term
),
parent_ngrams
AS
(
SELECT
NEW
.
ngrams_repo_element
->>
'root'
AS
term
),
ngrams_child_parent
AS
(
SELECT
child_ngrams
.
term
,
ngrams
.
terms
FROM
child_ngrams
LEFT
JOIN
ngrams
ON
child_ngrams
.
term
=
ngrams
.
terms
WHERE
ngrams
.
terms
IS
NULL
UNION
SELECT
parent_ngrams
.
term
,
ngrams
.
terms
FROM
parent_ngrams
LEFT
JOIN
ngrams
ON
parent_ngrams
.
term
=
ngrams
.
terms
WHERE
ngrams
.
terms
IS
NULL
AND
parent_ngrams
.
term
IS
NOT
NULL
)
SELECT
EXISTS
(
SELECT
*
FROM
ngrams_child_parent
)
INTO
missing_ngrams_exist
;
IF
missing_ngrams_exist
THEN
RAISE
EXCEPTION
'node_stories: ngrams are missing: %'
,
row_to_json
(
NEW
);
END
IF
;
RETURN
NEW
;
END
;
$$
LANGUAGE
plpgsql
;
CREATE
OR
REPLACE
TRIGGER
check_node_stories_json_trg
AFTER
INSERT
OR
UPDATE
ON
node_stories
FOR
EACH
ROW
EXECUTE
PROCEDURE
check_node_stories_json
();
CREATE
OR
REPLACE
FUNCTION
check_ngrams_json
()
RETURNS
TRIGGER
AS
$$
DECLARE
missing_ngrams_exist
boolean
;
BEGIN
WITH
child_ngrams
as
(
SELECT
jsonb_array_elements_text
(
ngrams_repo_element
->
'children'
)
AS
term
FROM
node_stories
WHERE
term
=
OLD
.
terms
),
parent_ngrams
AS
(
SELECT
ngrams_repo_element
->>
'root'
AS
term
FROM
node_stories
WHERE
term
=
OLD
.
terms
),
child_parent_ngrams
AS
(
SELECT
*
FROM
child_ngrams
UNION
SELECT
*
FROM
parent_ngrams
)
SELECT
EXISTS
(
SELECT
*
FROM
child_parent_ngrams
)
INTO
missing_ngrams_exist
;
IF
missing_ngrams_exist
THEN
RAISE
EXCEPTION
'ngrams are missing: %'
,
row_to_json
(
OLD
);
END
IF
;
RETURN
OLD
;
END
;
$$
LANGUAGE
plpgsql
;
CREATE
OR
REPLACE
TRIGGER
check_ngrams_json_trg
AFTER
DELETE
ON
ngrams
FOR
EACH
ROW
EXECUTE
PROCEDURE
check_ngrams_json
();
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment