You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
`EXPLAIN ANALYZE` output (tested assuming `ORDER BY crates_cnt DESC LIMIT 10 OFFSET 0`)
Before:
```
(cost=7129.79..7129.82 rows=10 width=127) (actual time=1.184..1.187 rows=10 loops=1)
```
After:
```
(cost=5.88..5.88 rows=1 width=131) (actual time=0.175..0.177 rows=10 loops=1)
```
About half of the performance comes from removing the `COALESCE`. Since
the subselect is including the `crates_cnt` from the toplevel category
(which is why it doesn't have to add `c.crates_cnt`), so it can never
return null.
The second big win is changing from a subselect to a join. PG is usually
quite good at figuring out when these cases are equivalent, but I
suspect that the use of an aggregate function in the subselect means
that it will actually have to subselect in a loop.
Finally, we avoid using `LIKE`, since it's more expensive than we need,
and can't be indexed. I've opted to use `split_part(slug)` in both the
join and outer filter, so that both can be covered by a single index
later. The "cheapest" way to do the outer filter is probably
`strpos(slug, '::') = 0`, but the difference is so small that it doesn't
matter.
I explicitly did not include an index here, since the data set is small
enough that it would never be used. If the number of categories grows
beyond a few hundred, this query can also benefit from an index on
`split_part(slug, '::', 1)`.
The test coverage around this method was pretty light, so I've added
some unit tests to give it a bit more coverage for correctness.
0 commit comments