mirror of
https://github.com/perlbot/perlbuut
synced 2025-06-07 16:45:40 -04:00
upgrade to pg12 and use generated columns, cuts query cost in more than half
This commit is contained in:
parent
d620a8e4bb
commit
5d56dee64c
2 changed files with 15 additions and 9 deletions
|
@ -1,24 +1,24 @@
|
||||||
WITH RECURSIVE factoid_lookup_order_inner (depth, namespace, server, alias_namespace, alias_server, parent_namespace, parent_server, recursive) AS (
|
EXPLAIN WITH RECURSIVE factoid_lookup_order_inner (depth, namespace, server, alias_namespace, alias_server, parent_namespace, parent_server, recursive, gen_server, gen_namespace) AS (
|
||||||
SELECT 0 AS depth, namespace, server, alias_namespace, alias_server, parent_namespace, parent_server, recursive
|
SELECT 0 AS depth, namespace, server, alias_namespace, alias_server, parent_namespace, parent_server, recursive, generated_server, generated_namespace
|
||||||
FROM factoid_config
|
FROM factoid_config
|
||||||
WHERE namespace = '#perlbot' AND server = 'notfreenode.net' -- PLACEHOLDER TARGET
|
WHERE namespace = '#perlbot' AND server = 'notfreenode.net' -- PLACEHOLDER TARGET
|
||||||
UNION ALL
|
UNION ALL
|
||||||
SELECT p.depth+1 AS depth, m.namespace, m.server, m.alias_namespace, m.alias_server, m.parent_namespace, m.parent_server, m.recursive
|
SELECT p.depth+1 AS depth, m.namespace, m.server, m.alias_namespace, m.alias_server, m.parent_namespace, m.parent_server, m.recursive, m.generated_server, m.generated_namespace
|
||||||
FROM factoid_config m
|
FROM factoid_config m
|
||||||
INNER JOIN factoid_lookup_order_inner p
|
INNER JOIN factoid_lookup_order_inner p
|
||||||
ON m.namespace = p.parent_namespace AND m.server = p.parent_server AND p.recursive
|
ON m.namespace = p.parent_namespace AND m.server = p.parent_server AND p.recursive
|
||||||
),
|
),
|
||||||
factoid_lookup_order (depth, namespace, server, alias_namespace, alias_server, parent_namespace, parent_server, recursive) AS (
|
factoid_lookup_order (depth, namespace, server, alias_namespace, alias_server, parent_namespace, parent_server, recursive, gen_server, gen_namespace) AS (
|
||||||
SELECT * FROM factoid_lookup_order_inner
|
SELECT * FROM factoid_lookup_order_inner
|
||||||
UNION ALL
|
UNION ALL
|
||||||
SELECT 0, '', '', NULL, NULL, NULL, NULL, false WHERE NOT EXISTS (table factoid_lookup_order_inner)
|
SELECT 0, '', '', NULL, NULL, NULL, NULL, false, '', '' WHERE NOT EXISTS (table factoid_lookup_order_inner)
|
||||||
),
|
),
|
||||||
get_latest_factoid (depth, factoid_id, subject, copula, predicate, author, modified_time, compose_macro, protected, original_subject, deleted, server, namespace) AS (
|
get_latest_factoid (depth, factoid_id, subject, copula, predicate, author, modified_time, compose_macro, protected, original_subject, deleted, server, namespace) AS (
|
||||||
SELECT DISTINCT ON(lo.depth) lo.depth, factoid_id, subject, copula, predicate, author, modified_time, compose_macro, protected, original_subject, f.deleted, f.server, f.namespace
|
SELECT DISTINCT ON(lo.depth) lo.depth, factoid_id, subject, copula, predicate, author, modified_time, compose_macro, protected, original_subject, f.deleted, f.server, f.namespace
|
||||||
FROM factoid f
|
FROM factoid f
|
||||||
INNER JOIN factoid_lookup_order lo
|
INNER JOIN factoid_lookup_order lo
|
||||||
ON COALESCE(f.server, '') = COALESCE(lo.alias_server, lo.server)
|
ON f.generated_server = lo.gen_server
|
||||||
AND COALESCE(f.namespace, '') = COALESCE(lo.alias_namespace, lo.namespace)
|
AND f.generated_namespace = lo.gen_namespace
|
||||||
WHERE original_subject = 'hi' -- PLACEHOLDER TARGET
|
WHERE original_subject = 'hi' -- PLACEHOLDER TARGET
|
||||||
ORDER BY depth ASC, factoid_id DESC
|
ORDER BY depth ASC, factoid_id DESC
|
||||||
)
|
)
|
||||||
|
|
|
@ -12,6 +12,9 @@ ALTER TABLE public.factoid ADD COLUMN deleted boolean DEFAULT false;
|
||||||
ALTER TABLE public.factoid ADD COLUMN namespace text;
|
ALTER TABLE public.factoid ADD COLUMN namespace text;
|
||||||
ALTER TABLE public.factoid ADD COLUMN server text;
|
ALTER TABLE public.factoid ADD COLUMN server text;
|
||||||
ALTER TABLE public.factoid ADD COLUMN last_rendered text;
|
ALTER TABLE public.factoid ADD COLUMN last_rendered text;
|
||||||
|
-- this actually lets me use a multi-column index that cuts the cost in half.
|
||||||
|
ALTER TABLE public.factoid ADD COLUMN generated_server text GENERATED ALWAYS AS (COALESCE(server, '')) STORED;
|
||||||
|
ALTER TABLE public.factoid ADD COLUMN generated_namespace text GENERATED ALWAYS AS (COALESCE(namespace, '')) STORED;
|
||||||
|
|
||||||
UPDATE public.factoid SET namespace=split_part(original_subject, E'\034', 3), server=split_part(original_subject, E'\034', 2);
|
UPDATE public.factoid SET namespace=split_part(original_subject, E'\034', 3), server=split_part(original_subject, E'\034', 2);
|
||||||
UPDATE public.factoid SET namespace=NULL WHERE namespace = '';
|
UPDATE public.factoid SET namespace=NULL WHERE namespace = '';
|
||||||
|
@ -34,8 +37,10 @@ CREATE TABLE public.factoid_config (
|
||||||
-- Should we do the recursive lookup into the parent_*, this is needed because NULL is a valid value for parent_*
|
-- Should we do the recursive lookup into the parent_*, this is needed because NULL is a valid value for parent_*
|
||||||
recursive boolean DEFAULT false,
|
recursive boolean DEFAULT false,
|
||||||
command_prefix text,
|
command_prefix text,
|
||||||
|
generated_server text GENERATED ALWAYS AS (COALESCE(alias_server, server)) STORED,
|
||||||
|
generated_namespace text GENERATED ALWAYS AS (COALESCE(alias_namespace, namespace)) STORED,
|
||||||
|
|
||||||
CONSTRAINT unique_config UNIQUE (server, namespace)
|
PRIMARY KEY (server, namespace)
|
||||||
);
|
);
|
||||||
|
|
||||||
INSERT INTO public.factoid_config (server, namespace, alias_server, alias_namespace, recursive, command_prefix)
|
INSERT INTO public.factoid_config (server, namespace, alias_server, alias_namespace, recursive, command_prefix)
|
||||||
|
@ -46,6 +51,7 @@ INSERT INTO public.factoid_config (server, namespace, alias_server, alias_namesp
|
||||||
|
|
||||||
CREATE INDEX IF NOT EXISTS factoid_original_subject_lookup_idx ON public.factoid (original_subject);
|
CREATE INDEX IF NOT EXISTS factoid_original_subject_lookup_idx ON public.factoid (original_subject);
|
||||||
CREATE INDEX IF NOT EXISTS factoid_original_subject_trigram_idx ON public.factoid USING GIN(original_subject gin_trgm_ops);
|
CREATE INDEX IF NOT EXISTS factoid_original_subject_trigram_idx ON public.factoid USING GIN(original_subject gin_trgm_ops);
|
||||||
|
CREATE INDEX IF NOT EXISTS factoid_generated_server_lookup_idx ON public.factoid (generated_server, generated_namespace);
|
||||||
|
CREATE INDEX IF NOT EXISTS factoid_config_generated_idx ON public.factoid_config (generated_server, generated_namespace);
|
||||||
|
|
||||||
COMMIT;
|
COMMIT;
|
||||||
|
|
Loading…
Add table
Reference in a new issue