PERF: add indexes to speed up profile pages (#11598)
These 2 indexes optimise performance on profile pages. The summary page displays: 1. A list of "Top Link" - links sorted by number of clicks posted by user 2. A list of "Top Replies" - replies made by a user that go the most hearts These two areas could devolve into full index or table scans, new indexes are there to avoid this cost on large dbs One minor downside is that storage requirements go a tiny bit up to maintain the new indexes
This commit is contained in:
parent
357d698557
commit
53f4d54f23
|
@ -1174,4 +1174,5 @@ end
|
|||
# index_posts_on_topic_id_and_post_number (topic_id,post_number) UNIQUE
|
||||
# index_posts_on_topic_id_and_sort_order (topic_id,sort_order)
|
||||
# index_posts_on_user_id_and_created_at (user_id,created_at)
|
||||
# index_posts_user_and_likes (user_id,like_count DESC,created_at DESC) WHERE (post_number > 1)
|
||||
#
|
||||
|
|
|
@ -402,10 +402,11 @@ end
|
|||
#
|
||||
# Indexes
|
||||
#
|
||||
# index_forum_thread_links_on_forum_thread_id (topic_id)
|
||||
# index_forum_thread_links_on_forum_thread_id_and_post_id_and_url (topic_id,post_id,url) UNIQUE
|
||||
# index_topic_links_on_extension (extension)
|
||||
# index_topic_links_on_link_post_id_and_reflection (link_post_id,reflection)
|
||||
# index_topic_links_on_post_id (post_id)
|
||||
# index_topic_links_on_topic_id (topic_id)
|
||||
# index_topic_links_on_user_and_clicks (user_id,clicks DESC,created_at DESC) WHERE ((NOT reflection) AND (NOT quote) AND (NOT internal))
|
||||
# index_topic_links_on_user_id (user_id)
|
||||
# unique_post_links (topic_id,post_id,url) UNIQUE
|
||||
#
|
||||
|
|
|
@ -0,0 +1,29 @@
|
|||
# frozen_string_literal: true
|
||||
|
||||
class AddUserProfileIndexes < ActiveRecord::Migration[6.0]
|
||||
disable_ddl_transaction!
|
||||
|
||||
def up
|
||||
execute <<~SQL
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS index_topic_links_on_user_and_clicks
|
||||
ON topic_links(user_id, clicks DESC, created_at DESC)
|
||||
WHERE (NOT reflection and NOT quote and NOT internal)
|
||||
SQL
|
||||
|
||||
execute <<~SQL
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS index_posts_user_and_likes
|
||||
ON posts(user_id, like_count desc, created_at desc)
|
||||
WHERE post_number > 1
|
||||
SQL
|
||||
end
|
||||
|
||||
def down
|
||||
execute <<~SQL
|
||||
DROP INDEX IF EXISTS index_posts_user_and_likes
|
||||
SQL
|
||||
|
||||
execute <<~SQL
|
||||
DROP INDEX IF EXISTS index_topic_links_on_user_and_clicks
|
||||
SQL
|
||||
end
|
||||
end
|
Loading…
Reference in New Issue