diff --git a/resources/migrations/00014_add_better_cards_table_sort_indexes.down.sql b/resources/migrations/00014_add_better_cards_table_sort_indexes.down.sql new file mode 100644 index 0000000..6282feb --- /dev/null +++ b/resources/migrations/00014_add_better_cards_table_sort_indexes.down.sql @@ -0,0 +1,23 @@ +DROP INDEX IF EXISTS cards_name_asc_id_idx; +DROP INDEX IF EXISTS cards_name_desc_id_idx; + +DROP INDEX IF EXISTS cards_set_code_asc_id_idx; +DROP INDEX IF EXISTS cards_set_code_desc_id_idx; + +DROP INDEX IF EXISTS cards_converted_mana_cost_nulls_first_asc_id_idx; +DROP INDEX IF EXISTS cards_converted_mana_cost_nulls_last_desc_id_idx; + +DROP INDEX IF EXISTS cards_type_asc_id_idx; +DROP INDEX IF EXISTS cards_type_desc_id_idx; + +DROP INDEX IF EXISTS cards_rarity_asc_id_idx; +DROP INDEX IF EXISTS cards_rarity_desc_id_idx; + +DROP INDEX IF EXISTS cards_paper_price_nulls_first_asc_id_idx; +DROP INDEX IF EXISTS cards_paper_price_nulls_last_desc_id_idx; + +DROP INDEX IF EXISTS cards_online_price_nulls_first_asc_id_idx; +DROP INDEX IF EXISTS cards_online_price_nulls_last_desc_id_idx; + +DROP INDEX IF EXISTS cards_owned_count_asc_id_idx; +DROP INDEX IF EXISTS cards_owned_count_desc_id_idx; diff --git a/resources/migrations/00014_add_better_cards_table_sort_indexes.up.sql b/resources/migrations/00014_add_better_cards_table_sort_indexes.up.sql new file mode 100644 index 0000000..5d4ab1a --- /dev/null +++ b/resources/migrations/00014_add_better_cards_table_sort_indexes.up.sql @@ -0,0 +1,31 @@ +-- these indexes are to make sure that all the sorting possible via the web UI +-- is fast and _stable_ across multiple pages of the same value +-- (e.g. sorting on rarity and navigating through multiple pages of 'Common' values) +-- +-- of course, these additional indexes don't take care of all possible sorting and filtering +-- permutations available through the web UI (still possible to end up with some bitmap scans, etc. +-- in the query plans used in some cases)... but it definitely is better then nothing + +CREATE INDEX cards_name_asc_id_idx ON cards (name ASC, id); +CREATE INDEX cards_name_desc_id_idx ON cards (name DESC, id); + +CREATE INDEX cards_set_code_asc_id_idx ON cards (set_code ASC, id); +CREATE INDEX cards_set_code_desc_id_idx ON cards (set_code DESC, id); + +CREATE INDEX cards_converted_mana_cost_nulls_first_asc_id_idx ON cards (converted_mana_cost ASC NULLS FIRST, id); +CREATE INDEX cards_converted_mana_cost_nulls_last_desc_id_idx ON cards (converted_mana_cost DESC NULLS LAST, id); + +CREATE INDEX cards_type_asc_id_idx ON cards (type ASC, id); +CREATE INDEX cards_type_desc_id_idx ON cards (type DESC, id); + +CREATE INDEX cards_rarity_asc_id_idx ON cards (rarity ASC, id); +CREATE INDEX cards_rarity_desc_id_idx ON cards (rarity DESC, id); + +CREATE INDEX cards_paper_price_nulls_first_asc_id_idx ON cards (paper_price ASC NULLS FIRST, id); +CREATE INDEX cards_paper_price_nulls_last_desc_id_idx ON cards (paper_price DESC NULLS LAST, id); + +CREATE INDEX cards_online_price_nulls_first_asc_id_idx ON cards (online_price ASC NULLS FIRST, id); +CREATE INDEX cards_online_price_nulls_last_desc_id_idx ON cards (online_price DESC NULLS LAST, id); + +CREATE INDEX cards_owned_count_asc_id_idx ON cards (owned_count ASC, id); +CREATE INDEX cards_owned_count_desc_id_idx ON cards (owned_count DESC, id); diff --git a/src/mtgcoll/views/functions/cards.clj b/src/mtgcoll/views/functions/cards.clj index 5b1b782..3dfead3 100644 --- a/src/mtgcoll/views/functions/cards.clj +++ b/src/mtgcoll/views/functions/cards.clj @@ -212,7 +212,7 @@ :from [[:cards :c]] :join [[:sets :s] [:= :c.set_code :s.code]]} (if order-by - {:order-by [order-by]})) + {:order-by [order-by [:c.id]]})) :cards_list]]}] (if (seq hsql-filters) (assoc q :where (concat [:and] hsql-filters))