feat: initial commit
This commit is contained in:
commit
e214116e40
253 changed files with 17406 additions and 0 deletions
27
queries/functions/get_feed_data.psql
Normal file
27
queries/functions/get_feed_data.psql
Normal file
|
@ -0,0 +1,27 @@
|
|||
CREATE OR REPLACE FUNCTION get_feed_data(feed_key TEXT)
|
||||
RETURNS JSON AS $$
|
||||
DECLARE
|
||||
result JSON;
|
||||
sql_query TEXT;
|
||||
BEGIN
|
||||
CASE feed_key
|
||||
WHEN 'movies' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_movies WHERE feed IS NOT NULL';
|
||||
WHEN 'books' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_books WHERE feed IS NOT NULL';
|
||||
WHEN 'posts' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_posts WHERE feed IS NOT NULL';
|
||||
WHEN 'links' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_links WHERE feed IS NOT NULL';
|
||||
WHEN 'allActivity' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_all_activity WHERE feed IS NOT NULL';
|
||||
WHEN 'syndication' THEN
|
||||
sql_query := 'SELECT json_agg(feed ORDER BY (feed->>''date'')::timestamp DESC) FROM optimized_syndication WHERE feed IS NOT NULL';
|
||||
ELSE
|
||||
RETURN NULL;
|
||||
END CASE;
|
||||
|
||||
EXECUTE sql_query INTO result;
|
||||
RETURN result;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
14
queries/functions/parsecountryfield.psql
Normal file
14
queries/functions/parsecountryfield.psql
Normal file
|
@ -0,0 +1,14 @@
|
|||
DECLARE
|
||||
delimiters TEXT[] := ARRAY[',', '/', '&', 'and'];
|
||||
countries TEXT[];
|
||||
result TEXT := '';
|
||||
BEGIN
|
||||
countries := string_to_array(countryField, ',');
|
||||
|
||||
FOR i IN 1..array_length(delimiters, 1) LOOP
|
||||
countries := array_cat(countries, string_to_array(result, delimiters[i]));
|
||||
END LOOP;
|
||||
|
||||
result := array_to_string(countries, ' ');
|
||||
RETURN trim(result);
|
||||
END
|
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 text,
|
||||
rank real,
|
||||
total_count bigint
|
||||
)
|
||||
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,
|
||||
COUNT(*) OVER() AS total_count
|
||||
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
|
||||
s.type = 'post' DESC,
|
||||
s.content_date DESC NULLS LAST,
|
||||
rank DESC
|
||||
LIMIT page_size OFFSET page_offset;
|
||||
END;
|
||||
$$
|
||||
LANGUAGE plpgsql;
|
4
queries/functions/slugify.psql
Normal file
4
queries/functions/slugify.psql
Normal file
|
@ -0,0 +1,4 @@
|
|||
SELECT lower(regexp_replace(
|
||||
unaccent(regexp_replace($1, '[^\\w\\s-]', '', 'g')),
|
||||
'\\s+', '-', 'g'
|
||||
));
|
5
queries/functions/update_album_key.psql
Normal file
5
queries/functions/update_album_key.psql
Normal file
|
@ -0,0 +1,5 @@
|
|||
BEGIN
|
||||
UPDATE listens
|
||||
SET album_key = new_album_key
|
||||
WHERE album_key = old_album_key;
|
||||
END;
|
26
queries/functions/update_days_read.psql
Normal file
26
queries/functions/update_days_read.psql
Normal file
|
@ -0,0 +1,26 @@
|
|||
CREATE OR REPLACE FUNCTION update_days_read()
|
||||
RETURNS TRIGGER AS $$
|
||||
DECLARE
|
||||
pacific_now TIMESTAMPTZ;
|
||||
pacific_today DATE;
|
||||
last_read DATE;
|
||||
BEGIN
|
||||
SELECT (NOW() AT TIME ZONE 'America/Los_Angeles')::DATE INTO pacific_today;
|
||||
|
||||
SELECT COALESCE(last_read_date::DATE, pacific_today - INTERVAL '1 day') INTO last_read FROM reading_streak LIMIT 1;
|
||||
|
||||
IF last_read < pacific_today - INTERVAL '1 day' THEN
|
||||
UPDATE reading_streak
|
||||
SET days_read = 0, last_read_date = NOW() AT TIME ZONE 'America/Los_Angeles'
|
||||
WHERE id = 1;
|
||||
END IF;
|
||||
|
||||
IF last_read IS DISTINCT FROM pacific_today THEN
|
||||
UPDATE reading_streak
|
||||
SET days_read = days_read + 1, last_read_date = NOW() AT TIME ZONE 'America/Los_Angeles'
|
||||
WHERE id = 1;
|
||||
END IF;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
36
queries/functions/update_listen_totals.psql
Normal file
36
queries/functions/update_listen_totals.psql
Normal file
|
@ -0,0 +1,36 @@
|
|||
BEGIN
|
||||
WITH artist_plays AS (
|
||||
SELECT artist_name, COUNT(*)::integer as total_plays
|
||||
FROM listens
|
||||
GROUP BY artist_name
|
||||
)
|
||||
UPDATE artists
|
||||
SET total_plays = COALESCE(ap.total_plays, 0)
|
||||
FROM artist_plays ap
|
||||
WHERE artists.name_string = ap.artist_name;
|
||||
|
||||
WITH album_plays AS (
|
||||
SELECT album_key, artist_name, COUNT(*)::integer as total_plays
|
||||
FROM listens
|
||||
GROUP BY album_key, artist_name
|
||||
)
|
||||
UPDATE albums
|
||||
SET total_plays = COALESCE(ap.total_plays, 0)
|
||||
FROM album_plays ap
|
||||
WHERE albums.key = ap.album_key
|
||||
AND albums.artist_name = ap.artist_name;
|
||||
|
||||
WITH genre_plays AS (
|
||||
SELECT g.id, COUNT(*)::integer as total_plays
|
||||
FROM listens l
|
||||
JOIN artists a ON l.artist_name = a.name_string
|
||||
JOIN genres g ON a.genres::text = g.id::text
|
||||
GROUP BY g.id
|
||||
)
|
||||
UPDATE genres
|
||||
SET total_plays = COALESCE(gp.total_plays, 0)
|
||||
FROM genre_plays gp
|
||||
WHERE genres.id = gp.id;
|
||||
|
||||
RAISE NOTICE 'All listen totals are up to date';
|
||||
END;
|
11
queries/functions/update_scheduled_episode_status.psql
Normal file
11
queries/functions/update_scheduled_episode_status.psql
Normal file
|
@ -0,0 +1,11 @@
|
|||
CREATE OR REPLACE FUNCTION update_scheduled_episode_status()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
UPDATE scheduled_episodes
|
||||
SET status = 'aired'
|
||||
WHERE air_date < CURRENT_DATE
|
||||
AND status = 'upcoming';
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
12
queries/functions/update_scheduled_on_watch.psql
Normal file
12
queries/functions/update_scheduled_on_watch.psql
Normal file
|
@ -0,0 +1,12 @@
|
|||
CREATE OR REPLACE FUNCTION update_scheduled_on_watch()
|
||||
RETURNS TRIGGER AS $$
|
||||
BEGIN
|
||||
UPDATE scheduled_episodes
|
||||
SET status = 'watched'
|
||||
WHERE show_id = NEW.show
|
||||
AND season_number = NEW.season_number
|
||||
AND episode_number = NEW.episode_number;
|
||||
|
||||
RETURN NEW;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
Loading…
Add table
Add a link
Reference in a new issue