Skip to content

Commit

Permalink
refactor: improve migration to reduce downtime
Browse files Browse the repository at this point in the history
  • Loading branch information
omBratteng committed Nov 5, 2024
1 parent 1462ba3 commit 07d84e8
Showing 1 changed file with 23 additions and 8 deletions.
31 changes: 23 additions & 8 deletions src/migration/1730717128269-UserStatsTopReader.ts
Original file line number Diff line number Diff line change
Expand Up @@ -4,10 +4,8 @@ export class UserStatsTopReader1730717128269 implements MigrationInterface {
name = 'UserStatsTopReader1730717128269'

public async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(`DELETE FROM "public"."typeorm_metadata" WHERE "type" = $1 AND "name" = $2 AND "schema" = $3`, ["MATERIALIZED_VIEW","user_stats","public"]);
await queryRunner.query(`DROP MATERIALIZED VIEW "user_stats"`);

await queryRunner.query(`CREATE MATERIALIZED VIEW "user_stats" AS SELECT u."id", (SELECT COALESCE(COUNT(*), 0)
// Create the new view as a temporary view
await queryRunner.query(`CREATE MATERIALIZED VIEW "user_stats_tmp" AS SELECT u."id", (SELECT COALESCE(COUNT(*), 0)
FROM "user"
WHERE "referralId" = u."id"
) AS "referrals", (SELECT COALESCE(SUM(p."views"), 0)
Expand All @@ -27,14 +25,22 @@ export class UserStatsTopReader1730717128269 implements MigrationInterface {
FROM "user_top_reader" utp
WHERE utp."userId" = u."id"
) AS "topReaderBadges" FROM "public"."user" "u" WHERE "u"."infoConfirmed" = TRUE AND "u"."id" != '404'`);

// Rename the current view to the old view
await queryRunner.query(`ALTER TABLE "public"."user_stats" RENAME TO "user_stats_old"`);
// Rename the temporary view to the current view
await queryRunner.query(`ALTER TABLE "public"."user_stats_tmp" RENAME TO "user_stats"`);
// Drop the old view
await queryRunner.query(`DROP MATERIALIZED VIEW "user_stats_old"`);

// Metadata
await queryRunner.query(`DELETE FROM "public"."typeorm_metadata" WHERE "type" = $1 AND "name" = $2 AND "schema" = $3`, ["MATERIALIZED_VIEW","user_stats","public"]);
await queryRunner.query(`INSERT INTO "public"."typeorm_metadata"("database", "schema", "table", "type", "name", "value") VALUES (DEFAULT, $1, DEFAULT, $2, $3, $4)`, ["public","MATERIALIZED_VIEW","user_stats","SELECT u.\"id\", (SELECT COALESCE(COUNT(*), 0)\n FROM \"user\"\n WHERE \"referralId\" = u.\"id\"\n ) AS \"referrals\", (SELECT COALESCE(SUM(p.\"views\"), 0)\n FROM \"post\" p\n WHERE (p.\"authorId\" = u.\"id\" OR p.\"scoutId\" = u.\"id\")\n AND p.\"visible\" = TRUE\n AND p.\"deleted\" = FALSE\n ) AS \"views\", (SELECT COALESCE(SUM(p.\"upvotes\"), 0)\n FROM \"post\" p\n WHERE (p.\"authorId\" = u.\"id\" OR p.\"scoutId\" = u.\"id\")\n AND p.\"visible\" = TRUE\n AND p.\"deleted\" = FALSE\n ) AS \"postUpvotes\", (SELECT COALESCE(SUM(c.\"upvotes\"), 0)\n FROM \"comment\" c\n WHERE c.\"userId\" = u.\"id\"\n ) AS \"commentUpvotes\", (SELECT COALESCE(COUNT(*), 0)\n FROM \"user_top_reader\" utp\n WHERE utp.\"userId\" = u.\"id\"\n ) AS \"topReaderBadges\" FROM \"public\".\"user\" \"u\" WHERE \"u\".\"infoConfirmed\" = TRUE AND \"u\".\"id\" != '404'"]);
}

public async down(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(`DELETE FROM "public"."typeorm_metadata" WHERE "type" = $1 AND "name" = $2 AND "schema" = $3`, ["MATERIALIZED_VIEW","user_stats","public"]);
await queryRunner.query(`DROP MATERIALIZED VIEW "user_stats"`);

await queryRunner.query(`CREATE MATERIALIZED VIEW "user_stats" AS SELECT u."id", (SELECT COALESCE(COUNT(*), 0)
// Create the new view as a temporary view
await queryRunner.query(`CREATE MATERIALIZED VIEW "user_stats_tmp" AS SELECT u."id", (SELECT COALESCE(COUNT(*), 0)
FROM "user"
WHERE "referralId" = u."id"
) AS "referrals", (SELECT COALESCE(SUM(p."views"), 0)
Expand All @@ -51,6 +57,15 @@ export class UserStatsTopReader1730717128269 implements MigrationInterface {
FROM "comment" c
WHERE c."userId" = u."id"
) AS "commentUpvotes" FROM "public"."user" "u" WHERE "u"."infoConfirmed" = TRUE AND "u"."id" != '404'`);
// Rename the current view to the old view
await queryRunner.query(`ALTER TABLE "public"."user_stats" RENAME TO "user_stats_old"`);
// Rename the temporary view to the current view
await queryRunner.query(`ALTER TABLE "public"."user_stats_tmp" RENAME TO "user_stats"`);
// Drop the old view
await queryRunner.query(`DROP MATERIALIZED VIEW "user_stats_old"`);

// Metadata
await queryRunner.query(`DELETE FROM "public"."typeorm_metadata" WHERE "type" = $1 AND "name" = $2 AND "schema" = $3`, ["MATERIALIZED_VIEW","user_stats","public"]);
await queryRunner.query(`INSERT INTO "public"."typeorm_metadata"("database", "schema", "table", "type", "name", "value") VALUES (DEFAULT, $1, DEFAULT, $2, $3, $4)`, ["public","MATERIALIZED_VIEW","user_stats","SELECT u.\"id\", (SELECT COALESCE(COUNT(*), 0)\n FROM \"user\"\n WHERE \"referralId\" = u.\"id\"\n ) AS \"referrals\", (SELECT COALESCE(SUM(p.\"views\"), 0)\n FROM \"post\" p\n WHERE (p.\"authorId\" = u.\"id\" OR p.\"scoutId\" = u.\"id\")\n AND p.\"visible\" = TRUE\n AND p.\"deleted\" = FALSE\n ) AS \"views\", (SELECT COALESCE(SUM(p.\"upvotes\"), 0)\n FROM \"post\" p\n WHERE (p.\"authorId\" = u.\"id\" OR p.\"scoutId\" = u.\"id\")\n AND p.\"visible\" = TRUE\n AND p.\"deleted\" = FALSE\n ) AS \"postUpvotes\", (SELECT COALESCE(SUM(c.\"upvotes\"), 0)\n FROM \"comment\" c\n WHERE c.\"userId\" = u.\"id\"\n ) AS \"commentUpvotes\" FROM \"public\".\"user\" \"u\" WHERE \"u\".\"infoConfirmed\" = TRUE AND \"u\".\"id\" != '404'"]);
}

Expand Down

0 comments on commit 07d84e8

Please sign in to comment.