coryd.dev/queries/views/feeds/recent_activity.sql

147 lines
3.1 KiB
SQL

CREATE OR REPLACE VIEW optimized_recent_activity AS
WITH
activity_data AS (
SELECT
NULL::bigint AS id,
p.date AS content_date,
p.title,
p.content AS description,
p.url AS url,
p.featured AS featured,
p.tags::TEXT[],
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
NULL::bigint AS id,
l.date AS content_date,
l.title,
l.description,
l.link AS url,
NULL AS featured,
l.tags::TEXT[],
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
NULL::bigint AS id,
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 featured,
b.tags::TEXT[],
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
NULL::bigint AS id,
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 featured,
m.tags::TEXT[],
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.id,
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 featured,
NULL AS tags,
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.concert_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;