From 6b842050f7b0820bbd3051d9bfec1fffdf6d8df4 Mon Sep 17 00:00:00 2001 From: Chocobozzz Date: Mon, 9 Mar 2020 14:44:44 +0100 Subject: Wrap videos list query in raw SQL --- server/models/account/user-video-history.ts | 2 +- server/models/video/video-query-builder.ts | 218 ++++++++++++++++++++++------ server/models/video/video.ts | 157 +++++++++++++++----- 3 files changed, 292 insertions(+), 85 deletions(-) diff --git a/server/models/account/user-video-history.ts b/server/models/account/user-video-history.ts index 3fe4c8db1..522eebeaf 100644 --- a/server/models/account/user-video-history.ts +++ b/server/models/account/user-video-history.ts @@ -59,7 +59,7 @@ export class UserVideoHistoryModel extends Model { return VideoModel.listForApi({ start, count, - sort: '-UserVideoHistories.updatedAt', + sort: '-"userVideoHistory"."updatedAt"', nsfw: null, // All includeLocalVideos: true, withFiles: false, diff --git a/server/models/video/video-query-builder.ts b/server/models/video/video-query-builder.ts index c4b31e58e..61f628c06 100644 --- a/server/models/video/video-query-builder.ts +++ b/server/models/video/video-query-builder.ts @@ -52,9 +52,9 @@ export type BuildVideosQueryOptions = { function buildListQuery (model: typeof Model, options: BuildVideosQueryOptions) { const and: string[] = [] - const cte: string[] = [] const joins: string[] = [] const replacements: any = {} + const cte: string[] = [] let attributes: string[] = options.attributes || [ '"video"."id"' ] let group = options.group || '' @@ -63,7 +63,7 @@ function buildListQuery (model: typeof Model, options: BuildVideosQueryOptions) joins.push( 'INNER JOIN "videoChannel" ON "videoChannel"."id" = "video"."channelId"' + 'INNER JOIN "account" ON "account"."id" = "videoChannel"."accountId"' + - 'INNER JOIN "actor" ON "account"."actorId" = "actor"."id"' + 'INNER JOIN "actor" "accountActor" ON "account"."actorId" = "accountActor"."id"' ) and.push('"video"."id" NOT IN (SELECT "videoBlacklist"."videoId" FROM "videoBlacklist")') @@ -72,33 +72,19 @@ function buildListQuery (model: typeof Model, options: BuildVideosQueryOptions) const blockerIds = [ options.serverAccountId ] if (options.user) blockerIds.push(options.user.Account.id) - cte.push( - '"mutedAccount" AS (' + - ' SELECT "targetAccountId" AS "id"' + - ' FROM "accountBlocklist"' + - ' WHERE "accountId" IN (' + createSafeIn(model, blockerIds) + ')' + - ' UNION ALL' + - ' SELECT "account"."id" AS "id"' + - ' FROM account' + - ' INNER JOIN "actor" ON account."actorId" = actor.id' + - ' INNER JOIN "serverBlocklist" ON "actor"."serverId" = "serverBlocklist"."targetServerId"' + - ' WHERE "serverBlocklist"."accountId" IN (' + createSafeIn(model, blockerIds) + ')' + - ')' - ) - - cte.push( - '"mutedChannel" AS (' + - ' SELECT "videoChannel"."id"' + - ' FROM "videoChannel"' + - ' INNER JOIN "mutedAccount" ON "mutedAccount"."id" = "videoChannel"."accountId"' + - ' )' - ) + const inClause = createSafeIn(model, blockerIds) and.push( - '"video"."channelId" NOT IN (SELECT "id" FROM "mutedChannel")' + 'NOT EXISTS (' + + ' SELECT 1 FROM "accountBlocklist" ' + + ' WHERE "accountBlocklist"."accountId" IN (' + inClause + ') ' + + ' AND "accountBlocklist"."targetAccountId" = "account"."id" ' + + ')' + + 'AND NOT EXISTS (' + + ' SELECT 1 FROM "serverBlocklist" WHERE "serverBlocklist"."accountId" IN (' + inClause + ') ' + + ' AND "serverBlocklist"."targetServerId" = "accountActor"."serverId"' + + ')' ) - - replacements.videoChannelId = options.videoChannelId } // Only list public/published videos @@ -153,7 +139,7 @@ function buildListQuery (model: typeof Model, options: BuildVideosQueryOptions) ' OR' + ' EXISTS (' + ' SELECT 1 from "actorFollow" ' + - ' WHERE "actorFollow"."targetActorId" = "actor"."id" AND "actorFollow"."actorId" = :followerActorId' + + ' WHERE "actorFollow"."targetActorId" = "videoChannel"."actorId" AND "actorFollow"."actorId" = :followerActorId' + ' )' if (options.includeLocalVideos) { @@ -242,6 +228,8 @@ function buildListQuery (model: typeof Model, options: BuildVideosQueryOptions) joins.push('LEFT JOIN "videoView" ON "video"."id" = "videoView"."videoId" AND "videoView"."startDate" >= :viewsGteDate') replacements.viewsGteDate = viewsGteDate + attributes.push('COALESCE(SUM("videoView"."views"), 0) AS "videoViewsSum"') + group = 'GROUP BY "video"."id"' } @@ -249,7 +237,7 @@ function buildListQuery (model: typeof Model, options: BuildVideosQueryOptions) joins.push('INNER JOIN "userVideoHistory" on "video"."id" = "userVideoHistory"."videoId"') and.push('"userVideoHistory"."userId" = :historyOfUser') - replacements.historyOfUser = options.historyOfUser + replacements.historyOfUser = options.historyOfUser.id } if (options.startDate) { @@ -286,9 +274,20 @@ function buildListQuery (model: typeof Model, options: BuildVideosQueryOptions) const escapedSearch = model.sequelize.escape(options.search) const escapedLikeSearch = model.sequelize.escape('%' + options.search + '%') + cte.push( + '"trigramSearch" AS (' + + ' SELECT "video"."id", ' + + ` similarity(lower(immutable_unaccent("video"."name")), lower(immutable_unaccent(${escapedSearch}))) as similarity ` + + ' FROM "video" ' + + ' WHERE lower(immutable_unaccent("video"."name")) % lower(immutable_unaccent(' + escapedSearch + ')) OR ' + + ' lower(immutable_unaccent("video"."name")) LIKE lower(immutable_unaccent(' + escapedLikeSearch + '))' + + ')' + ) + + joins.push('LEFT JOIN "trigramSearch" ON "video"."id" = "trigramSearch"."id"') + let base = '(' + - ' lower(immutable_unaccent("video"."name")) % lower(immutable_unaccent(' + escapedSearch + ')) OR ' + - ' lower(immutable_unaccent("video"."name")) LIKE lower(immutable_unaccent(' + escapedLikeSearch + ')) OR ' + + ' "trigramSearch"."id" IS NOT NULL OR ' + ' EXISTS (' + ' SELECT 1 FROM "videoTag" ' + ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' + @@ -303,50 +302,57 @@ function buildListQuery (model: typeof Model, options: BuildVideosQueryOptions) base += ')' and.push(base) - attributes.push(`similarity(lower(immutable_unaccent("video"."name")), lower(immutable_unaccent(${escapedSearch}))) as similarity`) + attributes.push(`COALESCE("trigramSearch"."similarity", 0) as similarity`) } else { attributes.push('0 as similarity') } if (options.isCount === true) attributes = [ 'COUNT(*) as "total"' ] - const cteString = cte.length !== 0 - ? 'WITH ' + cte.join(', ') + ' ' - : '' - - let query = cteString + - 'SELECT ' + attributes.join(', ') + ' ' + - 'FROM "video" ' + joins.join(' ') + ' ' + - 'WHERE ' + and.join(' AND ') + ' ' + - group + ' ' + - having + ' ' - + let suffix = '' + let order = '' if (options.isCount !== true) { const count = parseInt(options.count + '', 10) const start = parseInt(options.start + '', 10) - query += buildOrder(model, options.sort) + ' ' + + order = buildOrder(model, options.sort) + + suffix = order + ' ' + 'LIMIT ' + count + ' ' + 'OFFSET ' + start } - return { query, replacements } + const cteString = cte.length !== 0 + ? `WITH ${cte.join(', ')} ` + : '' + + const query = cteString + + 'SELECT ' + attributes.join(', ') + ' ' + + 'FROM "video" ' + joins.join(' ') + ' ' + + 'WHERE ' + and.join(' AND ') + ' ' + + group + ' ' + + having + ' ' + + suffix + + return { query, replacements, order } } function buildOrder (model: typeof Model, value: string) { const { direction, field } = buildDirectionAndField(value) - if (field.match(/^[a-zA-Z]+$/) === null) throw new Error('Invalid sort column ' + field) + if (field.match(/^[a-zA-Z."]+$/) === null) throw new Error('Invalid sort column ' + field) if (field.toLowerCase() === 'random') return 'ORDER BY RANDOM()' if (field.toLowerCase() === 'trending') { // Sort by aggregation - return `ORDER BY COALESCE(SUM("videoView"."views"), 0) ${direction}, "video"."views" ${direction}` + return `ORDER BY "videoViewsSum" ${direction}, "video"."views" ${direction}` } let firstSort: string if (field.toLowerCase() === 'match') { // Search firstSort = '"similarity"' + } else if (field.includes('.')) { + firstSort = field } else { firstSort = `"video"."${field}"` } @@ -354,6 +360,124 @@ function buildOrder (model: typeof Model, value: string) { return `ORDER BY ${firstSort} ${direction}, "video"."id" ASC` } +function wrapForAPIResults (baseQuery: string, replacements: any, options: BuildVideosQueryOptions, order: string) { + const attributes = { + '"video".*': '', + '"VideoChannel"."id"': '"VideoChannel.id"', + '"VideoChannel"."name"': '"VideoChannel.name"', + '"VideoChannel"."description"': '"VideoChannel.description"', + '"VideoChannel"."actorId"': '"VideoChannel.actorId"', + '"VideoChannel->Actor"."id"': '"VideoChannel.Actor.id"', + '"VideoChannel->Actor"."preferredUsername"': '"VideoChannel.Actor.preferredUsername"', + '"VideoChannel->Actor"."url"': '"VideoChannel.Actor.url"', + '"VideoChannel->Actor"."serverId"': '"VideoChannel.Actor.serverId"', + '"VideoChannel->Actor"."avatarId"': '"VideoChannel.Actor.avatarId"', + '"VideoChannel->Account"."id"': '"VideoChannel.Account.id"', + '"VideoChannel->Account"."name"': '"VideoChannel.Account.name"', + '"VideoChannel->Account->Actor"."id"': '"VideoChannel.Account.Actor.id"', + '"VideoChannel->Account->Actor"."preferredUsername"': '"VideoChannel.Account.Actor.preferredUsername"', + '"VideoChannel->Account->Actor"."url"': '"VideoChannel.Account.Actor.url"', + '"VideoChannel->Account->Actor"."serverId"': '"VideoChannel.Account.Actor.serverId"', + '"VideoChannel->Account->Actor"."avatarId"': '"VideoChannel.Account.Actor.avatarId"', + '"VideoChannel->Actor->Server"."id"': '"VideoChannel.Actor.Server.id"', + '"VideoChannel->Actor->Server"."host"': '"VideoChannel.Actor.Server.host"', + '"VideoChannel->Actor->Avatar"."id"': '"VideoChannel.Actor.Avatar.id"', + '"VideoChannel->Actor->Avatar"."filename"': '"VideoChannel.Actor.Avatar.filename"', + '"VideoChannel->Actor->Avatar"."fileUrl"': '"VideoChannel.Actor.Avatar.fileUrl"', + '"VideoChannel->Actor->Avatar"."onDisk"': '"VideoChannel.Actor.Avatar.onDisk"', + '"VideoChannel->Actor->Avatar"."createdAt"': '"VideoChannel.Actor.Avatar.createdAt"', + '"VideoChannel->Actor->Avatar"."updatedAt"': '"VideoChannel.Actor.Avatar.updatedAt"', + '"VideoChannel->Account->Actor->Server"."id"': '"VideoChannel.Account.Actor.Server.id"', + '"VideoChannel->Account->Actor->Server"."host"': '"VideoChannel.Account.Actor.Server.host"', + '"VideoChannel->Account->Actor->Avatar"."id"': '"VideoChannel.Account.Actor.Avatar.id"', + '"VideoChannel->Account->Actor->Avatar"."filename"': '"VideoChannel.Account.Actor.Avatar.filename"', + '"VideoChannel->Account->Actor->Avatar"."fileUrl"': '"VideoChannel.Account.Actor.Avatar.fileUrl"', + '"VideoChannel->Account->Actor->Avatar"."onDisk"': '"VideoChannel.Account.Actor.Avatar.onDisk"', + '"VideoChannel->Account->Actor->Avatar"."createdAt"': '"VideoChannel.Account.Actor.Avatar.createdAt"', + '"VideoChannel->Account->Actor->Avatar"."updatedAt"': '"VideoChannel.Account.Actor.Avatar.updatedAt"', + '"Thumbnails"."id"': '"Thumbnails.id"', + '"Thumbnails"."type"': '"Thumbnails.type"', + '"Thumbnails"."filename"': '"Thumbnails.filename"' + } + + const joins = [ + 'INNER JOIN "video" ON "tmp"."id" = "video"."id"', + + 'INNER JOIN "videoChannel" AS "VideoChannel" ON "video"."channelId" = "VideoChannel"."id"', + 'INNER JOIN "actor" AS "VideoChannel->Actor" ON "VideoChannel"."actorId" = "VideoChannel->Actor"."id"', + 'INNER JOIN "account" AS "VideoChannel->Account" ON "VideoChannel"."accountId" = "VideoChannel->Account"."id"', + 'INNER JOIN "actor" AS "VideoChannel->Account->Actor" ON "VideoChannel->Account"."actorId" = "VideoChannel->Account->Actor"."id"', + + 'LEFT OUTER JOIN "server" AS "VideoChannel->Actor->Server" ON "VideoChannel->Actor"."serverId" = "VideoChannel->Actor->Server"."id"', + 'LEFT OUTER JOIN "avatar" AS "VideoChannel->Actor->Avatar" ON "VideoChannel->Actor"."avatarId" = "VideoChannel->Actor->Avatar"."id"', + + 'LEFT OUTER JOIN "server" AS "VideoChannel->Account->Actor->Server" ' + + 'ON "VideoChannel->Account->Actor"."serverId" = "VideoChannel->Account->Actor->Server"."id"', + + 'LEFT OUTER JOIN "avatar" AS "VideoChannel->Account->Actor->Avatar" ' + + 'ON "VideoChannel->Account->Actor"."avatarId" = "VideoChannel->Account->Actor->Avatar"."id"', + + 'LEFT OUTER JOIN "thumbnail" AS "Thumbnails" ON "video"."id" = "Thumbnails"."videoId"' + ] + + if (options.withFiles) { + joins.push('INNER JOIN "videoFile" AS "VideoFiles" ON "VideoFiles"."videoId" = "video"."id"') + + Object.assign(attributes, { + '"VideoFiles"."id"': '"VideoFiles.id"', + '"VideoFiles"."createdAt"': '"VideoFiles.createdAt"', + '"VideoFiles"."updatedAt"': '"VideoFiles.updatedAt"', + '"VideoFiles"."resolution"': '"VideoFiles.resolution"', + '"VideoFiles"."size"': '"VideoFiles.size"', + '"VideoFiles"."extname"': '"VideoFiles.extname"', + '"VideoFiles"."infoHash"': '"VideoFiles.infoHash"', + '"VideoFiles"."fps"': '"VideoFiles.fps"', + '"VideoFiles"."videoId"': '"VideoFiles.videoId"' + }) + } + + if (options.user) { + joins.push( + 'LEFT OUTER JOIN "userVideoHistory" ' + + 'ON "video"."id" = "userVideoHistory"."videoId" AND "userVideoHistory"."userId" = :userVideoHistoryId' + ) + replacements.userVideoHistoryId = options.user.id + + Object.assign(attributes, { + '"userVideoHistory"."id"': '"userVideoHistory.id"', + '"userVideoHistory"."currentTime"': '"userVideoHistory.currentTime"' + }) + } + + if (options.videoPlaylistId) { + joins.push( + 'INNER JOIN "videoPlaylistElement" as "VideoPlaylistElement" ON "videoPlaylistElement"."videoId" = "video"."id" ' + + 'AND "VideoPlaylistElement"."videoPlaylistId" = :videoPlaylistId' + ) + replacements.videoPlaylistId = options.videoPlaylistId + + Object.assign(attributes, { + '"VideoPlaylistElement"."createdAt"': '"VideoPlaylistElement.createdAt"', + '"VideoPlaylistElement"."updatedAt"': '"VideoPlaylistElement.updatedAt"', + '"VideoPlaylistElement"."url"': '"VideoPlaylistElement.url"', + '"VideoPlaylistElement"."position"': '"VideoPlaylistElement.position"', + '"VideoPlaylistElement"."startTimestamp"': '"VideoPlaylistElement.startTimestamp"', + '"VideoPlaylistElement"."stopTimestamp"': '"VideoPlaylistElement.stopTimestamp"', + '"VideoPlaylistElement"."videoPlaylistId"': '"VideoPlaylistElement.videoPlaylistId"' + }) + } + + const select = 'SELECT ' + Object.keys(attributes).map(key => { + const value = attributes[key] + if (value) return `${key} AS ${value}` + + return key + }).join(', ') + + return `${select} FROM (${baseQuery}) AS "tmp" ${joins.join(' ')} ${order}` +} + export { - buildListQuery + buildListQuery, + wrapForAPIResults } diff --git a/server/models/video/video.ts b/server/models/video/video.ts index 217ca8e50..7f94e834a 100644 --- a/server/models/video/video.ts +++ b/server/models/video/video.ts @@ -1,5 +1,5 @@ import * as Bluebird from 'bluebird' -import { maxBy, minBy } from 'lodash' +import { maxBy, minBy, pick } from 'lodash' import { join } from 'path' import { FindOptions, IncludeOptions, Op, QueryTypes, ScopeOptions, Sequelize, Transaction, WhereOptions } from 'sequelize' import { @@ -124,7 +124,7 @@ import { MThumbnail } from '../../typings/models/video/thumbnail' import { VideoFile } from '@shared/models/videos/video-file.model' import { getHLSDirectory, getTorrentFileName, getTorrentFilePath, getVideoFilename, getVideoFilePath } from '@server/lib/video-paths' import { ModelCache } from '@server/models/model-cache' -import { buildListQuery, BuildVideosQueryOptions } from './video-query-builder' +import { buildListQuery, BuildVideosQueryOptions, wrapForAPIResults } from './video-query-builder' export enum ScopeNames { AVAILABLE_FOR_LIST_IDS = 'AVAILABLE_FOR_LIST_IDS', @@ -1408,19 +1408,25 @@ export class VideoModel extends Model { options: BuildVideosQueryOptions, countVideos = true ) { - const { query, replacements } = buildListQuery(VideoModel, options) - const { query: queryCount, replacements: replacementsCount } = buildListQuery(VideoModel, Object.assign({}, options, { isCount: true })) + function getCount () { + if (countVideos !== true) return Promise.resolve(undefined) - const [ count, rows ] = await Promise.all([ - countVideos - ? this.sequelize.query(queryCount, { replacements: replacementsCount, type: QueryTypes.SELECT }) - .then(rows => rows.length !== 0 ? rows[0].total : 0) - : Promise.resolve(undefined), + const countOptions = Object.assign({}, options, { isCount: true }) + const { query: queryCount, replacements: replacementsCount } = buildListQuery(VideoModel, countOptions) - this.sequelize.query(query, { replacements, type: QueryTypes.SELECT }) - .then(rows => rows.map(r => r.id)) - .then(ids => VideoModel.loadCompleteVideosForApi(ids, options)) - ]) + return VideoModel.sequelize.query(queryCount, { replacements: replacementsCount, type: QueryTypes.SELECT }) + .then(rows => rows.length !== 0 ? rows[0].total : 0) + } + + function getModels () { + const { query, replacements, order } = buildListQuery(VideoModel, options) + const queryModels = wrapForAPIResults(query, replacements, options, order) + + return VideoModel.sequelize.query(queryModels, { replacements, type: QueryTypes.SELECT, nest: true }) + .then(rows => VideoModel.buildAPIResult(rows)) + } + + const [ count, rows ] = await Promise.all([ getCount(), getModels() ]) return { data: rows, @@ -1428,36 +1434,113 @@ export class VideoModel extends Model { } } - private static loadCompleteVideosForApi (ids: number[], options: BuildVideosQueryOptions) { - if (ids.length === 0) return [] + private static buildAPIResult (rows: any[]) { + const memo: { [ id: number ]: VideoModel } = {} + + const thumbnailsDone = new Set() + const historyDone = new Set() + const videoFilesDone = new Set() + + const videos: VideoModel[] = [] + + const avatarKeys = [ 'id', 'filename', 'fileUrl', 'onDisk', 'createdAt', 'updatedAt' ] + const actorKeys = [ 'id', 'preferredUsername', 'url', 'serverId', 'avatarId' ] + const serverKeys = [ 'id', 'host' ] + const videoFileKeys = [ 'id', 'createdAt', 'updatedAt', 'resolution', 'size', 'extname', 'infoHash', 'fps', 'videoId' ] + const videoKeys = [ + 'id', + 'uuid', + 'name', + 'category', + 'licence', + 'language', + 'privacy', + 'nsfw', + 'description', + 'support', + 'duration', + 'views', + 'likes', + 'dislikes', + 'remote', + 'url', + 'commentsEnabled', + 'downloadEnabled', + 'waitTranscoding', + 'state', + 'publishedAt', + 'originallyPublishedAt', + 'channelId', + 'createdAt', + 'updatedAt' + ] - const secondQuery: FindOptions = { - offset: 0, - limit: options.count, - order: [ // Keep original order - Sequelize.literal( - ids.map(id => `"VideoModel".id = ${id} DESC`).join(', ') - ) - ] - } + function buildActor (rowActor: any) { + const avatarModel = rowActor.Avatar.id !== null + ? new AvatarModel(pick(rowActor.Avatar, avatarKeys)) + : null - const apiScope: (string | ScopeOptions)[] = [] + const serverModel = rowActor.Server.id !== null + ? new ServerModel(pick(rowActor.Server, serverKeys)) + : null - if (options.user) { - apiScope.push({ method: [ ScopeNames.WITH_USER_HISTORY, options.user.id ] }) + const actorModel = new ActorModel(pick(rowActor, actorKeys)) + actorModel.Avatar = avatarModel + actorModel.Server = serverModel + + return actorModel } - apiScope.push({ - method: [ - ScopeNames.FOR_API, { - ids, - withFiles: options.withFiles, - videoPlaylistId: options.videoPlaylistId - } as ForAPIOptions - ] - }) + for (const row of rows) { + if (!memo[row.id]) { + // Build Channel + const channel = row.VideoChannel + const channelModel = new VideoChannelModel(pick(channel, [ 'id', 'name', 'description', 'actorId' ])) + channelModel.Actor = buildActor(channel.Actor) + + const account = row.VideoChannel.Account + const accountModel = new AccountModel(pick(account, [ 'id', 'name' ])) + accountModel.Actor = buildActor(account.Actor) + + channelModel.Account = accountModel + + const videoModel = new VideoModel(pick(row, videoKeys)) + videoModel.VideoChannel = channelModel + + videoModel.UserVideoHistories = [] + videoModel.Thumbnails = [] + videoModel.VideoFiles = [] + + memo[row.id] = videoModel + // Don't take object value to have a sorted array + videos.push(videoModel) + } + + const videoModel = memo[row.id] + + if (row.userVideoHistory?.id && !historyDone.has(row.userVideoHistory.id)) { + const historyModel = new UserVideoHistoryModel(pick(row.userVideoHistory, [ 'id', 'currentTime' ])) + videoModel.UserVideoHistories.push(historyModel) + + historyDone.add(row.userVideoHistory.id) + } + + if (row.Thumbnails?.id && !thumbnailsDone.has(row.Thumbnails.id)) { + const thumbnailModel = new ThumbnailModel(pick(row.Thumbnails, [ 'id', 'type', 'filename' ])) + videoModel.Thumbnails.push(thumbnailModel) + + thumbnailsDone.add(row.Thumbnails.id) + } + + if (row.VideoFiles?.id && !videoFilesDone.has(row.VideoFiles.id)) { + const videoFileModel = new VideoFileModel(pick(row.VideoFiles, videoFileKeys)) + videoModel.VideoFiles.push(videoFileModel) + + videoFilesDone.add(row.VideoFiles.id) + } + } - return VideoModel.scope(apiScope).findAll(secondQuery) + return videos } private static isPrivacyForFederation (privacy: VideoPrivacy) { -- cgit v1.2.3