From d3dd952cc585e63dcfacd6ac21abf4289294b605 Mon Sep 17 00:00:00 2001 From: Chocobozzz Date: Wed, 25 Oct 2023 16:15:41 +0200 Subject: [PATCH] Try to optimize tagsOneOf/tagsAllOf SQL queries Using a CTE because the query will probably return a few results I tried a IN clause but PG doesn't seem to be more efficient with it The CTE seems to be the only choice --- .../sql/video/videos-id-list-query-builder.ts | 18 ++++++++++-------- 1 file changed, 10 insertions(+), 8 deletions(-) diff --git a/server/core/models/video/sql/video/videos-id-list-query-builder.ts b/server/core/models/video/sql/video/videos-id-list-query-builder.ts index 090eaddbc..01a877c57 100644 --- a/server/core/models/video/sql/video/videos-id-list-query-builder.ts +++ b/server/core/models/video/sql/video/videos-id-list-query-builder.ts @@ -434,28 +434,30 @@ export class VideosIdListQueryBuilder extends AbstractRunQuery { private whereTagsOneOf (tagsOneOf: string[]) { const tagsOneOfLower = tagsOneOf.map(t => t.toLowerCase()) - this.and.push( - 'EXISTS (' + - ' SELECT 1 FROM "videoTag" ' + + this.cte.push( + '"tagsOneOf" AS (' + + ' SELECT "videoTag"."videoId" AS "videoId" FROM "videoTag" ' + ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' + ' WHERE lower("tag"."name") IN (' + createSafeIn(this.sequelize, tagsOneOfLower) + ') ' + - ' AND "video"."id" = "videoTag"."videoId"' + ')' ) + + this.joins.push('INNER JOIN "tagsOneOf" ON "video"."id" = "tagsOneOf"."videoId"') } private whereTagsAllOf (tagsAllOf: string[]) { const tagsAllOfLower = tagsAllOf.map(t => t.toLowerCase()) - this.and.push( - 'EXISTS (' + - ' SELECT 1 FROM "videoTag" ' + + this.cte.push( + '"tagsAllOf" AS (' + + ' SELECT "videoTag"."videoId" AS "videoId" FROM "videoTag" ' + ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' + ' WHERE lower("tag"."name") IN (' + createSafeIn(this.sequelize, tagsAllOfLower) + ') ' + - ' AND "video"."id" = "videoTag"."videoId" ' + ' GROUP BY "videoTag"."videoId" HAVING COUNT(*) = ' + tagsAllOfLower.length + ')' ) + + this.joins.push('INNER JOIN "tagsAllOf" ON "video"."id" = "tagsAllOf"."videoId"') } private wherePrivacyOneOf (privacyOneOf: VideoPrivacyType[]) {