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 account media query #10121

Merged
merged 1 commit into from
Feb 26, 2019
Merged

Improve account media query #10121

merged 1 commit into from
Feb 26, 2019

Conversation

abcang
Copy link
Contributor

@abcang abcang commented Feb 26, 2019

By narrowing down by statuses.account_id, index_statuses_20180106 can be used and it becomes faster.

before:

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 "statuses"."id" IN (SELECT "mentions"."status_id" FROM "mentions" WHERE "mentions"."account_id" = yyy)) AND (statuses.created_at <= '2019-02-26 09:21:23.846620') ORDER BY "statuses"."id" DESC LIMIT 20
Limit  (cost=3609.37..29375.14 rows=20 width=8)
  ->  Unique  (cost=3609.37..75266716.19 rows=58421 width=8)
        ->  Merge Join  (cost=3609.37..75266570.13 rows=58421 width=8)
              Merge Cond: (statuses.id = media_attachments.status_id)
              ->  Index Scan Backward using statuses_pkey on statuses  (cost=3374.35..74945413.91 rows=121241046 width=8)
                    Filter: ((created_at <= '2019-02-26 09:21:23.84662'::timestamp without time zone) AND ((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..3370.75 rows=1211 width=8)
                            Index Cond: (account_id = yyy)
              ->  Index Only Scan Backward using index_media_attachments_on_account_id_and_status_id on media_attachments  (cost=0.56..17317.88 rows=60723 width=8)
                    Index Cond: (account_id = xxx)

after:

SELECT  DISTINCT "statuses"."id" FROM "statuses" INNER JOIN "media_attachments" ON "media_attachments"."status_id" = "statuses"."id" WHERE "statuses"."account_id" = xxx AND "media_attachments"."account_id" = xxx AND ("statuses"."visibility" IN (0, 1) OR "statuses"."id" IN (SELECT "mentions"."status_id" FROM "mentions" WHERE "mentions"."account_id" = yyy)) AND (statuses.created_at <= '2019-02-26 09:21:23.846620') ORDER BY "statuses"."id" DESC LIMIT 20
Limit  (cost=3609.37..42304.73 rows=4 width=8)
  ->  Unique  (cost=3609.37..42304.73 rows=4 width=8)
        ->  Merge Join  (cost=3609.37..42304.72 rows=4 width=8)
              Merge Cond: (statuses.id = media_attachments.status_id)
              ->  Index Scan using index_statuses_20180106 on statuses  (cost=3374.35..24816.73 rows=7419 width=8)
                    Index Cond: (account_id = xxx)
                    Filter: ((created_at <= '2019-02-26 09:21:23.84662'::timestamp without time zone) AND ((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..3370.75 rows=1211 width=8)
                            Index Cond: (account_id = yyy)
              ->  Index Only Scan Backward using index_media_attachments_on_account_id_and_status_id on media_attachments  (cost=0.56..17317.88 rows=60723 width=8)
                    Index Cond: (account_id = xxx)

@abcang abcang added the performance Runtime performance label Feb 26, 2019
Copy link
Contributor

@ClearlyClaire ClearlyClaire left a comment

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

LGTM!

Hm, looking at the query, I'm wondering where does that created_at query come from? I don't know how expensive it is, but it doesn't seem relevent.

@abcang
Copy link
Contributor Author

abcang commented Feb 26, 2019

Oh, I'm sorry. Please ignore created_at because it is due to extension of Pawoo. It does not affect query improvement.

@Gargron Gargron merged commit a5e7ada into master Feb 26, 2019
@ykzts ykzts deleted the abcang-patch-1 branch February 26, 2019 14:29
Gargron pushed a commit that referenced this pull request Mar 5, 2019
hiyuki2578 pushed a commit to ProjectMyosotis/mastodon that referenced this pull request Oct 2, 2019
messenjahofchrist pushed a commit to Origin-Creative/mastodon that referenced this pull request Jul 30, 2021
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
performance Runtime performance
Projects
None yet
Development

Successfully merging this pull request may close these issues.

4 participants