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