Compare commits
2 commits
63abfa51f7
...
193b1fa5e3
Author | SHA1 | Date | |
---|---|---|---|
193b1fa5e3 | |||
aa3dc9549f |
3 changed files with 23 additions and 2 deletions
|
@ -60,8 +60,23 @@ class Item < ApplicationRecord
|
||||||
}
|
}
|
||||||
scope :occupies, ->(zone_label) {
|
scope :occupies, ->(zone_label) {
|
||||||
zone_ids = Zone.matching_label(zone_label).map(&:id)
|
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
|
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) {
|
scope :not_occupies, ->(zone_label) {
|
||||||
zone_ids = Zone.matching_label(zone_label).map(&:id)
|
zone_ids = Zone.matching_label(zone_label).map(&:id)
|
||||||
|
|
5
db/migrate/20240603181855_add_index_on_name_to_items.rb
Normal file
5
db/migrate/20240603181855_add_index_on_name_to_items.rb
Normal file
|
@ -0,0 +1,5 @@
|
||||||
|
class AddIndexOnNameToItems < ActiveRecord::Migration[7.1]
|
||||||
|
def change
|
||||||
|
add_index :items, :name
|
||||||
|
end
|
||||||
|
end
|
|
@ -10,7 +10,7 @@
|
||||||
#
|
#
|
||||||
# It's strongly recommended that you check this file into your version control system.
|
# It's strongly recommended that you check this file into your version control system.
|
||||||
|
|
||||||
ActiveRecord::Schema[7.1].define(version: 2024_05_22_233638) do
|
ActiveRecord::Schema[7.1].define(version: 2024_06_03_181855) do
|
||||||
create_table "alt_styles", charset: "utf8mb4", collation: "utf8mb4_unicode_520_ci", force: :cascade do |t|
|
create_table "alt_styles", charset: "utf8mb4", collation: "utf8mb4_unicode_520_ci", force: :cascade do |t|
|
||||||
t.integer "species_id", null: false
|
t.integer "species_id", null: false
|
||||||
t.integer "color_id", null: false
|
t.integer "color_id", null: false
|
||||||
|
@ -140,6 +140,7 @@ ActiveRecord::Schema[7.1].define(version: 2024_05_22_233638) do
|
||||||
t.index ["modeling_status_hint", "created_at"], name: "items_modeling_status_hint_and_created_at"
|
t.index ["modeling_status_hint", "created_at"], name: "items_modeling_status_hint_and_created_at"
|
||||||
t.index ["modeling_status_hint", "id"], name: "items_modeling_status_hint_and_id"
|
t.index ["modeling_status_hint", "id"], name: "items_modeling_status_hint_and_id"
|
||||||
t.index ["modeling_status_hint"], name: "items_modeling_status_hint"
|
t.index ["modeling_status_hint"], name: "items_modeling_status_hint"
|
||||||
|
t.index ["name"], name: "index_items_on_name"
|
||||||
end
|
end
|
||||||
|
|
||||||
create_table "login_cookies", id: :integer, charset: "utf8mb4", collation: "utf8mb4_unicode_520_ci", force: :cascade do |t|
|
create_table "login_cookies", id: :integer, charset: "utf8mb4", collation: "utf8mb4_unicode_520_ci", force: :cascade do |t|
|
||||||
|
|
Loading…
Reference in a new issue