Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
perf(svelte-ui): create image look index
This patch surfaces the query execution times in the UI. This patch creates an image look index in the backend to optimize the look images select. For collection-specific queries (e.g. searching for "Gucci" or "Prada"), this reduces the query time from ~50ms to ~5ms. ``` postgres=# select * from pg_indexes where indexname ilike 'idx_%'; schemaname | tablename | indexname | tablespace | indexdef ------------+------------+----------------+------------+--------------------------------------------------------------------------- public | Collection | idx_gin | | CREATE INDEX idx_gin ON public."Collection" USING gin (name gin_trgm_ops) public | Image | idx_image_look | | CREATE INDEX idx_image_look ON public."Image" USING hash ("lookId") (2 rows) Time: 3.740 ms postgres=# drop index idx_gin; DROP INDEX Time: 9.993 ms postgres=# drop index idx_image_look; DROP INDEX Time: 8.670 ms postgres=# explain (analyze, buffers) select distinct on ("Collection"."name") "Collection"."id", "Collection"."name", "Collection"."date", "Collection"."location", "Look"."number", "Image"."url" from "Collection" left join "Look" on "Look"."collectionId" = "Collection"."id" left join "Image" on "Image"."lookId" = "Look"."id" where ("Look"."number" = 1 and "Collection"."name" ilike '%dior%') order by "Collection"."name" desc; QUERY PLAN ------------------------------------------------------------------------------------------------------------------------------------------------------------------------ Unique (cost=12671.52..12672.63 rows=206 width=153) (actual time=88.662..88.705 rows=179 loops=1) Buffers: shared hit=7456 -> Sort (cost=12671.52..12672.08 rows=222 width=153) (actual time=88.657..88.670 rows=179 loops=1) Sort Key: "Collection".name DESC Sort Method: quicksort Memory: 56kB Buffers: shared hit=7456 -> Hash Right Join (cost=2372.82..12662.87 rows=222 width=153) (actual time=27.578..88.258 rows=179 loops=1) Hash Cond: ("Image"."lookId" = "Look".id) Buffers: shared hit=7456 -> Seq Scan on "Image" (cost=0.00..9177.42 rows=296142 width=105) (actual time=0.031..31.160 rows=296142 loops=1) Buffers: shared hit=6216 -> Hash (cost=2370.28..2370.28 rows=203 width=56) (actual time=27.162..27.163 rows=179 loops=1) Buckets: 1024 Batches: 1 Memory Usage: 24kB Buffers: shared hit=1240 -> Nested Loop (cost=0.42..2370.28 rows=203 width=56) (actual time=0.585..27.015 rows=179 loops=1) Buffers: shared hit=1240 -> Seq Scan on "Collection" (cost=0.00..767.12 rows=206 width=48) (actual time=0.555..23.710 rows=183 loops=1) Filter: (name ~~* '%dior%'::text) Rows Removed by Filter: 20227 Buffers: shared hit=512 -> Index Scan using "Look_collectionId_number_key" on "Look" (cost=0.42..7.78 rows=1 width=12) (actual time=0.017..0.017 rows=1 loops=183) Index Cond: (("collectionId" = "Collection".id) AND (number = 1)) Buffers: shared hit=728 Planning: Buffers: shared hit=46 dirtied=1 Planning Time: 1.831 ms Execution Time: 88.808 ms (27 rows) Time: 93.344 ms postgres=# CREATE INDEX idx_gin ON public."Collection" USING gin (name gin_trgm_ops); CREATE INDEX Time: 152.687 ms postgres=# CREATE INDEX idx_image_look ON public."Image" USING hash ("lookId"); CREATE INDEX Time: 221.699 ms postgres=# explain (analyze, buffers) select distinct on ("Collection"."name") "Collection"."id", "Collection"."name", "Collection"."date", "Collection"."location", "Look"."number", "Image"."url" from "Collection" left join "Look" on "Look"."collectionId" = "Collection"."id" left join "Image" on "Image"."lookId" = "Look"."id" where ("Look"."number" = 1 and "Collection"."name" ilike '%dior%') order by "Collection"."name" desc; QUERY PLAN ------------------------------------------------------------------------------------------------------------------------------------------------------------------ Unique (cost=2323.74..2324.85 rows=206 width=153) (actual time=4.776..4.882 rows=179 loops=1) Buffers: shared hit=1258 -> Sort (cost=2323.74..2324.30 rows=222 width=153) (actual time=4.772..4.799 rows=179 loops=1) Sort Key: "Collection".name DESC Sort Method: quicksort Memory: 56kB Buffers: shared hit=1258 -> Nested Loop Left Join (cost=23.01..2315.09 rows=222 width=153) (actual time=0.469..4.005 rows=179 loops=1) Buffers: shared hit=1258 -> Nested Loop (cost=23.01..2017.25 rows=203 width=56) (actual time=0.424..2.642 rows=179 loops=1) Buffers: shared hit=899 -> Bitmap Heap Scan on "Collection" (cost=22.59..414.09 rows=206 width=48) (actual time=0.308..0.988 rows=183 loops=1) Recheck Cond: (name ~~* '%dior%'::text) Heap Blocks: exact=166 Buffers: shared hit=171 -> Bitmap Index Scan on idx_gin (cost=0.00..22.54 rows=206 width=0) (actual time=0.162..0.162 rows=183 loops=1) Index Cond: (name ~~* '%dior%'::text) Buffers: shared hit=5 -> Index Scan using "Look_collectionId_number_key" on "Look" (cost=0.42..7.78 rows=1 width=12) (actual time=0.008..0.008 rows=1 loops=183) Index Cond: (("collectionId" = "Collection".id) AND (number = 1)) Buffers: shared hit=728 -> Index Scan using idx_image_look on "Image" (cost=0.00..1.46 rows=1 width=105) (actual time=0.007..0.007 rows=1 loops=179) Index Cond: ("lookId" = "Look".id) Buffers: shared hit=359 Planning: Buffers: shared hit=67 Planning Time: 1.314 ms Execution Time: 4.983 ms (27 rows) Time: 10.000 ms ```
- Loading branch information