From 7935cffd6b14a0861489c32ba091cff7f75d818a Mon Sep 17 00:00:00 2001 From: Antoine Eiche Date: Thu, 6 Jun 2019 11:57:11 +0200 Subject: [PATCH] Create a pg_trgm index on builds.drvpath The search query uses the LIKE operator which requires a sequential scan (it can't use the already existing B-tree index). This new index (trigram) avoids a sequential scan of the builds table when the LIKE operator is used. Here is the analyze of a request on the builds table with this index: explain analyze select * from builds where drvpath like '%k3r71gz0gv16ld8rhcp2bb8gb5w1xc4b%'; QUERY PLAN ----------------------------------------------------------------------------------------------------------------------------------- Bitmap Heap Scan on builds (cost=128.00..132.01 rows=1 width=492) (actual time=0.070..0.077 rows=1 loops=1) Recheck Cond: (drvpath ~~ '%k3r71gz0gv16ld8rhcp2bb8gb5w1xc4b%'::text) -> Bitmap Index Scan on indextrgmbuildsondrvpath (cost=0.00..128.00 rows=1 width=0) (actual time=0.047..0.047 rows=3 loops=1) Index Cond: (drvpath ~~ '%k3r71gz0gv16ld8rhcp2bb8gb5w1xc4b%'::text) Total runtime: 0.206 ms (5 rows) --- src/sql/hydra.sql | 6 ++++++ src/sql/upgrade-57.sql | 2 ++ 2 files changed, 8 insertions(+) create mode 100644 src/sql/upgrade-57.sql diff --git a/src/sql/hydra.sql b/src/sql/hydra.sql index 4c8710b8..a39d9aac 100644 --- a/src/sql/hydra.sql +++ b/src/sql/hydra.sql @@ -688,3 +688,9 @@ create index IndexBuildsOnKeep on Builds(keep) where keep = 1; create index IndexJobsetEvalsOnJobsetId on JobsetEvals(project, jobset, id desc) where hasNewBuilds = 1; create index IndexBuildsOnNotificationPendingSince on Builds(notificationPendingSince) where notificationPendingSince is not null; + +#ifdef POSTGRESQL +-- Provide an index used by LIKE operator on builds.drvpath (search query) +CREATE EXTENSION pg_trgm; +CREATE INDEX IndexTrgmBuildsOnDrvpath ON builds USING gin (drvpath gin_trgm_ops); +#endif diff --git a/src/sql/upgrade-57.sql b/src/sql/upgrade-57.sql new file mode 100644 index 00000000..f950a6e0 --- /dev/null +++ b/src/sql/upgrade-57.sql @@ -0,0 +1,2 @@ +CREATE EXTENSION pg_trgm; +CREATE INDEX IndexTrgmBuildsOnDrvpath ON builds USING gin (drvpath gin_trgm_ops);