feat: initial view queries

This commit is contained in:
Cory Dransfeldt 2024-10-12 13:07:26 -07:00
parent 8f44ce9bdd
commit 08e2c2ff3f
No known key found for this signature in database
23 changed files with 1282 additions and 10 deletions

View file

@ -0,0 +1,89 @@
CREATE OR REPLACE VIEW optimized_all_activity AS
WITH feed_data AS (
SELECT
p.date AS content_date,
'post' AS content_type,
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,
'link' AS content_type,
CONCAT(l.title, ' via ', l.name) AS title,
l.description,
l.link AS url,
NULL AS image,
NULL AS rating,
l.tags,
json_build_object(
'title', CONCAT(l.title, ' via ', l.name),
'url', l.link,
'description', l.description,
'date', l.date
) AS feed
FROM optimized_links l
UNION ALL
SELECT
b.date_finished AS content_date,
'book' AS content_type,
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,
'movie' AS content_type,
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 feed_data;

94
views/feeds/search.psql Normal file
View file

@ -0,0 +1,94 @@
CREATE OR REPLACE VIEW optimized_search_index AS
WITH search_data AS (
SELECT
'post' AS content_type,
CONCAT('📝 ', p.title) AS title,
CONCAT('https://coryd.dev', p.url) AS url,
p.tags,
NULL AS genre_name,
NULL AS genre_url
FROM optimized_posts p
UNION ALL
SELECT
'link' AS content_type,
CONCAT('🔗 ', l.title, ' via ', l.name) AS title,
l.link AS url,
l.tags,
NULL AS genre_name,
NULL AS genre_url
FROM optimized_links l
UNION ALL
SELECT
'book' AS content_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.tags,
NULL AS genre_name,
NULL AS genre_url
FROM optimized_books b
WHERE LOWER(b.status) = 'finished'
UNION ALL
SELECT
'movie' AS content_type,
CASE
WHEN m.rating IS NOT NULL THEN CONCAT('🎥 ', m.title, ' (', m.rating, ')') -- Add emoji and rating for movies
ELSE CONCAT('🎥 ', m.title)
END AS title,
CONCAT('https://coryd.dev', m.url) AS url,
m.tags,
NULL AS genre_name,
NULL AS genre_url
FROM optimized_movies m
WHERE m.last_watched IS NOT NULL
UNION ALL
SELECT
'artist' AS content_type,
CONCAT('🎧 ', ar.name, ' - ', ar.genre_name) AS title,
CONCAT('https://coryd.dev', ar.url) AS url,
ARRAY[ar.genre_name] AS tags,
ar.genre_name,
CONCAT('https://coryd.dev', ar.genre_slug) AS genre_url
FROM optimized_artists ar
UNION ALL
SELECT
'genre' AS content_type,
CONCAT('🎵 ', g.name) AS title,
CONCAT('https://coryd.dev', g.url) AS url,
NULL AS tags,
g.name AS genre_name,
CONCAT('https://coryd.dev', g.url) AS genre_url
FROM optimized_genres g
),
search_data_with_id AS (
SELECT
ROW_NUMBER() OVER (ORDER BY url) AS id,
search_data.*
FROM search_data
)
SELECT
json_agg(
json_build_object(
'id', search_data_with_id.id,
'url', search_data_with_id.url,
'title', search_data_with_id.title,
'tags', search_data_with_id.tags,
'genre_name', search_data_with_id.genre_name,
'genre_url', search_data_with_id.genre_url
)
) AS search_index
FROM search_data_with_id;

57
views/feeds/sitemap.psql Normal file
View file

@ -0,0 +1,57 @@
CREATE OR REPLACE VIEW optimized_sitemap AS
WITH sitemap_data AS (
SELECT
p.date AS content_date,
'post' AS content_type,
p.title,
CONCAT('https://coryd.dev', p.url) AS url
FROM optimized_posts p
UNION ALL
SELECT
b.date_finished AS content_date,
'book' AS content_type,
b.title,
CONCAT('https://coryd.dev', b.url) AS url
FROM optimized_books b
WHERE LOWER(b.status) = 'finished'
UNION ALL
SELECT
m.last_watched AS content_date,
'movie' AS content_type,
m.title,
CONCAT('https://coryd.dev', m.url) AS url
FROM optimized_movies m
WHERE m.last_watched IS NOT NULL
UNION ALL
SELECT
NULL AS content_date,
'artist' AS content_type,
ar.name AS title,
CONCAT('https://coryd.dev', ar.url) AS url
FROM optimized_artists ar
UNION ALL
SELECT
NULL AS content_date,
'genre' AS content_type,
g.name AS title,
CONCAT('https://coryd.dev', g.url) AS url
FROM optimized_genres g
)
SELECT
json_agg(
json_build_object(
'url', sd.url,
'title', sd.title,
'date', sd.content_date
)
) AS sitemap
FROM sitemap_data sd;

View file

@ -0,0 +1,103 @@
CREATE OR REPLACE VIEW optimized_syndication AS
WITH syndication_data AS (
SELECT
p.date AS content_date,
'post' AS content_type,
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,
'link' AS content_type,
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 ''
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,
'book' AS content_type,
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,
'movie' AS content_type,
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(syndication_data.* ORDER BY syndication_data.content_date DESC) AS syndication
FROM syndication_data;