Commit 713da4c2 authored by Alexandre Delanoë's avatar Alexandre Delanoë

Merge remote-tracking branch 'origin/199-dev-materialized-view-refresh-issue' into dev-merge

parents b7e406b1 cc1ff624
...@@ -79,7 +79,7 @@ main = do ...@@ -79,7 +79,7 @@ main = do
refreshIndex :: Cmd'' DevEnv IOException () refreshIndex :: Cmd'' DevEnv IOException ()
refreshIndex = do refreshIndex = do
_ <- execPGSQuery [sql| refresh materialized view context_node_ngrams_view; |] () _ <- execPGSQuery [sql| REFRESH MATERIALIZED VIEW CONCURRENTLY context_node_ngrams_view; |] ()
pure () pure ()
addIndex :: Cmd'' DevEnv IOException Int64 addIndex :: Cmd'' DevEnv IOException Int64
...@@ -87,17 +87,24 @@ addIndex = do ...@@ -87,17 +87,24 @@ addIndex = do
execPGSQuery query () execPGSQuery query ()
where where
query = [sql| query = [sql|
create materialized view if not exists context_node_ngrams_view as CREATE MATERIALIZED VIEW IF NOT EXISTS context_node_ngrams_view AS
select context_node_ngrams.context_id, ngrams_id, nodes_contexts.node_id SELECT DISTINCT context_node_ngrams.context_id, ngrams_id, nodes_contexts.node_id
from nodes_contexts FROM nodes_contexts
join context_node_ngrams JOIN context_node_ngrams
on context_node_ngrams.context_id = nodes_contexts.context_id; ON context_node_ngrams.context_id = nodes_contexts.context_id;
create index if not exists context_node_ngrams_context_id_ngrams_id_idx on context_node_ngrams(context_id, ngrams_id); CREATE INDEX IF NOT EXISTS context_node_ngrams_context_id_ngrams_id_idx
create index if not exists context_node_ngrams_view_context_id_idx on context_node_ngrams_view(context_id); ON context_node_ngrams(context_id, ngrams_id);
create index if not exists context_node_ngrams_view_ngrams_id_idx on context_node_ngrams_view(ngrams_id);
create index if not exists context_node_ngrams_view_node_id_idx on context_node_ngrams_view(node_id); CREATE INDEX IF NOT EXISTS context_node_ngrams_view_context_id_idx
create index if not exists node_stories_ngrams_id_idx on node_stories(ngrams_id); ON context_node_ngrams_view(context_id);
CREATE INDEX IF NOT EXISTS context_node_ngrams_view_ngrams_id_idx
ON context_node_ngrams_view(ngrams_id);
CREATE INDEX IF NOT EXISTS context_node_ngrams_view_node_id_idx
ON context_node_ngrams_view(node_id);
CREATE UNIQUE INDEX IF NOT EXISTS context_node_ngrams_view_context_ngrams_node_uniq_idx
ON context_node_ngrams_view (context_id, ngrams_id, node_id);
CREATE INDEX IF NOT EXISTS node_stories_ngrams_id_idx
ON node_stories(ngrams_id);
|] |]
...@@ -337,14 +337,23 @@ CREATE OR REPLACE function node_pos(int, int) returns bigint ...@@ -337,14 +337,23 @@ CREATE OR REPLACE function node_pos(int, int) returns bigint
--create index node_by_pos on nodes using btree(node_pos(id,typename)); --create index node_by_pos on nodes using btree(node_pos(id,typename));
-- Optimization for Ngrams Table View -- Optimization for Ngrams Table View
create materialized view if not exists context_node_ngrams_view as CREATE MATERIALIZED VIEW IF NOT EXISTS context_node_ngrams_view AS
select context_node_ngrams.context_id, ngrams_id, nodes_contexts.node_id SELECT DISTINCT context_node_ngrams.context_id, ngrams_id, nodes_contexts.node_id
from nodes_contexts FROM nodes_contexts
join context_node_ngrams JOIN context_node_ngrams
on context_node_ngrams.context_id = nodes_contexts.context_id; ON context_node_ngrams.context_id = nodes_contexts.context_id;
create index if not exists context_node_ngrams_context_id_ngrams_id_idx on context_node_ngrams(context_id, ngrams_id); CREATE INDEX IF NOT EXISTS context_node_ngrams_context_id_ngrams_id_idx
create index if not exists context_node_ngrams_view_context_id_idx on context_node_ngrams_view(context_id); ON context_node_ngrams(context_id, ngrams_id);
create index if not exists context_node_ngrams_view_ngrams_id_idx on context_node_ngrams_view(ngrams_id);
create index if not exists context_node_ngrams_view_node_id_idx on context_node_ngrams_view(node_id); CREATE INDEX IF NOT EXISTS context_node_ngrams_view_context_id_idx
create index if not exists node_stories_ngrams_id_idx on node_stories(ngrams_id); ON context_node_ngrams_view(context_id);
CREATE INDEX IF NOT EXISTS context_node_ngrams_view_ngrams_id_idx
ON context_node_ngrams_view(ngrams_id);
CREATE INDEX IF NOT EXISTS context_node_ngrams_view_node_id_idx
ON context_node_ngrams_view(node_id);
CREATE UNIQUE INDEX IF NOT EXISTS context_node_ngrams_view_context_ngrams_node_uniq_idx
ON context_node_ngrams_view (context_id, ngrams_id, node_id);
CREATE INDEX IF NOT EXISTS node_stories_ngrams_id_idx
ON node_stories(ngrams_id);
...@@ -129,24 +129,53 @@ getOccByNgramsOnlyFast cId lId nt = do ...@@ -129,24 +129,53 @@ getOccByNgramsOnlyFast cId lId nt = do
query :: DPS.Query query :: DPS.Query
query = [sql| query = [sql|
WITH node_context_ids AS WITH cnnv AS
(select context_id, ngrams_id ( SELECT DISTINCT context_node_ngrams.context_id,
FROM context_node_ngrams_view context_node_ngrams.ngrams_id,
nodes_contexts.node_id
FROM nodes_contexts
JOIN context_node_ngrams ON context_node_ngrams.context_id = nodes_contexts.context_id
),
node_context_ids AS
(SELECT context_id, ngrams_id, terms
FROM cnnv
JOIN ngrams ON cnnv.ngrams_id = ngrams.id
WHERE node_id = ? WHERE node_id = ?
), ns AS ),
(select ngrams_id FROM node_stories ncids_agg AS
WHERE node_id = ? AND ngrams_type_id = ? (SELECT ngrams_id, terms, array_agg(DISTINCT context_id) AS agg
) FROM node_context_ids
GROUP BY (ngrams_id, terms)),
SELECT ng.terms, ns AS
ARRAY ( SELECT DISTINCT context_id (SELECT ngrams_id, terms
FROM node_context_ids FROM node_stories
WHERE ns.ngrams_id = node_context_ids.ngrams_id JOIN ngrams ON ngrams_id = ngrams.id
) WHERE node_id = ? AND ngrams_type_id = ?
AS context_ids )
FROM ngrams ng
JOIN ns ON ng.id = ns.ngrams_id SELECT ns.terms, CASE WHEN agg IS NULL THEN '{}' ELSE agg END
FROM ns
LEFT JOIN ncids_agg ON ns.ngrams_id = ncids_agg.ngrams_id
|] |]
-- query = [sql|
-- WITH node_context_ids AS
-- (select context_id, ngrams_id
-- FROM context_node_ngrams_view
-- WHERE node_id = ?
-- ), ns AS
-- (select ngrams_id FROM node_stories
-- WHERE node_id = ? AND ngrams_type_id = ?
-- )
-- SELECT ng.terms,
-- ARRAY ( SELECT DISTINCT context_id
-- FROM node_context_ids
-- WHERE ns.ngrams_id = node_context_ids.ngrams_id
-- )
-- AS context_ids
-- FROM ngrams ng
-- JOIN ns ON ng.id = ns.ngrams_id
-- |]
selectNgramsOccurrencesOnlyByContextUser_withSample :: HasDBid NodeType selectNgramsOccurrencesOnlyByContextUser_withSample :: HasDBid NodeType
...@@ -403,6 +432,5 @@ refreshNgramsMaterialized :: Cmd err () ...@@ -403,6 +432,5 @@ refreshNgramsMaterialized :: Cmd err ()
refreshNgramsMaterialized = void $ execPGSQuery refreshNgramsMaterializedQuery () refreshNgramsMaterialized = void $ execPGSQuery refreshNgramsMaterializedQuery ()
where where
refreshNgramsMaterializedQuery :: DPS.Query refreshNgramsMaterializedQuery :: DPS.Query
refreshNgramsMaterializedQuery = [sql| refresh materialized view context_node_ngrams_view; |] refreshNgramsMaterializedQuery =
[sql| REFRESH MATERIALIZED VIEW CONCURRENTLY context_node_ngrams_view; |]
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment