354 lines
11 KiB
SQL
354 lines
11 KiB
SQL
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(globals.cdn_url, '/', df_art.filename_disk) AS image,
|
|
CONCAT(globals.cdn_url, '/', df_backdrop.filename_disk) AS backdrop,
|
|
json_build_object(
|
|
'title',
|
|
s.title,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_art.filename_disk),
|
|
'backdrop',
|
|
CONCAT(globals.cdn_url, '/', 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,
|
|
json_build_object(
|
|
'title',
|
|
CONCAT('Show • ', s.title, ' • ', globals.site_name),
|
|
'description',
|
|
LEFT(
|
|
regexp_replace(
|
|
regexp_replace(
|
|
regexp_replace(s.description, E'[*_`~#>-]', '', 'g'),
|
|
E'\\[(.*?)\\]\\((.*?)\\)',
|
|
E'\\1',
|
|
'g'
|
|
),
|
|
E'!\\[(.*?)\\]\\((.*?)\\)',
|
|
'',
|
|
'g'
|
|
),
|
|
250
|
|
),
|
|
'open_graph_image',
|
|
CASE
|
|
WHEN df_backdrop.filename_disk IS NOT NULL
|
|
AND df_backdrop.filename_disk != ''
|
|
AND df_backdrop.filename_disk != '/' THEN CONCAT('/', df_backdrop.filename_disk)
|
|
ELSE NULL
|
|
END,
|
|
'url',
|
|
CONCAT(globals.url, s.slug),
|
|
'type',
|
|
'scheduled_show'
|
|
) AS metadata,
|
|
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
|
|
CROSS JOIN optimized_globals globals
|
|
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(globals.cdn_url, '/', df_art.filename_disk) AS image,
|
|
CONCAT(globals.cdn_url, '/', df_backdrop.filename_disk) AS backdrop,
|
|
json_build_object(
|
|
'title',
|
|
s.title,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_art.filename_disk),
|
|
'backdrop',
|
|
CONCAT(globals.cdn_url, '/', 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')
|
|
ORDER BY
|
|
se.season_number ASC,
|
|
se.episode_number ASC
|
|
LIMIT
|
|
1
|
|
),
|
|
s.year::text
|
|
)
|
|
) AS grid,
|
|
json_build_object(
|
|
'title',
|
|
CONCAT('Show • ', s.title, ' • ', globals.site_name),
|
|
'description',
|
|
LEFT(
|
|
regexp_replace(
|
|
regexp_replace(
|
|
regexp_replace(s.description, E'[*_`~#>-]', '', 'g'),
|
|
E'\\[(.*?)\\]\\((.*?)\\)',
|
|
E'\\1',
|
|
'g'
|
|
),
|
|
E'!\\[(.*?)\\]\\((.*?)\\)',
|
|
'',
|
|
'g'
|
|
),
|
|
250
|
|
),
|
|
'open_graph_image',
|
|
CASE
|
|
WHEN df_backdrop.filename_disk IS NOT NULL
|
|
AND df_backdrop.filename_disk != ''
|
|
AND df_backdrop.filename_disk != '/' THEN CONCAT('/', df_backdrop.filename_disk)
|
|
ELSE NULL
|
|
END,
|
|
'url',
|
|
CONCAT(globals.url, s.slug),
|
|
'type',
|
|
'scheduled_show'
|
|
) AS metadata
|
|
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
|
|
CROSS JOIN optimized_globals globals
|
|
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
|
|
(
|
|
SELECT
|
|
MIN(se.air_date)
|
|
FROM
|
|
scheduled_episodes se
|
|
WHERE
|
|
se.show_id = s.id
|
|
AND se.status IN ('upcoming', 'aired')
|
|
) ASC NULLS LAST
|
|
) unstarted
|
|
)
|
|
) AS scheduled_shows
|