]> git.immae.eu Git - github/Chocobozzz/PeerTube.git/blame - server/models/video/sql/videos-id-list-query-builder.ts
Use raw SQL for video get request
[github/Chocobozzz/PeerTube.git] / server / models / video / sql / videos-id-list-query-builder.ts
CommitLineData
e5dbd508
C
1import { Sequelize } from 'sequelize'
2import validator from 'validator'
3import { exists } from '@server/helpers/custom-validators/misc'
4import { buildDirectionAndField, createSafeIn } from '@server/models/utils'
5import { MUserAccountId, MUserId } from '@server/types/models'
6import { VideoFilter, VideoPrivacy, VideoState } from '@shared/models'
d9bf974f 7import { AbstractVideosQueryBuilder } from './shared/abstract-videos-query-builder'
e5dbd508
C
8
9export type BuildVideosListQueryOptions = {
10 attributes?: string[]
11
12 serverAccountId: number
13 followerActorId: number
14 includeLocalVideos: boolean
15
16 count: number
17 start: number
18 sort: string
19
20 nsfw?: boolean
21 filter?: VideoFilter
22 isLive?: boolean
23
24 categoryOneOf?: number[]
25 licenceOneOf?: number[]
26 languageOneOf?: string[]
27 tagsOneOf?: string[]
28 tagsAllOf?: string[]
29
30 withFiles?: boolean
31
32 accountId?: number
33 videoChannelId?: number
34
35 videoPlaylistId?: number
36
37 trendingAlgorithm?: string // best, hot, or any other algorithm implemented
38 trendingDays?: number
39
40 user?: MUserAccountId
41 historyOfUser?: MUserId
42
43 startDate?: string // ISO 8601
44 endDate?: string // ISO 8601
45 originallyPublishedStartDate?: string
46 originallyPublishedEndDate?: string
47
48 durationMin?: number // seconds
49 durationMax?: number // seconds
50
51 search?: string
52
53 isCount?: boolean
54
55 group?: string
56 having?: string
57}
58
59export class VideosIdListQueryBuilder extends AbstractVideosQueryBuilder {
d9bf974f
C
60 protected replacements: any = {}
61
e5dbd508 62 private attributes: string[]
d9bf974f 63 private joins: string[] = []
e5dbd508 64
e5dbd508 65 private readonly and: string[] = []
e5dbd508
C
66
67 private readonly cte: string[] = []
68
69 private group = ''
70 private having = ''
71
72 private sort = ''
73 private limit = ''
74 private offset = ''
75
76 constructor (protected readonly sequelize: Sequelize) {
77 super()
78 }
79
80 queryVideoIds (options: BuildVideosListQueryOptions) {
81 this.buildIdsListQuery(options)
82
83 return this.runQuery()
84 }
85
86 countVideoIds (countOptions: BuildVideosListQueryOptions): Promise<number> {
87 this.buildIdsListQuery(countOptions)
88
89 return this.runQuery().then(rows => rows.length !== 0 ? rows[0].total : 0)
90 }
91
92 getIdsListQueryAndSort (options: BuildVideosListQueryOptions) {
93 this.buildIdsListQuery(options)
94 return { query: this.query, sort: this.sort, replacements: this.replacements }
95 }
96
97 private buildIdsListQuery (options: BuildVideosListQueryOptions) {
98 this.attributes = options.attributes || [ '"video"."id"' ]
99
100 if (options.group) this.group = options.group
101 if (options.having) this.having = options.having
102
103 this.joins = this.joins.concat([
104 'INNER JOIN "videoChannel" ON "videoChannel"."id" = "video"."channelId"',
105 'INNER JOIN "account" ON "account"."id" = "videoChannel"."accountId"',
106 'INNER JOIN "actor" "accountActor" ON "account"."actorId" = "accountActor"."id"'
107 ])
108
109 this.whereNotBlacklisted()
110
111 if (options.serverAccountId) {
112 this.whereNotBlocked(options.serverAccountId, options.user)
113 }
114
115 // Only list public/published videos
116 if (!options.filter || (options.filter !== 'all-local' && options.filter !== 'all')) {
117 this.whereStateAndPrivacyAvailable(options.user)
118 }
119
120 if (options.videoPlaylistId) {
121 this.joinPlaylist(options.videoPlaylistId)
122 }
123
124 if (options.filter && (options.filter === 'local' || options.filter === 'all-local')) {
125 this.whereOnlyLocal()
126 }
127
128 if (options.accountId) {
129 this.whereAccountId(options.accountId)
130 }
131
132 if (options.videoChannelId) {
133 this.whereChannelId(options.videoChannelId)
134 }
135
136 if (options.followerActorId) {
137 this.whereFollowerActorId(options.followerActorId, options.includeLocalVideos)
138 }
139
140 if (options.withFiles === true) {
141 this.whereFileExists()
142 }
143
144 if (options.tagsOneOf) {
145 this.whereTagsOneOf(options.tagsOneOf)
146 }
147
148 if (options.tagsAllOf) {
149 this.whereTagsAllOf(options.tagsAllOf)
150 }
151
152 if (options.nsfw === true) {
153 this.whereNSFW()
154 } else if (options.nsfw === false) {
155 this.whereSFW()
156 }
157
158 if (options.isLive === true) {
159 this.whereLive()
160 } else if (options.isLive === false) {
161 this.whereVOD()
162 }
163
164 if (options.categoryOneOf) {
165 this.whereCategoryOneOf(options.categoryOneOf)
166 }
167
168 if (options.licenceOneOf) {
169 this.whereLicenceOneOf(options.licenceOneOf)
170 }
171
172 if (options.languageOneOf) {
173 this.whereLanguageOneOf(options.languageOneOf)
174 }
175
176 // We don't exclude results in this so if we do a count we don't need to add this complex clause
177 if (options.isCount !== true) {
178 if (options.trendingDays) {
179 this.groupForTrending(options.trendingDays)
180 } else if ([ 'best', 'hot' ].includes(options.trendingAlgorithm)) {
181 this.groupForHotOrBest(options.trendingAlgorithm, options.user)
182 }
183 }
184
185 if (options.historyOfUser) {
186 this.joinHistory(options.historyOfUser.id)
187 }
188
189 if (options.startDate) {
190 this.whereStartDate(options.startDate)
191 }
192
193 if (options.endDate) {
194 this.whereEndDate(options.endDate)
195 }
196
197 if (options.originallyPublishedStartDate) {
198 this.whereOriginallyPublishedStartDate(options.originallyPublishedStartDate)
199 }
200
201 if (options.originallyPublishedEndDate) {
202 this.whereOriginallyPublishedEndDate(options.originallyPublishedEndDate)
203 }
204
205 if (options.durationMin) {
206 this.whereDurationMin(options.durationMin)
207 }
208
209 if (options.durationMax) {
210 this.whereDurationMax(options.durationMax)
211 }
212
213 this.whereSearch(options.search)
214
215 if (options.isCount === true) {
216 this.setCountAttribute()
217 } else {
218 if (exists(options.sort)) {
219 this.setSort(options.sort)
220 }
221
222 if (exists(options.count)) {
223 this.setLimit(options.count)
224 }
225
226 if (exists(options.start)) {
227 this.setOffset(options.start)
228 }
229 }
230
231 const cteString = this.cte.length !== 0
232 ? `WITH ${this.cte.join(', ')} `
233 : ''
234
235 this.query = cteString +
236 'SELECT ' + this.attributes.join(', ') + ' ' +
237 'FROM "video" ' + this.joins.join(' ') + ' ' +
238 'WHERE ' + this.and.join(' AND ') + ' ' +
239 this.group + ' ' +
240 this.having + ' ' +
241 this.sort + ' ' +
242 this.limit + ' ' +
243 this.offset
244 }
245
246 private setCountAttribute () {
247 this.attributes = [ 'COUNT(*) as "total"' ]
248 }
249
250 private joinHistory (userId: number) {
251 this.joins.push('INNER JOIN "userVideoHistory" ON "video"."id" = "userVideoHistory"."videoId"')
252
253 this.and.push('"userVideoHistory"."userId" = :historyOfUser')
254
255 this.replacements.historyOfUser = userId
256 }
257
258 private joinPlaylist (playlistId: number) {
259 this.joins.push(
260 'INNER JOIN "videoPlaylistElement" "video"."id" = "videoPlaylistElement"."videoId" ' +
261 'AND "videoPlaylistElement"."videoPlaylistId" = :videoPlaylistId'
262 )
263
264 this.replacements.videoPlaylistId = playlistId
265 }
266
267 private whereStateAndPrivacyAvailable (user?: MUserAccountId) {
268 this.and.push(
269 `("video"."state" = ${VideoState.PUBLISHED} OR ` +
270 `("video"."state" = ${VideoState.TO_TRANSCODE} AND "video"."waitTranscoding" IS false))`
271 )
272
273 if (user) {
274 this.and.push(
275 `("video"."privacy" = ${VideoPrivacy.PUBLIC} OR "video"."privacy" = ${VideoPrivacy.INTERNAL})`
276 )
277 } else { // Or only public videos
278 this.and.push(
279 `"video"."privacy" = ${VideoPrivacy.PUBLIC}`
280 )
281 }
282 }
283
284 private whereOnlyLocal () {
285 this.and.push('"video"."remote" IS FALSE')
286 }
287
288 private whereAccountId (accountId: number) {
289 this.and.push('"account"."id" = :accountId')
290 this.replacements.accountId = accountId
291 }
292
293 private whereChannelId (channelId: number) {
294 this.and.push('"videoChannel"."id" = :videoChannelId')
295 this.replacements.videoChannelId = channelId
296 }
297
298 private whereFollowerActorId (followerActorId: number, includeLocalVideos: boolean) {
299 let query =
300 '(' +
301 ' EXISTS (' +
302 ' SELECT 1 FROM "videoShare" ' +
303 ' INNER JOIN "actorFollow" "actorFollowShare" ON "actorFollowShare"."targetActorId" = "videoShare"."actorId" ' +
304 ' AND "actorFollowShare"."actorId" = :followerActorId AND "actorFollowShare"."state" = \'accepted\' ' +
305 ' WHERE "videoShare"."videoId" = "video"."id"' +
306 ' )' +
307 ' OR' +
308 ' EXISTS (' +
309 ' SELECT 1 from "actorFollow" ' +
310 ' WHERE "actorFollow"."targetActorId" = "videoChannel"."actorId" AND "actorFollow"."actorId" = :followerActorId ' +
311 ' AND "actorFollow"."state" = \'accepted\'' +
312 ' )'
313
314 if (includeLocalVideos) {
315 query += ' OR "video"."remote" IS FALSE'
316 }
317
318 query += ')'
319
320 this.and.push(query)
321 this.replacements.followerActorId = followerActorId
322 }
323
324 private whereFileExists () {
325 this.and.push(
326 '(' +
327 ' EXISTS (SELECT 1 FROM "videoFile" WHERE "videoFile"."videoId" = "video"."id") ' +
328 ' OR EXISTS (' +
329 ' SELECT 1 FROM "videoStreamingPlaylist" ' +
330 ' INNER JOIN "videoFile" ON "videoFile"."videoStreamingPlaylistId" = "videoStreamingPlaylist"."id" ' +
331 ' WHERE "videoStreamingPlaylist"."videoId" = "video"."id"' +
332 ' )' +
333 ')'
334 )
335 }
336
337 private whereTagsOneOf (tagsOneOf: string[]) {
338 const tagsOneOfLower = tagsOneOf.map(t => t.toLowerCase())
339
340 this.and.push(
341 'EXISTS (' +
342 ' SELECT 1 FROM "videoTag" ' +
343 ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
344 ' WHERE lower("tag"."name") IN (' + createSafeIn(this.sequelize, tagsOneOfLower) + ') ' +
345 ' AND "video"."id" = "videoTag"."videoId"' +
346 ')'
347 )
348 }
349
350 private whereTagsAllOf (tagsAllOf: string[]) {
351 const tagsAllOfLower = tagsAllOf.map(t => t.toLowerCase())
352
353 this.and.push(
354 'EXISTS (' +
355 ' SELECT 1 FROM "videoTag" ' +
356 ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
357 ' WHERE lower("tag"."name") IN (' + createSafeIn(this.sequelize, tagsAllOfLower) + ') ' +
358 ' AND "video"."id" = "videoTag"."videoId" ' +
359 ' GROUP BY "videoTag"."videoId" HAVING COUNT(*) = ' + tagsAllOfLower.length +
360 ')'
361 )
362 }
363
364 private whereCategoryOneOf (categoryOneOf: number[]) {
365 this.and.push('"video"."category" IN (:categoryOneOf)')
366 this.replacements.categoryOneOf = categoryOneOf
367 }
368
369 private whereLicenceOneOf (licenceOneOf: number[]) {
370 this.and.push('"video"."licence" IN (:licenceOneOf)')
371 this.replacements.licenceOneOf = licenceOneOf
372 }
373
374 private whereLanguageOneOf (languageOneOf: string[]) {
375 const languages = languageOneOf.filter(l => l && l !== '_unknown')
376 const languagesQueryParts: string[] = []
377
378 if (languages.length !== 0) {
379 languagesQueryParts.push('"video"."language" IN (:languageOneOf)')
380 this.replacements.languageOneOf = languages
381
382 languagesQueryParts.push(
383 'EXISTS (' +
384 ' SELECT 1 FROM "videoCaption" WHERE "videoCaption"."language" ' +
385 ' IN (' + createSafeIn(this.sequelize, languages) + ') AND ' +
386 ' "videoCaption"."videoId" = "video"."id"' +
387 ')'
388 )
389 }
390
391 if (languageOneOf.includes('_unknown')) {
392 languagesQueryParts.push('"video"."language" IS NULL')
393 }
394
395 if (languagesQueryParts.length !== 0) {
396 this.and.push('(' + languagesQueryParts.join(' OR ') + ')')
397 }
398 }
399
400 private whereNSFW () {
401 this.and.push('"video"."nsfw" IS TRUE')
402 }
403
404 private whereSFW () {
405 this.and.push('"video"."nsfw" IS FALSE')
406 }
407
408 private whereLive () {
409 this.and.push('"video"."isLive" IS TRUE')
410 }
411
412 private whereVOD () {
413 this.and.push('"video"."isLive" IS FALSE')
414 }
415
416 private whereNotBlocked (serverAccountId: number, user?: MUserAccountId) {
417 const blockerIds = [ serverAccountId ]
418 if (user) blockerIds.push(user.Account.id)
419
420 const inClause = createSafeIn(this.sequelize, blockerIds)
421
422 this.and.push(
423 'NOT EXISTS (' +
424 ' SELECT 1 FROM "accountBlocklist" ' +
425 ' WHERE "accountBlocklist"."accountId" IN (' + inClause + ') ' +
426 ' AND "accountBlocklist"."targetAccountId" = "account"."id" ' +
427 ')' +
428 'AND NOT EXISTS (' +
429 ' SELECT 1 FROM "serverBlocklist" WHERE "serverBlocklist"."accountId" IN (' + inClause + ') ' +
430 ' AND "serverBlocklist"."targetServerId" = "accountActor"."serverId"' +
431 ')'
432 )
433 }
434
435 private whereSearch (search?: string) {
436 if (!search) {
437 this.attributes.push('0 as similarity')
438 return
439 }
440
441 const escapedSearch = this.sequelize.escape(search)
442 const escapedLikeSearch = this.sequelize.escape('%' + search + '%')
443
444 this.cte.push(
445 '"trigramSearch" AS (' +
446 ' SELECT "video"."id", ' +
447 ` similarity(lower(immutable_unaccent("video"."name")), lower(immutable_unaccent(${escapedSearch}))) as similarity ` +
448 ' FROM "video" ' +
449 ' WHERE lower(immutable_unaccent("video"."name")) % lower(immutable_unaccent(' + escapedSearch + ')) OR ' +
450 ' lower(immutable_unaccent("video"."name")) LIKE lower(immutable_unaccent(' + escapedLikeSearch + '))' +
451 ')'
452 )
453
454 this.joins.push('LEFT JOIN "trigramSearch" ON "video"."id" = "trigramSearch"."id"')
455
456 let base = '(' +
457 ' "trigramSearch"."id" IS NOT NULL OR ' +
458 ' EXISTS (' +
459 ' SELECT 1 FROM "videoTag" ' +
460 ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
461 ` WHERE lower("tag"."name") = ${escapedSearch} ` +
462 ' AND "video"."id" = "videoTag"."videoId"' +
463 ' )'
464
465 if (validator.isUUID(search)) {
466 base += ` OR "video"."uuid" = ${escapedSearch}`
467 }
468
469 base += ')'
470
471 this.and.push(base)
472 this.attributes.push(`COALESCE("trigramSearch"."similarity", 0) as similarity`)
473 }
474
475 private whereNotBlacklisted () {
476 this.and.push('"video"."id" NOT IN (SELECT "videoBlacklist"."videoId" FROM "videoBlacklist")')
477 }
478
479 private whereStartDate (startDate: string) {
480 this.and.push('"video"."publishedAt" >= :startDate')
481 this.replacements.startDate = startDate
482 }
483
484 private whereEndDate (endDate: string) {
485 this.and.push('"video"."publishedAt" <= :endDate')
486 this.replacements.endDate = endDate
487 }
488
489 private whereOriginallyPublishedStartDate (startDate: string) {
490 this.and.push('"video"."originallyPublishedAt" >= :originallyPublishedStartDate')
491 this.replacements.originallyPublishedStartDate = startDate
492 }
493
494 private whereOriginallyPublishedEndDate (endDate: string) {
495 this.and.push('"video"."originallyPublishedAt" <= :originallyPublishedEndDate')
496 this.replacements.originallyPublishedEndDate = endDate
497 }
498
499 private whereDurationMin (durationMin: number) {
500 this.and.push('"video"."duration" >= :durationMin')
501 this.replacements.durationMin = durationMin
502 }
503
504 private whereDurationMax (durationMax: number) {
505 this.and.push('"video"."duration" <= :durationMax')
506 this.replacements.durationMax = durationMax
507 }
508
509 private groupForTrending (trendingDays: number) {
510 const viewsGteDate = new Date(new Date().getTime() - (24 * 3600 * 1000) * trendingDays)
511
512 this.joins.push('LEFT JOIN "videoView" ON "video"."id" = "videoView"."videoId" AND "videoView"."startDate" >= :viewsGteDate')
513 this.replacements.viewsGteDate = viewsGteDate
514
515 this.attributes.push('COALESCE(SUM("videoView"."views"), 0) AS "score"')
516
517 this.group = 'GROUP BY "video"."id"'
518 }
519
520 private groupForHotOrBest (trendingAlgorithm: string, user?: MUserAccountId) {
521 /**
522 * "Hotness" is a measure based on absolute view/comment/like/dislike numbers,
523 * with fixed weights only applied to their log values.
524 *
525 * This algorithm gives little chance for an old video to have a good score,
526 * for which recent spikes in interactions could be a sign of "hotness" and
527 * justify a better score. However there are multiple ways to achieve that
528 * goal, which is left for later. Yes, this is a TODO :)
529 *
530 * notes:
531 * - weights and base score are in number of half-days.
532 * - all comments are counted, regardless of being written by the video author or not
533 * see https://github.com/reddit-archive/reddit/blob/master/r2/r2/lib/db/_sorts.pyx#L47-L58
534 * - we have less interactions than on reddit, so multiply weights by an arbitrary factor
535 */
536 const weights = {
537 like: 3 * 50,
538 dislike: -3 * 50,
539 view: Math.floor((1 / 3) * 50),
540 comment: 2 * 50, // a comment takes more time than a like to do, but can be done multiple times
541 history: -2 * 50
542 }
543
544 this.joins.push('LEFT JOIN "videoComment" ON "video"."id" = "videoComment"."videoId"')
545
546 let attribute =
547 `LOG(GREATEST(1, "video"."likes" - 1)) * ${weights.like} ` + // likes (+)
548 `+ LOG(GREATEST(1, "video"."dislikes" - 1)) * ${weights.dislike} ` + // dislikes (-)
549 `+ LOG("video"."views" + 1) * ${weights.view} ` + // views (+)
550 `+ LOG(GREATEST(1, COUNT(DISTINCT "videoComment"."id"))) * ${weights.comment} ` + // comments (+)
551 '+ (SELECT (EXTRACT(epoch FROM "video"."publishedAt") - 1446156582) / 47000) ' // base score (in number of half-days)
552
553 if (trendingAlgorithm === 'best' && user) {
554 this.joins.push(
555 'LEFT JOIN "userVideoHistory" ON "video"."id" = "userVideoHistory"."videoId" AND "userVideoHistory"."userId" = :bestUser'
556 )
557 this.replacements.bestUser = user.id
558
559 attribute += `+ POWER(COUNT(DISTINCT "userVideoHistory"."id"), 2.0) * ${weights.history} `
560 }
561
562 attribute += 'AS "score"'
563 this.attributes.push(attribute)
564
565 this.group = 'GROUP BY "video"."id"'
566 }
567
568 private setSort (sort: string) {
569 if (sort === '-originallyPublishedAt' || sort === 'originallyPublishedAt') {
570 this.attributes.push('COALESCE("video"."originallyPublishedAt", "video"."publishedAt") AS "publishedAtForOrder"')
571 }
572
573 this.sort = this.buildOrder(sort)
574 }
575
576 private buildOrder (value: string) {
577 const { direction, field } = buildDirectionAndField(value)
578 if (field.match(/^[a-zA-Z."]+$/) === null) throw new Error('Invalid sort column ' + field)
579
580 if (field.toLowerCase() === 'random') return 'ORDER BY RANDOM()'
581
582 if ([ 'trending', 'hot', 'best' ].includes(field.toLowerCase())) { // Sort by aggregation
583 return `ORDER BY "score" ${direction}, "video"."views" ${direction}`
584 }
585
586 let firstSort: string
587
588 if (field.toLowerCase() === 'match') { // Search
589 firstSort = '"similarity"'
590 } else if (field === 'originallyPublishedAt') {
591 firstSort = '"publishedAtForOrder"'
592 } else if (field.includes('.')) {
593 firstSort = field
594 } else {
595 firstSort = `"video"."${field}"`
596 }
597
598 return `ORDER BY ${firstSort} ${direction}, "video"."id" ASC`
599 }
600
601 private setLimit (countArg: number) {
602 const count = parseInt(countArg + '', 10)
603 this.limit = `LIMIT ${count}`
604 }
605
606 private setOffset (startArg: number) {
607 const start = parseInt(startArg + '', 10)
608 this.offset = `OFFSET ${start}`
609 }
610}