--- /dev/null
+import { VideoFilter, VideoPrivacy, VideoState } from '@shared/models'
+import { buildDirectionAndField, createSafeIn } from '@server/models/utils'
+import { Model } from 'sequelize-typescript'
+import { MUserAccountId, MUserId } from '@server/typings/models'
+import validator from 'validator'
+
+export type BuildVideosQueryOptions = {
+ attributes?: string[]
+
+ serverAccountId: number
+ followerActorId: number
+ includeLocalVideos: boolean
+
+ count: number
+ start: number
+ sort: string
+
+ filter?: VideoFilter
+ categoryOneOf?: number[]
+ nsfw?: boolean
+ licenceOneOf?: number[]
+ languageOneOf?: string[]
+ tagsOneOf?: string[]
+ tagsAllOf?: string[]
+
+ withFiles?: boolean
+
+ accountId?: number
+ videoChannelId?: number
+
+ videoPlaylistId?: number
+
+ trendingDays?: number
+ user?: MUserAccountId
+ historyOfUser?: MUserId
+
+ startDate?: string // ISO 8601
+ endDate?: string // ISO 8601
+ originallyPublishedStartDate?: string
+ originallyPublishedEndDate?: string
+
+ durationMin?: number // seconds
+ durationMax?: number // seconds
+
+ search?: string
+
+ isCount?: boolean
+
+ group?: string
+ having?: string
+}
+
+function buildListQuery (model: typeof Model, options: BuildVideosQueryOptions) {
+ const and: string[] = []
+ const cte: string[] = []
+ const joins: string[] = []
+ const replacements: any = {}
+
+ let attributes: string[] = options.attributes || [ '"video"."id"' ]
+ let group = options.group || ''
+ const having = options.having || ''
+
+ 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"'
+ )
+
+ and.push('"video"."id" NOT IN (SELECT "videoBlacklist"."videoId" FROM "videoBlacklist")')
+
+ if (options.serverAccountId) {
+ 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"' +
+ ' )'
+ )
+
+ and.push(
+ '"video"."channelId" NOT IN (SELECT "id" FROM "mutedChannel")'
+ )
+
+ replacements.videoChannelId = options.videoChannelId
+ }
+
+ // Only list public/published videos
+ if (!options.filter || options.filter !== 'all-local') {
+ and.push(
+ `("video"."state" = ${VideoState.PUBLISHED} OR ` +
+ `("video"."state" = ${VideoState.TO_TRANSCODE} AND "video"."waitTranscoding" IS false))`
+ )
+
+ if (options.user) {
+ and.push(
+ `("video"."privacy" = ${VideoPrivacy.PUBLIC} OR "video"."privacy" = ${VideoPrivacy.INTERNAL})`
+ )
+ } else { // Or only public videos
+ and.push(
+ `"video"."privacy" = ${VideoPrivacy.PUBLIC}`
+ )
+ }
+ }
+
+ if (options.videoPlaylistId) {
+ joins.push(
+ 'INNER JOIN "videoPlaylistElement" "video"."id" = "videoPlaylistElement"."videoId" ' +
+ 'AND "videoPlaylistElement"."videoPlaylistId" = :videoPlaylistId'
+ )
+
+ replacements.videoPlaylistId = options.videoPlaylistId
+ }
+
+ if (options.filter && (options.filter === 'local' || options.filter === 'all-local')) {
+ and.push('"video"."remote" IS FALSE')
+ }
+
+ if (options.accountId) {
+ and.push('"account"."id" = :accountId')
+ replacements.accountId = options.accountId
+ }
+
+ if (options.videoChannelId) {
+ and.push('"videoChannel"."id" = :videoChannelId')
+ replacements.videoChannelId = options.videoChannelId
+ }
+
+ if (options.followerActorId) {
+ let query =
+ '(' +
+ ' EXISTS (' +
+ ' SELECT 1 FROM "videoShare" ' +
+ ' INNER JOIN "actorFollow" "actorFollowShare" ON "actorFollowShare"."targetActorId" = "videoShare"."actorId" ' +
+ ' AND "actorFollowShare"."actorId" = :followerActorId WHERE "videoShare"."videoId" = "video"."id"' +
+ ' )' +
+ ' OR' +
+ ' EXISTS (' +
+ ' SELECT 1 from "actorFollow" ' +
+ ' WHERE "actorFollow"."targetActorId" = "actor"."id" AND "actorFollow"."actorId" = :followerActorId' +
+ ' )'
+
+ if (options.includeLocalVideos) {
+ query += ' OR "video"."remote" IS FALSE'
+ }
+
+ query += ')'
+
+ and.push(query)
+ replacements.followerActorId = options.followerActorId
+ }
+
+ if (options.withFiles === true) {
+ and.push('EXISTS (SELECT 1 FROM "videoFile" WHERE "videoFile"."videoId" = "video"."id")')
+ }
+
+ if (options.tagsOneOf) {
+ const tagsOneOfLower = options.tagsOneOf.map(t => t.toLowerCase())
+
+ and.push(
+ 'EXISTS (' +
+ ' SELECT 1 FROM "videoTag" ' +
+ ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
+ ' WHERE lower("tag"."name") IN (' + createSafeIn(model, tagsOneOfLower) + ') ' +
+ ' AND "video"."id" = "videoTag"."videoId"' +
+ ')'
+ )
+ }
+
+ if (options.tagsAllOf) {
+ const tagsAllOfLower = options.tagsAllOf.map(t => t.toLowerCase())
+
+ and.push(
+ 'EXISTS (' +
+ ' SELECT 1 FROM "videoTag" ' +
+ ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
+ ' WHERE lower("tag"."name") IN (' + createSafeIn(model, tagsAllOfLower) + ') ' +
+ ' AND "video"."id" = "videoTag"."videoId" ' +
+ ' GROUP BY "videoTag"."videoId" HAVING COUNT(*) = ' + tagsAllOfLower.length +
+ ')'
+ )
+ }
+
+ if (options.nsfw === true) {
+ and.push('"video"."nsfw" IS TRUE')
+ }
+
+ if (options.nsfw === false) {
+ and.push('"video"."nsfw" IS FALSE')
+ }
+
+ if (options.categoryOneOf) {
+ and.push('"video"."category" IN (:categoryOneOf)')
+ replacements.categoryOneOf = options.categoryOneOf
+ }
+
+ if (options.licenceOneOf) {
+ and.push('"video"."licence" IN (:licenceOneOf)')
+ replacements.licenceOneOf = options.licenceOneOf
+ }
+
+ if (options.languageOneOf) {
+ replacements.languageOneOf = options.languageOneOf.filter(l => l && l !== '_unknown')
+
+ let languagesQuery = '("video"."language" IN (:languageOneOf) OR '
+
+ if (options.languageOneOf.includes('_unknown')) {
+ languagesQuery += '"video"."language" IS NULL OR '
+ }
+
+ and.push(
+ languagesQuery +
+ ' EXISTS (' +
+ ' SELECT 1 FROM "videoCaption" WHERE "videoCaption"."language" ' +
+ ' IN (' + createSafeIn(model, options.languageOneOf) + ') AND ' +
+ ' "videoCaption"."videoId" = "video"."id"' +
+ ' )' +
+ ')'
+ )
+ }
+
+ // We don't exclude results in this if so if we do a count we don't need to add this complex clauses
+ if (options.trendingDays && options.isCount !== true) {
+ const viewsGteDate = new Date(new Date().getTime() - (24 * 3600 * 1000) * options.trendingDays)
+
+ joins.push('LEFT JOIN "videoView" ON "video"."id" = "videoView"."videoId" AND "videoView"."startDate" >= :viewsGteDate')
+ replacements.viewsGteDate = viewsGteDate
+
+ group = 'GROUP BY "video"."id"'
+ }
+
+ if (options.historyOfUser) {
+ joins.push('INNER JOIN "userVideoHistory" on "video"."id" = "userVideoHistory"."videoId"')
+
+ and.push('"userVideoHistory"."userId" = :historyOfUser')
+ replacements.historyOfUser = options.historyOfUser
+ }
+
+ if (options.startDate) {
+ and.push('"video"."publishedAt" >= :startDate')
+ replacements.startDate = options.startDate
+ }
+
+ if (options.endDate) {
+ and.push('"video"."publishedAt" <= :endDate')
+ replacements.endDate = options.endDate
+ }
+
+ if (options.originallyPublishedStartDate) {
+ and.push('"video"."originallyPublishedAt" >= :originallyPublishedStartDate')
+ replacements.originallyPublishedStartDate = options.originallyPublishedStartDate
+ }
+
+ if (options.originallyPublishedEndDate) {
+ and.push('"video"."originallyPublishedAt" <= :originallyPublishedEndDate')
+ replacements.originallyPublishedEndDate = options.originallyPublishedEndDate
+ }
+
+ if (options.durationMin) {
+ and.push('"video"."duration" >= :durationMin')
+ replacements.durationMin = options.durationMin
+ }
+
+ if (options.durationMax) {
+ and.push('"video"."duration" <= :durationMax')
+ replacements.durationMax = options.durationMax
+ }
+
+ if (options.search) {
+ const escapedSearch = model.sequelize.escape(options.search)
+ const escapedLikeSearch = model.sequelize.escape('%' + options.search + '%')
+
+ let base = '(' +
+ ' lower(immutable_unaccent("video"."name")) % lower(immutable_unaccent(' + escapedSearch + ')) OR ' +
+ ' lower(immutable_unaccent("video"."name")) LIKE lower(immutable_unaccent(' + escapedLikeSearch + ')) OR ' +
+ ' EXISTS (' +
+ ' SELECT 1 FROM "videoTag" ' +
+ ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
+ ` WHERE lower("tag"."name") = ${escapedSearch} ` +
+ ' AND "video"."id" = "videoTag"."videoId"' +
+ ' )'
+
+ if (validator.isUUID(options.search)) {
+ base += ` OR "video"."uuid" = ${escapedSearch}`
+ }
+
+ base += ')'
+ and.push(base)
+
+ attributes.push(`similarity(lower(immutable_unaccent("video"."name")), lower(immutable_unaccent(${escapedSearch}))) 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 + ' '
+
+ if (options.isCount !== true) {
+ const count = parseInt(options.count + '', 10)
+ const start = parseInt(options.start + '', 10)
+
+ query += buildOrder(model, options.sort) + ' ' +
+ 'LIMIT ' + count + ' ' +
+ 'OFFSET ' + start
+ }
+
+ return { query, replacements }
+}
+
+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.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}`
+ }
+
+ let firstSort: string
+
+ if (field.toLowerCase() === 'match') { // Search
+ firstSort = '"similarity"'
+ } else {
+ firstSort = `"video"."${field}"`
+ }
+
+ return `ORDER BY ${firstSort} ${direction}, "video"."id" ASC`
+}
+
+export {
+ buildListQuery
+}
import * as Bluebird from 'bluebird'
import { maxBy, minBy } from 'lodash'
import { join } from 'path'
-import { CountOptions, FindOptions, IncludeOptions, Op, QueryTypes, ScopeOptions, Sequelize, Transaction, WhereOptions } from 'sequelize'
+import { FindOptions, IncludeOptions, Op, QueryTypes, ScopeOptions, Sequelize, Transaction, WhereOptions } from 'sequelize'
import {
AllowNull,
BeforeDestroy,
import { ActorModel } from '../activitypub/actor'
import { AvatarModel } from '../avatar/avatar'
import { ServerModel } from '../server/server'
-import {
- buildBlockedAccountSQL,
- buildTrigramSearchIndex,
- buildWhereIdOrUUID,
- createSafeIn,
- createSimilarityAttribute,
- getVideoSort,
- isOutdated,
- throwIfNotValid
-} from '../utils'
+import { buildTrigramSearchIndex, buildWhereIdOrUUID, getVideoSort, isOutdated, throwIfNotValid } from '../utils'
import { TagModel } from './tag'
import { VideoAbuseModel } from './video-abuse'
import { ScopeNames as VideoChannelScopeNames, SummaryOptions, VideoChannelModel } from './video-channel'
MVideoFormattableDetails,
MVideoForUser,
MVideoFullLight,
- MVideoIdThumbnail, MVideoImmutable,
+ MVideoIdThumbnail,
+ MVideoImmutable,
MVideoThumbnail,
MVideoThumbnailBlacklist,
MVideoWithAllFiles,
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 validator from 'validator'
import { ModelCache } from '@server/models/model-cache'
+import { buildListQuery, BuildVideosQueryOptions } from './video-query-builder'
export enum ScopeNames {
AVAILABLE_FOR_LIST_IDS = 'AVAILABLE_FOR_LIST_IDS',
return query
},
- [ScopeNames.AVAILABLE_FOR_LIST_IDS]: (options: AvailableForListIDsOptions) => {
- const whereAnd = options.baseWhere ? [].concat(options.baseWhere) : []
-
- const query: FindOptions = {
- raw: true,
- include: []
- }
-
- const attributesType = options.attributesType || 'id'
-
- if (attributesType === 'id') query.attributes = [ 'id' ]
- else if (attributesType === 'none') query.attributes = []
-
- whereAnd.push({
- id: {
- [Op.notIn]: Sequelize.literal(
- '(SELECT "videoBlacklist"."videoId" FROM "videoBlacklist")'
- )
- }
- })
-
- if (options.serverAccountId) {
- whereAnd.push({
- channelId: {
- [Op.notIn]: Sequelize.literal(
- '(' +
- 'SELECT id FROM "videoChannel" WHERE "accountId" IN (' +
- buildBlockedAccountSQL(options.serverAccountId, options.user ? options.user.Account.id : undefined) +
- ')' +
- ')'
- )
- }
- })
- }
-
- // Only list public/published videos
- if (!options.filter || options.filter !== 'all-local') {
- const publishWhere = {
- // Always list published videos, or videos that are being transcoded but on which we don't want to wait for transcoding
- [Op.or]: [
- {
- state: VideoState.PUBLISHED
- },
- {
- [Op.and]: {
- state: VideoState.TO_TRANSCODE,
- waitTranscoding: false
- }
- }
- ]
- }
- whereAnd.push(publishWhere)
-
- // List internal videos if the user is logged in
- if (options.user) {
- const privacyWhere = {
- [Op.or]: [
- {
- privacy: VideoPrivacy.INTERNAL
- },
- {
- privacy: VideoPrivacy.PUBLIC
- }
- ]
- }
-
- whereAnd.push(privacyWhere)
- } else { // Or only public videos
- const privacyWhere = { privacy: VideoPrivacy.PUBLIC }
- whereAnd.push(privacyWhere)
- }
- }
-
- if (options.videoPlaylistId) {
- query.include.push({
- attributes: [],
- model: VideoPlaylistElementModel.unscoped(),
- required: true,
- where: {
- videoPlaylistId: options.videoPlaylistId
- }
- })
-
- query.subQuery = false
- }
-
- if (options.filter && (options.filter === 'local' || options.filter === 'all-local')) {
- whereAnd.push({
- remote: false
- })
- }
-
- if (options.accountId || options.videoChannelId) {
- const videoChannelInclude: IncludeOptions = {
- attributes: [],
- model: VideoChannelModel.unscoped(),
- required: true
- }
-
- if (options.videoChannelId) {
- videoChannelInclude.where = {
- id: options.videoChannelId
- }
- }
-
- if (options.accountId) {
- const accountInclude: IncludeOptions = {
- attributes: [],
- model: AccountModel.unscoped(),
- required: true
- }
-
- accountInclude.where = { id: options.accountId }
- videoChannelInclude.include = [ accountInclude ]
- }
-
- query.include.push(videoChannelInclude)
- }
-
- if (options.followerActorId) {
- let localVideosReq = ''
- if (options.includeLocalVideos === true) {
- localVideosReq = ' UNION ALL SELECT "video"."id" FROM "video" WHERE remote IS FALSE'
- }
-
- // Force actorId to be a number to avoid SQL injections
- const actorIdNumber = parseInt(options.followerActorId.toString(), 10)
- whereAnd.push({
- id: {
- [Op.in]: Sequelize.literal(
- '(' +
- 'SELECT "videoShare"."videoId" AS "id" FROM "videoShare" ' +
- 'INNER JOIN "actorFollow" ON "actorFollow"."targetActorId" = "videoShare"."actorId" ' +
- 'WHERE "actorFollow"."actorId" = ' + actorIdNumber +
- ' UNION ALL ' +
- 'SELECT "video"."id" AS "id" FROM "video" ' +
- '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 "actorFollow" ON "actorFollow"."targetActorId" = "actor"."id" ' +
- 'WHERE "actorFollow"."actorId" = ' + actorIdNumber +
- localVideosReq +
- ')'
- )
- }
- })
- }
-
- if (options.withFiles === true) {
- whereAnd.push({
- id: {
- [Op.in]: Sequelize.literal(
- '(SELECT "videoId" FROM "videoFile")'
- )
- }
- })
- }
-
- // FIXME: issues with sequelize count when making a join on n:m relation, so we just make a IN()
- if (options.tagsAllOf || options.tagsOneOf) {
- if (options.tagsOneOf) {
- const tagsOneOfLower = options.tagsOneOf.map(t => t.toLowerCase())
-
- whereAnd.push({
- id: {
- [Op.in]: Sequelize.literal(
- '(' +
- 'SELECT "videoId" FROM "videoTag" ' +
- 'INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
- 'WHERE lower("tag"."name") IN (' + createSafeIn(VideoModel, tagsOneOfLower) + ')' +
- ')'
- )
- }
- })
- }
-
- if (options.tagsAllOf) {
- const tagsAllOfLower = options.tagsAllOf.map(t => t.toLowerCase())
-
- whereAnd.push({
- id: {
- [Op.in]: Sequelize.literal(
- '(' +
- 'SELECT "videoId" FROM "videoTag" ' +
- 'INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
- 'WHERE lower("tag"."name") IN (' + createSafeIn(VideoModel, tagsAllOfLower) + ')' +
- 'GROUP BY "videoTag"."videoId" HAVING COUNT(*) = ' + tagsAllOfLower.length +
- ')'
- )
- }
- })
- }
- }
-
- if (options.nsfw === true || options.nsfw === false) {
- whereAnd.push({ nsfw: options.nsfw })
- }
-
- if (options.categoryOneOf) {
- whereAnd.push({
- category: {
- [Op.or]: options.categoryOneOf
- }
- })
- }
-
- if (options.licenceOneOf) {
- whereAnd.push({
- licence: {
- [Op.or]: options.licenceOneOf
- }
- })
- }
-
- if (options.languageOneOf) {
- let videoLanguages = options.languageOneOf
- if (options.languageOneOf.find(l => l === '_unknown')) {
- videoLanguages = videoLanguages.concat([ null ])
- }
-
- whereAnd.push({
- [Op.or]: [
- {
- language: {
- [Op.or]: videoLanguages
- }
- },
- {
- id: {
- [Op.in]: Sequelize.literal(
- '(' +
- 'SELECT "videoId" FROM "videoCaption" ' +
- 'WHERE "language" IN (' + createSafeIn(VideoModel, options.languageOneOf) + ') ' +
- ')'
- )
- }
- }
- ]
- })
- }
-
- if (options.trendingDays) {
- query.include.push(VideoModel.buildTrendingQuery(options.trendingDays))
-
- query.subQuery = false
- }
-
- if (options.historyOfUser) {
- query.include.push({
- model: UserVideoHistoryModel,
- required: true,
- where: {
- userId: options.historyOfUser.id
- }
- })
-
- // Even if the relation is n:m, we know that a user only have 0..1 video history
- // So we won't have multiple rows for the same video
- // Without this, we would not be able to sort on "updatedAt" column of UserVideoHistoryModel
- query.subQuery = false
- }
-
- query.where = {
- [Op.and]: whereAnd
- }
-
- return query
- },
[ScopeNames.WITH_THUMBNAILS]: {
include: [
{
throw new Error('Try to filter all-local but no user has not the see all videos right')
}
- const query: FindOptions & { where?: null } = {
- offset: options.start,
- limit: options.count,
- order: getVideoSort(options.sort)
- }
-
- let trendingDays: number
- if (options.sort.endsWith('trending')) {
- trendingDays = CONFIG.TRENDING.VIDEOS.INTERVAL_DAYS
-
- query.group = 'VideoModel.id'
- }
+ const trendingDays = options.sort.endsWith('trending')
+ ? CONFIG.TRENDING.VIDEOS.INTERVAL_DAYS
+ : undefined
const serverActor = await getServerActor()
// followerActorId === null has a meaning, so just check undefined
- const followerActorId = options.followerActorId !== undefined ? options.followerActorId : serverActor.id
+ const followerActorId = options.followerActorId !== undefined
+ ? options.followerActorId
+ : serverActor.id
const queryOptions = {
+ start: options.start,
+ count: options.count,
+ sort: options.sort,
followerActorId,
serverAccountId: serverActor.Account.id,
nsfw: options.nsfw,
trendingDays
}
- return VideoModel.getAvailableForApi(query, queryOptions, options.countVideos)
+ return VideoModel.getAvailableForApi(queryOptions, options.countVideos)
}
static async searchAndPopulateAccountAndServer (options: {
user?: MUserAccountId
filter?: VideoFilter
}) {
- const whereAnd = []
-
- if (options.startDate || options.endDate) {
- const publishedAtRange = {}
-
- if (options.startDate) publishedAtRange[Op.gte] = options.startDate
- if (options.endDate) publishedAtRange[Op.lte] = options.endDate
-
- whereAnd.push({ publishedAt: publishedAtRange })
- }
-
- if (options.originallyPublishedStartDate || options.originallyPublishedEndDate) {
- const originallyPublishedAtRange = {}
-
- if (options.originallyPublishedStartDate) originallyPublishedAtRange[Op.gte] = options.originallyPublishedStartDate
- if (options.originallyPublishedEndDate) originallyPublishedAtRange[Op.lte] = options.originallyPublishedEndDate
-
- whereAnd.push({ originallyPublishedAt: originallyPublishedAtRange })
- }
-
- if (options.durationMin || options.durationMax) {
- const durationRange = {}
-
- if (options.durationMin) durationRange[Op.gte] = options.durationMin
- if (options.durationMax) durationRange[Op.lte] = options.durationMax
-
- whereAnd.push({ duration: durationRange })
- }
-
- const attributesInclude = []
- const escapedSearch = VideoModel.sequelize.escape(options.search)
- const escapedLikeSearch = VideoModel.sequelize.escape('%' + options.search + '%')
- if (options.search) {
- const trigramSearch = {
- id: {
- [Op.in]: Sequelize.literal(
- '(' +
- 'SELECT "video"."id" FROM "video" ' +
- 'WHERE ' +
- 'lower(immutable_unaccent("video"."name")) % lower(immutable_unaccent(' + escapedSearch + ')) OR ' +
- 'lower(immutable_unaccent("video"."name")) LIKE lower(immutable_unaccent(' + escapedLikeSearch + '))' +
- 'UNION ALL ' +
- 'SELECT "video"."id" FROM "video" LEFT JOIN "videoTag" ON "videoTag"."videoId" = "video"."id" ' +
- 'INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
- 'WHERE lower("tag"."name") = lower(' + escapedSearch + ')' +
- ')'
- )
- }
- }
-
- if (validator.isUUID(options.search)) {
- whereAnd.push({
- [Op.or]: [
- trigramSearch,
- {
- uuid: options.search
- }
- ]
- })
- } else {
- whereAnd.push(trigramSearch)
- }
-
- attributesInclude.push(createSimilarityAttribute('VideoModel.name', options.search))
- }
-
- // Cannot search on similarity if we don't have a search
- if (!options.search) {
- attributesInclude.push(
- Sequelize.literal('0 as similarity')
- )
- }
-
- const query = {
- attributes: {
- include: attributesInclude
- },
- offset: options.start,
- limit: options.count,
- order: getVideoSort(options.sort)
- }
-
const serverActor = await getServerActor()
const queryOptions = {
followerActorId: serverActor.id,
tagsAllOf: options.tagsAllOf,
user: options.user,
filter: options.filter,
- baseWhere: whereAnd
+ start: options.start,
+ count: options.count,
+ sort: options.sort,
+ startDate: options.startDate,
+ endDate: options.endDate,
+ originallyPublishedStartDate: options.originallyPublishedStartDate,
+ originallyPublishedEndDate: options.originallyPublishedEndDate,
+
+ durationMin: options.durationMin,
+ durationMax: options.durationMax,
+
+ search: options.search
}
- return VideoModel.getAvailableForApi(query, queryOptions)
+ return VideoModel.getAvailableForApi(queryOptions)
}
static load (id: number | string, t?: Transaction): Bluebird<MVideoThumbnail> {
const serverActor = await getServerActor()
const followerActorId = serverActor.id
- const scopeOptions: AvailableForListIDsOptions = {
+ const queryOptions: BuildVideosQueryOptions = {
+ attributes: [ `"${field}"` ],
+ group: `GROUP BY "${field}"`,
+ having: `HAVING COUNT("${field}") >= ${threshold}`,
+ start: 0,
+ sort: 'random',
+ count,
serverAccountId: serverActor.Account.id,
followerActorId,
- includeLocalVideos: true,
- attributesType: 'none' // Don't break aggregation
+ includeLocalVideos: true
}
- const query: FindOptions = {
- attributes: [ field ],
- limit: count,
- group: field,
- having: Sequelize.where(
- Sequelize.fn('COUNT', Sequelize.col(field)), { [Op.gte]: threshold }
- ),
- order: [ (this.sequelize as any).random() ]
- }
+ const { query, replacements } = buildListQuery(VideoModel, queryOptions)
- return VideoModel.scope({ method: [ ScopeNames.AVAILABLE_FOR_LIST_IDS, scopeOptions ] })
- .findAll(query)
- .then(rows => rows.map(r => r[field]))
+ return this.sequelize.query<any>(query, { replacements, type: QueryTypes.SELECT })
+ .then(rows => rows.map(r => r[field]))
}
static buildTrendingQuery (trendingDays: number) {
}
private static async getAvailableForApi (
- query: FindOptions & { where?: null }, // Forbid where field in query
- options: AvailableForListIDsOptions,
+ options: BuildVideosQueryOptions,
countVideos = true
) {
- const idsScope: ScopeOptions = {
- method: [
- ScopeNames.AVAILABLE_FOR_LIST_IDS, options
- ]
- }
-
- // Remove trending sort on count, because it uses a group by
- const countOptions = Object.assign({}, options, { trendingDays: undefined })
- const countQuery: CountOptions = Object.assign({}, query, { attributes: undefined, group: undefined })
- const countScope: ScopeOptions = {
- method: [
- ScopeNames.AVAILABLE_FOR_LIST_IDS, countOptions
- ]
- }
+ const { query, replacements } = buildListQuery(VideoModel, options)
+ const { query: queryCount, replacements: replacementsCount } = buildListQuery(VideoModel, Object.assign({}, options, { isCount: true }))
const [ count, rows ] = await Promise.all([
countVideos
- ? VideoModel.scope(countScope).count(countQuery)
+ ? this.sequelize.query<any>(queryCount, { replacements: replacementsCount, type: QueryTypes.SELECT })
+ .then(rows => rows.length !== 0 ? rows[0].total : 0)
: Promise.resolve<number>(undefined),
- VideoModel.scope(idsScope)
- .findAll(Object.assign({}, query, { raw: true }))
+ this.sequelize.query<any>(query, { replacements, type: QueryTypes.SELECT })
.then(rows => rows.map(r => r.id))
- .then(ids => VideoModel.loadCompleteVideosForApi(ids, query, options))
+ .then(ids => VideoModel.loadCompleteVideosForApi(ids, options))
])
return {
}
}
- private static loadCompleteVideosForApi (ids: number[], query: FindOptions, options: AvailableForListIDsOptions) {
+ private static loadCompleteVideosForApi (ids: number[], options: BuildVideosQueryOptions) {
if (ids.length === 0) return []
const secondQuery: FindOptions = {
offset: 0,
- limit: query.limit,
- attributes: query.attributes,
+ limit: options.count,
order: [ // Keep original order
Sequelize.literal(
ids.map(id => `"VideoModel".id = ${id} DESC`).join(', ')