feat: initial commit
This commit is contained in:
commit
e214116e40
253 changed files with 17406 additions and 0 deletions
145
queries/views/media/shows/scheduled_shows.psql
Normal file
145
queries/views/media/shows/scheduled_shows.psql
Normal file
|
@ -0,0 +1,145 @@
|
|||
CREATE OR REPLACE VIEW optimized_scheduled_shows AS
|
||||
SELECT json_build_object(
|
||||
'watching', (
|
||||
SELECT json_agg(watching) FROM (
|
||||
SELECT
|
||||
s.id,
|
||||
s.tmdb_id,
|
||||
s.title,
|
||||
s.year,
|
||||
s.ongoing,
|
||||
s.slug AS url,
|
||||
CONCAT('/', df_art.filename_disk) AS image,
|
||||
CONCAT('/', df_backdrop.filename_disk) AS backdrop,
|
||||
json_build_object(
|
||||
'title', s.title,
|
||||
'image', CONCAT('/', df_art.filename_disk),
|
||||
'backdrop', CONCAT('/', df_backdrop.filename_disk),
|
||||
'url', s.slug,
|
||||
'alt', CONCAT('Poster from ', s.title),
|
||||
'subtext', COALESCE(
|
||||
(SELECT CONCAT(
|
||||
'S', se.season_number, 'E', se.episode_number, ' • ',
|
||||
CASE
|
||||
WHEN EXTRACT(YEAR FROM se.air_date) < EXTRACT(YEAR FROM CURRENT_DATE)
|
||||
THEN TO_CHAR(se.air_date, 'FMMM/FMDD/YY')
|
||||
ELSE TO_CHAR(se.air_date, 'FMMM/FMDD')
|
||||
END
|
||||
)
|
||||
FROM scheduled_episodes se
|
||||
WHERE se.show_id = s.id
|
||||
AND se.status IN ('upcoming', 'aired')
|
||||
AND NOT EXISTS (
|
||||
SELECT 1 FROM episodes e
|
||||
WHERE e.show = s.id
|
||||
AND e.season_number = se.season_number
|
||||
AND e.episode_number = se.episode_number
|
||||
)
|
||||
ORDER BY se.season_number ASC, se.episode_number ASC
|
||||
LIMIT 1),
|
||||
(SELECT CONCAT(
|
||||
'S', e.season_number, 'E', e.episode_number, ' • ',
|
||||
CASE
|
||||
WHEN EXTRACT(YEAR FROM e.last_watched_at) < EXTRACT(YEAR FROM CURRENT_DATE)
|
||||
THEN TO_CHAR(e.last_watched_at, 'FMMM/FMDD/YY')
|
||||
ELSE TO_CHAR(e.last_watched_at, 'FMMM/FMDD')
|
||||
END
|
||||
)
|
||||
FROM episodes e
|
||||
WHERE e.show = s.id
|
||||
ORDER BY e.last_watched_at DESC, e.season_number DESC, e.episode_number DESC
|
||||
LIMIT 1),
|
||||
s.year::text
|
||||
)
|
||||
) AS grid,
|
||||
CASE
|
||||
WHEN (
|
||||
SELECT se.air_date
|
||||
FROM scheduled_episodes se
|
||||
WHERE se.show_id = s.id
|
||||
AND se.status IN ('upcoming', 'aired')
|
||||
AND NOT EXISTS (
|
||||
SELECT 1 FROM episodes e
|
||||
WHERE e.show = s.id
|
||||
AND e.season_number = se.season_number
|
||||
AND e.episode_number = se.episode_number
|
||||
)
|
||||
ORDER BY se.season_number ASC, se.episode_number ASC
|
||||
LIMIT 1
|
||||
) >= NOW()
|
||||
THEN (
|
||||
SELECT se.air_date::timestamp
|
||||
FROM scheduled_episodes se
|
||||
WHERE se.show_id = s.id
|
||||
AND se.status IN ('upcoming', 'aired')
|
||||
AND NOT EXISTS (
|
||||
SELECT 1 FROM episodes e
|
||||
WHERE e.show = s.id
|
||||
AND e.season_number = se.season_number
|
||||
AND e.episode_number = se.episode_number
|
||||
)
|
||||
ORDER BY se.season_number ASC, se.episode_number ASC
|
||||
LIMIT 1
|
||||
)
|
||||
ELSE (
|
||||
SELECT MIN(e.last_watched_at)::timestamp
|
||||
FROM episodes e
|
||||
WHERE e.show = s.id
|
||||
)
|
||||
END AS sort_date
|
||||
FROM shows s
|
||||
LEFT JOIN directus_files df_art ON s.art = df_art.id
|
||||
LEFT JOIN directus_files df_backdrop ON s.backdrop = df_backdrop.id
|
||||
WHERE s.ongoing = true
|
||||
AND EXISTS (
|
||||
SELECT 1
|
||||
FROM scheduled_episodes se
|
||||
WHERE se.show_id = s.id
|
||||
AND se.status IN ('upcoming', 'aired')
|
||||
)
|
||||
AND EXISTS (
|
||||
SELECT 1
|
||||
FROM episodes e
|
||||
WHERE e.show = s.id
|
||||
)
|
||||
ORDER BY sort_date ASC NULLS LAST, s.title ASC NULLS LAST
|
||||
) watching
|
||||
),
|
||||
'unstarted', (
|
||||
SELECT json_agg(unstarted) FROM (
|
||||
SELECT
|
||||
s.id,
|
||||
s.tmdb_id,
|
||||
s.title,
|
||||
s.year,
|
||||
s.ongoing,
|
||||
s.slug AS url,
|
||||
CONCAT('/', df_art.filename_disk) AS image,
|
||||
CONCAT('/', df_backdrop.filename_disk) AS backdrop,
|
||||
json_build_object(
|
||||
'title', s.title,
|
||||
'image', CONCAT('/', df_art.filename_disk),
|
||||
'backdrop', CONCAT('/', df_backdrop.filename_disk),
|
||||
'url', s.slug,
|
||||
'alt', CONCAT('Poster from ', s.title),
|
||||
'subtext', s.year::text
|
||||
) AS grid
|
||||
FROM shows s
|
||||
LEFT JOIN directus_files df_art ON s.art = df_art.id
|
||||
LEFT JOIN directus_files df_backdrop ON s.backdrop = df_backdrop.id
|
||||
WHERE s.ongoing = true
|
||||
AND EXISTS (
|
||||
SELECT 1
|
||||
FROM scheduled_episodes se
|
||||
WHERE se.show_id = s.id
|
||||
AND se.status IN ('upcoming', 'aired')
|
||||
)
|
||||
AND NOT EXISTS (
|
||||
SELECT 1
|
||||
FROM episodes e
|
||||
WHERE e.show = s.id
|
||||
)
|
||||
ORDER BY s.title ASC
|
||||
) unstarted
|
||||
)
|
||||
) AS scheduled_shows
|
Loading…
Add table
Add a link
Reference in a new issue