[db] fixes for context_node_ngrams_view materialized view

Unique index is necessary when one wants to refresh the view
concurrently.
parent 494b3e64
Pipeline #4124 passed with stages
in 71 minutes and 42 seconds
......@@ -79,7 +79,7 @@ main = do
refreshIndex :: Cmd'' DevEnv IOException ()
refreshIndex = do
_ <- execPGSQuery [sql| REFRESH MATERIALIZED VIEW context_node_ngrams_view; |] ()
_ <- execPGSQuery [sql| REFRESH MATERIALIZED VIEW CONCURRENTLY context_node_ngrams_view; |] ()
pure ()
addIndex :: Cmd'' DevEnv IOException Int64
......@@ -87,15 +87,24 @@ addIndex = do
execPGSQuery query ()
where
query = [sql|
create materialized view if not exists context_node_ngrams_view as
select context_node_ngrams.context_id, ngrams_id, nodes_contexts.node_id
from nodes_contexts
join context_node_ngrams
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_view_context_id_idx 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 index if not exists node_stories_ngrams_id_idx on node_stories(ngrams_id);
CREATE MATERIALIZED VIEW IF NOT EXISTS context_node_ngrams_view AS
SELECT DISTINCT context_node_ngrams.context_id, ngrams_id, nodes_contexts.node_id
FROM nodes_contexts
JOIN context_node_ngrams
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_view_context_id_idx
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
--create index node_by_pos on nodes using btree(node_pos(id,typename));
-- Optimization for Ngrams Table View
create materialized view if not exists context_node_ngrams_view as
select context_node_ngrams.context_id, ngrams_id, nodes_contexts.node_id
from nodes_contexts
join context_node_ngrams
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_view_context_id_idx 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 index if not exists node_stories_ngrams_id_idx on node_stories(ngrams_id);
CREATE MATERIALIZED VIEW IF NOT EXISTS context_node_ngrams_view AS
SELECT DISTINCT context_node_ngrams.context_id, ngrams_id, nodes_contexts.node_id
FROM nodes_contexts
JOIN context_node_ngrams
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_view_context_id_idx
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);
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