backend: improve removeMentionedRemoteUsersColumn revert query (#403)
This is an optimized version made by Volpeon that should run faster if the instance has a lot of notes. See <https://is-a.wyvern.rip/notes/9habqldl6j> for a comparison of the EXPLAIN ANALYZE of the old and new queries. Co-authored-by: Volpeon <git@volpeon.ink> Reviewed-on: #403
This commit is contained in:
parent
650b797fd6
commit
dbe2b7611d
1 changed files with 9 additions and 1 deletions
|
@ -7,6 +7,14 @@ export class removeMentionedRemoteUsersColumn1661376843000 {
|
|||
|
||||
async down(queryRunner) {
|
||||
await queryRunner.query(`ALTER TABLE "note" ADD "mentionedRemoteUsers" TEXT NOT NULL DEFAULT '[]'::text`);
|
||||
await queryRunner.query(`UPDATE "note" SET "mentionedRemoteUsers" = (SELECT COALESCE(json_agg(row_to_json("data"))::text, '[]') FROM (SELECT "url", "uri", "username", "host" FROM "user" JOIN "user_profile" ON "user"."id" = "user_profile". "userId" WHERE "user"."host" IS NOT NULL AND "user"."id" = ANY("note"."mentions")) AS "data")`);
|
||||
await queryRunner.query(`CREATE TEMP TABLE IF NOT EXISTS "temp_mentions" AS
|
||||
SELECT "id", "url", "uri", "username", "host"
|
||||
FROM "user"
|
||||
JOIN "user_profile" ON "user"."id" = "user_profile". "userId" WHERE "user"."host" IS NOT NULL`);
|
||||
await queryRunner.query(`CREATE UNIQUE INDEX "temp_mentions_id" ON "temp_mentions"("id")`);
|
||||
await queryRunner.query(`UPDATE "note" SET "mentionedRemoteUsers" = (
|
||||
SELECT COALESCE(json_agg(row_to_json("data")::jsonb - 'id')::text, '[]') FROM "temp_mentions" AS "data"
|
||||
WHERE "data"."id" = ANY("note"."mentions")
|
||||
)`);
|
||||
}
|
||||
}
|
||||
|
|
Loading…
Reference in a new issue