chore: search cleanup
This commit is contained in:
parent
19d17f70d2
commit
fca18da3f7
36 changed files with 71 additions and 60 deletions
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 integer,
|
||||
rank real
|
||||
) 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
|
||||
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 rank DESC
|
||||
LIMIT page_size OFFSET page_offset;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
36
queries/views/content/links.psql
Normal file
36
queries/views/content/links.psql
Normal file
|
@ -0,0 +1,36 @@
|
|||
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
|
||||
ORDER BY
|
||||
l.date DESC;
|
152
queries/views/content/posts.psql
Normal file
152
queries/views/content/posts.psql
Normal file
|
@ -0,0 +1,152 @@
|
|||
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 = '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
|
||||
)
|
||||
WHEN pb.collection = 'divider' THEN json_build_object(
|
||||
'type', pb.collection,
|
||||
'markup', d.markup
|
||||
)
|
||||
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 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
|
||||
LEFT JOIN divider d ON pb.collection = 'divider' AND d.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
|
||||
))
|
||||
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
|
||||
))
|
||||
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)
|
||||
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
|
||||
))
|
||||
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', CONCAT('https://coryd.dev', p.slug),
|
||||
'description', 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;
|
91
queries/views/feeds/all-content.psql
Normal file
91
queries/views/feeds/all-content.psql
Normal file
|
@ -0,0 +1,91 @@
|
|||
CREATE OR REPLACE VIEW optimized_all_activity AS
|
||||
WITH feed_data AS (
|
||||
SELECT
|
||||
p.date AS content_date,
|
||||
p.title,
|
||||
p.description,
|
||||
CONCAT('https://coryd.dev', p.url) AS url,
|
||||
NULL AS image,
|
||||
NULL AS rating,
|
||||
p.tags,
|
||||
json_build_object(
|
||||
'title', p.title,
|
||||
'url', CONCAT('https://coryd.dev', p.url),
|
||||
'description', p.description,
|
||||
'date', p.date
|
||||
) AS feed
|
||||
FROM optimized_posts p
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
l.date AS content_date,
|
||||
l.title,
|
||||
l.description,
|
||||
l.link AS url,
|
||||
NULL AS image,
|
||||
NULL AS rating,
|
||||
l.tags,
|
||||
json_build_object(
|
||||
'title', l.title,
|
||||
'url', l.link,
|
||||
'description', l.description,
|
||||
'date', l.date
|
||||
) AS feed
|
||||
FROM optimized_links l
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
b.date_finished AS content_date,
|
||||
b.title,
|
||||
b.description,
|
||||
CONCAT('https://coryd.dev', b.url) AS url,
|
||||
b.image,
|
||||
b.rating,
|
||||
b.tags,
|
||||
CASE
|
||||
WHEN LOWER(b.status) = 'finished' THEN json_build_object(
|
||||
'title', b.title,
|
||||
'url', CONCAT('https://coryd.dev', b.url),
|
||||
'description', b.description,
|
||||
'image', b.image,
|
||||
'rating', b.rating,
|
||||
'date', b.date_finished
|
||||
)
|
||||
ELSE NULL
|
||||
END AS feed
|
||||
FROM optimized_books b
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
m.last_watched AS content_date,
|
||||
m.title,
|
||||
m.description,
|
||||
CONCAT('https://coryd.dev', m.url) AS url,
|
||||
m.image,
|
||||
m.rating,
|
||||
m.tags,
|
||||
CASE
|
||||
WHEN m.last_watched IS NOT NULL THEN json_build_object(
|
||||
'title', m.title,
|
||||
'url', CONCAT('https://coryd.dev', m.url),
|
||||
'description', m.description,
|
||||
'image', m.image,
|
||||
'rating', m.rating,
|
||||
'date', m.last_watched
|
||||
)
|
||||
ELSE NULL
|
||||
END AS feed
|
||||
FROM optimized_movies m
|
||||
)
|
||||
|
||||
SELECT json_agg(feed_data.* ORDER BY feed_data.content_date DESC) AS feed
|
||||
FROM (
|
||||
SELECT *
|
||||
FROM feed_data
|
||||
WHERE feed IS NOT NULL
|
||||
ORDER BY content_date DESC
|
||||
LIMIT 20
|
||||
) AS feed_data;
|
97
queries/views/feeds/search.psql
Normal file
97
queries/views/feeds/search.psql
Normal file
|
@ -0,0 +1,97 @@
|
|||
CREATE OR REPLACE VIEW optimized_search_index AS
|
||||
WITH search_data AS (
|
||||
SELECT
|
||||
'post' AS type,
|
||||
CONCAT('📝 ', p.title) AS title,
|
||||
CONCAT('https://coryd.dev', p.url) AS url,
|
||||
p.description AS description,
|
||||
p.tags,
|
||||
NULL AS genre_name,
|
||||
NULL AS genre_url,
|
||||
NULL::integer 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 AS url,
|
||||
l.description AS description,
|
||||
l.tags,
|
||||
NULL AS genre_name,
|
||||
NULL AS genre_url,
|
||||
NULL::integer 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,
|
||||
CONCAT('https://coryd.dev', b.url) AS url,
|
||||
b.description AS description,
|
||||
b.tags,
|
||||
NULL AS genre_name,
|
||||
NULL AS genre_url,
|
||||
NULL::integer 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,
|
||||
CONCAT('https://coryd.dev', ar.url) AS url,
|
||||
ar.description AS description,
|
||||
ARRAY[ar.genre_name] AS tags,
|
||||
ar.genre_name,
|
||||
CONCAT('https://coryd.dev', ar.genre_slug) AS genre_url,
|
||||
ar.total_plays,
|
||||
NULL AS content_date
|
||||
FROM optimized_artists ar
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
'genre' AS type,
|
||||
CONCAT(COALESCE(g.emoji, '🎵'), ' ', g.name) AS title,
|
||||
CONCAT('https://coryd.dev', g.url) AS url,
|
||||
g.description AS description,
|
||||
NULL AS tags,
|
||||
g.name AS genre_name,
|
||||
CONCAT('https://coryd.dev', g.url) AS genre_url,
|
||||
NULL::integer AS total_plays,
|
||||
NULL AS content_date
|
||||
FROM optimized_genres g
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
'show' AS type,
|
||||
CASE
|
||||
WHEN s.review IS NOT NULL THEN CONCAT('📺 ', s.title, ' (', s.year, ') - ', s.review)
|
||||
ELSE CONCAT('📺 ', s.title, ' (', s.year, ')')
|
||||
END AS title,
|
||||
CONCAT('https://coryd.dev', s.url) AS url,
|
||||
s.description AS description,
|
||||
s.tags,
|
||||
NULL AS genre_name,
|
||||
NULL AS genre_url,
|
||||
NULL::integer AS total_plays,
|
||||
s.last_watched_at AS content_date
|
||||
FROM optimized_shows s
|
||||
WHERE s.last_watched_at IS NOT NULL
|
||||
)
|
||||
|
||||
SELECT
|
||||
ROW_NUMBER() OVER (ORDER BY url) AS id,
|
||||
*
|
||||
FROM search_data;
|
68
queries/views/feeds/sitemap.psql
Normal file
68
queries/views/feeds/sitemap.psql
Normal file
|
@ -0,0 +1,68 @@
|
|||
CREATE OR REPLACE VIEW optimized_sitemap AS
|
||||
WITH sitemap_data AS (
|
||||
SELECT
|
||||
p.date AS content_date,
|
||||
p.title,
|
||||
CONCAT('https://coryd.dev', p.url) AS url,
|
||||
'monthly' AS changefreq,
|
||||
0.7 AS priority
|
||||
FROM optimized_posts p
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
b.date_finished AS content_date,
|
||||
b.title,
|
||||
CONCAT('https://coryd.dev', b.url) AS url,
|
||||
'monthly' AS changefreq,
|
||||
0.5 AS priority
|
||||
FROM optimized_books b
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
m.last_watched AS content_date,
|
||||
m.title,
|
||||
CONCAT('https://coryd.dev', m.url) AS url,
|
||||
'weekly' AS changefreq,
|
||||
0.6 AS priority
|
||||
FROM optimized_movies m
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
NULL AS content_date,
|
||||
ar.name AS title,
|
||||
CONCAT('https://coryd.dev', ar.url) AS url,
|
||||
'monthly' AS changefreq,
|
||||
0.5 AS priority
|
||||
FROM optimized_artists ar
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
NULL AS content_date,
|
||||
g.name AS title,
|
||||
CONCAT('https://coryd.dev', g.url) AS url,
|
||||
'yearly' AS changefreq,
|
||||
0.3 AS priority
|
||||
FROM optimized_genres g
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
s.last_watched_at AS content_date,
|
||||
s.title,
|
||||
CONCAT('https://coryd.dev', s.url) AS url,
|
||||
'weekly' AS changefreq,
|
||||
0.8 AS priority
|
||||
FROM optimized_shows s
|
||||
)
|
||||
|
||||
SELECT
|
||||
url,
|
||||
title,
|
||||
content_date AS lastmod,
|
||||
changefreq,
|
||||
priority
|
||||
FROM sitemap_data;
|
105
queries/views/feeds/syndication.psql
Normal file
105
queries/views/feeds/syndication.psql
Normal file
|
@ -0,0 +1,105 @@
|
|||
CREATE OR REPLACE VIEW optimized_syndication AS
|
||||
WITH syndication_data AS (
|
||||
SELECT
|
||||
p.date AS content_date,
|
||||
p.title,
|
||||
p.description,
|
||||
CONCAT('https://coryd.dev', p.url) AS url,
|
||||
p.tags,
|
||||
json_build_object(
|
||||
'title', CONCAT('📝 ', p.title, ' ', (
|
||||
SELECT array_to_string(
|
||||
array_agg('#' || initcap(replace(t.name, ' ', ''))), ' '
|
||||
)
|
||||
FROM unnest(p.tags) AS t(name)
|
||||
)),
|
||||
'description', p.description,
|
||||
'url', CONCAT('https://coryd.dev', p.url),
|
||||
'date', p.date
|
||||
) AS syndication
|
||||
FROM optimized_posts p
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
l.date AS content_date,
|
||||
l.title,
|
||||
l.description,
|
||||
l.link AS url,
|
||||
l.tags,
|
||||
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(t.name, ' ', ''))), ' '
|
||||
)
|
||||
FROM unnest(l.tags) AS t(name)
|
||||
)
|
||||
),
|
||||
'description', l.description,
|
||||
'url', l.link,
|
||||
'date', l.date
|
||||
) AS syndication
|
||||
FROM optimized_links l
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
b.date_finished AS content_date,
|
||||
b.title,
|
||||
b.description,
|
||||
CONCAT('https://coryd.dev', b.url) AS url,
|
||||
b.tags,
|
||||
CASE
|
||||
WHEN LOWER(b.status) = 'finished' THEN json_build_object(
|
||||
'title', CONCAT('📖 ', b.title, ' ', (
|
||||
SELECT array_to_string(
|
||||
array_agg('#' || initcap(replace(t.name, ' ', ''))), ' '
|
||||
)
|
||||
FROM unnest(b.tags) AS t(name)
|
||||
)),
|
||||
'description', b.description,
|
||||
'url', CONCAT('https://coryd.dev', b.url),
|
||||
'date', b.date_finished
|
||||
)
|
||||
ELSE NULL
|
||||
END AS syndication
|
||||
FROM optimized_books b
|
||||
|
||||
UNION ALL
|
||||
|
||||
SELECT
|
||||
m.last_watched AS content_date,
|
||||
m.title,
|
||||
m.description,
|
||||
CONCAT('https://coryd.dev', m.url) AS url,
|
||||
m.tags,
|
||||
CASE
|
||||
WHEN m.last_watched IS NOT NULL THEN json_build_object(
|
||||
'title', CONCAT('🎥 ', m.title, ' ', (
|
||||
SELECT array_to_string(
|
||||
array_agg('#' || initcap(replace(t.name, ' ', ''))), ' '
|
||||
)
|
||||
FROM unnest(m.tags) AS t(name)
|
||||
)),
|
||||
'description', m.description,
|
||||
'url', CONCAT('https://coryd.dev', m.url),
|
||||
'date', m.last_watched
|
||||
)
|
||||
ELSE NULL
|
||||
END AS syndication
|
||||
FROM optimized_movies m
|
||||
)
|
||||
|
||||
SELECT json_agg(limited_data.*) AS syndication
|
||||
FROM (
|
||||
SELECT *
|
||||
FROM syndication_data
|
||||
WHERE syndication IS NOT NULL
|
||||
ORDER BY content_date DESC
|
||||
LIMIT 20
|
||||
) AS limited_data;
|
22
queries/views/globals/index.psql
Normal file
22
queries/views/globals/index.psql
Normal file
|
@ -0,0 +1,22 @@
|
|||
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.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;
|
63
queries/views/globals/pages.psql
Normal file
63
queries/views/globals/pages.psql
Normal file
|
@ -0,0 +1,63 @@
|
|||
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 = '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
|
||||
)
|
||||
WHEN pb.collection = 'divider' THEN json_build_object(
|
||||
'type', pb.collection,
|
||||
'markup', d.markup
|
||||
)
|
||||
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 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
|
||||
LEFT JOIN divider d ON pb.collection = 'divider' AND d.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;
|
120
queries/views/media/books.psql
Normal file
120
queries/views/media/books.psql
Normal file
|
@ -0,0 +1,120 @@
|
|||
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
|
||||
))
|
||||
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
|
||||
))
|
||||
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
|
||||
))
|
||||
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
|
||||
))
|
||||
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)
|
||||
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', 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 b.star_rating
|
||||
ELSE NULL
|
||||
END
|
||||
) AS grid,
|
||||
|
||||
CASE
|
||||
WHEN LOWER(b.read_status) = 'finished' AND b.star_rating IS NOT NULL THEN json_build_object(
|
||||
'title', b.title,
|
||||
'url', CONCAT('https://coryd.dev', b.slug),
|
||||
'date', b.date_finished,
|
||||
'description', b.description,
|
||||
'image', CONCAT('/', df.filename_disk),
|
||||
'rating', b.star_rating
|
||||
)
|
||||
ELSE NULL
|
||||
END AS feed
|
||||
|
||||
FROM
|
||||
books b
|
||||
LEFT JOIN
|
||||
directus_files df ON b.art = df.id
|
||||
GROUP BY
|
||||
b.id, df.filename_disk;
|
125
queries/views/media/movies.psql
Normal file
125
queries/views/media/movies.psql
Normal file
|
@ -0,0 +1,125 @@
|
|||
CREATE OR REPLACE VIEW optimized_movies AS
|
||||
SELECT
|
||||
m.id,
|
||||
m.last_watched,
|
||||
m.title,
|
||||
m.year,
|
||||
m.collected,
|
||||
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', 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.star_rating, ' (', m.year, ')')
|
||||
ELSE CONCAT('(', m.year, ')')
|
||||
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', m.title,
|
||||
'url', CONCAT('https://coryd.dev/movies/', m.slug),
|
||||
'date', m.last_watched,
|
||||
'description', 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;
|
33
queries/views/media/music/album-releases.psql
Normal file
33
queries/views/media/music/album-releases.psql
Normal file
|
@ -0,0 +1,33 @@
|
|||
CREATE OR REPLACE VIEW optimized_album_releases AS
|
||||
SELECT
|
||||
a.name AS title,
|
||||
a.release_date,
|
||||
a.release_link AS url,
|
||||
a.total_plays,
|
||||
CONCAT('/', df.filename_disk) AS image,
|
||||
'album-release' AS type,
|
||||
|
||||
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', a.release_link,
|
||||
'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;
|
118
queries/views/media/music/artists.psql
Normal file
118
queries/views/media/music/artists.psql
Normal file
|
@ -0,0 +1,118 @@
|
|||
CREATE OR REPLACE VIEW optimized_artists AS
|
||||
SELECT
|
||||
ar.name_string AS name,
|
||||
ar.slug AS url,
|
||||
ar.tentative,
|
||||
ar.total_plays,
|
||||
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(
|
||||
'alt', CONCAT(ar.total_plays, ' plays of ', ar.name_string),
|
||||
'subtext', CONCAT(ar.total_plays, ' plays')
|
||||
) AS grid,
|
||||
|
||||
(
|
||||
SELECT json_agg(json_build_object(
|
||||
'name', a.name,
|
||||
'release_year', a.release_year,
|
||||
'total_plays', a.total_plays,
|
||||
'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.date_finished DESC)
|
||||
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', related_ar.total_plays
|
||||
) 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;
|
36
queries/views/media/music/concerts.psql
Normal file
36
queries/views/media/music/concerts.psql
Normal file
|
@ -0,0 +1,36 @@
|
|||
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;
|
56
queries/views/media/music/genres.psql
Normal file
56
queries/views/media/music/genres.psql
Normal file
|
@ -0,0 +1,56 @@
|
|||
CREATE OR REPLACE VIEW optimized_genres AS
|
||||
SELECT
|
||||
g.id,
|
||||
g.name,
|
||||
g.description,
|
||||
g.emoji,
|
||||
g.total_plays,
|
||||
g.wiki_link,
|
||||
g.slug AS url,
|
||||
|
||||
(
|
||||
SELECT json_agg(json_build_object(
|
||||
'name', a.name_string,
|
||||
'url', a.slug,
|
||||
'total_plays', a.total_plays
|
||||
) ORDER BY a.total_plays DESC)
|
||||
FROM artists a
|
||||
WHERE a.genres = g.id
|
||||
) AS artists,
|
||||
|
||||
(
|
||||
SELECT json_agg(json_build_object(
|
||||
'title', b.title,
|
||||
'author', b.author,
|
||||
'url', b.slug
|
||||
))
|
||||
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;
|
24
queries/views/media/music/listens.psql
Normal file
24
queries/views/media/music/listens.psql
Normal file
|
@ -0,0 +1,24 @@
|
|||
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;
|
22
queries/views/media/music/month/albums.psql
Normal file
22
queries/views/media/music/month/albums.psql
Normal 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;
|
22
queries/views/media/music/month/artists.psql
Normal file
22
queries/views/media/music/month/artists.psql
Normal 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;
|
17
queries/views/media/music/month/genres.psql
Normal file
17
queries/views/media/music/month/genres.psql
Normal 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;
|
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;
|
24
queries/views/media/music/now-playing.psql
Normal file
24
queries/views/media/music/now-playing.psql
Normal file
|
@ -0,0 +1,24 @@
|
|||
CREATE VIEW optimized_latest_listen AS
|
||||
WITH latest_listen AS (
|
||||
SELECT
|
||||
l.track_name,
|
||||
l.artist_name,
|
||||
a.emoji AS artist_emoji,
|
||||
g.emoji AS genre_emoji,
|
||||
a.slug AS url,
|
||||
ROW_NUMBER() OVER (ORDER BY l.listened_at DESC) AS row_num
|
||||
FROM
|
||||
listens l
|
||||
JOIN artists a ON l.artist_name = a.name_string
|
||||
LEFT JOIN genres g ON a.genres = g.id
|
||||
)
|
||||
SELECT
|
||||
track_name,
|
||||
artist_name,
|
||||
artist_emoji,
|
||||
genre_emoji,
|
||||
url
|
||||
FROM
|
||||
latest_listen
|
||||
WHERE
|
||||
row_num = 1;
|
29
queries/views/media/music/recent-tracks.psql
Normal file
29
queries/views/media/music/recent-tracks.psql
Normal file
|
@ -0,0 +1,29 @@
|
|||
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;
|
22
queries/views/media/music/three-month/albums.psql
Normal file
22
queries/views/media/music/three-month/albums.psql
Normal 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;
|
22
queries/views/media/music/three-month/artists.psql
Normal file
22
queries/views/media/music/three-month/artists.psql
Normal 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;
|
17
queries/views/media/music/three-month/genres.psql
Normal file
17
queries/views/media/music/three-month/genres.psql
Normal 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;
|
37
queries/views/media/music/three-month/tracks.psql
Normal file
37
queries/views/media/music/three-month/tracks.psql
Normal 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;
|
22
queries/views/media/music/week/albums.psql
Normal file
22
queries/views/media/music/week/albums.psql
Normal 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;
|
22
queries/views/media/music/week/artists.psql
Normal file
22
queries/views/media/music/week/artists.psql
Normal 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;
|
17
queries/views/media/music/week/genres.psql
Normal file
17
queries/views/media/music/week/genres.psql
Normal 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;
|
37
queries/views/media/music/week/tracks.psql
Normal file
37
queries/views/media/music/week/tracks.psql
Normal 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;
|
131
queries/views/media/shows.psql
Normal file
131
queries/views/media/shows.psql
Normal file
|
@ -0,0 +1,131 @@
|
|||
CREATE OR REPLACE VIEW optimized_shows AS
|
||||
SELECT
|
||||
s.id,
|
||||
s.title,
|
||||
s.year,
|
||||
s.collected,
|
||||
s.favorite,
|
||||
s.tattoo,
|
||||
s.description,
|
||||
s.review,
|
||||
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(s.title, ' (', s.year, ')'),
|
||||
'subtext', COALESCE(
|
||||
(
|
||||
SELECT
|
||||
CASE
|
||||
WHEN e1.last_watched_at >= NOW() - INTERVAL '90 days' THEN
|
||||
CONCAT('S', e1.season_number, 'E', e1.episode_number)
|
||||
ELSE
|
||||
CONCAT('(', s.year::TEXT, ')')
|
||||
END
|
||||
FROM episodes e1
|
||||
WHERE e1.show = s.id
|
||||
ORDER BY e1.last_watched_at DESC, e1.season_number DESC, e1.episode_number DESC
|
||||
LIMIT 1
|
||||
),
|
||||
CONCAT('(', s.year::TEXT, ')')
|
||||
)
|
||||
) 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.season_number DESC, e2.episode_number DESC
|
||||
LIMIT 1)
|
||||
),
|
||||
'last_watched_at', MAX(e.last_watched_at)
|
||||
) 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)
|
||||
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)
|
||||
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;
|
Reference in a new issue