feat: initial commit
This commit is contained in:
commit
be4bda5696
254 changed files with 17416 additions and 0 deletions
10
queries/views/media/shows/last_watched_episodes.psql
Normal file
10
queries/views/media/shows/last_watched_episodes.psql
Normal file
|
@ -0,0 +1,10 @@
|
|||
CREATE OR REPLACE VIEW optimized_last_watched_episodes AS
|
||||
SELECT DISTINCT ON (e.show)
|
||||
e.show AS show_id,
|
||||
e.season_number,
|
||||
e.episode_number,
|
||||
e.last_watched_at,
|
||||
CONCAT('S', e.season_number, 'E', e.episode_number) AS last_watched_episode
|
||||
FROM episodes e
|
||||
WHERE e.last_watched_at IS NOT NULL
|
||||
ORDER BY e.show, e.last_watched_at DESC;
|
26
queries/views/media/shows/scheduled_episodes.psql
Normal file
26
queries/views/media/shows/scheduled_episodes.psql
Normal file
|
@ -0,0 +1,26 @@
|
|||
CREATE OR REPLACE VIEW optimized_scheduled_episodes AS
|
||||
SELECT
|
||||
se.show_id,
|
||||
se.season_number,
|
||||
se.episode_number,
|
||||
se.status,
|
||||
se.air_date,
|
||||
(
|
||||
SELECT CONCAT('S', se2.season_number, 'E', se2.episode_number)
|
||||
FROM scheduled_episodes se2
|
||||
WHERE se2.show_id = se.show_id
|
||||
AND se2.status IN ('upcoming', 'aired')
|
||||
ORDER BY se2.air_date ASC
|
||||
LIMIT 1
|
||||
) AS next_scheduled_episode,
|
||||
(
|
||||
SELECT se2.air_date
|
||||
FROM scheduled_episodes se2
|
||||
WHERE se2.show_id = se.show_id
|
||||
AND se2.status IN ('upcoming', 'aired')
|
||||
ORDER BY se2.air_date ASC
|
||||
LIMIT 1
|
||||
) AS next_air_date
|
||||
FROM scheduled_episodes se
|
||||
WHERE se.status IN ('upcoming', 'aired')
|
||||
GROUP BY se.show_id, se.season_number, se.episode_number, se.status, se.air_date;
|
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
|
125
queries/views/media/shows/shows.psql
Normal file
125
queries/views/media/shows/shows.psql
Normal file
|
@ -0,0 +1,125 @@
|
|||
CREATE OR REPLACE VIEW optimized_shows AS
|
||||
SELECT
|
||||
s.id,
|
||||
s.tmdb_id,
|
||||
s.title,
|
||||
s.year,
|
||||
s.favorite,
|
||||
s.tattoo,
|
||||
s.description,
|
||||
s.review,
|
||||
s.ongoing,
|
||||
s.slug AS url,
|
||||
CONCAT('/', df_art.filename_disk) AS image,
|
||||
CONCAT('/', df_backdrop.filename_disk) AS backdrop,
|
||||
json_build_object(
|
||||
'title', NULL,
|
||||
'image', CONCAT('/', df_art.filename_disk),
|
||||
'backdrop', CONCAT('/', df_backdrop.filename_disk),
|
||||
'url', s.slug,
|
||||
'alt', CONCAT('Poster from ', s.title),
|
||||
'subtext', CASE
|
||||
WHEN (
|
||||
SELECT MAX(e1.last_watched_at)
|
||||
FROM episodes e1
|
||||
WHERE e1.show = s.id
|
||||
) >= NOW() - INTERVAL '90 days' THEN
|
||||
(SELECT CONCAT('S', e2.season_number, 'E', e2.episode_number)
|
||||
FROM episodes e2
|
||||
WHERE e2.show = s.id
|
||||
ORDER BY e2.last_watched_at DESC, e2.season_number DESC, e2.episode_number DESC
|
||||
LIMIT 1)
|
||||
ELSE
|
||||
s.year::text
|
||||
END
|
||||
) AS grid,
|
||||
json_build_object(
|
||||
'title', s.title,
|
||||
'year', s.year,
|
||||
'url', s.slug,
|
||||
'image', CONCAT('/', df_art.filename_disk),
|
||||
'backdrop', CONCAT('/', df_backdrop.filename_disk),
|
||||
'formatted_episode', COALESCE((
|
||||
SELECT CONCAT('S', e2.season_number, 'E', e2.episode_number)
|
||||
FROM episodes e2
|
||||
WHERE e2.show = s.id
|
||||
ORDER BY e2.last_watched_at DESC, e2.season_number DESC, e2.episode_number DESC
|
||||
LIMIT 1
|
||||
), NULL),
|
||||
'last_watched_at', (
|
||||
SELECT MAX(e3.last_watched_at)
|
||||
FROM episodes e3
|
||||
WHERE e3.show = s.id
|
||||
)
|
||||
) AS episode,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', m.title, 'year', m.year, 'url', m.slug)
|
||||
ORDER BY m.year DESC)
|
||||
FROM
|
||||
shows_movies sm
|
||||
LEFT JOIN movies m ON sm.movies_id = m.id
|
||||
WHERE
|
||||
sm.shows_id = s.id
|
||||
) AS movies,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', b.title, 'author', b.author, 'url', b.slug)
|
||||
ORDER BY b.title ASC)
|
||||
FROM
|
||||
shows_books sb
|
||||
LEFT JOIN books b ON sb.books_id = b.id
|
||||
WHERE
|
||||
sb.shows_id = s.id
|
||||
) AS books,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', p.title, 'date', p.date, 'url', p.slug)
|
||||
ORDER BY p.date DESC)
|
||||
FROM
|
||||
posts_shows ps
|
||||
LEFT JOIN posts p ON ps.posts_id = p.id
|
||||
WHERE
|
||||
ps.shows_id = s.id
|
||||
) AS posts,
|
||||
(
|
||||
SELECT
|
||||
array_agg(t.name)
|
||||
FROM
|
||||
shows_tags st
|
||||
LEFT JOIN tags t ON st.tags_id = t.id
|
||||
WHERE
|
||||
st.shows_id = s.id
|
||||
) AS tags,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', rs.title, 'year', rs.year, 'url', rs.slug)
|
||||
ORDER BY rs.year DESC)
|
||||
FROM
|
||||
related_shows sr
|
||||
LEFT JOIN shows rs ON sr.related_shows_id = rs.id
|
||||
WHERE
|
||||
sr.shows_id = s.id
|
||||
) AS related_shows,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('name', a.name_string, 'url', a.slug, 'country', a.country, 'total_plays', a.total_plays)
|
||||
ORDER BY a.name_string ASC)
|
||||
FROM
|
||||
shows_artists sa
|
||||
LEFT JOIN artists a ON sa.artists_id = a.id
|
||||
WHERE
|
||||
sa.shows_id = s.id
|
||||
) AS artists,
|
||||
MAX(e.last_watched_at) AS last_watched_at
|
||||
FROM
|
||||
shows s
|
||||
LEFT JOIN episodes e ON s.id = e.show
|
||||
LEFT JOIN directus_files df_art ON s.art = df_art.id
|
||||
LEFT JOIN directus_files df_backdrop ON s.backdrop = df_backdrop.id
|
||||
GROUP BY
|
||||
s.id,
|
||||
df_art.filename_disk,
|
||||
df_backdrop.filename_disk
|
||||
ORDER BY
|
||||
MAX(e.last_watched_at) DESC;
|
Loading…
Add table
Add a link
Reference in a new issue