1
0
Fork 0
forked from OpenNeo/impress

Improve performance for occupies:X searches

I noticed in the app that these queries were slowwww! I was able to
track it down to a bad query plan, as we explain in the comment.

I searched online for "mysql query performance filter on one join table
sort by another", and was surprised to find this answer suggest a
subquery, which I've often been told to expect to be slower compared to
joins? But it certainly worked in this case!

https://stackoverflow.com/questions/35679693/mysql-optimize-join-with-filter-and-order-on-different-tables
This commit is contained in:
Emi Matchu 2024-06-03 11:45:51 -07:00
parent aa3dc9549f
commit 193b1fa5e3

View file

@ -60,8 +60,23 @@ class Item < ApplicationRecord
}
scope :occupies, ->(zone_label) {
zone_ids = Zone.matching_label(zone_label).map(&:id)
# NOTE: In searches, this query performs much better using a subquery
# instead of joins! This is because, in the joins case, filtering by an
# `swf_assets` field but sorting by an `items` field causes the query
# planner to only be able to use an index for *one* of them. In this case,
# MySQL can use the `swf_assets`.`zone_id` index to get the item IDs for
# the subquery, then use the `items`.`name` index to sort them.
i = arel_table
psa = ParentSwfAssetRelationship.arel_table
sa = SwfAsset.arel_table
joins(:swf_assets).where(sa[:zone_id].in(zone_ids)).distinct
where(
ParentSwfAssetRelationship.joins(:swf_asset).
where(sa[:zone_id].in(zone_ids)).
where(psa[:parent_type].eq("Item")).
where(psa[:parent_id].eq(i[:id])).
arel.exists
)
}
scope :not_occupies, ->(zone_label) {
zone_ids = Zone.matching_label(zone_label).map(&:id)