374 lines
9.3 KiB
SQL
374 lines
9.3 KiB
SQL
CREATE OR REPLACE VIEW optimized_posts AS
|
|
SELECT
|
|
p.id,
|
|
p.date,
|
|
p.title,
|
|
p.description,
|
|
p.content,
|
|
p.featured,
|
|
p.slug AS url,
|
|
CASE
|
|
WHEN df.filename_disk IS NOT NULL
|
|
AND df.filename_disk != ''
|
|
AND df.filename_disk != '/' THEN CONCAT(globals.cdn_url, '/', 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 = 'forgejo_banner' THEN json_build_object('type', pb.collection, 'url', fb.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 forgejo_banner fb ON pb.collection = 'forgejo_banner'
|
|
AND fb.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,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_artist.filename_disk),
|
|
'grid',
|
|
json_build_object(
|
|
'title',
|
|
a.name_string,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_artist.filename_disk),
|
|
'alt',
|
|
CONCAT(
|
|
to_char(a.total_plays, 'FM999,999,999,999'),
|
|
' plays of ',
|
|
a.name_string
|
|
),
|
|
'subtext',
|
|
CONCAT(
|
|
to_char(a.total_plays, 'FM999,999,999,999'),
|
|
' plays'
|
|
),
|
|
'url',
|
|
a.slug
|
|
),
|
|
'type',
|
|
'music'
|
|
)
|
|
ORDER BY
|
|
a.total_plays DESC
|
|
)
|
|
FROM
|
|
posts_artists pa
|
|
LEFT JOIN artists a ON pa.artists_id = a.id
|
|
LEFT JOIN directus_files df_artist ON a.art = df_artist.id
|
|
WHERE
|
|
pa.posts_id = p.id
|
|
AND a.total_plays IS NOT NULL
|
|
AND a.total_plays > 0
|
|
) AS artists,
|
|
(
|
|
SELECT
|
|
json_agg(
|
|
json_build_object(
|
|
'title',
|
|
b.title,
|
|
'author',
|
|
b.author,
|
|
'url',
|
|
b.slug,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_book.filename_disk),
|
|
'grid',
|
|
json_build_object(
|
|
'title',
|
|
NULL,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_book.filename_disk),
|
|
'alt',
|
|
CONCAT('Cover for ', b.title, ' by ', b.author),
|
|
'subtext',
|
|
CASE
|
|
WHEN b.star_rating IS NOT NULL THEN b.star_rating
|
|
ELSE NULL
|
|
END,
|
|
'url',
|
|
b.slug
|
|
),
|
|
'type',
|
|
'books'
|
|
)
|
|
ORDER BY
|
|
b.title ASC
|
|
)
|
|
FROM
|
|
posts_books pbk
|
|
LEFT JOIN books b ON pbk.books_id = b.id
|
|
LEFT JOIN directus_files df_book ON b.art = df_book.id
|
|
WHERE
|
|
pbk.posts_id = p.id
|
|
AND LOWER(b.read_status) = 'finished'
|
|
) AS books,
|
|
(
|
|
SELECT
|
|
json_agg(
|
|
json_build_object(
|
|
'title',
|
|
m.title,
|
|
'year',
|
|
m.year,
|
|
'url',
|
|
m.slug,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_movie.filename_disk),
|
|
'grid',
|
|
json_build_object(
|
|
'title',
|
|
NULL,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_movie.filename_disk),
|
|
'alt',
|
|
CONCAT('Poster for ', m.title, ' (', m.year, ')'),
|
|
'subtext',
|
|
CASE
|
|
WHEN m.star_rating IS NOT NULL THEN m.star_rating::text
|
|
ELSE m.year::text
|
|
END,
|
|
'url',
|
|
m.slug
|
|
),
|
|
'type',
|
|
'movies'
|
|
)
|
|
ORDER BY
|
|
m.year ASC
|
|
)
|
|
FROM
|
|
posts_movies pm
|
|
LEFT JOIN movies m ON pm.movies_id = m.id
|
|
LEFT JOIN directus_files df_movie ON m.art = df_movie.id
|
|
WHERE
|
|
pm.posts_id = p.id
|
|
AND m.last_watched IS NOT NULL
|
|
) AS movies,
|
|
(
|
|
SELECT
|
|
json_agg(
|
|
json_build_object(
|
|
'title',
|
|
s.title,
|
|
'year',
|
|
s.year,
|
|
'url',
|
|
s.slug,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_show.filename_disk),
|
|
'grid',
|
|
json_build_object(
|
|
'title',
|
|
NULL,
|
|
'image',
|
|
CONCAT(globals.cdn_url, '/', df_show.filename_disk),
|
|
'alt',
|
|
CONCAT('Artwork for ', 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,
|
|
'url',
|
|
s.slug
|
|
),
|
|
'type',
|
|
'tv'
|
|
)
|
|
ORDER BY
|
|
s.year ASC
|
|
)
|
|
FROM
|
|
posts_shows ps
|
|
LEFT JOIN shows s ON ps.shows_id = s.id
|
|
LEFT JOIN directus_files df_show ON s.art = df_show.id
|
|
WHERE
|
|
ps.posts_id = p.id
|
|
AND EXISTS (
|
|
SELECT
|
|
1
|
|
FROM
|
|
episodes e
|
|
WHERE
|
|
e.show = s.id
|
|
AND e.last_watched_at IS NOT NULL
|
|
)
|
|
) 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(globals.cdn_url, '/', df.filename_disk)
|
|
ELSE NULL
|
|
END
|
|
) AS feed,
|
|
json_build_object(
|
|
'title',
|
|
p.title,
|
|
'description',
|
|
LEFT(
|
|
regexp_replace(
|
|
regexp_replace(
|
|
regexp_replace(p.description, E'[*_`~#>-]', '', 'g'),
|
|
E'\\[(.*?)\\]\\((.*?)\\)',
|
|
E'\\1',
|
|
'g'
|
|
),
|
|
E'!\\[(.*?)\\]\\((.*?)\\)',
|
|
'',
|
|
'g'
|
|
),
|
|
250
|
|
),
|
|
'open_graph_image',
|
|
CASE
|
|
WHEN df.filename_disk IS NOT NULL
|
|
AND df.filename_disk != ''
|
|
AND df.filename_disk != '/' THEN CONCAT('/', df.filename_disk)
|
|
ELSE globals.metadata ->> 'open_graph_image'
|
|
END,
|
|
'url',
|
|
CONCAT(globals.url, p.slug),
|
|
'type',
|
|
'article'
|
|
) AS metadata
|
|
FROM
|
|
posts p
|
|
LEFT JOIN directus_files df ON p.image = df.id
|
|
CROSS JOIN optimized_globals globals
|
|
GROUP BY
|
|
p.id,
|
|
df.filename_disk,
|
|
globals.cdn_url,
|
|
globals.site_name,
|
|
globals.url,
|
|
globals.metadata ->> 'open_graph_image';
|