From 6bf926eb3b41e24e4418c4324317db345cc7d0de Mon Sep 17 00:00:00 2001 From: Matchu Date: Wed, 21 Mar 2012 18:25:30 -0500 Subject: [PATCH] major SQL optimization. how did we get away with so few indexes?! --- .../20120321214802_index_associations.rb | 41 +++++++++++++++++++ ...0120321222001_index_closet_hanger_query.rb | 22 ++++++++++ ...120321231507_index_closet_hanger_query2.rb | 20 +++++++++ db/schema.rb | 20 ++++++++- 4 files changed, 101 insertions(+), 2 deletions(-) create mode 100644 db/migrate/20120321214802_index_associations.rb create mode 100644 db/migrate/20120321222001_index_closet_hanger_query.rb create mode 100644 db/migrate/20120321231507_index_closet_hanger_query2.rb diff --git a/db/migrate/20120321214802_index_associations.rb b/db/migrate/20120321214802_index_associations.rb new file mode 100644 index 00000000..0449632a --- /dev/null +++ b/db/migrate/20120321214802_index_associations.rb @@ -0,0 +1,41 @@ +class IndexAssociations < ActiveRecord::Migration + def self.up + add_index :closet_hangers, :item_id + add_index :closet_hangers, :list_id + add_index :closet_hangers, :user_id + + add_index :closet_lists, :user_id + + add_index :contributions, [:contributed_id, :contributed_type] + add_index :contributions, :user_id + + add_index :item_outfit_relationships, :item_id + add_index :item_outfit_relationships, :outfit_id + + add_index :outfits, :pet_state_id + add_index :outfits, :user_id + + remove_index :parents_swf_assets, :name => "parent_swf_assets_parent_id" + add_index :parents_swf_assets, [:parent_id, :parent_type] + end + + def self.down + remove_index :closet_hangers, :item_id + remove_index :closet_hangers, :list_id + remove_index :closet_hangers, :user_id + + remove_index :closet_lists, :user_id + + remove_index :contributions, [:contributed_id, :contributed_type] + remove_index :contributions, :user_id + + remove_index :item_outfit_relationships, :item_id + remove_index :item_outfit_relationships, :outfit_id + + remove_index :outfits, :pet_state_id + remove_index :outfits, :user_id + + add_index "parents_swf_assets", :parent_id, :name => "parent_swf_assets_parent_id" + remove_index :parents_swf_assets, [:parent_id, :parent_type] + end +end diff --git a/db/migrate/20120321222001_index_closet_hanger_query.rb b/db/migrate/20120321222001_index_closet_hanger_query.rb new file mode 100644 index 00000000..f8912e5b --- /dev/null +++ b/db/migrate/20120321222001_index_closet_hanger_query.rb @@ -0,0 +1,22 @@ +class IndexClosetHangerQuery < ActiveRecord::Migration + def self.up + # SELECT COUNT(DISTINCT `closet_hangers`.`id`) FROM `closet_hangers` INNER + # JOIN `users` ON `users`.`id` = `closet_hangers`.`user_id` LEFT OUTER JOIN + # `closet_lists` ON `closet_lists`.`id` = `closet_hangers`.`list_id` WHERE + # `closet_hangers`.`owned` = XXX AND (`closet_hangers`.item_id = XXX) AND + # ((`closet_hangers`.`list_id` IS NULL AND + # `users`.`owned_closet_hangers_visibility` >= XXX OR + # `closet_lists`.`visibility` >= XXX)); + + # It's not a huge improvement over the association index, but it's nice to + # be able to scan fewer rows for so little penalty, right? + + remove_index :closet_hangers, :item_id + add_index :closet_hangers, [:item_id, :owned] + end + + def self.down + remove_index :closet_hangers, [:item_id, :owned] + add_index :closet_hangers, :item_id + end +end diff --git a/db/migrate/20120321231507_index_closet_hanger_query2.rb b/db/migrate/20120321231507_index_closet_hanger_query2.rb new file mode 100644 index 00000000..73ae9c4f --- /dev/null +++ b/db/migrate/20120321231507_index_closet_hanger_query2.rb @@ -0,0 +1,20 @@ +class IndexClosetHangerQuery2 < ActiveRecord::Migration + def self.up + # SELECT `objects`.* FROM `objects` + # INNER JOIN `item_outfit_relationships` ON + # `objects`.id = `item_outfit_relationships`.item_id + # WHERE ((`item_outfit_relationships`.outfit_id = 138510) AND + # ((`item_outfit_relationships`.`is_worn` = 1))); + + # Small optimization, but an optimization nonetheless! + # Note that MySQL indexes can be reused for left-subsets, by which I mean + # this index can also act as just an index for outfit_id. Neat, eh? + remove_index :item_outfit_relationships, :outfit_id + add_index :item_outfit_relationships, [:outfit_id, :is_worn] + end + + def self.down + remove_index :item_outfit_relationships, [:outfit_id, :is_worn] + add_index :item_outfit_relationships, :outfit_id + end +end diff --git a/db/schema.rb b/db/schema.rb index 78f6acf6..0500a942 100644 --- a/db/schema.rb +++ b/db/schema.rb @@ -10,7 +10,7 @@ # # It's strongly recommended to check this file into your version control system. -ActiveRecord::Schema.define(:version => 20120112204234) do +ActiveRecord::Schema.define(:version => 20120321231507) do create_table "auth_servers", :force => true do |t| t.string "short_name", :limit => 10, :null => false @@ -30,6 +30,10 @@ ActiveRecord::Schema.define(:version => 20120112204234) do t.integer "list_id" end + add_index "closet_hangers", ["item_id", "owned"], :name => "index_closet_hangers_on_item_id_and_owned" + add_index "closet_hangers", ["list_id"], :name => "index_closet_hangers_on_list_id" + add_index "closet_hangers", ["user_id"], :name => "index_closet_hangers_on_user_id" + create_table "closet_lists", :force => true do |t| t.string "name" t.text "description" @@ -40,6 +44,8 @@ ActiveRecord::Schema.define(:version => 20120112204234) do t.integer "visibility", :default => 1, :null => false end + add_index "closet_lists", ["user_id"], :name => "index_closet_lists_on_user_id" + create_table "colors", :force => true do |t| t.string "name" t.boolean "basic", :default => false, :null => false @@ -52,6 +58,9 @@ ActiveRecord::Schema.define(:version => 20120112204234) do t.datetime "created_at", :null => false end + add_index "contributions", ["contributed_id", "contributed_type"], :name => "index_contributions_on_contributed_id_and_contributed_type" + add_index "contributions", ["user_id"], :name => "index_contributions_on_user_id" + create_table "forums", :force => true do |t| t.string "name" t.text "description" @@ -68,6 +77,9 @@ ActiveRecord::Schema.define(:version => 20120112204234) do t.datetime "updated_at" end + add_index "item_outfit_relationships", ["item_id"], :name => "index_item_outfit_relationships_on_item_id" + add_index "item_outfit_relationships", ["outfit_id", "is_worn"], :name => "index_item_outfit_relationships_on_outfit_id_and_is_worn" + create_table "login_cookies", :force => true do |t| t.integer "user_id", :null => false t.integer "series", :null => false @@ -105,16 +117,20 @@ ActiveRecord::Schema.define(:version => 20120112204234) do t.datetime "updated_at" t.string "name" t.boolean "starred", :default => false, :null => false + t.string "image" end + add_index "outfits", ["pet_state_id"], :name => "index_outfits_on_pet_state_id" + add_index "outfits", ["user_id"], :name => "index_outfits_on_user_id" + create_table "parents_swf_assets", :force => true do |t| t.integer "parent_id", :limit => 3, :null => false t.integer "swf_asset_id", :limit => 3, :null => false t.string "parent_type", :limit => 8, :null => false end + add_index "parents_swf_assets", ["parent_id", "parent_type"], :name => "index_parents_swf_assets_on_parent_id_and_parent_type" add_index "parents_swf_assets", ["parent_id", "swf_asset_id"], :name => "unique_parents_swf_assets", :unique => true - add_index "parents_swf_assets", ["parent_id"], :name => "parent_swf_assets_parent_id" add_index "parents_swf_assets", ["swf_asset_id"], :name => "parents_swf_assets_swf_asset_id" create_table "pet_loads", :force => true do |t|