Skip to content

Commit

Permalink
allow refresh concurrently of materialized views
Browse files Browse the repository at this point in the history
  • Loading branch information
CarlosQ96 committed Jun 7, 2024
1 parent 11e59a4 commit cd21204
Show file tree
Hide file tree
Showing 15 changed files with 626 additions and 45 deletions.
63 changes: 63 additions & 0 deletions migration/1717643016553-ProjectFuturePowerView_V2.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,63 @@
import { MigrationInterface, QueryRunner } from 'typeorm';

export class ProjectFuturePowerViewV21717643016553
implements MigrationInterface
{
public async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(
`
DROP
MATERIALIZED VIEW IF EXISTS public.project_future_power_view;
CREATE MATERIALIZED VIEW IF NOT EXISTS public.project_future_power_view AS
SELECT
innerview."projectId",
innerview."totalPower",
rank() OVER (
ORDER BY
innerview."totalPower" DESC
) AS "powerRank",
"powerRound".round + 1 as "round"
FROM
(
SELECT
project.id AS "projectId",
CASE project.verified and project."statusId" = 5 WHEN false THEN 0 :: double precision ELSE COALESCE(
sum(pp."boostedPower"),
0 :: double precision
) END AS "totalPower"
FROM
project project
JOIN (
SELECT
"powerRound".round,
"powerBoostingSnapshot"."projectId",
"powerBoostingSnapshot"."userId",
avg(
"powerBalanceSnapshot".balance * "powerBoostingSnapshot".percentage :: double precision / 100 :: double precision
) AS "boostedPower",
now() AS "updateTime"
FROM
power_round "powerRound"
JOIN power_snapshot "powerSnapshot" ON "powerSnapshot"."roundNumber" = "powerRound".round + 1 and "powerSnapshot".synced = true
JOIN power_balance_snapshot "powerBalanceSnapshot" ON "powerBalanceSnapshot"."powerSnapshotId" = "powerSnapshot".id
JOIN power_boosting_snapshot "powerBoostingSnapshot" ON "powerBoostingSnapshot"."powerSnapshotId" = "powerSnapshot".id
AND "powerBoostingSnapshot"."userId" = "powerBalanceSnapshot"."userId"
GROUP BY
"powerRound".round,
"powerBoostingSnapshot"."projectId",
"powerBoostingSnapshot"."userId"
) pp ON pp."projectId" = project.id
GROUP BY
project.id
) innerview,
power_round "powerRound"
ORDER BY
innerview."totalPower" DESC WITH DATA;
CREATE UNIQUE INDEX project_future_power_view_project_id_unique ON public.project_future_power_view ("projectId");
CREATE INDEX project_future_power_view_project_id ON public.project_future_power_view USING hash ("projectId") TABLESPACE pg_default;
`,
);
}

public async down(_queryRunner: QueryRunner): Promise<void> {}
}
62 changes: 62 additions & 0 deletions migration/1717643739652-ProjectPowerView_V2.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,62 @@
import { MigrationInterface, QueryRunner } from 'typeorm';

export class ProjectPowerViewV21717643739652 implements MigrationInterface {
public async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(
`
DROP
MATERIALIZED VIEW IF EXISTS public.project_power_view;
CREATE MATERIALIZED VIEW IF NOT EXISTS public.project_power_view AS
SELECT
innerview."projectId",
ROUND(CAST(innerview."totalPower" as NUMERIC), 2) as "totalPower",
rank() OVER (
ORDER BY
innerview."totalPower" DESC
) AS "powerRank",
"powerRound".round
FROM
(
SELECT
project.id AS "projectId",
CASE project.verified and project."statusId" = 5 WHEN false THEN 0 :: double precision ELSE COALESCE(
sum(pp."boostedPower"),
0 :: double precision
) END AS "totalPower"
FROM
project project
LEFT JOIN (
SELECT
"powerRound".round,
"powerBoostingSnapshot"."projectId",
"powerBoostingSnapshot"."userId",
avg(
"powerBalanceSnapshot".balance * "powerBoostingSnapshot".percentage :: double precision / 100 :: double precision
) AS "boostedPower",
now() AS "updateTime"
FROM
power_round "powerRound"
JOIN power_snapshot "powerSnapshot" ON "powerSnapshot"."roundNumber" = "powerRound".round
JOIN power_balance_snapshot "powerBalanceSnapshot" ON "powerBalanceSnapshot"."powerSnapshotId" = "powerSnapshot".id
JOIN power_boosting_snapshot "powerBoostingSnapshot" ON "powerBoostingSnapshot"."powerSnapshotId" = "powerSnapshot".id
AND "powerBoostingSnapshot"."userId" = "powerBalanceSnapshot"."userId"
GROUP BY
"powerRound".round,
"powerBoostingSnapshot"."projectId",
"powerBoostingSnapshot"."userId"
) pp ON pp."projectId" = project.id
GROUP BY
project.id
) innerview,
power_round "powerRound"
ORDER BY
innerview."totalPower" DESC WITH DATA;
CREATE UNIQUE INDEX project_power_view_project_id_round_unique ON public.project_power_view ("projectId", "round");
CREATE INDEX project_power_view_project_id ON public.project_power_view USING hash ("projectId") TABLESPACE pg_default;
CREATE INDEX project_power_view_total_power ON public.project_power_view USING btree ("totalPower" DESC) TABLESPACE pg_default;
`,
);
}

public async down(_queryRunner: QueryRunner): Promise<void> {}
}
37 changes: 37 additions & 0 deletions migration/1717644442966-ProjectUserInstantPowerView_V2.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,37 @@
import { MigrationInterface, QueryRunner } from 'typeorm';

export class ProjectUserInstantPowerViewV21717644442966
implements MigrationInterface
{
public async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(`
DROP MATERIALIZED VIEW IF EXISTS PUBLIC.PROJECT_USER_INSTANT_POWER_VIEW;
CREATE MATERIALIZED VIEW IF NOT EXISTS PUBLIC.PROJECT_USER_INSTANT_POWER_VIEW AS
SELECT "powerBoosting"."id",
"powerBoosting"."projectId",
"powerBoosting"."userId",
("instantPowerBalance".BALANCE * "powerBoosting".PERCENTAGE :: double precision / 100 :: double precision) AS "boostedPower",
NOW() AS "updateTime"
FROM INSTANT_POWER_BALANCE "instantPowerBalance"
JOIN POWER_BOOSTING "powerBoosting" ON "powerBoosting"."userId" = "instantPowerBalance"."userId";
`);

await queryRunner.query(`
CREATE UNIQUE INDEX project_user_instant_power_view_id ON public.project_user_instant_power_view ("id");
`);

await queryRunner.query(`
CREATE UNIQUE INDEX project_user_instant_power_view_project_user_id ON public.project_user_instant_power_view ("projectId", "userId");
`);

await queryRunner.query(`
CREATE INDEX project_user_instant_power_view_project_id ON PUBLIC.PROJECT_USER_INSTANT_POWER_VIEW USING hash ("projectId") TABLESPACE pg_default;
`);
await queryRunner.query(`
CREATE INDEX PROJECT_USER_INSTANT_POWER_VIEW_TOTAL_POWER ON PUBLIC.PROJECT_USER_INSTANT_POWER_VIEW USING BTREE ("boostedPower" DESC) TABLESPACE PG_DEFAULT;
`);
}

public async down(_queryRunner: QueryRunner): Promise<void> {}
}
36 changes: 36 additions & 0 deletions migration/1717645768886-UserProjectPowerView_V2.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
import { MigrationInterface, QueryRunner } from 'typeorm';

export class UserProjectPowerViewV21717645768886 implements MigrationInterface {
public async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(
`
DROP
MATERIALIZED VIEW IF EXISTS public.user_project_power_view;
CREATE MATERIALIZED VIEW IF NOT EXISTS PUBLIC.USER_PROJECT_POWER_VIEW TABLESPACE PG_DEFAULT AS
SELECT
row_number() over() as "id",
"powerRound".ROUND,
"powerBoostingSnapshot"."projectId" as "projectId",
"powerBoostingSnapshot"."userId" as "userId",
avg(
"powerBalanceSnapshot".balance * "powerBoostingSnapshot".PERCENTAGE :: double precision / 100 :: double precision
) AS "boostedPower"
FROM
POWER_ROUND "powerRound"
JOIN POWER_SNAPSHOT "powerSnapshot" ON "powerSnapshot"."roundNumber" = "powerRound".ROUND
JOIN POWER_BALANCE_SNAPSHOT "powerBalanceSnapshot" ON "powerBalanceSnapshot"."powerSnapshotId" = "powerSnapshot".id
JOIN POWER_BOOSTING_SNAPSHOT "powerBoostingSnapshot" ON "powerBoostingSnapshot"."powerSnapshotId" = "powerSnapshot".id
and "powerBoostingSnapshot"."userId" = "powerBalanceSnapshot"."userId"
group by
round,
"powerBoostingSnapshot"."projectId",
"powerBoostingSnapshot"."userId";
CREATE UNIQUE INDEX user_project_power_view_id_idx ON PUBLIC.USER_PROJECT_POWER_VIEW(id);
CREATE INDEX USER_PROJECT_POWER_VIEW_POWER_BOOSTED ON PUBLIC.USER_PROJECT_POWER_VIEW USING BTREE ("boostedPower" DESC) TABLESPACE PG_DEFAULT;
CREATE INDEX USER_PROJECT_POWER_VIEW_PROJECT_ID ON PUBLIC.USER_PROJECT_POWER_VIEW USING HASH ("projectId") TABLESPACE PG_DEFAULT;
`,
);
}

public async down(_queryRunner: QueryRunner): Promise<void> {}
}
55 changes: 55 additions & 0 deletions migration/1717646357435-ProjectEstimatedMatchingView_V2.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,55 @@
import { MigrationInterface, QueryRunner } from 'typeorm';

export class ProjectEstimatedMatchingViewV21717646357435
implements MigrationInterface
{
public async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(
`
DROP MATERIALIZED VIEW IF EXISTS project_estimated_matching_view;
CREATE MATERIALIZED VIEW project_estimated_matching_view AS
SELECT
donations_by_user."projectId",
donations_by_user."qfRoundId",
SUM(donations_by_user."valueUsd") as "sumValueUsd",
COUNT(*) as "uniqueDonorsCount",
SUM(SQRT(donations_by_user."valueUsd")) as "sqrtRootSum",
POWER(SUM(SQRT(donations_by_user."valueUsd")), 2) as "sqrtRootSumSquared",
COUNT(donations_by_user."userId") as "donorsCount"
FROM (
SELECT
"donation"."projectId",
"donation"."qfRoundId",
SUM("donation"."valueUsd") as "valueUsd",
"donation"."userId"
FROM
"donation"
INNER JOIN "user" ON "user"."id" = "donation"."userId"
INNER JOIN "qf_round" ON "qf_round"."id" = "donation"."qfRoundId"
WHERE
"donation"."status" = 'verified'
AND "donation"."createdAt" BETWEEN "qf_round"."beginDate" AND "qf_round"."endDate"
GROUP BY
"donation"."projectId",
"donation"."qfRoundId",
"donation"."userId"
) as donations_by_user
GROUP BY
donations_by_user."projectId",
donations_by_user."qfRoundId";
CREATE INDEX idx_project_estimated_matching_project_id ON project_estimated_matching_view USING hash ("projectId");
CREATE INDEX idx_project_estimated_matching_qf_round_id ON project_estimated_matching_view USING btree ("qfRoundId");
CREATE UNIQUE INDEX idx_project_estimated_matching_unique ON project_estimated_matching_view ("projectId", "qfRoundId");
`,
);
}

public async down(queryRunner: QueryRunner): Promise<void> {
await queryRunner.query(
`
DROP MATERIALIZED VIEW project_estimated_matching_view;
`,
);
}
}
Loading

0 comments on commit cd21204

Please sign in to comment.