feat: optimize db queries (#297)

This commit is contained in:
Julian Tölle 2023-09-17 00:31:39 +02:00 committed by GitHub
parent fd28daa37a
commit dd57a52ab6
No known key found for this signature in database
GPG key ID: 4AEE18F83AFDEB23
5 changed files with 104 additions and 33 deletions

View file

@ -0,0 +1,72 @@
import { MigrationInterface, QueryRunner, TableIndex } from "typeorm";
export class OptimizeDBIndices0000000000008 implements MigrationInterface {
async up(queryRunner: QueryRunner): Promise<void> {
await queryRunner.createIndices("artist", [
new TableIndex({
// This index helps with the "update artist" job
name: "IDX_ARTIST_UPDATED_AT",
columnNames: ["updatedAt"],
}),
]);
await queryRunner.createIndices("listen", [
new TableIndex({
// This index helps with the "getCrawlableUserInfo" query
name: "IDX_LISTEN_USER_ID_PLAYED_AT",
columnNames: ["userId", "playedAt"],
}),
]);
// handled by Primary Key on (albumId, artistId)
await queryRunner.dropIndex("album_artist", "IDX_ALBUM_ARTISTS_ALBUM_ID");
// handled by Primary Key on (artistId, genreId)
await queryRunner.dropIndex("artist_genres", "IDX_ARTIST_GENRES_ARTIST_ID");
// handled by IDX_LISTEN_UNIQUE on (trackId, userId, playedAt)
await queryRunner.dropIndex("listen", "IDX_LISTEN_TRACK_ID");
// handled by IDX_LISTEN_USER_ID_PLAYED_AT on (userId, playedAt)
await queryRunner.dropIndex("listen", "IDX_LISTEN_USER_ID");
// handled by Primary Key on (trackId, artistId)
await queryRunner.dropIndex("track_artists", "IDX_TRACK_ARTISTS_TRACK_ID");
}
async down(queryRunner: QueryRunner): Promise<void> {
await queryRunner.createIndices("album_artist", [
new TableIndex({
name: "IDX_ALBUM_ARTISTS_ALBUM_ID",
columnNames: ["albumId"],
}),
]);
await queryRunner.createIndices("artist_genres", [
new TableIndex({
name: "IDX_ARTIST_GENRES_ARTIST_ID",
columnNames: ["artistId"],
}),
]);
await queryRunner.createIndices("listen", [
new TableIndex({
name: "IDX_LISTEN_TRACK_ID",
columnNames: ["trackId"],
}),
new TableIndex({
name: "IDX_LISTEN_USER_ID",
columnNames: ["userId"],
}),
]);
await queryRunner.createIndices("track_artists", [
new TableIndex({
name: "IDX_TRACK_ARTISTS_TRACK_ID",
columnNames: ["trackId"],
}),
]);
await queryRunner.dropIndex("artist", "IDX_ARTIST_UPDATED_AT");
await queryRunner.dropIndex("listen", "IDX_LISTEN_USER_ID_PLAYED_AT");
}
}

View file

@ -77,16 +77,6 @@ export class ListensService {
});
}
async getMostRecentListenPerUser(): Promise<Listen[]> {
return this.listenRepository
.createQueryBuilder("listen")
.leftJoinAndSelect("listen.user", "user")
.distinctOn(["user.id"])
.orderBy({ "user.id": "ASC", "listen.playedAt": "DESC" })
.limit(1)
.getMany();
}
getScopedQueryBuilder(): ListenScopes {
return this.listenRepository.scoped;
}

View file

@ -53,7 +53,7 @@ export class SchedulerService implements OnApplicationBootstrap {
const INACTIVE_CUTOFF_MSEC = 60 * 60 * 1000;
await Promise.all(
userInfo.map(({ user, lastListen }) => {
userInfo.map(({ userID, lastListen }) => {
let pollRate = POLL_RATE_INACTIVE_SEC;
const timeSinceLastListen = new Date().getTime() - lastListen.getTime();
@ -62,10 +62,10 @@ export class SchedulerService implements OnApplicationBootstrap {
}
this.importSpotifyJobService.sendThrottled(
{ userID: user.id },
{ userID },
{},
pollRate,
user.id,
userID,
);
}),
);

View file

@ -43,27 +43,31 @@ export class SpotifyService {
) {}
@Span()
async getCrawlableUserInfo(): Promise<{ user: User; lastListen: Date }[]> {
// All of this is kinda inefficient, we do two db queries and join in code,
// i can't be bothered to do this properly in the db for now.
// Should be refactored if listory gets hundreds of users (lol).
async getCrawlableUserInfo(): Promise<
{ userID: string; lastListen: Date }[]
> {
const users = await this.usersService
.getQueryBuilder()
.select(`user.id as "userID"`)
.addSelect(`listen."playedAt" as "lastListen"`)
.leftJoin(
(qb) =>
qb
.distinctOn(["listen.userId"])
.select(`listen."userId"`)
.addSelect(`listen."playedAt"`)
.from("listen", "listen")
.orderBy("listen.userId", "DESC")
.addOrderBy("listen.playedAt", "DESC"),
"listen",
`listen."userId" = user.id`,
)
.getRawMany<{ userID: string; lastListen?: Date }>();
const [users, listens] = await Promise.all([
this.usersService.findAll(),
this.listensService.getMostRecentListenPerUser(),
]);
return users.map((user) => {
const lastListen = listens.find((listen) => listen.user.id === user.id);
return {
user,
// Return 1970 if no listen exists
lastListen: lastListen ? lastListen.playedAt : new Date(0),
};
});
return;
return users.map(({ userID, lastListen }) => ({
userID,
lastListen: lastListen || new Date(0),
}));
}
@ImportSpotifyJob.Handle()

View file

@ -1,3 +1,4 @@
import { SelectQueryBuilder } from "typeorm";
import { JobService } from "@apricote/nest-pg-boss";
import { Injectable, NotFoundException } from "@nestjs/common";
import { IImportSpotifyJob, ImportSpotifyJob } from "../sources/jobs";
@ -65,4 +66,8 @@ export class UsersService {
user.spotify = spotify;
await this.userRepository.save(user);
}
getQueryBuilder(): SelectQueryBuilder<User> {
return this.userRepository.createQueryBuilder("user");
}
}