]> git.immae.eu Git - github/Chocobozzz/PeerTube.git/blob - server/models/video/video-query-builder.ts
6211c9e565acee0c1b2500da83fe5c0f1f6f267e
[github/Chocobozzz/PeerTube.git] / server / models / video / video-query-builder.ts
1 import { VideoFilter, VideoPrivacy, VideoState } from '@shared/models'
2 import { buildDirectionAndField, createSafeIn } from '@server/models/utils'
3 import { Model } from 'sequelize-typescript'
4 import { MUserAccountId, MUserId } from '@server/typings/models'
5 import validator from 'validator'
6 import { exists } from '@server/helpers/custom-validators/misc'
7
8 export type BuildVideosQueryOptions = {
9 attributes?: string[]
10
11 serverAccountId: number
12 followerActorId: number
13 includeLocalVideos: boolean
14
15 count: number
16 start: number
17 sort: string
18
19 filter?: VideoFilter
20 categoryOneOf?: number[]
21 nsfw?: boolean
22 licenceOneOf?: number[]
23 languageOneOf?: string[]
24 tagsOneOf?: string[]
25 tagsAllOf?: string[]
26
27 withFiles?: boolean
28
29 accountId?: number
30 videoChannelId?: number
31
32 videoPlaylistId?: number
33
34 trendingDays?: number
35 user?: MUserAccountId
36 historyOfUser?: MUserId
37
38 startDate?: string // ISO 8601
39 endDate?: string // ISO 8601
40 originallyPublishedStartDate?: string
41 originallyPublishedEndDate?: string
42
43 durationMin?: number // seconds
44 durationMax?: number // seconds
45
46 search?: string
47
48 isCount?: boolean
49
50 group?: string
51 having?: string
52 }
53
54 function buildListQuery (model: typeof Model, options: BuildVideosQueryOptions) {
55 const and: string[] = []
56 const joins: string[] = []
57 const replacements: any = {}
58 const cte: string[] = []
59
60 let attributes: string[] = options.attributes || [ '"video"."id"' ]
61 let group = options.group || ''
62 const having = options.having || ''
63
64 joins.push(
65 'INNER JOIN "videoChannel" ON "videoChannel"."id" = "video"."channelId"' +
66 'INNER JOIN "account" ON "account"."id" = "videoChannel"."accountId"' +
67 'INNER JOIN "actor" "accountActor" ON "account"."actorId" = "accountActor"."id"'
68 )
69
70 and.push('"video"."id" NOT IN (SELECT "videoBlacklist"."videoId" FROM "videoBlacklist")')
71
72 if (options.serverAccountId) {
73 const blockerIds = [ options.serverAccountId ]
74 if (options.user) blockerIds.push(options.user.Account.id)
75
76 const inClause = createSafeIn(model, blockerIds)
77
78 and.push(
79 'NOT EXISTS (' +
80 ' SELECT 1 FROM "accountBlocklist" ' +
81 ' WHERE "accountBlocklist"."accountId" IN (' + inClause + ') ' +
82 ' AND "accountBlocklist"."targetAccountId" = "account"."id" ' +
83 ')' +
84 'AND NOT EXISTS (' +
85 ' SELECT 1 FROM "serverBlocklist" WHERE "serverBlocklist"."accountId" IN (' + inClause + ') ' +
86 ' AND "serverBlocklist"."targetServerId" = "accountActor"."serverId"' +
87 ')'
88 )
89 }
90
91 // Only list public/published videos
92 if (!options.filter || options.filter !== 'all-local') {
93 and.push(
94 `("video"."state" = ${VideoState.PUBLISHED} OR ` +
95 `("video"."state" = ${VideoState.TO_TRANSCODE} AND "video"."waitTranscoding" IS false))`
96 )
97
98 if (options.user) {
99 and.push(
100 `("video"."privacy" = ${VideoPrivacy.PUBLIC} OR "video"."privacy" = ${VideoPrivacy.INTERNAL})`
101 )
102 } else { // Or only public videos
103 and.push(
104 `"video"."privacy" = ${VideoPrivacy.PUBLIC}`
105 )
106 }
107 }
108
109 if (options.videoPlaylistId) {
110 joins.push(
111 'INNER JOIN "videoPlaylistElement" "video"."id" = "videoPlaylistElement"."videoId" ' +
112 'AND "videoPlaylistElement"."videoPlaylistId" = :videoPlaylistId'
113 )
114
115 replacements.videoPlaylistId = options.videoPlaylistId
116 }
117
118 if (options.filter && (options.filter === 'local' || options.filter === 'all-local')) {
119 and.push('"video"."remote" IS FALSE')
120 }
121
122 if (options.accountId) {
123 and.push('"account"."id" = :accountId')
124 replacements.accountId = options.accountId
125 }
126
127 if (options.videoChannelId) {
128 and.push('"videoChannel"."id" = :videoChannelId')
129 replacements.videoChannelId = options.videoChannelId
130 }
131
132 if (options.followerActorId) {
133 let query =
134 '(' +
135 ' EXISTS (' +
136 ' SELECT 1 FROM "videoShare" ' +
137 ' INNER JOIN "actorFollow" "actorFollowShare" ON "actorFollowShare"."targetActorId" = "videoShare"."actorId" ' +
138 ' AND "actorFollowShare"."actorId" = :followerActorId AND "actorFollowShare"."state" = \'accepted\' ' +
139 ' WHERE "videoShare"."videoId" = "video"."id"' +
140 ' )' +
141 ' OR' +
142 ' EXISTS (' +
143 ' SELECT 1 from "actorFollow" ' +
144 ' WHERE "actorFollow"."targetActorId" = "videoChannel"."actorId" AND "actorFollow"."actorId" = :followerActorId ' +
145 ' AND "actorFollow"."state" = \'accepted\'' +
146 ' )'
147
148 if (options.includeLocalVideos) {
149 query += ' OR "video"."remote" IS FALSE'
150 }
151
152 query += ')'
153
154 and.push(query)
155 replacements.followerActorId = options.followerActorId
156 }
157
158 if (options.withFiles === true) {
159 and.push('EXISTS (SELECT 1 FROM "videoFile" WHERE "videoFile"."videoId" = "video"."id")')
160 }
161
162 if (options.tagsOneOf) {
163 const tagsOneOfLower = options.tagsOneOf.map(t => t.toLowerCase())
164
165 and.push(
166 'EXISTS (' +
167 ' SELECT 1 FROM "videoTag" ' +
168 ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
169 ' WHERE lower("tag"."name") IN (' + createSafeIn(model, tagsOneOfLower) + ') ' +
170 ' AND "video"."id" = "videoTag"."videoId"' +
171 ')'
172 )
173 }
174
175 if (options.tagsAllOf) {
176 const tagsAllOfLower = options.tagsAllOf.map(t => t.toLowerCase())
177
178 and.push(
179 'EXISTS (' +
180 ' SELECT 1 FROM "videoTag" ' +
181 ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
182 ' WHERE lower("tag"."name") IN (' + createSafeIn(model, tagsAllOfLower) + ') ' +
183 ' AND "video"."id" = "videoTag"."videoId" ' +
184 ' GROUP BY "videoTag"."videoId" HAVING COUNT(*) = ' + tagsAllOfLower.length +
185 ')'
186 )
187 }
188
189 if (options.nsfw === true) {
190 and.push('"video"."nsfw" IS TRUE')
191 }
192
193 if (options.nsfw === false) {
194 and.push('"video"."nsfw" IS FALSE')
195 }
196
197 if (options.categoryOneOf) {
198 and.push('"video"."category" IN (:categoryOneOf)')
199 replacements.categoryOneOf = options.categoryOneOf
200 }
201
202 if (options.licenceOneOf) {
203 and.push('"video"."licence" IN (:licenceOneOf)')
204 replacements.licenceOneOf = options.licenceOneOf
205 }
206
207 if (options.languageOneOf) {
208 const languages = options.languageOneOf.filter(l => l && l !== '_unknown')
209 const languagesQueryParts: string[] = []
210
211 if (languages.length !== 0) {
212 languagesQueryParts.push('"video"."language" IN (:languageOneOf)')
213 replacements.languageOneOf = languages
214
215 languagesQueryParts.push(
216 'EXISTS (' +
217 ' SELECT 1 FROM "videoCaption" WHERE "videoCaption"."language" ' +
218 ' IN (' + createSafeIn(model, languages) + ') AND ' +
219 ' "videoCaption"."videoId" = "video"."id"' +
220 ')'
221 )
222 }
223
224 if (options.languageOneOf.includes('_unknown')) {
225 languagesQueryParts.push('"video"."language" IS NULL')
226 }
227
228 if (languagesQueryParts.length !== 0) {
229 and.push('(' + languagesQueryParts.join(' OR ') + ')')
230 }
231 }
232
233 // We don't exclude results in this if so if we do a count we don't need to add this complex clauses
234 if (options.trendingDays && options.isCount !== true) {
235 const viewsGteDate = new Date(new Date().getTime() - (24 * 3600 * 1000) * options.trendingDays)
236
237 joins.push('LEFT JOIN "videoView" ON "video"."id" = "videoView"."videoId" AND "videoView"."startDate" >= :viewsGteDate')
238 replacements.viewsGteDate = viewsGteDate
239
240 attributes.push('COALESCE(SUM("videoView"."views"), 0) AS "videoViewsSum"')
241
242 group = 'GROUP BY "video"."id"'
243 }
244
245 if (options.historyOfUser) {
246 joins.push('INNER JOIN "userVideoHistory" on "video"."id" = "userVideoHistory"."videoId"')
247
248 and.push('"userVideoHistory"."userId" = :historyOfUser')
249 replacements.historyOfUser = options.historyOfUser.id
250 }
251
252 if (options.startDate) {
253 and.push('"video"."publishedAt" >= :startDate')
254 replacements.startDate = options.startDate
255 }
256
257 if (options.endDate) {
258 and.push('"video"."publishedAt" <= :endDate')
259 replacements.endDate = options.endDate
260 }
261
262 if (options.originallyPublishedStartDate) {
263 and.push('"video"."originallyPublishedAt" >= :originallyPublishedStartDate')
264 replacements.originallyPublishedStartDate = options.originallyPublishedStartDate
265 }
266
267 if (options.originallyPublishedEndDate) {
268 and.push('"video"."originallyPublishedAt" <= :originallyPublishedEndDate')
269 replacements.originallyPublishedEndDate = options.originallyPublishedEndDate
270 }
271
272 if (options.durationMin) {
273 and.push('"video"."duration" >= :durationMin')
274 replacements.durationMin = options.durationMin
275 }
276
277 if (options.durationMax) {
278 and.push('"video"."duration" <= :durationMax')
279 replacements.durationMax = options.durationMax
280 }
281
282 if (options.search) {
283 const escapedSearch = model.sequelize.escape(options.search)
284 const escapedLikeSearch = model.sequelize.escape('%' + options.search + '%')
285
286 cte.push(
287 '"trigramSearch" AS (' +
288 ' SELECT "video"."id", ' +
289 ` similarity(lower(immutable_unaccent("video"."name")), lower(immutable_unaccent(${escapedSearch}))) as similarity ` +
290 ' FROM "video" ' +
291 ' WHERE lower(immutable_unaccent("video"."name")) % lower(immutable_unaccent(' + escapedSearch + ')) OR ' +
292 ' lower(immutable_unaccent("video"."name")) LIKE lower(immutable_unaccent(' + escapedLikeSearch + '))' +
293 ')'
294 )
295
296 joins.push('LEFT JOIN "trigramSearch" ON "video"."id" = "trigramSearch"."id"')
297
298 let base = '(' +
299 ' "trigramSearch"."id" IS NOT NULL OR ' +
300 ' EXISTS (' +
301 ' SELECT 1 FROM "videoTag" ' +
302 ' INNER JOIN "tag" ON "tag"."id" = "videoTag"."tagId" ' +
303 ` WHERE lower("tag"."name") = ${escapedSearch} ` +
304 ' AND "video"."id" = "videoTag"."videoId"' +
305 ' )'
306
307 if (validator.isUUID(options.search)) {
308 base += ` OR "video"."uuid" = ${escapedSearch}`
309 }
310
311 base += ')'
312 and.push(base)
313
314 attributes.push(`COALESCE("trigramSearch"."similarity", 0) as similarity`)
315 } else {
316 attributes.push('0 as similarity')
317 }
318
319 if (options.isCount === true) attributes = [ 'COUNT(*) as "total"' ]
320
321 let suffix = ''
322 let order = ''
323 if (options.isCount !== true) {
324
325 if (exists(options.sort)) {
326 if (options.sort === '-originallyPublishedAt' || options.sort === 'originallyPublishedAt') {
327 attributes.push('COALESCE("video"."originallyPublishedAt", "video"."publishedAt") AS "publishedAtForOrder"')
328 }
329
330 order = buildOrder(model, options.sort)
331 suffix += `${order} `
332 }
333
334 if (exists(options.count)) {
335 const count = parseInt(options.count + '', 10)
336 suffix += `LIMIT ${count} `
337 }
338
339 if (exists(options.start)) {
340 const start = parseInt(options.start + '', 10)
341 suffix += `OFFSET ${start} `
342 }
343 }
344
345 const cteString = cte.length !== 0
346 ? `WITH ${cte.join(', ')} `
347 : ''
348
349 const query = cteString +
350 'SELECT ' + attributes.join(', ') + ' ' +
351 'FROM "video" ' + joins.join(' ') + ' ' +
352 'WHERE ' + and.join(' AND ') + ' ' +
353 group + ' ' +
354 having + ' ' +
355 suffix
356
357 return { query, replacements, order }
358 }
359
360 function buildOrder (model: typeof Model, value: string) {
361 const { direction, field } = buildDirectionAndField(value)
362 if (field.match(/^[a-zA-Z."]+$/) === null) throw new Error('Invalid sort column ' + field)
363
364 if (field.toLowerCase() === 'random') return 'ORDER BY RANDOM()'
365
366 if (field.toLowerCase() === 'trending') { // Sort by aggregation
367 return `ORDER BY "videoViewsSum" ${direction}, "video"."views" ${direction}`
368 }
369
370 let firstSort: string
371
372 if (field.toLowerCase() === 'match') { // Search
373 firstSort = '"similarity"'
374 } else if (field === 'originallyPublishedAt') {
375 firstSort = '"publishedAtForOrder"'
376 } else if (field.includes('.')) {
377 firstSort = field
378 } else {
379 firstSort = `"video"."${field}"`
380 }
381
382 return `ORDER BY ${firstSort} ${direction}, "video"."id" ASC`
383 }
384
385 function wrapForAPIResults (baseQuery: string, replacements: any, options: BuildVideosQueryOptions, order: string) {
386 const attributes = {
387 '"video".*': '',
388 '"VideoChannel"."id"': '"VideoChannel.id"',
389 '"VideoChannel"."name"': '"VideoChannel.name"',
390 '"VideoChannel"."description"': '"VideoChannel.description"',
391 '"VideoChannel"."actorId"': '"VideoChannel.actorId"',
392 '"VideoChannel->Actor"."id"': '"VideoChannel.Actor.id"',
393 '"VideoChannel->Actor"."preferredUsername"': '"VideoChannel.Actor.preferredUsername"',
394 '"VideoChannel->Actor"."url"': '"VideoChannel.Actor.url"',
395 '"VideoChannel->Actor"."serverId"': '"VideoChannel.Actor.serverId"',
396 '"VideoChannel->Actor"."avatarId"': '"VideoChannel.Actor.avatarId"',
397 '"VideoChannel->Account"."id"': '"VideoChannel.Account.id"',
398 '"VideoChannel->Account"."name"': '"VideoChannel.Account.name"',
399 '"VideoChannel->Account->Actor"."id"': '"VideoChannel.Account.Actor.id"',
400 '"VideoChannel->Account->Actor"."preferredUsername"': '"VideoChannel.Account.Actor.preferredUsername"',
401 '"VideoChannel->Account->Actor"."url"': '"VideoChannel.Account.Actor.url"',
402 '"VideoChannel->Account->Actor"."serverId"': '"VideoChannel.Account.Actor.serverId"',
403 '"VideoChannel->Account->Actor"."avatarId"': '"VideoChannel.Account.Actor.avatarId"',
404 '"VideoChannel->Actor->Server"."id"': '"VideoChannel.Actor.Server.id"',
405 '"VideoChannel->Actor->Server"."host"': '"VideoChannel.Actor.Server.host"',
406 '"VideoChannel->Actor->Avatar"."id"': '"VideoChannel.Actor.Avatar.id"',
407 '"VideoChannel->Actor->Avatar"."filename"': '"VideoChannel.Actor.Avatar.filename"',
408 '"VideoChannel->Actor->Avatar"."fileUrl"': '"VideoChannel.Actor.Avatar.fileUrl"',
409 '"VideoChannel->Actor->Avatar"."onDisk"': '"VideoChannel.Actor.Avatar.onDisk"',
410 '"VideoChannel->Actor->Avatar"."createdAt"': '"VideoChannel.Actor.Avatar.createdAt"',
411 '"VideoChannel->Actor->Avatar"."updatedAt"': '"VideoChannel.Actor.Avatar.updatedAt"',
412 '"VideoChannel->Account->Actor->Server"."id"': '"VideoChannel.Account.Actor.Server.id"',
413 '"VideoChannel->Account->Actor->Server"."host"': '"VideoChannel.Account.Actor.Server.host"',
414 '"VideoChannel->Account->Actor->Avatar"."id"': '"VideoChannel.Account.Actor.Avatar.id"',
415 '"VideoChannel->Account->Actor->Avatar"."filename"': '"VideoChannel.Account.Actor.Avatar.filename"',
416 '"VideoChannel->Account->Actor->Avatar"."fileUrl"': '"VideoChannel.Account.Actor.Avatar.fileUrl"',
417 '"VideoChannel->Account->Actor->Avatar"."onDisk"': '"VideoChannel.Account.Actor.Avatar.onDisk"',
418 '"VideoChannel->Account->Actor->Avatar"."createdAt"': '"VideoChannel.Account.Actor.Avatar.createdAt"',
419 '"VideoChannel->Account->Actor->Avatar"."updatedAt"': '"VideoChannel.Account.Actor.Avatar.updatedAt"',
420 '"Thumbnails"."id"': '"Thumbnails.id"',
421 '"Thumbnails"."type"': '"Thumbnails.type"',
422 '"Thumbnails"."filename"': '"Thumbnails.filename"'
423 }
424
425 const joins = [
426 'INNER JOIN "video" ON "tmp"."id" = "video"."id"',
427
428 'INNER JOIN "videoChannel" AS "VideoChannel" ON "video"."channelId" = "VideoChannel"."id"',
429 'INNER JOIN "actor" AS "VideoChannel->Actor" ON "VideoChannel"."actorId" = "VideoChannel->Actor"."id"',
430 'INNER JOIN "account" AS "VideoChannel->Account" ON "VideoChannel"."accountId" = "VideoChannel->Account"."id"',
431 'INNER JOIN "actor" AS "VideoChannel->Account->Actor" ON "VideoChannel->Account"."actorId" = "VideoChannel->Account->Actor"."id"',
432
433 'LEFT OUTER JOIN "server" AS "VideoChannel->Actor->Server" ON "VideoChannel->Actor"."serverId" = "VideoChannel->Actor->Server"."id"',
434 'LEFT OUTER JOIN "avatar" AS "VideoChannel->Actor->Avatar" ON "VideoChannel->Actor"."avatarId" = "VideoChannel->Actor->Avatar"."id"',
435
436 'LEFT OUTER JOIN "server" AS "VideoChannel->Account->Actor->Server" ' +
437 'ON "VideoChannel->Account->Actor"."serverId" = "VideoChannel->Account->Actor->Server"."id"',
438
439 'LEFT OUTER JOIN "avatar" AS "VideoChannel->Account->Actor->Avatar" ' +
440 'ON "VideoChannel->Account->Actor"."avatarId" = "VideoChannel->Account->Actor->Avatar"."id"',
441
442 'LEFT OUTER JOIN "thumbnail" AS "Thumbnails" ON "video"."id" = "Thumbnails"."videoId"'
443 ]
444
445 if (options.withFiles) {
446 joins.push('INNER JOIN "videoFile" AS "VideoFiles" ON "VideoFiles"."videoId" = "video"."id"')
447
448 Object.assign(attributes, {
449 '"VideoFiles"."id"': '"VideoFiles.id"',
450 '"VideoFiles"."createdAt"': '"VideoFiles.createdAt"',
451 '"VideoFiles"."updatedAt"': '"VideoFiles.updatedAt"',
452 '"VideoFiles"."resolution"': '"VideoFiles.resolution"',
453 '"VideoFiles"."size"': '"VideoFiles.size"',
454 '"VideoFiles"."extname"': '"VideoFiles.extname"',
455 '"VideoFiles"."infoHash"': '"VideoFiles.infoHash"',
456 '"VideoFiles"."fps"': '"VideoFiles.fps"',
457 '"VideoFiles"."videoId"': '"VideoFiles.videoId"'
458 })
459 }
460
461 if (options.user) {
462 joins.push(
463 'LEFT OUTER JOIN "userVideoHistory" ' +
464 'ON "video"."id" = "userVideoHistory"."videoId" AND "userVideoHistory"."userId" = :userVideoHistoryId'
465 )
466 replacements.userVideoHistoryId = options.user.id
467
468 Object.assign(attributes, {
469 '"userVideoHistory"."id"': '"userVideoHistory.id"',
470 '"userVideoHistory"."currentTime"': '"userVideoHistory.currentTime"'
471 })
472 }
473
474 if (options.videoPlaylistId) {
475 joins.push(
476 'INNER JOIN "videoPlaylistElement" as "VideoPlaylistElement" ON "videoPlaylistElement"."videoId" = "video"."id" ' +
477 'AND "VideoPlaylistElement"."videoPlaylistId" = :videoPlaylistId'
478 )
479 replacements.videoPlaylistId = options.videoPlaylistId
480
481 Object.assign(attributes, {
482 '"VideoPlaylistElement"."createdAt"': '"VideoPlaylistElement.createdAt"',
483 '"VideoPlaylistElement"."updatedAt"': '"VideoPlaylistElement.updatedAt"',
484 '"VideoPlaylistElement"."url"': '"VideoPlaylistElement.url"',
485 '"VideoPlaylistElement"."position"': '"VideoPlaylistElement.position"',
486 '"VideoPlaylistElement"."startTimestamp"': '"VideoPlaylistElement.startTimestamp"',
487 '"VideoPlaylistElement"."stopTimestamp"': '"VideoPlaylistElement.stopTimestamp"',
488 '"VideoPlaylistElement"."videoPlaylistId"': '"VideoPlaylistElement.videoPlaylistId"'
489 })
490 }
491
492 const select = 'SELECT ' + Object.keys(attributes).map(key => {
493 const value = attributes[key]
494 if (value) return `${key} AS ${value}`
495
496 return key
497 }).join(', ')
498
499 return `${select} FROM (${baseQuery}) AS "tmp" ${joins.join(' ')} ${order}`
500 }
501
502 export {
503 buildListQuery,
504 wrapForAPIResults
505 }