feat: initial commit

This commit is contained in:
Cory Dransfeldt 2025-03-27 16:46:02 -07:00
commit e214116e40
No known key found for this signature in database
253 changed files with 17406 additions and 0 deletions

View 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;

View 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;

View 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;

View 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;

View 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;

View 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;

View 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;

View 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;

View 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;

View 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;