Skip to content

Commit

Permalink
perf(svelte-ui): create image look index
Browse files Browse the repository at this point in the history
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
nicholaschiang committed Nov 29, 2024
1 parent cbd889b commit 29f7187
Show file tree
Hide file tree
Showing 6 changed files with 106 additions and 57 deletions.
2 changes: 2 additions & 0 deletions svelte-ui/src/lib/server/db/schema/tables.ts
Original file line number Diff line number Diff line change
Expand Up @@ -531,6 +531,7 @@ export const collection = pgTable(
},
(table) => {
return {
nameIndex: index("idx_gin").using("gin", table.name),
brandIdSeasonIdSexLevelLocationKey: uniqueIndex(
"Collection_brandId_seasonId_sex_level_location_key",
).using(
Expand Down Expand Up @@ -749,6 +750,7 @@ export const image = pgTable(
},
(table) => {
return {
imageLookIndex: index("idx_image_look").using("hash", table.lookId),
urlKey: uniqueIndex("Image_url_key").using(
"btree",
table.url.asc().nullsLast().op("text_ops"),
Expand Down
10 changes: 10 additions & 0 deletions svelte-ui/src/routes/+error.svelte
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
<script>
import { page } from "$app/stores"
</script>

<div class="flex h-screen w-screen flex-col items-center justify-center">
<h1>{$page.status}</h1>
{#if $page.error}
<p>{$page.error.message}</p>
{/if}
</div>
24 changes: 17 additions & 7 deletions svelte-ui/src/routes/+page.server.ts
Original file line number Diff line number Diff line change
Expand Up @@ -12,19 +12,29 @@ const query = db
lookImageUrl: tables.image.url,
})
.from(tables.collection)
.leftJoin(
tables.look,
.leftJoin(tables.look, eq(tables.look.collectionId, tables.collection.id))
.leftJoin(tables.image, eq(tables.image.lookId, tables.look.id))
.orderBy(desc(tables.collection.name))
.where(
and(
eq(tables.look.collectionId, tables.collection.id),
eq(tables.look.number, 1),
ilike(tables.collection.name, sql.placeholder("search")),
),
)
.leftJoin(tables.image, eq(tables.image.lookId, tables.look.id))
.orderBy(desc(tables.collection.name))
.where(ilike(tables.collection.name, sql.placeholder("search")))
.prepare("collections")

async function getCollections(search: string) {
console.time(`collections-${search}`)
const start = performance.now()
const collections = await query.execute({ search: `%${search}%` })
const end = performance.now()
console.timeEnd(`collections-${search}`)
const time = end - start
console.log(`collections-${search}: ${time}ms`)
return { collections, time }
}

export async function load({ url }) {
const search = url.searchParams.get("q") ?? ""
return { collections: query.execute({ search: `%${search}%` }) }
return { data: getCollections(search) }
}
19 changes: 13 additions & 6 deletions svelte-ui/src/routes/+page.svelte
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,7 @@
value = new URLSearchParams(location.search).get("q") ?? ""
})
type Collection = Awaited<typeof data.collections>[number]
type Collection = Awaited<typeof data.data>["collections"][number]
const sort = (a: Collection, b: Collection) =>
new Date(b.collectionDate ?? new Date()).valueOf() -
new Date(a.collectionDate ?? new Date()).valueOf()
Expand All @@ -41,19 +41,26 @@
/>
</form>
<div class="flex flex-col gap-2">
{#await data.collections}
{#await data.data}
<p>Loading...</p>
{:then collections}
<p>Found {collections.length} results</p>
{:then data}
<p>
Found {data.collections.length} results
<span class="text-gray-400 dark:text-gray-500"
>({data.time.toFixed(2)}ms)</span
>
</p>
{:catch error}
<p>Error: {error.message}</p>
{/await}
</div>
<div
class="grid gap-x-2 gap-y-8 sm:grid-cols-2 md:grid-cols-3 lg:grid-cols-4 2xl:grid-cols-6"
>
{#await data.collections then collections}
{#each collections.sort(sort) as collection (collection.collectionId)}
{#await data.data then data}
{#each data.collections
.slice(0, 100)
.sort(sort) as collection (collection.collectionId)}
<a
href="/collections/{collection.collectionId}"
class="flex flex-col gap-2 text-xs"
Expand Down
65 changes: 43 additions & 22 deletions svelte-ui/src/routes/collections/[collectionId]/+page.server.ts
Original file line number Diff line number Diff line change
@@ -1,28 +1,49 @@
import { eq } from "drizzle-orm"
import { eq, Placeholder, sql } from "drizzle-orm"
import { error } from "@sveltejs/kit"
import * as tables from "$lib/server/db/schema/tables"
import { db } from "$lib/server/db"

export async function load({ params }) {
return {
collection: db.query.collection
.findMany({
where: eq(tables.collection.id, params.collectionId),
const query = db.query.collection.findFirst({
where: eq(tables.collection.id, sql.placeholder("collectionId")),
with: {
brand: true,
season: true,
articles: {
with: {
user_authorId: true,
publication: true,
},
},
looks: {
with: {
brand: true,
season: true,
articles: {
with: {
user_authorId: true,
publication: true,
},
},
looks: {
with: {
images: true,
},
},
images: true,
},
})
.then((collections) => collections[0]),
}
},
},
}).prepare("collection")

async function getCollection(collectionId: number) {
console.time(`collection-${collectionId}`)
const start = performance.now()
const collection = await query.execute({ collectionId })
const end = performance.now()
console.timeEnd(`collection-${collectionId}`)
const time = end - start
console.log(`collection-${collectionId}: ${time}ms`)

const q = query.getQuery()
let sql = q.sql
q.params.forEach((param, i) => {
sql = sql.replaceAll(`$${i + 1}`, String(param instanceof Placeholder ? collectionId : param))
})
console.log(sql)

if (collection == null) error(404, { message: "Collection Not Found" })
return { collection, time }
}

export async function load({ params }) {
const collectionId = Number(params.collectionId)
if (isNaN(collectionId)) error(400, { message: "Invalid Collection ID" })
return { data: getCollection(collectionId) }
}
43 changes: 21 additions & 22 deletions svelte-ui/src/routes/collections/[collectionId]/+page.svelte
Original file line number Diff line number Diff line change
Expand Up @@ -14,38 +14,37 @@
<Header>
<a href="/">Collections</a>
<ChevronRight class="h-4 w-4 text-gray-200 dark:text-gray-800" />
{#await data.collection then collection}
<a href="/?q={encodeURIComponent(collection.brand.name)}"
>{collection.brand.name}</a
{#await data.data then data}
<a href="/?q={encodeURIComponent(data.collection.brand.name)}"
>{data.collection.brand.name}</a
>
<ChevronRight class="h-4 w-4 text-gray-200 dark:text-gray-800" />
<a href="/?q={encodeURIComponent(formatSeasonName(collection.season))}"
>{formatSeasonName(collection.season)}
{formatLevelName(collection.level)}</a
<a href="/?q={encodeURIComponent(formatSeasonName(data.collection.season))}"
>{formatSeasonName(data.collection.season)}
{formatLevelName(data.collection.level)}</a
>
<div class="flex items-center gap-1">
{#if collection.date}
<span class="text-sm text-gray-400 dark:text-gray-500"
>({formatDate(new Date(collection.date))})</span
>
<div
class="flex items-center gap-1 text-sm text-gray-400 dark:text-gray-500"
>
{#if data.collection.date}
<span>({formatDate(new Date(data.collection.date))})</span>
{/if}
{#if collection.location}
<span class="text-sm text-gray-400 dark:text-gray-500"
>({formatLocation(collection.location)})</span
>
{#if data.collection.location}
<span>({formatLocation(data.collection.location)})</span>
{/if}
<span>({data.time.toFixed(2)}ms)</span>
</div>
{/await}
</Header>
<div class="flex h-full flex-col xl:flex-row">
<div class="flex flex-col gap-6 p-6 xl:w-0 xl:grow">
{#await data.collection}
{#await data.data}
<p>Loading...</p>
{:then collection}
{:then data}
<div
class="grid gap-x-2 gap-y-4 md:grid-cols-2 lg:grid-cols-3 xl:grid-cols-2 2xl:grid-cols-3"
>
{#each collection.looks as look (look.id)}
{#each data.collection.looks as look (look.id)}
<a
href={look.images[0].url}
target="_blank"
Expand All @@ -60,7 +59,7 @@
loading="lazy"
decoding="async"
src={look.images[0].url}
alt="Look {look.number} of {collection.name}"
alt="Look {look.number} of {data.collection.name}"
class="flex h-full w-full items-center justify-center object-cover"
/>
{:else}
Expand All @@ -75,10 +74,10 @@
</div>
{/await}
</div>
{#await data.collection then collection}
{#if collection.articles.length}
{#await data.data then data}
{#if data.collection.articles.length}
<div class="flex flex-col gap-12 p-6 xl:pr-12">
{#each collection.articles as article (article.id)}
{#each data.collection.articles as article (article.id)}
<div class="flex flex-col gap-4 text-sm">
<div>
<h2 class="flex items-center gap-2">
Expand Down

0 comments on commit 29f7187

Please sign in to comment.