feat: initial commit
This commit is contained in:
commit
e214116e40
253 changed files with 17406 additions and 0 deletions
27
queries/functions/get_feed_data.psql
Normal file
27
queries/functions/get_feed_data.psql
Normal file
|
@ -0,0 +1,27 @@
|
|||
CREATE OR REPLACE FUNCTION get_feed_data(feed_key TEXT)
|
||||
RETURNS JSON AS $$
|
||||
DECLARE
|
||||
result JSON;
|
||||
sql_query TEXT;
|
||||
BEGIN
|
||||
CASE feed_key
|
||||
WHEN 'movies' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_movies WHERE feed IS NOT NULL';
|
||||
WHEN 'books' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_books WHERE feed IS NOT NULL';
|
||||
WHEN 'posts' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_posts WHERE feed IS NOT NULL';
|
||||
WHEN 'links' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_links WHERE feed IS NOT NULL';
|
||||
WHEN 'allActivity' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_all_activity WHERE feed IS NOT NULL';
|
||||
WHEN 'syndication' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_syndication WHERE feed IS NOT NULL';
|
||||
ELSE
|
||||
RETURN NULL;
|
||||
END CASE;
|
||||
|
||||
EXECUTE sql_query INTO result;
|
||||
RETURN result;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
14
queries/functions/parsecountryfield.psql
Normal file
14
queries/functions/parsecountryfield.psql
Normal file
|
@ -0,0 +1,14 @@
|
|||
DECLARE
|
||||
delimiters TEXT[] := ARRAY[',', '/', '&', 'and'];
|
||||
countries TEXT[];
|
||||
result TEXT := '';
|
||||
BEGIN
|
||||
countries := string_to_array(countryField, ',');
|
||||
|
||||
FOR i IN 1..array_length(delimiters, 1) LOOP
|
||||
countries := array_cat(countries, string_to_array(result, delimiters[i]));
|
||||
END LOOP;
|
||||
|
||||
result := array_to_string(countries, ' ');
|
||||
RETURN trim(result);
|
||||
END
|
42
queries/functions/search.psql
Normal file
42
queries/functions/search.psql
Normal file
|
@ -0,0 +1,42 @@
|
|||
CREATE OR REPLACE FUNCTION public.search_optimized_index(search_query text, page_size integer, page_offset integer, types text[])
|
||||
RETURNS TABLE(
|
||||
result_id integer,
|
||||
url text,
|
||||
title text,
|
||||
description text,
|
||||
tags text,
|
||||
genre_name text,
|
||||
genre_url text,
|
||||
type text,
|
||||
total_plays text,
|
||||
rank real,
|
||||
total_count bigint
|
||||
)
|
||||
AS $$
|
||||
BEGIN
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
s.id::integer AS result_id,
|
||||
s.url,
|
||||
s.title,
|
||||
s.description,
|
||||
array_to_string(s.tags, ', ') AS tags,
|
||||
s.genre_name,
|
||||
s.genre_url,
|
||||
s.type,
|
||||
s.total_plays,
|
||||
ts_rank_cd(to_tsvector('english', s.title || ' ' || s.description || array_to_string(s.tags, ' ')), plainto_tsquery('english', search_query)) AS rank,
|
||||
COUNT(*) OVER() AS total_count
|
||||
FROM
|
||||
optimized_search_index s
|
||||
WHERE(types IS NULL
|
||||
OR s.type = ANY(types))
|
||||
AND plainto_tsquery('english', search_query) @@ to_tsvector('english', s.title || ' ' || s.description || array_to_string(s.tags, ' '))
|
||||
ORDER BY
|
||||
s.type = 'post' DESC,
|
||||
s.content_date DESC NULLS LAST,
|
||||
rank DESC
|
||||
LIMIT page_size OFFSET page_offset;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
4
queries/functions/slugify.psql
Normal file
4
queries/functions/slugify.psql
Normal file
|
@ -0,0 +1,4 @@
|
|||
SELECT lower(regexp_replace(
|
||||
unaccent(regexp_replace($1, '[^\\w\\s-]', '', 'g')),
|
||||
'\\s+', '-', 'g'
|
||||
));
|
5
queries/functions/update_album_key.psql
Normal file
5
queries/functions/update_album_key.psql
Normal file
|
@ -0,0 +1,5 @@
|
|||
BEGIN
|
||||
UPDATE listens
|
||||
SET album_key = new_album_key
|
||||
WHERE album_key = old_album_key;
|
||||
END;
|
26
queries/functions/update_days_read.psql
Normal file
26
queries/functions/update_days_read.psql
Normal file
|
@ -0,0 +1,26 @@
|
|||
CREATE OR REPLACE FUNCTION update_days_read()
|
||||
RETURNS TRIGGER AS $$
|
||||
DECLARE
|
||||
pacific_now TIMESTAMPTZ;
|
||||
pacific_today DATE;
|
||||
last_read DATE;
|
||||
BEGIN
|
||||
SELECT (NOW() AT TIME ZONE 'America/Los_Angeles')::DATE INTO pacific_today;
|
||||
|
||||
SELECT COALESCE(last_read_date::DATE, pacific_today - INTERVAL '1 day') INTO last_read FROM reading_streak LIMIT 1;
|
||||
|
||||
IF last_read < pacific_today - INTERVAL '1 day' THEN
|
||||
UPDATE reading_streak
|
||||
SET days_read = 0, last_read_date = NOW() AT TIME ZONE 'America/Los_Angeles'
|
||||
WHERE id = 1;
|
||||
END IF;
|
||||
|
||||
IF last_read IS DISTINCT FROM pacific_today THEN
|
||||
UPDATE reading_streak
|
||||
SET days_read = days_read + 1, last_read_date = NOW() AT TIME ZONE 'America/Los_Angeles'
|
||||
WHERE id = 1;
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
36
queries/functions/update_listen_totals.psql
Normal file
36
queries/functions/update_listen_totals.psql
Normal file
|
@ -0,0 +1,36 @@
|
|||
BEGIN
|
||||
WITH artist_plays AS (
|
||||
SELECT artist_name, COUNT(*)::integer as total_plays
|
||||
FROM listens
|
||||
GROUP BY artist_name
|
||||
)
|
||||
UPDATE artists
|
||||
SET total_plays = COALESCE(ap.total_plays, 0)
|
||||
FROM artist_plays ap
|
||||
WHERE artists.name_string = ap.artist_name;
|
||||
|
||||
WITH album_plays AS (
|
||||
SELECT album_key, artist_name, COUNT(*)::integer as total_plays
|
||||
FROM listens
|
||||
GROUP BY album_key, artist_name
|
||||
)
|
||||
UPDATE albums
|
||||
SET total_plays = COALESCE(ap.total_plays, 0)
|
||||
FROM album_plays ap
|
||||
WHERE albums.key = ap.album_key
|
||||
AND albums.artist_name = ap.artist_name;
|
||||
|
||||
WITH genre_plays AS (
|
||||
SELECT g.id, COUNT(*)::integer as total_plays
|
||||
FROM listens l
|
||||
JOIN artists a ON l.artist_name = a.name_string
|
||||
JOIN genres g ON a.genres::text = g.id::text
|
||||
GROUP BY g.id
|
||||
)
|
||||
UPDATE genres
|
||||
SET total_plays = COALESCE(gp.total_plays, 0)
|
||||
FROM genre_plays gp
|
||||
WHERE genres.id = gp.id;
|
||||
|
||||
RAISE NOTICE 'All listen totals are up to date';
|
||||
END;
|
11
queries/functions/update_scheduled_episode_status.psql
Normal file
11
queries/functions/update_scheduled_episode_status.psql
Normal file
|
@ -0,0 +1,11 @@
|
|||
CREATE OR REPLACE FUNCTION update_scheduled_episode_status()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
UPDATE scheduled_episodes
|
||||
SET status = 'aired'
|
||||
WHERE air_date < CURRENT_DATE
|
||||
AND status = 'upcoming';
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
12
queries/functions/update_scheduled_on_watch.psql
Normal file
12
queries/functions/update_scheduled_on_watch.psql
Normal file
|
@ -0,0 +1,12 @@
|
|||
CREATE OR REPLACE FUNCTION update_scheduled_on_watch()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
UPDATE scheduled_episodes
|
||||
SET status = 'watched'
|
||||
WHERE show_id = NEW.show
|
||||
AND season_number = NEW.season_number
|
||||
AND episode_number = NEW.episode_number;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
6
queries/jobs/update_scheduled_episodes.psql
Normal file
6
queries/jobs/update_scheduled_episodes.psql
Normal file
|
@ -0,0 +1,6 @@
|
|||
SELECT cron.schedule(
|
||||
'0 0 * * *',
|
||||
$$ UPDATE scheduled_episodes
|
||||
SET status = 'aired'
|
||||
WHERE air_date < CURRENT_DATE
|
||||
AND status = 'upcoming' $$);
|
16
queries/selects/top-albums.psql
Normal file
16
queries/selects/top-albums.psql
Normal file
|
@ -0,0 +1,16 @@
|
|||
SELECT
|
||||
l.artist_name,
|
||||
l.album_name,
|
||||
TO_CHAR(COUNT(l.id), 'FM999,999,999') AS total_listens
|
||||
FROM
|
||||
optimized_listens l
|
||||
WHERE
|
||||
EXTRACT(YEAR FROM TO_TIMESTAMP(l.listened_at)) = EXTRACT(YEAR FROM CURRENT_DATE)
|
||||
AND l.artist_name IS NOT NULL
|
||||
AND l.album_name IS NOT NULL
|
||||
GROUP BY
|
||||
l.artist_name,
|
||||
l.album_name
|
||||
ORDER BY
|
||||
COUNT(l.id) DESC
|
||||
LIMIT 10;
|
13
queries/selects/top-artists.psql
Normal file
13
queries/selects/top-artists.psql
Normal file
|
@ -0,0 +1,13 @@
|
|||
SELECT
|
||||
l.artist_name,
|
||||
TO_CHAR(COUNT(l.id), 'FM999,999,999') AS total_listens
|
||||
FROM
|
||||
optimized_listens l
|
||||
WHERE
|
||||
EXTRACT(YEAR FROM TO_TIMESTAMP(l.listened_at)) = EXTRACT(YEAR FROM CURRENT_DATE)
|
||||
AND l.artist_name IS NOT NULL
|
||||
GROUP BY
|
||||
l.artist_name
|
||||
ORDER BY
|
||||
COUNT(l.id) DESC
|
||||
LIMIT 10;
|
20
queries/triggers/decrement_total_plays.psql
Normal file
20
queries/triggers/decrement_total_plays.psql
Normal file
|
@ -0,0 +1,20 @@
|
|||
BEGIN
|
||||
UPDATE artists
|
||||
SET total_plays = total_plays - 1
|
||||
WHERE name_string = OLD.artist_name;
|
||||
|
||||
UPDATE albums
|
||||
SET total_plays = total_plays - 1
|
||||
WHERE name = OLD.album_name
|
||||
AND artist_name = OLD.artist_name;
|
||||
|
||||
UPDATE genres
|
||||
SET total_plays = total_plays - 1
|
||||
WHERE id = (
|
||||
SELECT genres
|
||||
FROM artists
|
||||
WHERE name_string = OLD.artist_name
|
||||
);
|
||||
|
||||
RETURN OLD;
|
||||
END;
|
4
queries/triggers/mark_scheduled_as_watched.psql
Normal file
4
queries/triggers/mark_scheduled_as_watched.psql
Normal file
|
@ -0,0 +1,4 @@
|
|||
CREATE TRIGGER mark_scheduled_as_watched
|
||||
AFTER INSERT ON episodes
|
||||
FOR EACH ROW
|
||||
EXECUTE FUNCTION update_scheduled_on_watch();
|
5
queries/triggers/update_days_read.psql
Normal file
5
queries/triggers/update_days_read.psql
Normal file
|
@ -0,0 +1,5 @@
|
|||
CREATE TRIGGER trigger_update_days_read
|
||||
AFTER UPDATE OF progress ON books
|
||||
FOR EACH ROW
|
||||
WHEN (OLD.progress IS DISTINCT FROM NEW.progress AND (NEW.read_status = 'started' OR NEW.read_status = 'finished'))
|
||||
EXECUTE FUNCTION update_days_read();
|
10
queries/triggers/update_scheduled_status.psql
Normal file
10
queries/triggers/update_scheduled_status.psql
Normal file
|
@ -0,0 +1,10 @@
|
|||
CREATE OR REPLACE FUNCTION update_scheduled_episode_status()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
IF NEW.air_date < CURRENT_DATE AND NEW.status = 'upcoming' THEN
|
||||
NEW.status := 'aired';
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
20
queries/triggers/update_total_plays.psql
Normal file
20
queries/triggers/update_total_plays.psql
Normal file
|
@ -0,0 +1,20 @@
|
|||
BEGIN
|
||||
UPDATE artists
|
||||
SET total_plays = total_plays + 1
|
||||
WHERE name_string = NEW.artist_name;
|
||||
|
||||
UPDATE albums
|
||||
SET total_plays = total_plays + 1
|
||||
WHERE key = NEW.album_key
|
||||
AND artist_name = NEW.artist_name;
|
||||
|
||||
UPDATE genres
|
||||
SET total_plays = total_plays + 1
|
||||
WHERE id = (
|
||||
SELECT genres
|
||||
FROM artists
|
||||
WHERE name_string = NEW.artist_name
|
||||
);
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
11
queries/views/content/blogroll.psql
Normal file
11
queries/views/content/blogroll.psql
Normal file
|
@ -0,0 +1,11 @@
|
|||
CREATE OR REPLACE VIEW optimized_blogroll AS
|
||||
SELECT
|
||||
name,
|
||||
url,
|
||||
rss_feed,
|
||||
json_feed,
|
||||
newsletter,
|
||||
mastodon
|
||||
FROM authors
|
||||
WHERE blogroll = true
|
||||
ORDER BY LOWER(unaccent(name)) ASC;
|
30
queries/views/content/links.psql
Normal file
30
queries/views/content/links.psql
Normal file
|
@ -0,0 +1,30 @@
|
|||
CREATE OR REPLACE VIEW optimized_links AS
|
||||
SELECT
|
||||
l.id,
|
||||
l.title,
|
||||
l.date,
|
||||
l.description,
|
||||
l.link,
|
||||
a.mastodon,
|
||||
a.name,
|
||||
json_build_object('name', a.name, 'url', a.url, 'mastodon', a.mastodon) AS author,
|
||||
'link' AS type,
|
||||
(
|
||||
SELECT array_agg(t.name)
|
||||
FROM links_tags lt
|
||||
LEFT JOIN tags t ON lt.tags_id = t.id
|
||||
WHERE lt.links_id = l.id
|
||||
) AS tags,
|
||||
json_build_object(
|
||||
'title', CONCAT(l.title, ' via ', a.name),
|
||||
'url', l.link,
|
||||
'description', l.description,
|
||||
'date', l.date
|
||||
) AS feed
|
||||
FROM
|
||||
links l
|
||||
JOIN authors a ON l.author = a.id
|
||||
GROUP BY
|
||||
l.id, l.title, l.date, l.description, l.link, a.mastodon, a.name, a.url
|
||||
ORDER BY
|
||||
l.date DESC;
|
126
queries/views/content/posts.psql
Normal file
126
queries/views/content/posts.psql
Normal file
|
@ -0,0 +1,126 @@
|
|||
CREATE OR REPLACE VIEW optimized_posts AS
|
||||
SELECT
|
||||
p.id,
|
||||
p.date,
|
||||
p.title,
|
||||
p.description,
|
||||
p.content,
|
||||
p.featured,
|
||||
p.slug AS url,
|
||||
p.mastodon_url,
|
||||
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,
|
||||
CASE WHEN EXTRACT(YEAR FROM AGE(CURRENT_DATE, p.date)) > 3 THEN
|
||||
TRUE
|
||||
ELSE
|
||||
FALSE
|
||||
END AS old_post,
|
||||
(
|
||||
SELECT
|
||||
json_agg(
|
||||
CASE WHEN pb.collection = 'youtube_player' THEN
|
||||
json_build_object('type', pb.collection, 'url', yp.url)
|
||||
WHEN pb.collection = 'github_banner' THEN
|
||||
json_build_object('type', pb.collection, 'url', gb.url)
|
||||
WHEN pb.collection = 'npm_banner' THEN
|
||||
json_build_object('type', pb.collection, 'url', nb.url, 'command', nb.command)
|
||||
WHEN pb.collection = 'rss_banner' THEN
|
||||
json_build_object('type', pb.collection, 'url', rb.url, 'text', rb.text)
|
||||
WHEN pb.collection = 'calendar_banner' THEN
|
||||
json_build_object('type', pb.collection, 'url', cb.url, 'text', cb.text)
|
||||
WHEN pb.collection = 'hero' THEN
|
||||
json_build_object('type', pb.collection, 'image', CONCAT('/', df_hero.filename_disk), 'alt_text', h.alt_text)
|
||||
WHEN pb.collection = 'markdown' THEN
|
||||
json_build_object('type', pb.collection, 'text', md.text)
|
||||
ELSE
|
||||
json_build_object('type', pb.collection)
|
||||
END)
|
||||
FROM
|
||||
posts_blocks pb
|
||||
LEFT JOIN youtube_player yp ON pb.collection = 'youtube_player'
|
||||
AND yp.id = pb.item::integer
|
||||
LEFT JOIN github_banner gb ON pb.collection = 'github_banner'
|
||||
AND gb.id = pb.item::integer
|
||||
LEFT JOIN npm_banner nb ON pb.collection = 'npm_banner'
|
||||
AND nb.id = pb.item::integer
|
||||
LEFT JOIN rss_banner rb ON pb.collection = 'rss_banner'
|
||||
AND rb.id = pb.item::integer
|
||||
LEFT JOIN calendar_banner cb ON pb.collection = 'calendar_banner'
|
||||
AND cb.id = pb.item::integer
|
||||
LEFT JOIN hero h ON pb.collection = 'hero'
|
||||
AND h.id = pb.item::integer
|
||||
LEFT JOIN directus_files df_hero ON h.image = df_hero.id
|
||||
LEFT JOIN markdown md ON pb.collection = 'markdown'
|
||||
AND md.id = pb.item::integer
|
||||
WHERE
|
||||
pb.posts_id = p.id) AS blocks,
|
||||
(
|
||||
SELECT
|
||||
array_agg(t.name)
|
||||
FROM
|
||||
posts_tags pt
|
||||
LEFT JOIN tags t ON pt.tags_id = t.id
|
||||
WHERE
|
||||
pt.posts_id = p.id) AS tags,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('name', g.name, 'url', g.slug) ORDER BY g.name ASC)
|
||||
FROM
|
||||
posts_genres gp
|
||||
LEFT JOIN genres g ON gp.genres_id = g.id
|
||||
WHERE
|
||||
gp.posts_id = p.id) AS genres,
|
||||
(
|
||||
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
|
||||
posts_artists pa
|
||||
LEFT JOIN artists a ON pa.artists_id = a.id
|
||||
WHERE
|
||||
pa.posts_id = p.id) AS artists,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', b.title, 'author', b.author, 'url', b.slug)
|
||||
ORDER BY b.title ASC)
|
||||
FROM
|
||||
posts_books pbk
|
||||
LEFT JOIN books b ON pbk.books_id = b.id
|
||||
WHERE
|
||||
pbk.posts_id = p.id) AS books,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', m.title, 'year', m.year, 'url', m.slug)
|
||||
ORDER BY m.year DESC)
|
||||
FROM
|
||||
posts_movies pm
|
||||
LEFT JOIN movies m ON pm.movies_id = m.id
|
||||
WHERE
|
||||
pm.posts_id = p.id) AS movies,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', s.title, 'year', s.year, 'url', s.slug) ORDER BY s.year DESC)
|
||||
FROM
|
||||
posts_shows ps
|
||||
LEFT JOIN shows s ON ps.shows_id = s.id
|
||||
WHERE
|
||||
ps.posts_id = p.id) AS shows,
|
||||
json_build_object('title', p.title, 'url', p.slug, 'description', p.description, 'content', p.content, 'date', p.date, '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 feed
|
||||
FROM
|
||||
posts p
|
||||
LEFT JOIN directus_files df ON p.image = df.id
|
||||
GROUP BY
|
||||
p.id,
|
||||
df.filename_disk;
|
||||
|
71
queries/views/feeds/all-activity.psql
Normal file
71
queries/views/feeds/all-activity.psql
Normal file
|
@ -0,0 +1,71 @@
|
|||
CREATE OR REPLACE VIEW optimized_all_activity AS
|
||||
WITH feed_data AS (
|
||||
SELECT json_build_object(
|
||||
'title', p.title,
|
||||
'url', p.url,
|
||||
'description', p.content,
|
||||
'date', p.date,
|
||||
'type', 'article',
|
||||
'label', 'Post',
|
||||
'content', p.content
|
||||
) AS feed
|
||||
FROM optimized_posts p
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT json_build_object(
|
||||
'title', CONCAT(l.title, ' via ', l.author->>'name'),
|
||||
'url', l.link,
|
||||
'description', l.description,
|
||||
'date', l.date,
|
||||
'type', 'link',
|
||||
'label', 'Link',
|
||||
'author', l.author
|
||||
) AS feed
|
||||
FROM optimized_links l
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT CASE
|
||||
WHEN LOWER(b.status) = 'finished' THEN
|
||||
json_build_object(
|
||||
'title', CONCAT(b.title, ' by ', b.author,
|
||||
CASE WHEN b.rating IS NOT NULL THEN CONCAT(' (', b.rating, ')') ELSE '' END
|
||||
),
|
||||
'url', b.url,
|
||||
'description', COALESCE(b.review, b.description),
|
||||
'date', b.date_finished,
|
||||
'type', 'books',
|
||||
'label', 'Book',
|
||||
'image', b.image,
|
||||
'rating', b.rating
|
||||
)
|
||||
ELSE NULL
|
||||
END AS feed
|
||||
FROM optimized_books b
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT CASE
|
||||
WHEN m.last_watched IS NOT NULL THEN
|
||||
json_build_object(
|
||||
'title', CONCAT(m.title,
|
||||
CASE WHEN m.rating IS NOT NULL THEN CONCAT(' (', m.rating, ')') ELSE '' END
|
||||
),
|
||||
'url', m.url,
|
||||
'description', COALESCE(m.review, m.description),
|
||||
'date', m.last_watched,
|
||||
'type', 'movies',
|
||||
'label', 'Movie',
|
||||
'image', m.image,
|
||||
'rating', m.rating
|
||||
)
|
||||
ELSE NULL
|
||||
END AS feed
|
||||
FROM optimized_movies m
|
||||
)
|
||||
SELECT feed
|
||||
FROM feed_data
|
||||
WHERE feed IS NOT NULL
|
||||
ORDER BY (feed->>'date')::timestamp DESC
|
||||
LIMIT 20;
|
12
queries/views/feeds/headers.psql
Normal file
12
queries/views/feeds/headers.psql
Normal file
|
@ -0,0 +1,12 @@
|
|||
CREATE OR REPLACE VIEW optimized_headers AS
|
||||
SELECT
|
||||
p.path AS resource_path,
|
||||
json_agg(json_build_object('header_name', hr.name, 'header_value', hr.value)) AS headers
|
||||
FROM
|
||||
paths p
|
||||
JOIN
|
||||
paths_header_rules phr ON p.id = phr.paths_id
|
||||
JOIN
|
||||
header_rules hr ON phr.header_rules_id = hr.id
|
||||
GROUP BY
|
||||
p.path;
|
109
queries/views/feeds/recent-activity.psql
Normal file
109
queries/views/feeds/recent-activity.psql
Normal file
|
@ -0,0 +1,109 @@
|
|||
CREATE OR REPLACE VIEW optimized_recent_activity AS
|
||||
WITH activity_data AS (
|
||||
SELECT
|
||||
p.date AS content_date,
|
||||
p.title,
|
||||
p.content AS description,
|
||||
p.url AS url,
|
||||
NULL AS author,
|
||||
NULL AS image,
|
||||
NULL AS rating,
|
||||
NULL AS artist_url,
|
||||
NULL AS venue_lat,
|
||||
NULL AS venue_lon,
|
||||
NULL AS venue_name,
|
||||
NULL AS notes,
|
||||
'article' AS type,
|
||||
'Post' AS label
|
||||
FROM optimized_posts p
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
l.date AS content_date,
|
||||
l.title,
|
||||
l.description,
|
||||
l.link AS url,
|
||||
l.author,
|
||||
NULL AS image,
|
||||
NULL AS rating,
|
||||
NULL AS artist_url,
|
||||
NULL AS venue_lat,
|
||||
NULL AS venue_lon,
|
||||
NULL AS venue_name,
|
||||
NULL AS notes,
|
||||
'link' AS type,
|
||||
'Link' AS label
|
||||
FROM optimized_links l
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
b.date_finished AS content_date,
|
||||
CONCAT(b.title,
|
||||
CASE WHEN b.rating IS NOT NULL THEN CONCAT(' (', b.rating, ')') ELSE '' END
|
||||
) AS title,
|
||||
b.description,
|
||||
b.url AS url,
|
||||
NULL AS author,
|
||||
b.image,
|
||||
b.rating,
|
||||
NULL AS artist_url,
|
||||
NULL AS venue_lat,
|
||||
NULL AS venue_lon,
|
||||
NULL AS venue_name,
|
||||
NULL AS notes,
|
||||
'books' AS type,
|
||||
'Book' AS label
|
||||
FROM optimized_books b
|
||||
WHERE LOWER(b.status) = 'finished'
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
m.last_watched AS content_date,
|
||||
CONCAT(m.title,
|
||||
CASE WHEN m.rating IS NOT NULL THEN CONCAT(' (', m.rating, ')') ELSE '' END
|
||||
) AS title,
|
||||
m.description,
|
||||
m.url AS url,
|
||||
NULL AS author,
|
||||
m.image,
|
||||
m.rating,
|
||||
NULL AS artist_url,
|
||||
NULL AS venue_lat,
|
||||
NULL AS venue_lon,
|
||||
NULL AS venue_name,
|
||||
NULL AS notes,
|
||||
'movies' AS type,
|
||||
'Movie' AS label
|
||||
FROM optimized_movies m
|
||||
WHERE m.last_watched IS NOT NULL
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
c.date AS content_date,
|
||||
CONCAT(c.artist->>'name', ' at ', c.venue->>'name_short') AS title,
|
||||
c.concert_notes AS description,
|
||||
NULL AS url,
|
||||
NULL AS author,
|
||||
NULL AS image,
|
||||
NULL AS rating,
|
||||
c.artist->>'url' AS artist_url,
|
||||
c.venue->>'latitude' AS venue_lat,
|
||||
c.venue->>'longitude' AS venue_lon,
|
||||
c.venue->>'name_short' AS venue_name,
|
||||
c.notes AS notes,
|
||||
'concerts' AS type,
|
||||
'Concert' AS label
|
||||
FROM optimized_concerts c
|
||||
)
|
||||
SELECT json_agg(recent_activity_data ORDER BY recent_activity_data.content_date DESC) AS feed
|
||||
FROM (
|
||||
SELECT *
|
||||
FROM activity_data
|
||||
WHERE content_date IS NOT NULL
|
||||
ORDER BY content_date DESC
|
||||
LIMIT 20
|
||||
) AS recent_activity_data;
|
7
queries/views/feeds/redirects.psql
Normal file
7
queries/views/feeds/redirects.psql
Normal file
|
@ -0,0 +1,7 @@
|
|||
CREATE OR REPLACE VIEW optimized_redirects AS
|
||||
SELECT
|
||||
r.from AS source_url,
|
||||
r.to AS destination_url,
|
||||
r.status_code
|
||||
FROM
|
||||
redirects r;
|
12
queries/views/feeds/robots.psql
Normal file
12
queries/views/feeds/robots.psql
Normal file
|
@ -0,0 +1,12 @@
|
|||
CREATE OR REPLACE VIEW optimized_robots AS
|
||||
SELECT
|
||||
r.path,
|
||||
array_agg(ua.user_agent ORDER BY ua.user_agent) AS user_agents
|
||||
FROM
|
||||
robots AS r
|
||||
JOIN
|
||||
robots_user_agents AS rua ON r.id = rua.robots_id
|
||||
JOIN
|
||||
user_agents AS ua ON rua.user_agents_id = ua.id
|
||||
GROUP BY
|
||||
r.path;
|
111
queries/views/feeds/search.psql
Normal file
111
queries/views/feeds/search.psql
Normal file
|
@ -0,0 +1,111 @@
|
|||
CREATE OR REPLACE VIEW optimized_search_index AS
|
||||
WITH search_data AS (
|
||||
SELECT
|
||||
'post' AS type,
|
||||
CONCAT('📝 ', p.title) AS title,
|
||||
p.url::TEXT AS url,
|
||||
p.description AS description,
|
||||
p.tags,
|
||||
NULL AS genre_name,
|
||||
NULL AS genre_url,
|
||||
NULL::TEXT AS total_plays,
|
||||
p.date AS content_date
|
||||
FROM
|
||||
optimized_posts p
|
||||
UNION ALL
|
||||
SELECT
|
||||
'link' AS type,
|
||||
CONCAT('🔗 ', l.title, ' via ', l.name) AS title,
|
||||
l.link::TEXT AS url,
|
||||
l.description AS description,
|
||||
l.tags,
|
||||
NULL AS genre_name,
|
||||
NULL AS genre_url,
|
||||
NULL::TEXT AS total_plays,
|
||||
l.date AS content_date
|
||||
FROM
|
||||
optimized_links l
|
||||
UNION ALL
|
||||
SELECT
|
||||
'book' AS type,
|
||||
CASE WHEN b.rating IS NOT NULL THEN
|
||||
CONCAT('📖 ', b.title, ' (', b.rating, ')')
|
||||
ELSE
|
||||
CONCAT('📖 ', b.title)
|
||||
END AS title,
|
||||
b.url::TEXT AS url,
|
||||
b.description AS description,
|
||||
b.tags,
|
||||
NULL AS genre_name,
|
||||
NULL AS genre_url,
|
||||
NULL::TEXT AS total_plays,
|
||||
b.date_finished AS content_date
|
||||
FROM
|
||||
optimized_books b
|
||||
WHERE
|
||||
LOWER(b.status) = 'finished'
|
||||
UNION ALL
|
||||
SELECT
|
||||
'artist' AS type,
|
||||
CONCAT(COALESCE(ar.emoji, ar.genre_emoji, '🎧'), ' ', ar.name) AS title,
|
||||
ar.url::TEXT AS url,
|
||||
ar.description AS description,
|
||||
ARRAY[ar.genre_name] AS tags,
|
||||
ar.genre_name,
|
||||
ar.genre_slug AS genre_url,
|
||||
TO_CHAR(ar.total_plays::NUMERIC, 'FM999,999,999,999') AS total_plays,
|
||||
NULL AS content_date
|
||||
FROM
|
||||
optimized_artists ar
|
||||
UNION ALL
|
||||
SELECT
|
||||
'genre' AS type,
|
||||
CONCAT(COALESCE(g.emoji, '🎵'), ' ', g.name) AS title,
|
||||
g.url::TEXT AS url,
|
||||
g.description AS description,
|
||||
NULL AS tags,
|
||||
g.name AS genre_name,
|
||||
g.url AS genre_url,
|
||||
NULL::TEXT AS total_plays,
|
||||
NULL AS content_date
|
||||
FROM
|
||||
optimized_genres g
|
||||
UNION ALL
|
||||
SELECT
|
||||
'show' AS type,
|
||||
CONCAT('📺 ', s.title, ' (', s.year, ')') AS title,
|
||||
s.url::TEXT AS url,
|
||||
s.description AS description,
|
||||
s.tags,
|
||||
NULL AS genre_name,
|
||||
NULL AS genre_url,
|
||||
NULL::TEXT AS total_plays,
|
||||
s.last_watched_at AS content_date
|
||||
FROM
|
||||
optimized_shows s
|
||||
WHERE
|
||||
s.last_watched_at IS NOT NULL
|
||||
UNION ALL
|
||||
SELECT
|
||||
'movie' AS type,
|
||||
CASE
|
||||
WHEN m.rating IS NOT NULL THEN CONCAT('🎬 ', m.title, ' (', m.rating, ')')
|
||||
ELSE CONCAT('🎬 ', m.title, ' (', m.year, ')')
|
||||
END AS title,
|
||||
m.url::TEXT AS url,
|
||||
m.description AS description,
|
||||
m.tags,
|
||||
NULL AS genre_name,
|
||||
NULL AS genre_url,
|
||||
NULL::TEXT AS total_plays,
|
||||
m.last_watched AS content_date
|
||||
FROM
|
||||
optimized_movies m
|
||||
WHERE
|
||||
m.last_watched IS NOT NULL
|
||||
)
|
||||
SELECT
|
||||
ROW_NUMBER() OVER (ORDER BY url) AS id,
|
||||
*
|
||||
FROM
|
||||
search_data;
|
46
queries/views/feeds/sitemap.psql
Normal file
46
queries/views/feeds/sitemap.psql
Normal file
|
@ -0,0 +1,46 @@
|
|||
CREATE OR REPLACE VIEW optimized_sitemap AS
|
||||
WITH sitemap_data AS (
|
||||
SELECT
|
||||
p.url::TEXT AS url
|
||||
FROM
|
||||
optimized_posts p
|
||||
UNION ALL
|
||||
SELECT
|
||||
b.url::TEXT AS url
|
||||
FROM
|
||||
optimized_books b
|
||||
UNION ALL
|
||||
SELECT
|
||||
m.url::TEXT AS url
|
||||
FROM
|
||||
optimized_movies m
|
||||
UNION ALL
|
||||
SELECT
|
||||
ar.url::TEXT AS url
|
||||
FROM
|
||||
optimized_artists ar
|
||||
UNION ALL
|
||||
SELECT
|
||||
g.url::TEXT AS url
|
||||
FROM
|
||||
optimized_genres g
|
||||
UNION ALL
|
||||
SELECT
|
||||
s.url::TEXT AS url
|
||||
FROM
|
||||
optimized_shows s
|
||||
UNION ALL
|
||||
SELECT
|
||||
pa.permalink::TEXT AS url
|
||||
FROM
|
||||
optimized_pages pa
|
||||
UNION ALL
|
||||
SELECT
|
||||
ss.slug AS url
|
||||
FROM
|
||||
static_slugs ss
|
||||
)
|
||||
SELECT
|
||||
url
|
||||
FROM
|
||||
sitemap_data;
|
190
queries/views/feeds/stats.psql
Normal file
190
queries/views/feeds/stats.psql
Normal file
|
@ -0,0 +1,190 @@
|
|||
CREATE OR REPLACE VIEW optimized_stats AS
|
||||
WITH artist_stats AS (
|
||||
SELECT
|
||||
TO_CHAR(COUNT(DISTINCT artist_name), 'FM999,999,999') AS artist_count
|
||||
FROM optimized_listens
|
||||
WHERE artist_name IS NOT NULL
|
||||
),
|
||||
track_stats AS (
|
||||
SELECT
|
||||
TO_CHAR(COUNT(*), 'FM999,999,999') AS listen_count
|
||||
FROM optimized_listens
|
||||
),
|
||||
concert_stats AS (
|
||||
SELECT
|
||||
TO_CHAR(COUNT(*), 'FM999,999,999') AS concert_count
|
||||
FROM concerts
|
||||
),
|
||||
venue_stats AS (
|
||||
SELECT
|
||||
TO_CHAR(COUNT(DISTINCT venue), 'FM999,999,999') AS venue_count
|
||||
FROM concerts
|
||||
),
|
||||
yearly_data AS (
|
||||
SELECT
|
||||
EXTRACT(YEAR FROM e.last_watched_at) AS year,
|
||||
0 AS artist_count,
|
||||
0 AS listen_count,
|
||||
0 AS genre_count,
|
||||
COUNT(DISTINCT e.show) AS show_count,
|
||||
COUNT(*) AS episode_count,
|
||||
0 AS post_count,
|
||||
0 AS link_count,
|
||||
0 AS book_count,
|
||||
0 AS movie_count,
|
||||
0 AS concert_count,
|
||||
0 AS venue_count
|
||||
FROM episodes e
|
||||
GROUP BY EXTRACT(YEAR FROM e.last_watched_at)
|
||||
HAVING EXTRACT(YEAR FROM e.last_watched_at) >= 2023
|
||||
UNION ALL
|
||||
SELECT
|
||||
EXTRACT(YEAR FROM p.date) AS year,
|
||||
0 AS artist_count,
|
||||
0 AS listen_count,
|
||||
0 AS genre_count,
|
||||
0 AS show_count,
|
||||
0 AS episode_count,
|
||||
COUNT(*) AS post_count,
|
||||
0 AS link_count,
|
||||
0 AS book_count,
|
||||
0 AS movie_count,
|
||||
0 AS concert_count,
|
||||
0 AS venue_count
|
||||
FROM optimized_posts p
|
||||
GROUP BY EXTRACT(YEAR FROM p.date)
|
||||
HAVING EXTRACT(YEAR FROM p.date) >= 2023
|
||||
UNION ALL
|
||||
SELECT
|
||||
EXTRACT(YEAR FROM o.date) AS year,
|
||||
0 AS artist_count,
|
||||
0 AS listen_count,
|
||||
0 AS genre_count,
|
||||
0 AS show_count,
|
||||
0 AS episode_count,
|
||||
0 AS post_count,
|
||||
COUNT(*) AS link_count,
|
||||
0 AS book_count,
|
||||
0 AS movie_count,
|
||||
0 AS concert_count,
|
||||
0 AS venue_count
|
||||
FROM optimized_links o
|
||||
GROUP BY EXTRACT(YEAR FROM o.date)
|
||||
HAVING EXTRACT(YEAR FROM o.date) >= 2023
|
||||
UNION ALL
|
||||
SELECT
|
||||
EXTRACT(YEAR FROM b.date_finished) AS year,
|
||||
0 AS artist_count,
|
||||
0 AS listen_count,
|
||||
0 AS genre_count,
|
||||
0 AS show_count,
|
||||
0 AS episode_count,
|
||||
0 AS post_count,
|
||||
0 AS link_count,
|
||||
COUNT(*) AS book_count,
|
||||
0 AS movie_count,
|
||||
0 AS concert_count,
|
||||
0 AS venue_count
|
||||
FROM optimized_books b
|
||||
WHERE LOWER(b.status) = 'finished'
|
||||
GROUP BY EXTRACT(YEAR FROM b.date_finished)
|
||||
HAVING EXTRACT(YEAR FROM b.date_finished) >= 2023
|
||||
UNION ALL
|
||||
SELECT
|
||||
EXTRACT(YEAR FROM m.last_watched) AS year,
|
||||
0 AS artist_count,
|
||||
0 AS listen_count,
|
||||
0 AS genre_count,
|
||||
0 AS show_count,
|
||||
0 AS episode_count,
|
||||
0 AS post_count,
|
||||
0 AS link_count,
|
||||
0 AS book_count,
|
||||
COUNT(*) AS movie_count,
|
||||
0 AS concert_count,
|
||||
0 AS venue_count
|
||||
FROM optimized_movies m
|
||||
GROUP BY EXTRACT(YEAR FROM m.last_watched)
|
||||
HAVING EXTRACT(YEAR FROM m.last_watched) >= 2023
|
||||
UNION ALL
|
||||
SELECT
|
||||
EXTRACT(YEAR FROM TO_TIMESTAMP(l.listened_at)) AS year,
|
||||
COUNT(DISTINCT l.artist_name) AS artist_count,
|
||||
COUNT(l.id) AS listen_count,
|
||||
COUNT(DISTINCT l.genre_name) AS genre_count,
|
||||
0 AS show_count,
|
||||
0 AS episode_count,
|
||||
0 AS post_count,
|
||||
0 AS link_count,
|
||||
0 AS book_count,
|
||||
0 AS movie_count,
|
||||
0 AS concert_count,
|
||||
0 AS venue_count
|
||||
FROM optimized_listens l
|
||||
GROUP BY EXTRACT(YEAR FROM TO_TIMESTAMP(l.listened_at))
|
||||
HAVING EXTRACT(YEAR FROM TO_TIMESTAMP(l.listened_at)) >= 2023
|
||||
UNION ALL
|
||||
SELECT
|
||||
EXTRACT(YEAR FROM c.date) AS year,
|
||||
0 AS artist_count,
|
||||
0 AS listen_count,
|
||||
0 AS genre_count,
|
||||
0 AS show_count,
|
||||
0 AS episode_count,
|
||||
0 AS post_count,
|
||||
0 AS link_count,
|
||||
0 AS book_count,
|
||||
0 AS movie_count,
|
||||
COUNT(*) AS concert_count,
|
||||
COUNT(DISTINCT c.venue) AS venue_count
|
||||
FROM concerts c
|
||||
GROUP BY EXTRACT(YEAR FROM c.date)
|
||||
HAVING EXTRACT(YEAR FROM c.date) >= 2023
|
||||
),
|
||||
aggregated_yearly_stats AS (
|
||||
SELECT
|
||||
year,
|
||||
SUM(artist_count) AS artist_count,
|
||||
SUM(listen_count) AS listen_count,
|
||||
SUM(genre_count) AS genre_count,
|
||||
SUM(show_count) AS show_count,
|
||||
SUM(episode_count) AS episode_count,
|
||||
SUM(post_count) AS post_count,
|
||||
SUM(link_count) AS link_count,
|
||||
SUM(book_count) AS book_count,
|
||||
SUM(movie_count) AS movie_count,
|
||||
SUM(concert_count) AS concert_count,
|
||||
SUM(venue_count) AS venue_count
|
||||
FROM yearly_data
|
||||
GROUP BY year
|
||||
ORDER BY year DESC
|
||||
)
|
||||
SELECT
|
||||
(SELECT artist_count FROM artist_stats) AS artist_count,
|
||||
(SELECT listen_count FROM track_stats) AS listen_count,
|
||||
(SELECT concert_count FROM concert_stats) AS concert_count,
|
||||
(SELECT venue_count FROM venue_stats) AS venue_count,
|
||||
(SELECT TO_CHAR(COUNT(DISTINCT e.show), 'FM999,999,999') FROM episodes e) AS show_count,
|
||||
(SELECT TO_CHAR(COUNT(*), 'FM999,999,999') FROM episodes e) AS episode_count,
|
||||
(SELECT TO_CHAR(COUNT(*), 'FM999,999,999') FROM optimized_posts) AS post_count,
|
||||
(SELECT TO_CHAR(COUNT(*), 'FM999,999,999') FROM optimized_links) AS link_count,
|
||||
(SELECT TO_CHAR(COUNT(*), 'FM999,999,999') FROM optimized_books WHERE LOWER(status) = 'finished') AS book_count,
|
||||
(SELECT TO_CHAR(COUNT(*), 'FM999,999,999') FROM optimized_movies WHERE last_watched IS NOT NULL) AS movie_count,
|
||||
(SELECT TO_CHAR(COUNT(DISTINCT genre_name), 'FM999,999,999') FROM optimized_listens WHERE genre_name IS NOT NULL) AS genre_count,
|
||||
JSON_AGG(
|
||||
JSON_BUILD_OBJECT(
|
||||
'year', ys.year,
|
||||
'artist_count', CASE WHEN ys.artist_count > 0 THEN TO_CHAR(ys.artist_count, 'FM999,999,999') ELSE NULL END,
|
||||
'listen_count', CASE WHEN ys.listen_count > 0 THEN TO_CHAR(ys.listen_count, 'FM999,999,999') ELSE NULL END,
|
||||
'genre_count', CASE WHEN ys.genre_count > 0 THEN TO_CHAR(ys.genre_count, 'FM999,999,999') ELSE NULL END,
|
||||
'show_count', CASE WHEN ys.show_count > 0 THEN TO_CHAR(ys.show_count, 'FM999,999,999') ELSE NULL END,
|
||||
'episode_count', CASE WHEN ys.episode_count > 0 THEN TO_CHAR(ys.episode_count, 'FM999,999,999') ELSE NULL END,
|
||||
'post_count', CASE WHEN ys.post_count > 0 THEN TO_CHAR(ys.post_count, 'FM999,999,999') ELSE NULL END,
|
||||
'link_count', CASE WHEN ys.link_count > 0 THEN TO_CHAR(ys.link_count, 'FM999,999,999') ELSE NULL END,
|
||||
'book_count', CASE WHEN ys.book_count > 0 THEN TO_CHAR(ys.book_count, 'FM999,999,999') ELSE NULL END,
|
||||
'movie_count', CASE WHEN ys.movie_count > 0 THEN TO_CHAR(ys.movie_count, 'FM999,999,999') ELSE NULL END,
|
||||
'concert_count', CASE WHEN ys.concert_count > 0 THEN TO_CHAR(ys.concert_count, 'FM999,999,999') ELSE NULL END,
|
||||
'venue_count', CASE WHEN ys.venue_count > 0 THEN TO_CHAR(ys.venue_count, 'FM999,999,999') ELSE NULL END
|
||||
)
|
||||
) AS yearly_breakdown
|
||||
FROM aggregated_yearly_stats ys;
|
7
queries/views/feeds/subscribe.psql
Normal file
7
queries/views/feeds/subscribe.psql
Normal file
|
@ -0,0 +1,7 @@
|
|||
CREATE OR REPLACE VIEW optimized_feeds AS
|
||||
SELECT
|
||||
f.title AS title,
|
||||
f.data AS data,
|
||||
f.permalink AS permalink
|
||||
FROM
|
||||
feeds f;
|
99
queries/views/feeds/syndication.psql
Normal file
99
queries/views/feeds/syndication.psql
Normal file
|
@ -0,0 +1,99 @@
|
|||
CREATE OR REPLACE VIEW optimized_syndication AS
|
||||
WITH syndication_data AS (
|
||||
SELECT
|
||||
p.date AS content_date,
|
||||
json_build_object(
|
||||
'title', CONCAT('📝 ', p.title, ' ', (
|
||||
SELECT array_to_string(
|
||||
array_agg('#' || initcap(replace(trim(tag_part), ' ', ''))),
|
||||
' '
|
||||
)
|
||||
FROM unnest(p.tags) AS t(name),
|
||||
regexp_split_to_table(t.name, '\s*&\s*') AS tag_part
|
||||
)),
|
||||
'description', p.description,
|
||||
'url', p.url,
|
||||
'image', p.image,
|
||||
'date', p.date
|
||||
) AS feed
|
||||
FROM optimized_posts p
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
l.date AS content_date,
|
||||
json_build_object(
|
||||
'title', CONCAT('🔗 ', l.title, CASE
|
||||
WHEN l.mastodon IS NOT NULL THEN ' via @' || split_part(l.mastodon, '@', 2) || '@' || split_part(split_part(l.mastodon, 'https://', 2), '/', 1)
|
||||
ELSE CONCAT(' via ', l.name)
|
||||
END, ' ', (
|
||||
SELECT array_to_string(
|
||||
array_agg('#' || initcap(replace(trim(tag_part), ' ', ''))),
|
||||
' '
|
||||
)
|
||||
FROM unnest(l.tags) AS t(name),
|
||||
regexp_split_to_table(t.name, '\s*&\s*') AS tag_part
|
||||
)),
|
||||
'description', l.description,
|
||||
'url', l.link,
|
||||
'date', l.date
|
||||
) AS feed
|
||||
FROM optimized_links l
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
b.date_finished AS content_date,
|
||||
CASE
|
||||
WHEN LOWER(b.status) = 'finished' THEN
|
||||
json_build_object(
|
||||
'title', CONCAT('📖 ', b.title, CASE
|
||||
WHEN b.rating IS NOT NULL THEN ' (' || b.rating || ')' ELSE '' END, ' ', (
|
||||
SELECT array_to_string(
|
||||
array_agg('#' || initcap(replace(trim(tag_part), ' ', ''))),
|
||||
' '
|
||||
)
|
||||
FROM unnest(b.tags) AS t(name),
|
||||
regexp_split_to_table(t.name, '\s*&\s*') AS tag_part
|
||||
)
|
||||
),
|
||||
'description', b.description,
|
||||
'url', b.url,
|
||||
'image', b.image,
|
||||
'date', b.date_finished
|
||||
)
|
||||
ELSE NULL
|
||||
END AS feed
|
||||
FROM optimized_books b
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
m.last_watched AS content_date,
|
||||
CASE
|
||||
WHEN m.last_watched IS NOT NULL THEN
|
||||
json_build_object(
|
||||
'title', CONCAT('🎥 ', m.title, CASE
|
||||
WHEN m.rating IS NOT NULL THEN ' (' || m.rating || ')' ELSE '' END, ' ', (
|
||||
SELECT array_to_string(
|
||||
array_agg('#' || initcap(replace(trim(tag_part), ' ', ''))),
|
||||
' '
|
||||
)
|
||||
FROM unnest(m.tags) AS t(name),
|
||||
regexp_split_to_table(t.name, '\s*&\s*') AS tag_part
|
||||
)
|
||||
),
|
||||
'description', m.description,
|
||||
'url', m.url,
|
||||
'image', m.image,
|
||||
'date', m.last_watched
|
||||
)
|
||||
ELSE NULL
|
||||
END AS feed
|
||||
FROM optimized_movies m
|
||||
)
|
||||
SELECT feed
|
||||
FROM syndication_data
|
||||
WHERE feed IS NOT NULL
|
||||
ORDER BY content_date DESC
|
||||
LIMIT 3;
|
23
queries/views/globals/index.psql
Normal file
23
queries/views/globals/index.psql
Normal file
|
@ -0,0 +1,23 @@
|
|||
CREATE OR REPLACE VIEW optimized_globals AS
|
||||
SELECT
|
||||
g.site_name,
|
||||
g.site_description,
|
||||
g.intro,
|
||||
g.author,
|
||||
g.email,
|
||||
g.mastodon,
|
||||
g.url,
|
||||
g.cdn_url,
|
||||
g.sitemap_uri,
|
||||
g.theme_color,
|
||||
g.site_type,
|
||||
g.locale,
|
||||
g.lang,
|
||||
g.webfinger_username,
|
||||
g.webfinger_hostname,
|
||||
CONCAT('/', df.filename_disk) AS avatar,
|
||||
CONCAT('/', df2.filename_disk) AS avatar_transparent
|
||||
FROM
|
||||
globals g
|
||||
LEFT JOIN directus_files df ON g.avatar = df.id
|
||||
LEFT JOIN directus_files df2 ON g.avatar_transparent = df2.id
|
14
queries/views/globals/nav.psql
Normal file
14
queries/views/globals/nav.psql
Normal file
|
@ -0,0 +1,14 @@
|
|||
CREATE OR REPLACE VIEW optimized_navigation AS
|
||||
SELECT
|
||||
n.id,
|
||||
n.menu_location,
|
||||
n.permalink,
|
||||
n.icon,
|
||||
n.title,
|
||||
n.sort,
|
||||
p.title AS page_title,
|
||||
p.permalink AS page_permalink
|
||||
FROM
|
||||
navigation n
|
||||
LEFT JOIN pages p ON n.pages = p.id;
|
||||
|
54
queries/views/globals/pages.psql
Normal file
54
queries/views/globals/pages.psql
Normal file
|
@ -0,0 +1,54 @@
|
|||
CREATE OR REPLACE VIEW optimized_pages AS
|
||||
SELECT
|
||||
p.id,
|
||||
p.title,
|
||||
p.permalink,
|
||||
p.description,
|
||||
CONCAT('/', df.filename_disk) AS open_graph_image,
|
||||
p.updated,
|
||||
(
|
||||
SELECT
|
||||
json_agg(
|
||||
CASE WHEN pb.collection = 'youtube_player' THEN
|
||||
json_build_object('type', pb.collection, 'url', yp.url)
|
||||
WHEN pb.collection = 'github_banner' THEN
|
||||
json_build_object('type', pb.collection, 'url', gb.url)
|
||||
WHEN pb.collection = 'npm_banner' THEN
|
||||
json_build_object('type', pb.collection, 'url', nb.url, 'command', nb.command)
|
||||
WHEN pb.collection = 'rss_banner' THEN
|
||||
json_build_object('type', pb.collection, 'url', rb.url, 'text', rb.text)
|
||||
WHEN pb.collection = 'calendar_banner' THEN
|
||||
json_build_object('type', pb.collection, 'url', cb.url, 'text', cb.text)
|
||||
WHEN pb.collection = 'hero' THEN
|
||||
json_build_object('type', pb.collection, 'image', CONCAT('/', df_hero.filename_disk), 'alt', h.alt_text)
|
||||
WHEN pb.collection = 'markdown' THEN
|
||||
json_build_object('type', pb.collection, 'text', md.text)
|
||||
ELSE
|
||||
json_build_object('type', pb.collection)
|
||||
END ORDER BY pb.sort)
|
||||
FROM
|
||||
pages_blocks pb
|
||||
LEFT JOIN youtube_player yp ON pb.collection = 'youtube_player'
|
||||
AND yp.id = pb.item::integer
|
||||
LEFT JOIN github_banner gb ON pb.collection = 'github_banner'
|
||||
AND gb.id = pb.item::integer
|
||||
LEFT JOIN npm_banner nb ON pb.collection = 'npm_banner'
|
||||
AND nb.id = pb.item::integer
|
||||
LEFT JOIN rss_banner rb ON pb.collection = 'rss_banner'
|
||||
AND rb.id = pb.item::integer
|
||||
LEFT JOIN calendar_banner cb ON pb.collection = 'calendar_banner'
|
||||
AND cb.id = pb.item::integer
|
||||
LEFT JOIN hero h ON pb.collection = 'hero'
|
||||
AND h.id = pb.item::integer
|
||||
LEFT JOIN directus_files df_hero ON h.image = df_hero.id
|
||||
LEFT JOIN markdown md ON pb.collection = 'markdown'
|
||||
AND md.id = pb.item::integer
|
||||
WHERE
|
||||
pb.pages_id = p.id) AS blocks
|
||||
FROM
|
||||
pages p
|
||||
LEFT JOIN directus_files df ON p.open_graph_image = df.id
|
||||
GROUP BY
|
||||
p.id,
|
||||
df.filename_disk;
|
||||
|
107
queries/views/media/books.psql
Normal file
107
queries/views/media/books.psql
Normal file
|
@ -0,0 +1,107 @@
|
|||
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,
|
||||
b.progress,
|
||||
b.read_status AS status,
|
||||
b.star_rating AS rating,
|
||||
b.review,
|
||||
b.slug AS url,
|
||||
CONCAT('/', df.filename_disk) AS image,
|
||||
b.favorite,
|
||||
b.tattoo,
|
||||
(
|
||||
SELECT
|
||||
array_agg(t.name)
|
||||
FROM
|
||||
books_tags bt
|
||||
LEFT JOIN tags t ON bt.tags_id = t.id
|
||||
WHERE
|
||||
bt.books_id = b.id) AS tags,
|
||||
(
|
||||
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
|
||||
books_artists ba
|
||||
LEFT JOIN artists a ON ba.artists_id = a.id
|
||||
WHERE
|
||||
ba.books_id = b.id) AS artists,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', m.title, 'year', m.year, 'url', m.slug)
|
||||
ORDER BY m.year DESC)
|
||||
FROM
|
||||
movies_books mb
|
||||
LEFT JOIN movies m ON mb.movies_id = m.id
|
||||
WHERE
|
||||
mb.books_id = b.id) AS movies,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('name', g.name, 'url', g.slug)
|
||||
ORDER BY g.name ASC)
|
||||
FROM
|
||||
genres_books gb
|
||||
LEFT JOIN genres g ON gb.genres_id = g.id
|
||||
WHERE
|
||||
gb.books_id = b.id) AS genres,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', s.title, 'year', s.year, 'url', s.slug)
|
||||
ORDER BY s.year DESC)
|
||||
FROM
|
||||
shows_books sb
|
||||
LEFT JOIN shows s ON sb.shows_id = s.id
|
||||
WHERE
|
||||
sb.books_id = b.id) AS shows,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', p.title, 'date', p.date, 'url', p.slug)
|
||||
ORDER BY p.date DESC)
|
||||
FROM
|
||||
posts_books pb
|
||||
LEFT JOIN posts p ON pb.posts_id = p.id
|
||||
WHERE
|
||||
pb.books_id = b.id) AS posts,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', rb.title, 'author', rb.author, 'url', rb.slug)
|
||||
ORDER BY rb.title ASC)
|
||||
FROM
|
||||
related_books rbk
|
||||
LEFT JOIN books rb ON rbk.related_books_id = rb.id
|
||||
WHERE
|
||||
rbk.books_id = b.id) AS related_books,
|
||||
json_build_object(
|
||||
'title', NULL,
|
||||
'image', CONCAT('/', df.filename_disk),
|
||||
'url', b.slug,
|
||||
'alt', CONCAT('Book cover from ', b.title, ' by ', b.author),
|
||||
'subtext', CASE
|
||||
WHEN b.star_rating IS NOT NULL THEN b.star_rating::text
|
||||
ELSE NULL
|
||||
END
|
||||
) AS grid,
|
||||
CASE
|
||||
WHEN LOWER(b.read_status) = 'finished' AND b.star_rating IS NOT NULL THEN
|
||||
json_build_object(
|
||||
'title', CONCAT(b.title, ' by ', b.author, ' (', b.star_rating, ')'),
|
||||
'url', b.slug,
|
||||
'date', b.date_finished,
|
||||
'description', COALESCE(b.review, b.description),
|
||||
'image', CONCAT('/', df.filename_disk),
|
||||
'rating', b.star_rating
|
||||
)
|
||||
ELSE
|
||||
NULL
|
||||
END AS feed,
|
||||
(SELECT TO_CHAR(days_read, 'FM999G999G999') FROM reading_streak LIMIT 1) AS days_read
|
||||
FROM
|
||||
books b
|
||||
LEFT JOIN directus_files df ON b.art = df.id
|
||||
GROUP BY
|
||||
b.id,
|
||||
df.filename_disk;
|
119
queries/views/media/movies.psql
Normal file
119
queries/views/media/movies.psql
Normal file
|
@ -0,0 +1,119 @@
|
|||
CREATE OR REPLACE VIEW optimized_movies AS
|
||||
SELECT
|
||||
m.id,
|
||||
m.tmdb_id,
|
||||
m.last_watched,
|
||||
m.title,
|
||||
m.year,
|
||||
m.plays,
|
||||
m.favorite,
|
||||
m.tattoo,
|
||||
m.star_rating AS rating,
|
||||
m.description,
|
||||
m.review,
|
||||
m.slug AS url,
|
||||
CONCAT('/', df.filename_disk) AS image,
|
||||
CONCAT('/', df2.filename_disk) AS backdrop,
|
||||
json_build_object(
|
||||
'title', NULL,
|
||||
'url', m.slug,
|
||||
'image', CONCAT('/', df.filename_disk),
|
||||
'backdrop', CONCAT('/', df2.filename_disk),
|
||||
'alt', CONCAT('Poster from ', m.title),
|
||||
'subtext', CASE
|
||||
WHEN m.last_watched >= NOW() - INTERVAL '90 days' THEN
|
||||
m.star_rating::text
|
||||
ELSE
|
||||
m.year::text
|
||||
END
|
||||
) AS grid,
|
||||
(
|
||||
SELECT
|
||||
array_agg(t.name)
|
||||
FROM
|
||||
movies_tags mt
|
||||
LEFT JOIN tags t ON mt.tags_id = t.id
|
||||
WHERE
|
||||
mt.movies_id = m.id) AS tags,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('name', g.name, 'url', g.slug)
|
||||
ORDER BY g.name ASC)
|
||||
FROM
|
||||
genres_movies gm
|
||||
LEFT JOIN genres g ON gm.genres_id = g.id
|
||||
WHERE
|
||||
gm.movies_id = m.id) AS genres,
|
||||
(
|
||||
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
|
||||
movies_artists ma
|
||||
LEFT JOIN artists a ON ma.artists_id = a.id
|
||||
WHERE
|
||||
ma.movies_id = m.id) AS artists,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', b.title, 'author', b.author, 'url', b.slug)
|
||||
ORDER BY b.title ASC)
|
||||
FROM
|
||||
movies_books mb
|
||||
LEFT JOIN books b ON mb.books_id = b.id
|
||||
WHERE
|
||||
mb.movies_id = m.id) AS books,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', s.title, 'year', s.year, 'url', s.slug)
|
||||
ORDER BY s.year DESC)
|
||||
FROM
|
||||
shows_movies sm
|
||||
LEFT JOIN shows s ON sm.shows_id = s.id
|
||||
WHERE
|
||||
sm.movies_id = m.id) AS shows,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', p.title, 'date', p.date, 'url', p.slug)
|
||||
ORDER BY p.date DESC)
|
||||
FROM
|
||||
posts_movies pm
|
||||
LEFT JOIN posts p ON pm.posts_id = p.id
|
||||
WHERE
|
||||
pm.movies_id = m.id) AS posts,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', rm.title, 'year', rm.year, 'url', rm.slug)
|
||||
ORDER BY rm.year DESC)
|
||||
FROM
|
||||
related_movies r
|
||||
LEFT JOIN movies rm ON r.related_movies_id = rm.id
|
||||
WHERE
|
||||
r.movies_id = m.id) AS related_movies,
|
||||
CASE
|
||||
WHEN m.star_rating IS NOT NULL AND m.last_watched IS NOT NULL THEN
|
||||
json_build_object(
|
||||
'title', CONCAT(m.title, CASE
|
||||
WHEN m.star_rating IS NOT NULL THEN CONCAT(' (', m.star_rating, ')')
|
||||
ELSE ''
|
||||
END),
|
||||
'url', m.slug,
|
||||
'date', m.last_watched,
|
||||
'description', COALESCE(m.review, m.description),
|
||||
'image', CONCAT('/', df.filename_disk),
|
||||
'rating', m.star_rating
|
||||
)
|
||||
ELSE
|
||||
NULL
|
||||
END AS feed
|
||||
FROM
|
||||
movies m
|
||||
LEFT JOIN directus_files df ON m.art = df.id
|
||||
LEFT JOIN directus_files df2 ON m.backdrop = df2.id
|
||||
GROUP BY
|
||||
m.id,
|
||||
df.filename_disk,
|
||||
df2.filename_disk
|
||||
ORDER BY
|
||||
m.last_watched DESC,
|
||||
m.favorite DESC,
|
||||
m.title ASC;
|
22
queries/views/media/music/album-releases.psql
Normal file
22
queries/views/media/music/album-releases.psql
Normal file
|
@ -0,0 +1,22 @@
|
|||
CREATE OR REPLACE VIEW optimized_album_releases AS
|
||||
SELECT
|
||||
a.name AS title,
|
||||
a.release_date,
|
||||
COALESCE(a.release_link, ar.slug) AS url,
|
||||
a.total_plays,
|
||||
CONCAT('/', df.filename_disk) AS image,
|
||||
json_build_object('name', ar.name_string, 'url', ar.slug, 'description', ar.description) AS artist,
|
||||
EXTRACT(EPOCH FROM a.release_date) AS release_timestamp,
|
||||
json_build_object(
|
||||
'title', a.name,
|
||||
'image', CONCAT('/', df.filename_disk),
|
||||
'url', COALESCE(a.release_link, ar.slug),
|
||||
'alt', CONCAT(a.name, ' by ', ar.name_string),
|
||||
'subtext', CONCAT(ar.name_string, ' / ', TO_CHAR(a.release_date, 'Mon FMDD, YYYY'))
|
||||
) AS grid
|
||||
FROM
|
||||
albums a
|
||||
LEFT JOIN directus_files df ON a.art = df.id
|
||||
LEFT JOIN artists ar ON a.artist = ar.id
|
||||
WHERE
|
||||
a.release_date IS NOT NULL;
|
29
queries/views/media/music/albums.psql
Normal file
29
queries/views/media/music/albums.psql
Normal file
|
@ -0,0 +1,29 @@
|
|||
CREATE OR REPLACE VIEW optimized_albums AS
|
||||
SELECT
|
||||
al.name AS name,
|
||||
al.release_year,
|
||||
to_char(al.total_plays, 'FM999,999,999,999') AS total_plays,
|
||||
al.total_plays AS total_plays_raw,
|
||||
ar.name_string AS artist_name,
|
||||
ar.slug AS artist_url,
|
||||
CONCAT('/', df_album.filename_disk) AS image,
|
||||
json_build_object(
|
||||
'title', al.name,
|
||||
'image', CONCAT('/', df_album.filename_disk),
|
||||
'url', ar.slug,
|
||||
'alt', CONCAT('Cover for ', al.name, ' by ', ar.name_string),
|
||||
'subtext', CONCAT(to_char(al.total_plays, 'FM999,999,999,999'), ' plays')
|
||||
) AS grid,
|
||||
json_build_object(
|
||||
'title', al.name,
|
||||
'artist', ar.name_string,
|
||||
'plays', to_char(al.total_plays, 'FM999,999,999,999'),
|
||||
'image', CONCAT('/', df_album.filename_disk),
|
||||
'url', ar.slug,
|
||||
'year', al.release_year,
|
||||
'alt', CONCAT('Cover for ', al.name, ' by ', ar.name_string)
|
||||
) AS table
|
||||
FROM albums al
|
||||
LEFT JOIN artists ar ON al.artist = ar.id
|
||||
LEFT JOIN directus_files df_album ON al.art = df_album.id
|
||||
GROUP BY al.id, ar.name_string, ar.slug, df_album.filename_disk;
|
109
queries/views/media/music/artists.psql
Normal file
109
queries/views/media/music/artists.psql
Normal file
|
@ -0,0 +1,109 @@
|
|||
CREATE OR REPLACE VIEW optimized_artists AS
|
||||
SELECT
|
||||
ar.name_string AS name,
|
||||
ar.slug AS url,
|
||||
ar.tentative,
|
||||
to_char(ar.total_plays, 'FM999,999,999,999') AS total_plays,
|
||||
ar.total_plays AS total_plays_raw,
|
||||
ar.country,
|
||||
ar.description,
|
||||
ar.favorite,
|
||||
g.name AS genre_name,
|
||||
g.slug AS genre_slug,
|
||||
g.emoji AS genre_emoji,
|
||||
json_build_object('name', g.name, 'url', g.slug, 'emoji', g.emoji) AS genre,
|
||||
ar.emoji,
|
||||
ar.tattoo,
|
||||
CONCAT('/', df.filename_disk) AS image,
|
||||
json_build_object(
|
||||
'title', ar.name_string,
|
||||
'image',
|
||||
CONCAT('/', df.filename_disk),
|
||||
'url', ar.slug,
|
||||
'alt', CONCAT(to_char(ar.total_plays, 'FM999,999,999,999'), ' plays of ', ar.name_string),
|
||||
'subtext', CONCAT(to_char(ar.total_plays, 'FM999,999,999,999'), ' plays')
|
||||
) AS grid,
|
||||
json_build_object(
|
||||
'title', ar.name_string,
|
||||
'genre', g.name,
|
||||
'genre_url', g.slug,
|
||||
'emoji', CASE WHEN ar.emoji IS NOT NULL THEN ar.emoji ELSE g.emoji END,
|
||||
'plays', to_char(ar.total_plays, 'FM999,999,999,999'),
|
||||
'image', CONCAT('/', df.filename_disk),
|
||||
'url', ar.slug,
|
||||
'alt', CONCAT(to_char(ar.total_plays, 'FM999,999,999,999'), ' plays of ', ar.name_string)
|
||||
) AS table,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('name', a.name, 'release_year', a.release_year, 'total_plays', to_char(a.total_plays, 'FM999,999,999,999'),
|
||||
'art', df_album.filename_disk)
|
||||
ORDER BY a.release_year)
|
||||
FROM
|
||||
albums a
|
||||
LEFT JOIN directus_files df_album ON a.art = df_album.id
|
||||
WHERE
|
||||
a.artist = ar.id) AS albums,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('id', c.id, 'date', c.date, 'venue_name', v.name, 'venue_name_short', trim(split_part(v.name, ',', 1)), 'venue_latitude', v.latitude, 'venue_longitude', v.longitude, 'notes', c.notes)
|
||||
ORDER BY c.date DESC)
|
||||
FROM
|
||||
concerts c
|
||||
LEFT JOIN venues v ON c.venue = v.id
|
||||
WHERE
|
||||
c.artist = ar.id) AS concerts,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', b.title, 'author', b.author, 'url', b.slug)
|
||||
ORDER BY b.title ASC)
|
||||
FROM
|
||||
books_artists ba
|
||||
LEFT JOIN books b ON ba.books_id = b.id
|
||||
WHERE
|
||||
ba.artists_id = ar.id) AS books,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', m.title, 'year', m.year, 'url', m.slug)
|
||||
ORDER BY m.year DESC)
|
||||
FROM
|
||||
movies_artists ma
|
||||
LEFT JOIN movies m ON ma.movies_id = m.id
|
||||
WHERE
|
||||
ma.artists_id = ar.id) AS movies,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', s.title, 'year', s.year, 'url', s.slug)
|
||||
ORDER BY s.year DESC)
|
||||
FROM
|
||||
shows_artists sa
|
||||
LEFT JOIN shows s ON sa.shows_id = s.id
|
||||
WHERE
|
||||
sa.artists_id = ar.id) AS shows,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', p.title, 'date', p.date, 'url', p.slug)
|
||||
ORDER BY p.date DESC)
|
||||
FROM
|
||||
posts_artists pa
|
||||
LEFT JOIN posts p ON pa.posts_id = p.id
|
||||
WHERE
|
||||
pa.artists_id = ar.id) AS posts,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('name', related_ar.name_string, 'url', related_ar.slug, 'country', related_ar.country, 'total_plays', to_char(related_ar.total_plays, 'FM999,999,999,999'))
|
||||
ORDER BY related_ar.name_string)
|
||||
FROM
|
||||
related_artists ra
|
||||
LEFT JOIN artists related_ar ON ra.related_artists_id = related_ar.id
|
||||
WHERE
|
||||
ra.artists_id = ar.id) AS related_artists
|
||||
FROM
|
||||
artists ar
|
||||
LEFT JOIN directus_files df ON ar.art = df.id
|
||||
LEFT JOIN genres g ON ar.genres = g.id
|
||||
GROUP BY
|
||||
ar.id,
|
||||
df.filename_disk,
|
||||
g.name,
|
||||
g.slug,
|
||||
g.emoji;
|
19
queries/views/media/music/concerts.psql
Normal file
19
queries/views/media/music/concerts.psql
Normal file
|
@ -0,0 +1,19 @@
|
|||
CREATE OR REPLACE VIEW optimized_concerts AS
|
||||
SELECT
|
||||
c.id,
|
||||
c.date,
|
||||
c.notes,
|
||||
CASE WHEN c.artist IS NOT NULL THEN
|
||||
json_build_object('name', a.name_string, 'url', a.slug)
|
||||
ELSE
|
||||
json_build_object('name', c.artist_name_string, 'url', NULL)
|
||||
END AS artist,
|
||||
json_build_object('name', v.name, 'name_short', trim(split_part(v.name, ',', 1)), 'latitude', v.latitude, 'longitude', v.longitude, 'notes', v.notes) AS venue,
|
||||
c.notes AS concert_notes
|
||||
FROM
|
||||
concerts c
|
||||
LEFT JOIN artists a ON c.artist = a.id
|
||||
LEFT JOIN venues v ON c.venue = v.id
|
||||
ORDER BY
|
||||
c.date DESC;
|
||||
|
50
queries/views/media/music/genres.psql
Normal file
50
queries/views/media/music/genres.psql
Normal file
|
@ -0,0 +1,50 @@
|
|||
CREATE OR REPLACE VIEW optimized_genres AS
|
||||
SELECT
|
||||
g.id,
|
||||
g.name,
|
||||
g.description,
|
||||
g.emoji,
|
||||
to_char(g.total_plays, 'FM999,999,999,999') AS total_plays,
|
||||
g.wiki_link,
|
||||
g.slug AS url,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('name', a.name_string, 'url', a.slug, 'image', CONCAT('/', df_artist.filename_disk), 'total_plays', to_char(a.total_plays, 'FM999,999,999,999'))
|
||||
ORDER BY a.total_plays DESC)
|
||||
FROM
|
||||
artists a
|
||||
LEFT JOIN directus_files df_artist ON a.art = df_artist.id
|
||||
WHERE
|
||||
a.genres = g.id) AS artists,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', b.title, 'author', b.author, 'url', b.slug)
|
||||
ORDER BY b.title ASC)
|
||||
FROM
|
||||
books b
|
||||
JOIN genres_books gb ON gb.books_id = b.id
|
||||
WHERE
|
||||
gb.genres_id = g.id) AS books,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', m.title, 'year', m.year, 'url', m.slug)
|
||||
ORDER BY m.year DESC)
|
||||
FROM
|
||||
movies m
|
||||
JOIN genres_movies gm ON gm.movies_id = m.id
|
||||
WHERE
|
||||
gm.genres_id = g.id) AS movies,
|
||||
(
|
||||
SELECT
|
||||
json_agg(json_build_object('title', p.title, 'date', p.date, 'url', p.slug)
|
||||
ORDER BY p.date DESC)
|
||||
FROM
|
||||
posts_genres pg
|
||||
LEFT JOIN posts p ON pg.posts_id = p.id
|
||||
WHERE
|
||||
pg.genres_id = g.id) AS posts
|
||||
FROM
|
||||
genres g
|
||||
ORDER BY
|
||||
g.id ASC;
|
||||
|
19
queries/views/media/music/latest-listen.psql
Normal file
19
queries/views/media/music/latest-listen.psql
Normal file
|
@ -0,0 +1,19 @@
|
|||
CREATE OR REPLACE VIEW optimized_latest_listen AS
|
||||
SELECT
|
||||
l.track_name::TEXT AS track_name,
|
||||
l.artist_name::TEXT AS artist_name,
|
||||
a.emoji::TEXT AS artist_emoji,
|
||||
g.emoji::TEXT AS genre_emoji,
|
||||
a.slug::TEXT AS url,
|
||||
NULL::FLOAT AS total_duration,
|
||||
NULL::FLOAT AS progress_ticks
|
||||
FROM
|
||||
listens l
|
||||
JOIN
|
||||
artists a
|
||||
ON l.artist_name = a.name_string
|
||||
LEFT JOIN
|
||||
genres g
|
||||
ON a.genres = g.id
|
||||
ORDER BY l.listened_at DESC
|
||||
LIMIT 1;
|
28
queries/views/media/music/listens.psql
Normal file
28
queries/views/media/music/listens.psql
Normal file
|
@ -0,0 +1,28 @@
|
|||
CREATE OR REPLACE VIEW optimized_listens AS SELECT DISTINCT ON (l.id, l.listened_at, l.track_name, l.artist_name, l.album_name)
|
||||
l.id,
|
||||
l.listened_at,
|
||||
l.track_name,
|
||||
l.artist_name,
|
||||
l.album_name,
|
||||
l.album_key,
|
||||
CONCAT('/', df_art.filename_disk) AS artist_art,
|
||||
a.genres AS artist_genres,
|
||||
g.name AS genre_name,
|
||||
g.slug AS genre_url,
|
||||
a.country AS artist_country,
|
||||
a.slug AS artist_url,
|
||||
CONCAT('/', df_album.filename_disk) AS album_art
|
||||
FROM
|
||||
listens l
|
||||
LEFT JOIN artists a ON (l.artist_name = a.name_string)
|
||||
LEFT JOIN albums al ON (l.album_key = al.key)
|
||||
LEFT JOIN directus_files df_art ON (a.art = df_art.id)
|
||||
LEFT JOIN directus_files df_album ON (al.art = df_album.id)
|
||||
LEFT JOIN genres g ON (a.genres = g.id)
|
||||
ORDER BY
|
||||
l.id,
|
||||
l.listened_at,
|
||||
l.track_name,
|
||||
l.artist_name,
|
||||
l.album_name;
|
||||
|
20
queries/views/media/music/month/albums.psql
Normal file
20
queries/views/media/music/month/albums.psql
Normal file
|
@ -0,0 +1,20 @@
|
|||
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;
|
||||
|
19
queries/views/media/music/month/artists.psql
Normal file
19
queries/views/media/music/month/artists.psql
Normal file
|
@ -0,0 +1,19 @@
|
|||
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;
|
||||
|
16
queries/views/media/music/month/genres.psql
Normal file
16
queries/views/media/music/month/genres.psql
Normal file
|
@ -0,0 +1,16 @@
|
|||
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;
|
||||
|
37
queries/views/media/music/month/tracks.psql
Normal file
37
queries/views/media/music/month/tracks.psql
Normal 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;
|
||||
|
23
queries/views/media/music/recent-tracks.psql
Normal file
23
queries/views/media/music/recent-tracks.psql
Normal file
|
@ -0,0 +1,23 @@
|
|||
CREATE OR REPLACE VIEW recent_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,
|
||||
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
|
||||
TO_TIMESTAMP(ol.listened_at) >= NOW() - INTERVAL '7 days'
|
||||
ORDER BY
|
||||
TO_TIMESTAMP(ol.listened_at) DESC;
|
||||
|
20
queries/views/media/music/week/albums.psql
Normal file
20
queries/views/media/music/week/albums.psql
Normal file
|
@ -0,0 +1,20 @@
|
|||
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;
|
||||
|
18
queries/views/media/music/week/artists.psql
Normal file
18
queries/views/media/music/week/artists.psql
Normal file
|
@ -0,0 +1,18 @@
|
|||
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;
|
16
queries/views/media/music/week/genres.psql
Normal file
16
queries/views/media/music/week/genres.psql
Normal file
|
@ -0,0 +1,16 @@
|
|||
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;
|
||||
|
46
queries/views/media/music/week/tracks.psql
Normal file
46
queries/views/media/music/week/tracks.psql
Normal file
|
@ -0,0 +1,46 @@
|
|||
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,
|
||||
RANK() OVER (ORDER BY COUNT(*) DESC, MAX(ol.listened_at) DESC) AS rank
|
||||
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),
|
||||
'rank', rank
|
||||
) AS chart
|
||||
FROM
|
||||
track_stats
|
||||
ORDER BY
|
||||
plays DESC,
|
||||
last_listened DESC;
|
248
queries/views/media/recent-media.psql
Normal file
248
queries/views/media/recent-media.psql
Normal file
|
@ -0,0 +1,248 @@
|
|||
CREATE OR REPLACE VIEW optimized_recent_media AS
|
||||
WITH ordered_artists AS (
|
||||
SELECT
|
||||
wa.artist_name,
|
||||
wa.artist_art,
|
||||
wa.artist_url,
|
||||
wa.plays,
|
||||
json_build_object(
|
||||
'title', wa.artist_name,
|
||||
'image', wa.artist_art,
|
||||
'url', wa.artist_url,
|
||||
'alt', CONCAT(wa.plays, ' plays of ', wa.artist_name),
|
||||
'subtext', CONCAT(wa.plays, ' plays')
|
||||
) AS grid
|
||||
FROM week_artists wa
|
||||
ORDER BY wa.plays DESC, wa.artist_name ASC
|
||||
),
|
||||
ordered_albums AS (
|
||||
SELECT
|
||||
wa.album_name,
|
||||
wa.album_art,
|
||||
wa.artist_name,
|
||||
wa.artist_url,
|
||||
wa.plays,
|
||||
json_build_object(
|
||||
'title', wa.album_name,
|
||||
'image', wa.album_art,
|
||||
'url', wa.artist_url,
|
||||
'alt', CONCAT(wa.album_name, ' by ', wa.artist_name, ' (', wa.plays, ' plays)'),
|
||||
'subtext', wa.artist_name
|
||||
) AS grid
|
||||
FROM week_albums wa
|
||||
ORDER BY wa.plays DESC, wa.album_name ASC
|
||||
),
|
||||
recent_music AS (
|
||||
SELECT * FROM (
|
||||
(
|
||||
SELECT
|
||||
artist_name AS title,
|
||||
artist_art AS image,
|
||||
artist_url AS url,
|
||||
'music' AS type,
|
||||
1 AS rank,
|
||||
grid
|
||||
FROM ordered_artists
|
||||
LIMIT 1
|
||||
)
|
||||
UNION ALL
|
||||
(
|
||||
SELECT
|
||||
album_name AS title,
|
||||
album_art AS image,
|
||||
artist_url AS url,
|
||||
'music' AS type,
|
||||
2 AS rank,
|
||||
grid
|
||||
FROM ordered_albums
|
||||
LIMIT 1
|
||||
)
|
||||
UNION ALL
|
||||
(
|
||||
SELECT
|
||||
artist_name AS title,
|
||||
artist_art AS image,
|
||||
artist_url AS url,
|
||||
'music' AS type,
|
||||
3 AS rank,
|
||||
grid
|
||||
FROM ordered_artists
|
||||
OFFSET 1 LIMIT 1
|
||||
)
|
||||
UNION ALL
|
||||
(
|
||||
SELECT
|
||||
album_name AS title,
|
||||
album_art AS image,
|
||||
artist_url AS url,
|
||||
'music' AS type,
|
||||
4 AS rank,
|
||||
grid
|
||||
FROM ordered_albums
|
||||
OFFSET 1 LIMIT 1
|
||||
)
|
||||
) AS recent_music_subquery
|
||||
),
|
||||
recent_watched_read AS (
|
||||
SELECT * FROM (
|
||||
(
|
||||
SELECT
|
||||
om.title,
|
||||
om.image,
|
||||
om.url,
|
||||
'tv' AS type,
|
||||
1 AS rank,
|
||||
json_build_object(
|
||||
'title', null,
|
||||
'url', om.url,
|
||||
'image', om.image,
|
||||
'backdrop', om.backdrop,
|
||||
'alt', CONCAT('Poster from ', om.title, ' (', om.year, ')'),
|
||||
'subtext', CASE WHEN om.rating IS NOT NULL THEN
|
||||
om.rating::text
|
||||
ELSE
|
||||
om.year::text
|
||||
END
|
||||
) AS grid
|
||||
FROM optimized_movies om
|
||||
WHERE om.last_watched IS NOT NULL
|
||||
ORDER BY om.last_watched DESC, om.title ASC
|
||||
LIMIT 1
|
||||
)
|
||||
UNION ALL
|
||||
(
|
||||
SELECT
|
||||
os.title,
|
||||
os.image,
|
||||
os.url,
|
||||
'tv' AS type,
|
||||
2 AS rank,
|
||||
json_build_object(
|
||||
'title', null,
|
||||
'image', os.image,
|
||||
'url', os.url,
|
||||
'alt', CONCAT('Poster from ', os.title),
|
||||
'subtext', (
|
||||
SELECT CONCAT('S', e.season_number, 'E', e.episode_number)
|
||||
FROM episodes e
|
||||
WHERE e.show = os.id
|
||||
ORDER BY e.last_watched_at DESC, e.season_number DESC, e.episode_number DESC
|
||||
LIMIT 1
|
||||
)
|
||||
) AS grid
|
||||
FROM optimized_shows os
|
||||
WHERE os.last_watched_at IS NOT NULL
|
||||
ORDER BY os.last_watched_at DESC, os.title ASC
|
||||
LIMIT 1
|
||||
)
|
||||
UNION ALL
|
||||
(
|
||||
SELECT
|
||||
ob.title,
|
||||
ob.image,
|
||||
ob.url,
|
||||
'books' AS type,
|
||||
3 AS rank,
|
||||
json_build_object(
|
||||
'title', null,
|
||||
'image', ob.image,
|
||||
'url', ob.url,
|
||||
'alt', CONCAT('Book cover from ', ob.title, ' by ', ob.author),
|
||||
'subtext', CASE WHEN ob.rating IS NOT NULL THEN
|
||||
ob.rating
|
||||
ELSE
|
||||
NULL
|
||||
END
|
||||
) AS grid
|
||||
FROM optimized_books ob
|
||||
WHERE ob.status = 'finished'
|
||||
ORDER BY ob.date_finished DESC, ob.title ASC
|
||||
LIMIT 1
|
||||
)
|
||||
UNION ALL
|
||||
(
|
||||
SELECT
|
||||
om.title,
|
||||
om.image,
|
||||
om.url,
|
||||
'tv' AS type,
|
||||
4 AS rank,
|
||||
json_build_object(
|
||||
'title', null,
|
||||
'url', om.url,
|
||||
'image', om.image,
|
||||
'backdrop', om.backdrop,
|
||||
'alt', CONCAT('Poster from ', om.title, ' (', om.year, ')'),
|
||||
'subtext', CASE WHEN om.rating IS NOT NULL THEN
|
||||
om.rating::text
|
||||
ELSE
|
||||
om.year::text
|
||||
END
|
||||
) AS grid
|
||||
FROM optimized_movies om
|
||||
WHERE om.last_watched IS NOT NULL
|
||||
ORDER BY om.last_watched DESC, om.title ASC
|
||||
OFFSET 1 LIMIT 1
|
||||
)
|
||||
UNION ALL
|
||||
(
|
||||
SELECT
|
||||
os.title,
|
||||
os.image,
|
||||
os.url,
|
||||
'tv' AS type,
|
||||
5 AS rank,
|
||||
json_build_object(
|
||||
'title', null,
|
||||
'image', os.image,
|
||||
'url', os.url,
|
||||
'alt', CONCAT('Poster from ', os.title),
|
||||
'subtext', (
|
||||
SELECT CONCAT('S', e.season_number, 'E', e.episode_number)
|
||||
FROM episodes e
|
||||
WHERE e.show = os.id
|
||||
ORDER BY e.last_watched_at DESC, e.season_number DESC, e.episode_number DESC
|
||||
LIMIT 1
|
||||
)
|
||||
) AS grid
|
||||
FROM optimized_shows os
|
||||
WHERE os.last_watched_at IS NOT NULL
|
||||
ORDER BY os.last_watched_at DESC, os.title ASC
|
||||
OFFSET 1 LIMIT 1
|
||||
)
|
||||
UNION ALL
|
||||
(
|
||||
SELECT
|
||||
ob.title,
|
||||
ob.image,
|
||||
ob.url,
|
||||
'books' AS type,
|
||||
6 AS rank,
|
||||
json_build_object(
|
||||
'title', null,
|
||||
'image', ob.image,
|
||||
'url', ob.url,
|
||||
'alt', CONCAT('Book cover from ', ob.title, ' by ', ob.author),
|
||||
'subtext', CASE WHEN ob.rating IS NOT NULL THEN
|
||||
ob.rating
|
||||
ELSE
|
||||
NULL
|
||||
END
|
||||
) AS grid
|
||||
FROM optimized_books ob
|
||||
WHERE ob.status = 'finished'
|
||||
ORDER BY ob.date_finished DESC, ob.title ASC
|
||||
OFFSET 1 LIMIT 1
|
||||
)
|
||||
) AS recent_watched_read_subquery
|
||||
)
|
||||
SELECT json_build_object(
|
||||
'recentMusic', (
|
||||
SELECT json_agg(m.* ORDER BY m.rank)
|
||||
FROM recent_music m
|
||||
),
|
||||
'recentWatchedRead', (
|
||||
SELECT json_agg(w.* ORDER BY w.rank)
|
||||
FROM recent_watched_read w
|
||||
)
|
||||
) AS recent_activity;
|
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