Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Improve performance of account_media_status_ids #6729

Merged
merged 1 commit into from Mar 10, 2018

Conversation

abcang
Copy link
Contributor

@abcang abcang commented Mar 10, 2018

I optimized queries used in the account's media timeline. Avoid getting slow by not narrowing down by statuses.account_id. When narrowing down by statuses.account_id, index_statuses_20180106 will be used and the table will be joined by Merge Join, so the query will be slow.

Before

Query

SELECT  "statuses"."id", "statuses"."updated_at" FROM "statuses" WHERE ("statuses"."account_id" = xxx AND "statuses"."visibility" IN (0, 1) OR "statuses"."account_id" = xxx AND "statuses"."id" IN (SELECT "mentions"."status_id" FROM "mentions" WHERE "mentions"."account_id" = yyy)) AND "statuses"."id" IN (SELECT DISTINCT "media_attachments"."status_id" FROM "media_attachments" WHERE "media_attachments"."account_id" = xxx AND ("media_attachments"."status_id" IS NOT NULL)) ORDER BY "statuses"."id" DESC LIMIT 20

Explain (no cache)

Limit  (cost=868.83..7832.66 rows=1 width=16) (actual time=51.901..4777.568 rows=20 loops=1)
  ->  Merge Semi Join  (cost=868.83..7832.66 rows=1 width=16) (actual time=51.900..4777.552 rows=20 loops=1)
        Merge Cond: (statuses.id = media_attachments.status_id)
        ->  Index Only Scan using index_statuses_20180106 on statuses  (cost=849.09..7802.43 rows=4023 width=16) (actual time=0.035..4769.964 rows=11964 loops=1)
              Index Cond: (account_id = xxx)
              Filter: ((visibility = ANY ('{0,1}'::integer[])) OR (hashed SubPlan 1))
              Rows Removed by Filter: 47
              Heap Fetches: 10083
              SubPlan 1
                ->  Index Only Scan using index_mentions_on_account_id_and_status_id on mentions  (cost=0.56..846.76 rows=707 width=8) (actual time=1.424..35.352 rows=433 loops=1)
                      Index Cond: (account_id = yyy)
                      Heap Fetches: 357
        ->  Sort  (cost=19.74..19.95 rows=86 width=8) (actual time=0.169..0.185 rows=20 loops=1)
              Sort Key: media_attachments.status_id DESC
              Sort Method: quicksort  Memory: 29kB
              ->  Unique  (cost=0.43..16.12 rows=86 width=8) (actual time=0.030..0.129 rows=95 loops=1)
                    ->  Index Only Scan using index_media_attachments_on_account_id_and_status_id on media_attachments  (cost=0.43..15.37 rows=297 width=8) (actual time=0.029..0.079 rows=121 loops=1)
                          Index Cond: ((account_id = xxx) AND (status_id IS NOT NULL))
                          Heap Fetches: 0
Planning time: 0.255 ms
Execution time: 4777.627 ms

Explain (cached)

Limit  (cost=868.83..7832.66 rows=1 width=16) (actual time=0.887..38.946 rows=20 loops=1)
  ->  Merge Semi Join  (cost=868.83..7832.66 rows=1 width=16) (actual time=0.886..38.937 rows=20 loops=1)
        Merge Cond: (statuses.id = media_attachments.status_id)
        ->  Index Only Scan using index_statuses_20180106 on statuses  (cost=849.09..7802.43 rows=4023 width=16) (actual time=0.035..35.264 rows=11964 loops=1)
              Index Cond: (account_id = xxx)
              Filter: ((visibility = ANY ('{0,1}'::integer[])) OR (hashed SubPlan 1))
              Rows Removed by Filter: 47
              Heap Fetches: 10080
              SubPlan 1
                ->  Index Only Scan using index_mentions_on_account_id_and_status_id on mentions  (cost=0.56..846.76 rows=707 width=8) (actual time=0.046..1.427 rows=433 loops=1)
                      Index Cond: (account_id = yyy)
                      Heap Fetches: 357
        ->  Sort  (cost=19.74..19.95 rows=86 width=8) (actual time=0.160..0.168 rows=20 loops=1)
              Sort Key: media_attachments.status_id DESC
              Sort Method: quicksort  Memory: 29kB
              ->  Unique  (cost=0.43..16.12 rows=86 width=8) (actual time=0.021..0.121 rows=95 loops=1)
                    ->  Index Only Scan using index_media_attachments_on_account_id_and_status_id on media_attachments  (cost=0.43..15.37 rows=297 width=8) (actual time=0.020..0.052 rows=121 loops=1)
                          Index Cond: ((account_id = xxx) AND (status_id IS NOT NULL))
                          Heap Fetches: 0
Planning time: 0.258 ms
Execution time: 39.017 ms

After

Query 1

SELECT  DISTINCT "statuses"."id" FROM "statuses" INNER JOIN "media_attachments" ON "media_attachments"."status_id" = "statuses"."id" WHERE ("media_attachments"."account_id" = xxx AND "statuses"."visibility" IN (0, 1) OR "media_attachments"."account_id" = xxx AND "statuses"."id" IN (SELECT "mentions"."status_id" FROM "mentions" WHERE "mentions"."account_id" = yyy)) ORDER BY "statuses"."id" DESC LIMIT 20

Explain (no cache)

Limit  (cost=849.53..18367.77 rows=20 width=8) (actual time=0.041..4.785 rows=20 loops=1)
  ->  Unique  (cost=849.53..253988.16 rows=289 width=8) (actual time=0.039..4.773 rows=20 loops=1)
        ->  Nested Loop  (cost=849.53..253987.44 rows=289 width=8) (actual time=0.039..4.751 rows=27 loops=1)
              ->  Index Only Scan Backward using index_media_attachments_on_account_id_and_status_id on media_attachments  (cost=0.43..14.63 rows=297 width=8) (actual time=0.021..0.050 rows=27 loops=1)
                    Index Cond: (account_id = xxx)
                    Heap Fetches: 0
              ->  Index Scan using statuses_pkey on statuses  (cost=849.09..855.12 rows=1 width=8) (actual time=0.172..0.173 rows=1 loops=27)
                    Index Cond: (id = media_attachments.status_id)
                    Filter: ((visibility = ANY ('{0,1}'::integer[])) OR (hashed SubPlan 1))
                    SubPlan 1
                      ->  Index Only Scan using index_mentions_on_account_id_and_status_id on mentions  (cost=0.56..846.76 rows=707 width=8) (never executed)
                            Index Cond: (account_id = yyy)
                            Heap Fetches: 0
Planning time: 0.306 ms
Execution time: 4.827 ms

Explain (cached)

Limit  (cost=849.53..18367.77 rows=20 width=8) (actual time=0.045..0.357 rows=20 loops=1)
  ->  Unique  (cost=849.53..253988.16 rows=289 width=8) (actual time=0.045..0.348 rows=20 loops=1)
        ->  Nested Loop  (cost=849.53..253987.44 rows=289 width=8) (actual time=0.043..0.334 rows=27 loops=1)
              ->  Index Only Scan Backward using index_media_attachments_on_account_id_and_status_id on media_attachments  (cost=0.43..14.63 rows=297 width=8) (actual time=0.019..0.032 rows=27 loops=1)
                    Index Cond: (account_id = xxx)
                    Heap Fetches: 0
              ->  Index Scan using statuses_pkey on statuses  (cost=849.09..855.12 rows=1 width=8) (actual time=0.010..0.010 rows=1 loops=27)
                    Index Cond: (id = media_attachments.status_id)
                    Filter: ((visibility = ANY ('{0,1}'::integer[])) OR (hashed SubPlan 1))
                    SubPlan 1
                      ->  Index Only Scan using index_mentions_on_account_id_and_status_id on mentions  (cost=0.56..846.76 rows=707 width=8) (never executed)
                            Index Cond: (account_id = yyy)
                            Heap Fetches: 0
Planning time: 0.314 ms
Execution time: 0.397 ms

Query 2

SELECT  "statuses"."id", "statuses"."updated_at" FROM "statuses" WHERE "statuses"."account_id" = xxx AND "statuses"."id" IN (aaaa, bbbb, cccc, dddd, eeee, ffff, gggg, hhhh, iiii, jjjj, kkkk, llll, mmmm, nnnn, oooo, pppp, qqqq, rrrr, ssss, tttt) ORDER BY "statuses"."id" DESC LIMIT 20

Explain

Limit  (cost=74.52..74.53 rows=1 width=16) (actual time=0.220..0.229 rows=15 loops=1)
  ->  Sort  (cost=74.52..74.53 rows=1 width=16) (actual time=0.220..0.224 rows=15 loops=1)
        Sort Key: id DESC
        Sort Method: quicksort  Memory: 25kB
        ->  Index Only Scan using index_statuses_20180106 on statuses  (cost=0.56..74.51 rows=1 width=16) (actual time=0.051..0.208 rows=15 loops=1)
              Index Cond: ((account_id = xxx) AND (id = ANY ('{aaaa,bbbb,cccc,dddd,eeee,ffff,gggg,hhhh,iiii,jjjj,kkkk,llll,mmmm,nnnn,oooo,pppp,qqqq,rrrr,ssss,tttt}'::bigint[])))
              Heap Fetches: 15
Planning time: 0.117 ms
Execution time: 0.254 ms

@Gargron Gargron merged commit 37b043d into mastodon:master Mar 10, 2018
@abcang abcang deleted the improve_account_media_status branch March 10, 2018 16:45
smorimoto pushed a commit to kibousoft/mastodon that referenced this pull request Apr 26, 2018
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

None yet

2 participants