feat: view queries in; media updated

This commit is contained in:
Cory Dransfeldt 2024-10-12 16:01:02 -07:00
parent 08e2c2ff3f
commit 057d75f863
No known key found for this signature in database
49 changed files with 578 additions and 353 deletions

View file

@ -8,7 +8,11 @@ SELECT
p.featured,
p.slug AS url,
p.mastodon_url,
CONCAT('/', df.filename_disk) AS image,
CASE
WHEN df.filename_disk IS NOT NULL AND df.filename_disk != '' AND df.filename_disk != '/'
THEN CONCAT('/', df.filename_disk)
ELSE NULL
END AS image,
p.image_alt,
(

View file

@ -40,7 +40,7 @@ WITH search_data AS (
SELECT
'movie' AS content_type,
CASE
WHEN m.rating IS NOT NULL THEN CONCAT('🎥 ', m.title, ' (', m.rating, ')') -- Add emoji and rating for movies
WHEN m.rating IS NOT NULL THEN CONCAT('🎥 ', m.title, ' (', m.rating, ')')
ELSE CONCAT('🎥 ', m.title)
END AS title,
CONCAT('https://coryd.dev', m.url) AS url,

View file

@ -1,6 +1,7 @@
CREATE OR REPLACE VIEW optimized_books AS
SELECT
b.date_finished,
EXTRACT(YEAR FROM b.date_finished) AS year,
b.author,
b.description,
b.title,
@ -87,6 +88,19 @@ SELECT
WHERE rbk.books_id = b.id
) AS related_books,
json_build_object(
'title', CONCAT(b.title, ' by ', b.author),
'image', CONCAT('/', df.filename_disk),
'url', b.slug,
'alt', CONCAT(b.title, ' by ', b.author),
'subtext',
CASE
WHEN b.star_rating IS NOT NULL
THEN CONCAT(EXTRACT(YEAR FROM b.date_finished), ' (', b.star_rating, ')')
ELSE EXTRACT(YEAR FROM b.date_finished)::TEXT
END
) AS grid,
CASE
WHEN LOWER(b.read_status) = 'finished' AND b.star_rating IS NOT NULL THEN json_build_object(
'title', b.title,

View file

@ -12,12 +12,22 @@ SELECT
m.description,
m.review,
'movie' AS type,
m.slug AS url,
CONCAT('/', df.filename_disk) AS image,
CONCAT('/', df2.filename_disk) AS backdrop,
json_build_object(
'title', m.title,
'url', m.slug,
'image', CONCAT('/', df.filename_disk),
'backdrop', CONCAT('/', df2.filename_disk),
'alt', CONCAT(m.title, ' (', m.year, ')'),
'subtext', CASE
WHEN m.star_rating IS NOT NULL THEN CONCAT(m.year, ' (', m.star_rating, ')')
ELSE m.year::TEXT
END
) AS grid,
(
SELECT array_agg(t.name)
FROM movies_tags mt
@ -95,7 +105,7 @@ SELECT
WHEN m.star_rating IS NOT NULL AND m.last_watched IS NOT NULL THEN
json_build_object(
'title', m.title,
'url', CONCAT('https://coryd.dev', m.slug),
'url', CONCAT('https://coryd.dev/movies/', m.slug),
'date', m.last_watched,
'description', m.description,
'image', CONCAT('/', df.filename_disk),

View file

@ -13,7 +13,15 @@ SELECT
'description', ar.description
) AS artist,
EXTRACT(EPOCH FROM a.release_date) AS release_timestamp
EXTRACT(EPOCH FROM a.release_date) AS release_timestamp,
json_build_object(
'title', a.name,
'image', CONCAT('/', df.filename_disk),
'url', a.release_link,
'alt', CONCAT(a.name, ' by ', ar.name_string),
'subtext', CONCAT(ar.name_string, ' / ', a.release_date)
) AS grid
FROM
albums a

View file

@ -1,21 +0,0 @@
CREATE OR REPLACE VIEW month_tracks AS
SELECT
ol.id,
ol.listened_at,
ol.track_name,
ol.artist_name,
ol.album_name,
ol.album_key,
ol.artist_art,
ol.artist_genres,
ol.genre_name,
ol.artist_country,
ol.album_art,
ol.artist_url,
ol.genre_url
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '30 days'
ORDER BY
TO_TIMESTAMP(ol.listened_at) DESC;

View file

@ -0,0 +1,22 @@
CREATE OR REPLACE VIEW month_albums AS
SELECT
ol.album_name,
ol.artist_name,
COUNT(*) AS plays,
ol.album_art,
ol.artist_url,
json_build_object(
'title', ol.album_name,
'image', ol.album_art,
'url', ol.artist_url,
'alt', CONCAT(ol.album_name, ' by ', ol.artist_name),
'subtext', ol.artist_name
) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '30 days'
GROUP BY
ol.album_name, ol.artist_name, ol.album_art, ol.artist_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,22 @@
CREATE OR REPLACE VIEW month_artists AS
SELECT
ol.artist_name,
COUNT(*) AS plays,
ol.artist_art,
ol.artist_url,
ARRAY_AGG(DISTINCT ol.genre_name) AS genres,
json_build_object(
'title', ol.artist_name,
'image', ol.artist_art,
'url', ol.artist_url,
'alt', CONCAT(COUNT(*), ' plays of ', ol.artist_name),
'subtext', CONCAT(COUNT(*), ' plays')
) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '30 days'
GROUP BY
ol.artist_name, ol.artist_art, ol.artist_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,17 @@
CREATE OR REPLACE VIEW month_genres AS
SELECT
ol.genre_name,
ol.genre_url,
COUNT(*) AS plays,
json_build_object(
'alt', ol.genre_name,
'subtext', CONCAT(COUNT(*), ' plays')
) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '30 days'
GROUP BY
ol.genre_name, ol.genre_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,37 @@
CREATE OR REPLACE VIEW month_tracks AS
WITH track_stats AS (
SELECT
ol.track_name,
ol.artist_name,
ol.album_name,
COUNT(*) AS plays,
MAX(ol.listened_at) AS last_listened,
ol.album_art,
ol.artist_url,
MAX(COUNT(*)) OVER () AS most_played
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '30 days'
GROUP BY
ol.track_name, ol.artist_name, ol.album_name, ol.album_art, ol.artist_url
)
SELECT
track_name,
artist_name,
album_name,
plays,
last_listened,
album_art,
artist_url,
json_build_object(
'title', track_name,
'artist', artist_name,
'url', artist_url,
'plays', plays,
'alt', CONCAT(track_name, ' by ', artist_name),
'subtext', CONCAT(album_name, ' (', plays, ' plays)'),
'percentage', ROUND((plays::decimal / most_played) * 100, 2)
) AS chart
FROM track_stats
ORDER BY plays DESC, last_listened DESC;

View file

@ -12,7 +12,15 @@ SELECT
ol.artist_country,
ol.album_art,
ol.artist_url,
ol.genre_url
ol.genre_url,
json_build_object(
'title', ol.track_name,
'subtext', ol.artist_name,
'alt', CONCAT(ol.track_name, ' by ', ol.artist_name),
'url', ol.artist_url,
'image', ol.album_art,
'played_at', ol.listened_at
) AS chart
FROM
optimized_listens ol
WHERE

View file

@ -1,21 +0,0 @@
CREATE OR REPLACE VIEW three_month_tracks AS
SELECT
ol.id,
ol.listened_at,
ol.track_name,
ol.artist_name,
ol.album_name,
ol.album_key,
ol.artist_art,
ol.artist_genres,
ol.genre_name,
ol.artist_country,
ol.album_art,
ol.artist_url,
ol.genre_url
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '3 months'
ORDER BY
TO_TIMESTAMP(ol.listened_at) DESC;

View file

@ -0,0 +1,22 @@
CREATE OR REPLACE VIEW three_month_albums AS
SELECT
ol.album_name,
ol.artist_name,
COUNT(*) AS plays,
ol.album_art,
ol.artist_url,
json_build_object(
'title', ol.album_name,
'image', ol.album_art,
'url', ol.artist_url,
'alt', CONCAT(ol.album_name, ' by ', ol.artist_name),
'subtext', ol.artist_name
) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '3 months'
GROUP BY
ol.album_name, ol.artist_name, ol.album_art, ol.artist_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,22 @@
CREATE OR REPLACE VIEW three_month_artists AS
SELECT
ol.artist_name,
COUNT(*) AS plays,
ol.artist_art,
ol.artist_url,
ARRAY_AGG(DISTINCT ol.genre_name) AS genres,
json_build_object(
'title', ol.artist_name,
'image', ol.artist_art,
'url', ol.artist_url,
'alt', CONCAT(COUNT(*), ' plays of ', ol.artist_name),
'subtext', CONCAT(COUNT(*), ' plays')
) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '3 months'
GROUP BY
ol.artist_name, ol.artist_art, ol.artist_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,17 @@
CREATE OR REPLACE VIEW three_month_genres AS
SELECT
ol.genre_name,
ol.genre_url,
COUNT(*) AS plays,
json_build_object(
'alt', ol.genre_name,
'subtext', CONCAT(COUNT(*), ' plays')
) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '3 months'
GROUP BY
ol.genre_name, ol.genre_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,37 @@
CREATE OR REPLACE VIEW three_month_tracks AS
WITH track_stats AS (
SELECT
ol.track_name,
ol.artist_name,
ol.album_name,
COUNT(*) AS plays,
MAX(ol.listened_at) AS last_listened,
ol.album_art,
ol.artist_url,
MAX(COUNT(*)) OVER () AS most_played
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '3 months'
GROUP BY
ol.track_name, ol.artist_name, ol.album_name, ol.album_art, ol.artist_url
)
SELECT
track_name,
artist_name,
album_name,
plays,
last_listened,
album_art,
artist_url,
json_build_object(
'title', track_name,
'artist', artist_name,
'url', artist_url,
'plays', plays,
'alt', CONCAT(track_name, ' by ', artist_name),
'subtext', CONCAT(album_name, ' (', plays, ' plays)'),
'percentage', ROUND((plays::decimal / most_played) * 100, 2)
) AS chart
FROM track_stats
ORDER BY plays DESC, last_listened DESC;

View file

@ -0,0 +1,22 @@
CREATE OR REPLACE VIEW week_albums AS
SELECT
ol.album_name,
ol.artist_name,
COUNT(*) AS plays,
ol.album_art,
ol.artist_url,
json_build_object(
'title', ol.album_name,
'image', ol.album_art,
'url', ol.artist_url,
'alt', CONCAT(ol.album_name, ' by ', ol.artist_name),
'subtext', ol.artist_name
) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '7 days'
GROUP BY
ol.album_name, ol.artist_name, ol.album_art, ol.artist_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,22 @@
CREATE OR REPLACE VIEW week_artists AS
SELECT
ol.artist_name,
COUNT(*) AS plays,
ol.artist_art,
ol.artist_url,
ARRAY_AGG(DISTINCT ol.genre_name) AS genres,
json_build_object(
'title', ol.artist_name,
'image', ol.artist_art,
'url', ol.artist_url,
'alt', CONCAT(COUNT(*), ' plays of ', ol.artist_name),
'subtext', CONCAT(COUNT(*), ' plays')
) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '7 days'
GROUP BY
ol.artist_name, ol.artist_art, ol.artist_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,17 @@
CREATE OR REPLACE VIEW week_genres AS
SELECT
ol.genre_name,
ol.genre_url,
COUNT(*) AS plays,
json_build_object(
'alt', ol.genre_name,
'subtext', CONCAT(COUNT(*), ' plays')
) AS grid
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '7 days'
GROUP BY
ol.genre_name, ol.genre_url
ORDER BY
plays DESC;

View file

@ -0,0 +1,37 @@
CREATE OR REPLACE VIEW week_tracks AS
WITH track_stats AS (
SELECT
ol.track_name,
ol.artist_name,
ol.album_name,
COUNT(*) AS plays,
MAX(ol.listened_at) AS last_listened,
ol.album_art,
ol.artist_url,
MAX(COUNT(*)) OVER () AS most_played
FROM
optimized_listens ol
WHERE
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '7 days'
GROUP BY
ol.track_name, ol.artist_name, ol.album_name, ol.album_art, ol.artist_url
)
SELECT
track_name,
artist_name,
album_name,
plays,
last_listened,
album_art,
artist_url,
json_build_object(
'title', track_name,
'artist', artist_name,
'url', artist_url,
'plays', plays,
'alt', CONCAT(track_name, ' by ', artist_name),
'subtext', CONCAT(album_name, ' (', plays, ' plays)'),
'percentage', ROUND((plays::decimal / most_played) * 100, 2)
) AS chart
FROM track_stats
ORDER BY plays DESC, last_listened DESC;

View file

@ -12,6 +12,19 @@ SELECT
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(s.title, ' (', s.year, ')'),
'subtext', CASE
WHEN MAX(e.season_number) IS NOT NULL AND MAX(e.episode_number) IS NOT NULL
THEN CONCAT('S', MAX(e.season_number), 'E', MAX(e.episode_number))
ELSE s.year::TEXT
END
) AS grid,
json_build_object(
'type', 'tv',
'title', s.title,