From 84ee77b158b00a3c2a64064c6457003ef411f1f6 Mon Sep 17 00:00:00 2001 From: ri72miieop <106687171+ri72miieop@users.noreply.github.com> Date: Wed, 13 Nov 2024 20:55:26 +0000 Subject: [PATCH 1/3] Functions for browser extension --- supabase/migrations/20241113161757_TES.sql | 338 +++++++++++++++++++++ 1 file changed, 338 insertions(+) create mode 100644 supabase/migrations/20241113161757_TES.sql diff --git a/supabase/migrations/20241113161757_TES.sql b/supabase/migrations/20241113161757_TES.sql new file mode 100644 index 0000000..0d8ed3c --- /dev/null +++ b/supabase/migrations/20241113161757_TES.sql @@ -0,0 +1,338 @@ +ALTER TABLE public.liked_tweets DROP COLUMN IF EXISTS fts; +ALTER TABLE public.liked_tweets ADD COLUMN fts tsvector GENERATED ALWAYS AS (to_tsvector('english', full_text)) STORED; +CREATE INDEX IF NOT EXISTS text_fts ON public.liked_tweets USING gin (fts); + + + +CREATE OR REPLACE FUNCTION tes_get_tweets_on_this_day( + p_limit INTEGER DEFAULT NULL, + p_account_id TEXT DEFAULT NULL +) +RETURNS TABLE ( + tweet_id TEXT, + account_id TEXT, + created_at TIMESTAMP WITH TIME ZONE, + full_text TEXT, + retweet_count INTEGER, + favorite_count INTEGER, + reply_to_tweet_id TEXT, + reply_to_user_id TEXT, + reply_to_username TEXT, + username TEXT, + account_display_name TEXT, + avatar_media_url TEXT +) AS $$ +DECLARE + current_month INTEGER; + current_day INTEGER; +BEGIN + -- Get the current month and day + SELECT EXTRACT(MONTH FROM CURRENT_DATE), EXTRACT(DAY FROM CURRENT_DATE) + INTO current_month, current_day; + + RETURN QUERY + SELECT + t.tweet_id, t.account_id, t.created_at, t.full_text, t.retweet_count, + t.favorite_count, t.reply_to_tweet_id, t.reply_to_user_id, t.reply_to_username, + a.username,a.account_display_name,p.avatar_media_url + FROM + public.tweets t + inner join account a on t.account_id = a.account_id + inner join profile p on t.account_id = p.account_id + WHERE + EXTRACT(MONTH FROM t.created_at AT TIME ZONE 'UTC') = current_month + AND EXTRACT(DAY FROM t.created_at AT TIME ZONE 'UTC') = current_day + AND EXTRACT(YEAR FROM t.created_at AT TIME ZONE 'UTC') < EXTRACT(YEAR FROM CURRENT_DATE) + AND (p_account_id IS NULL OR t.account_id = p_account_id) + ORDER BY + t.favorite_count DESC,t.retweet_count DESC + LIMIT p_limit; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION tes_get_tweet_counts_by_date(p_account_id TEXT) +RETURNS TABLE (tweet_date DATE, tweet_count BIGINT) AS $$ +BEGIN + RETURN QUERY + SELECT + DATE(created_at) AS tweet_date, + COUNT(*) AS tweet_count + FROM + public.tweets + WHERE + account_id = p_account_id + GROUP BY + DATE(created_at) + ORDER BY + tweet_date; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION tes_get_moots(user_id TEXT) +RETURNS TABLE ( + account_id TEXT, + username TEXT +) AS $$ +BEGIN + RETURN QUERY + SELECT + f1.follower_account_id as account_id, + mu.screen_name as username + FROM public.followers f1 + INNER JOIN public.following f2 + ON f1.account_id = f2.account_id + AND f1.follower_account_id = f2.following_account_id + left join mentioned_users mu on mu.user_id = f1.follower_account_id + where f1.account_id = get_moots.user_id; +END; +$$ LANGUAGE plpgsql; + + + +CREATE OR REPLACE FUNCTION tes_get_followers(user_id TEXT) +RETURNS TABLE ( + account_id TEXT, + username TEXT +) AS $$ +BEGIN + RETURN QUERY + SELECT + f1.follower_account_id AS account_id, + mu.screen_name AS username + FROM public.followers f1 + LEFT JOIN mentioned_users mu ON mu.user_id = f1.follower_account_id + WHERE f1.account_id = get_followers.user_id and mu.screen_name is not null; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION tes_get_followings(user_id TEXT) +RETURNS TABLE ( + account_id TEXT, + username TEXT +) AS $$ +BEGIN + RETURN QUERY + SELECT + f2.following_account_id AS account_id, + mu.screen_name AS username + FROM public.following f2 + LEFT JOIN mentioned_users mu ON mu.user_id = f2.following_account_id + WHERE f2.account_id = get_followings.user_id and mu.screen_name is not null; +END; +$$ LANGUAGE plpgsql; + + + + +CREATE OR REPLACE FUNCTION tes_search_liked_tweets( + search_query TEXT, + from_user TEXT DEFAULT NULL, + to_user TEXT DEFAULT NULL, + since_date DATE DEFAULT NULL, + until_date DATE DEFAULT NULL, + min_likes INTEGER DEFAULT 0, + min_retweets INTEGER DEFAULT 0, + max_likes INTEGER DEFAULT 100000000, + max_retweets INTEGER DEFAULT 100000000, + limit_ INTEGER DEFAULT 50, + auth_account_id TEXT DEFAULT NULL +) +RETURNS TABLE ( + tweet_id TEXT, + account_id TEXT, + created_at TIMESTAMP WITH TIME ZONE, + full_text TEXT, + retweet_count INTEGER, + favorite_count INTEGER, + reply_to_tweet_id TEXT, + avatar_media_url TEXT, + archive_upload_id BIGINT, + username TEXT, + account_display_name TEXT +) AS $$ +DECLARE + from_account_id TEXT; + to_account_id TEXT; +BEGIN + -- Get account_id for from_user + IF from_user IS NOT NULL THEN + SELECT a.account_id INTO from_account_id + FROM account as a + WHERE LOWER(a.username) = LOWER(from_user); + + -- Return empty if from_user not found + IF from_account_id IS NULL THEN + RETURN; + END IF; + END IF; + + -- Get account_id for to_user + IF to_user IS NOT NULL THEN + SELECT a.account_id INTO to_account_id + FROM account as a + WHERE LOWER(a.username) = LOWER(to_user); + + -- Return empty if to_user not found + IF to_account_id IS NULL THEN + RETURN; + END IF; + END IF; + + RETURN QUERY + WITH combined_tweets AS ( + SELECT + COALESCE(t.tweet_id,lt.tweet_id) as tweet_id, + t.account_id, + t.created_at, + COALESCE(t.full_text, lt.full_text) as full_text, + t.retweet_count, + t.favorite_count, + t.reply_to_user_id, + t.reply_to_tweet_id + FROM ( + SELECT lt.tweet_id, lt.full_text + FROM liked_tweets lt + left JOIN likes l ON lt.tweet_id = l.liked_tweet_id + WHERE l.account_id = auth_account_id + + ) lt + LEFT JOIN tweets t ON lt.tweet_id = t.tweet_id + + ), + matching_tweets AS ( + SELECT ct.tweet_id,ct.full_text + FROM combined_tweets ct + WHERE (search_query = '' OR to_tsvector('english', ct.full_text) @@ websearch_to_tsquery('english', search_query)) + AND (from_account_id IS NULL OR ct.account_id = from_account_id) + AND (to_account_id IS NULL OR ct.reply_to_user_id = to_account_id) + AND (since_date IS NULL OR ct.created_at >= since_date OR ct.created_at IS NULL) + AND (until_date IS NULL OR ct.created_at <= until_date OR ct.created_at IS NULL) + AND (min_likes IS NULL OR ct.favorite_count >= min_likes OR ct.favorite_count IS NULL) + AND (max_likes IS NULL OR ct.favorite_count <= max_likes OR ct.favorite_count IS NULL) + AND (min_retweets IS NULL OR ct.retweet_count >= min_retweets OR ct.retweet_count IS NULL) + AND (max_retweets IS NULL OR ct.retweet_count <= max_retweets OR ct.retweet_count IS NULL) + ORDER BY COALESCE(ct.created_at, '2099-12-31'::timestamp) DESC + LIMIT limit_ + ) + SELECT + COALESCE (mt.tweet_id,t.tweet_id), + t.account_id, + t.created_at, + COALESCE (mt.full_text,t.full_text), + t.retweet_count, + t.favorite_count, + t.reply_to_tweet_id, + p.avatar_media_url, + p.archive_upload_id, + a.username, + a.account_display_name + FROM matching_tweets mt + LEFT JOIN tweets t ON mt.tweet_id = t.tweet_id + LEFT JOIN account a ON t.account_id = a.account_id + LEFT JOIN LATERAL ( + SELECT COALESCE(p.avatar_media_url,'none.com') as avatar_media_url, p.archive_upload_id + FROM profile as p + WHERE p.account_id = t.account_id + ORDER BY p.archive_upload_id DESC + LIMIT 1 + ) p ON true + ORDER BY t.created_at DESC; +END; +$$ LANGUAGE plpgsql + + +CREATE OR REPLACE FUNCTION tes_search_tweets( + search_query TEXT, + from_user TEXT DEFAULT NULL, + to_user TEXT DEFAULT NULL, + since_date DATE DEFAULT NULL, + until_date DATE DEFAULT NULL, + min_likes INTEGER DEFAULT 0, + min_retweets INTEGER DEFAULT 0, + max_likes INTEGER DEFAULT 100000000, + max_retweets INTEGER DEFAULT 100000000, + limit_ INTEGER DEFAULT 50 +) +RETURNS TABLE ( + tweet_id TEXT, + account_id TEXT, + created_at TIMESTAMP WITH TIME ZONE, + full_text TEXT, + retweet_count INTEGER, + favorite_count INTEGER, + reply_to_tweet_id TEXT, + avatar_media_url TEXT, + archive_upload_id BIGINT, + username TEXT, + account_display_name TEXT +) AS $$ +DECLARE + from_account_id TEXT; + to_account_id TEXT; +BEGIN + -- Get account_id for from_user + IF from_user IS NOT NULL THEN + SELECT a.account_id INTO from_account_id + FROM account as a + WHERE LOWER(a.username) = LOWER(from_user); + + -- Return empty if from_user not found + IF from_account_id IS NULL THEN + RETURN; + END IF; + END IF; + + -- Get account_id for to_user + IF to_user IS NOT NULL THEN + SELECT a.account_id INTO to_account_id + FROM account as a + WHERE LOWER(a.username) = LOWER(to_user); + + -- Return empty if to_user not found + IF to_account_id IS NULL THEN + RETURN; + END IF; + END IF; + + RETURN QUERY + WITH matching_tweets AS ( + SELECT t.tweet_id + FROM tweets t + WHERE (search_query = '' OR t.fts @@ to_tsquery('english', search_query)) + AND (from_account_id IS NULL OR t.account_id = from_account_id) + AND (to_account_id IS NULL OR t.reply_to_user_id = to_account_id) + AND (since_date IS NULL OR t.created_at >= since_date) + AND (until_date IS NULL OR t.created_at <= until_date) + AND (min_likes IS NULL OR t.favorite_count >= min_likes) + AND (max_likes IS NULL OR t.favorite_count <= max_likes) + AND (min_retweets IS NULL OR t.retweet_count >= min_retweets) + AND (max_retweets IS NULL OR t.retweet_count <= max_retweets) + ORDER BY t.created_at DESC + LIMIT limit_ + ) + SELECT + t.tweet_id, + t.account_id, + t.created_at, + t.full_text, + t.retweet_count, + t.favorite_count, + t.reply_to_tweet_id, + p.avatar_media_url, + p.archive_upload_id, + a.username, + a.account_display_name + FROM matching_tweets mt + JOIN tweets t ON mt.tweet_id = t.tweet_id + JOIN account a ON t.account_id = a.account_id + LEFT JOIN LATERAL ( + SELECT p.avatar_media_url, p.archive_upload_id + FROM profile as p + WHERE p.account_id = t.account_id + ORDER BY p.archive_upload_id DESC + LIMIT 1 + ) p ON true + ORDER BY t.created_at DESC; +END; +$$ LANGUAGE plpgsql + From c15c3daa719bfad5d9daada91399b061e8078259 Mon Sep 17 00:00:00 2001 From: ri72miieop <106687171+ri72miieop@users.noreply.github.com> Date: Wed, 13 Nov 2024 21:49:54 +0000 Subject: [PATCH 2/3] update sql folder to be consistent with migration --- .../tes/01-tes_get_tweets_on_this_day.sql | 47 +++++++ .../tes/02-tes_get_tweet_counts_by_date.sql | 19 +++ sql/functions/tes/03-tes_get_moots.sql | 20 +++ sql/functions/tes/04-tes_get_followers.sql | 32 +++++ .../tes/05-tes_search_liked_tweets.sql | 118 ++++++++++++++++++ sql/functions/tes/06-tes_search_tweets.sql | 96 ++++++++++++++ sql/tables/11_liked_tweets.sql | 7 +- 7 files changed, 337 insertions(+), 2 deletions(-) create mode 100644 sql/functions/tes/01-tes_get_tweets_on_this_day.sql create mode 100644 sql/functions/tes/02-tes_get_tweet_counts_by_date.sql create mode 100644 sql/functions/tes/03-tes_get_moots.sql create mode 100644 sql/functions/tes/04-tes_get_followers.sql create mode 100644 sql/functions/tes/05-tes_search_liked_tweets.sql create mode 100644 sql/functions/tes/06-tes_search_tweets.sql diff --git a/sql/functions/tes/01-tes_get_tweets_on_this_day.sql b/sql/functions/tes/01-tes_get_tweets_on_this_day.sql new file mode 100644 index 0000000..0322f98 --- /dev/null +++ b/sql/functions/tes/01-tes_get_tweets_on_this_day.sql @@ -0,0 +1,47 @@ +DROP FUNCTION IF EXISTS tes_get_tweets_on_this_day; + +CREATE OR REPLACE FUNCTION tes_get_tweets_on_this_day( + p_limit INTEGER DEFAULT NULL, + p_account_id TEXT DEFAULT NULL +) +RETURNS TABLE ( + tweet_id TEXT, + account_id TEXT, + created_at TIMESTAMP WITH TIME ZONE, + full_text TEXT, + retweet_count INTEGER, + favorite_count INTEGER, + reply_to_tweet_id TEXT, + reply_to_user_id TEXT, + reply_to_username TEXT, + username TEXT, + account_display_name TEXT, + avatar_media_url TEXT +) AS $$ +DECLARE + current_month INTEGER; + current_day INTEGER; +BEGIN + -- Get the current month and day + SELECT EXTRACT(MONTH FROM CURRENT_DATE), EXTRACT(DAY FROM CURRENT_DATE) + INTO current_month, current_day; + + RETURN QUERY + SELECT + t.tweet_id, t.account_id, t.created_at, t.full_text, t.retweet_count, + t.favorite_count, t.reply_to_tweet_id, t.reply_to_user_id, t.reply_to_username, + a.username,a.account_display_name,p.avatar_media_url + FROM + public.tweets t + inner join account a on t.account_id = a.account_id + inner join profile p on t.account_id = p.account_id + WHERE + EXTRACT(MONTH FROM t.created_at AT TIME ZONE 'UTC') = current_month + AND EXTRACT(DAY FROM t.created_at AT TIME ZONE 'UTC') = current_day + AND EXTRACT(YEAR FROM t.created_at AT TIME ZONE 'UTC') < EXTRACT(YEAR FROM CURRENT_DATE) + AND (p_account_id IS NULL OR t.account_id = p_account_id) + ORDER BY + t.favorite_count DESC,t.retweet_count DESC + LIMIT p_limit; +END; +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/sql/functions/tes/02-tes_get_tweet_counts_by_date.sql b/sql/functions/tes/02-tes_get_tweet_counts_by_date.sql new file mode 100644 index 0000000..87c71b2 --- /dev/null +++ b/sql/functions/tes/02-tes_get_tweet_counts_by_date.sql @@ -0,0 +1,19 @@ +DROP FUNCTION IF EXISTS tes_get_tweet_counts_by_date; + +CREATE OR REPLACE FUNCTION tes_get_tweet_counts_by_date(p_account_id TEXT) +RETURNS TABLE (tweet_date DATE, tweet_count BIGINT) AS $$ +BEGIN + RETURN QUERY + SELECT + DATE(created_at) AS tweet_date, + COUNT(*) AS tweet_count + FROM + public.tweets + WHERE + account_id = p_account_id + GROUP BY + DATE(created_at) + ORDER BY + tweet_date; +END; +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/sql/functions/tes/03-tes_get_moots.sql b/sql/functions/tes/03-tes_get_moots.sql new file mode 100644 index 0000000..5484ffb --- /dev/null +++ b/sql/functions/tes/03-tes_get_moots.sql @@ -0,0 +1,20 @@ +DROP FUNCTION IF EXISTS tes_get_moots; + +CREATE OR REPLACE FUNCTION tes_get_moots(user_id TEXT) +RETURNS TABLE ( + account_id TEXT, + username TEXT +) AS $$ +BEGIN + RETURN QUERY + SELECT + f1.follower_account_id as account_id, + mu.screen_name as username + FROM public.followers f1 + INNER JOIN public.following f2 + ON f1.account_id = f2.account_id + AND f1.follower_account_id = f2.following_account_id + left join mentioned_users mu on mu.user_id = f1.follower_account_id + where f1.account_id = get_moots.user_id; +END; +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/sql/functions/tes/04-tes_get_followers.sql b/sql/functions/tes/04-tes_get_followers.sql new file mode 100644 index 0000000..25f508b --- /dev/null +++ b/sql/functions/tes/04-tes_get_followers.sql @@ -0,0 +1,32 @@ +DROP FUNCTION IF EXISTS tes_get_followers; +CREATE OR REPLACE FUNCTION tes_get_followers(user_id TEXT) +RETURNS TABLE ( + account_id TEXT, + username TEXT +) AS $$ +BEGIN + RETURN QUERY + SELECT + f1.follower_account_id AS account_id, + mu.screen_name AS username + FROM public.followers f1 + LEFT JOIN mentioned_users mu ON mu.user_id = f1.follower_account_id + WHERE f1.account_id = get_followers.user_id and mu.screen_name is not null; +END; +$$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION tes_get_followings(user_id TEXT) +RETURNS TABLE ( + account_id TEXT, + username TEXT +) AS $$ +BEGIN + RETURN QUERY + SELECT + f2.following_account_id AS account_id, + mu.screen_name AS username + FROM public.following f2 + LEFT JOIN mentioned_users mu ON mu.user_id = f2.following_account_id + WHERE f2.account_id = get_followings.user_id and mu.screen_name is not null; +END; +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/sql/functions/tes/05-tes_search_liked_tweets.sql b/sql/functions/tes/05-tes_search_liked_tweets.sql new file mode 100644 index 0000000..9df0ec2 --- /dev/null +++ b/sql/functions/tes/05-tes_search_liked_tweets.sql @@ -0,0 +1,118 @@ + +DROP FUNCTION IF EXISTS tes_search_liked_tweets; + +CREATE OR REPLACE FUNCTION tes_search_liked_tweets( + search_query TEXT, + from_user TEXT DEFAULT NULL, + to_user TEXT DEFAULT NULL, + since_date DATE DEFAULT NULL, + until_date DATE DEFAULT NULL, + min_likes INTEGER DEFAULT 0, + min_retweets INTEGER DEFAULT 0, + max_likes INTEGER DEFAULT 100000000, + max_retweets INTEGER DEFAULT 100000000, + limit_ INTEGER DEFAULT 50, + auth_account_id TEXT DEFAULT NULL +) +RETURNS TABLE ( + tweet_id TEXT, + account_id TEXT, + created_at TIMESTAMP WITH TIME ZONE, + full_text TEXT, + retweet_count INTEGER, + favorite_count INTEGER, + reply_to_tweet_id TEXT, + avatar_media_url TEXT, + archive_upload_id BIGINT, + username TEXT, + account_display_name TEXT +) AS $$ +DECLARE + from_account_id TEXT; + to_account_id TEXT; +BEGIN + -- Get account_id for from_user + IF from_user IS NOT NULL THEN + SELECT a.account_id INTO from_account_id + FROM account as a + WHERE LOWER(a.username) = LOWER(from_user); + + -- Return empty if from_user not found + IF from_account_id IS NULL THEN + RETURN; + END IF; + END IF; + + -- Get account_id for to_user + IF to_user IS NOT NULL THEN + SELECT a.account_id INTO to_account_id + FROM account as a + WHERE LOWER(a.username) = LOWER(to_user); + + -- Return empty if to_user not found + IF to_account_id IS NULL THEN + RETURN; + END IF; + END IF; + + RETURN QUERY + WITH combined_tweets AS ( + SELECT + COALESCE(t.tweet_id,lt.tweet_id) as tweet_id, + t.account_id, + t.created_at, + COALESCE(t.full_text, lt.full_text) as full_text, + t.retweet_count, + t.favorite_count, + t.reply_to_user_id, + t.reply_to_tweet_id + FROM ( + SELECT lt.tweet_id, lt.full_text + FROM liked_tweets lt + left JOIN likes l ON lt.tweet_id = l.liked_tweet_id + WHERE l.account_id = auth_account_id + + ) lt + LEFT JOIN tweets t ON lt.tweet_id = t.tweet_id + + ), + matching_tweets AS ( + SELECT ct.tweet_id,ct.full_text + FROM combined_tweets ct + WHERE (search_query = '' OR to_tsvector('english', ct.full_text) @@ websearch_to_tsquery('english', search_query)) + AND (from_account_id IS NULL OR ct.account_id = from_account_id) + AND (to_account_id IS NULL OR ct.reply_to_user_id = to_account_id) + AND (since_date IS NULL OR ct.created_at >= since_date OR ct.created_at IS NULL) + AND (until_date IS NULL OR ct.created_at <= until_date OR ct.created_at IS NULL) + AND (min_likes IS NULL OR ct.favorite_count >= min_likes OR ct.favorite_count IS NULL) + AND (max_likes IS NULL OR ct.favorite_count <= max_likes OR ct.favorite_count IS NULL) + AND (min_retweets IS NULL OR ct.retweet_count >= min_retweets OR ct.retweet_count IS NULL) + AND (max_retweets IS NULL OR ct.retweet_count <= max_retweets OR ct.retweet_count IS NULL) + ORDER BY COALESCE(ct.created_at, '2099-12-31'::timestamp) DESC + LIMIT limit_ + ) + SELECT + COALESCE (mt.tweet_id,t.tweet_id), + t.account_id, + t.created_at, + COALESCE (mt.full_text,t.full_text), + t.retweet_count, + t.favorite_count, + t.reply_to_tweet_id, + p.avatar_media_url, + p.archive_upload_id, + a.username, + a.account_display_name + FROM matching_tweets mt + LEFT JOIN tweets t ON mt.tweet_id = t.tweet_id + LEFT JOIN account a ON t.account_id = a.account_id + LEFT JOIN LATERAL ( + SELECT COALESCE(p.avatar_media_url,'none.com') as avatar_media_url, p.archive_upload_id + FROM profile as p + WHERE p.account_id = t.account_id + ORDER BY p.archive_upload_id DESC + LIMIT 1 + ) p ON true + ORDER BY t.created_at DESC; +END; +$$ LANGUAGE plpgsql \ No newline at end of file diff --git a/sql/functions/tes/06-tes_search_tweets.sql b/sql/functions/tes/06-tes_search_tweets.sql new file mode 100644 index 0000000..ef4e6fb --- /dev/null +++ b/sql/functions/tes/06-tes_search_tweets.sql @@ -0,0 +1,96 @@ +DROP FUNCTION IF EXISTS tes_search_tweets; + +CREATE OR REPLACE FUNCTION tes_search_tweets( + search_query TEXT, + from_user TEXT DEFAULT NULL, + to_user TEXT DEFAULT NULL, + since_date DATE DEFAULT NULL, + until_date DATE DEFAULT NULL, + min_likes INTEGER DEFAULT 0, + min_retweets INTEGER DEFAULT 0, + max_likes INTEGER DEFAULT 100000000, + max_retweets INTEGER DEFAULT 100000000, + limit_ INTEGER DEFAULT 50 +) +RETURNS TABLE ( + tweet_id TEXT, + account_id TEXT, + created_at TIMESTAMP WITH TIME ZONE, + full_text TEXT, + retweet_count INTEGER, + favorite_count INTEGER, + reply_to_tweet_id TEXT, + avatar_media_url TEXT, + archive_upload_id BIGINT, + username TEXT, + account_display_name TEXT +) AS $$ +DECLARE + from_account_id TEXT; + to_account_id TEXT; +BEGIN + -- Get account_id for from_user + IF from_user IS NOT NULL THEN + SELECT a.account_id INTO from_account_id + FROM account as a + WHERE LOWER(a.username) = LOWER(from_user); + + -- Return empty if from_user not found + IF from_account_id IS NULL THEN + RETURN; + END IF; + END IF; + + -- Get account_id for to_user + IF to_user IS NOT NULL THEN + SELECT a.account_id INTO to_account_id + FROM account as a + WHERE LOWER(a.username) = LOWER(to_user); + + -- Return empty if to_user not found + IF to_account_id IS NULL THEN + RETURN; + END IF; + END IF; + + RETURN QUERY + WITH matching_tweets AS ( + SELECT t.tweet_id + FROM tweets t + WHERE (search_query = '' OR t.fts @@ to_tsquery('english', search_query)) + AND (from_account_id IS NULL OR t.account_id = from_account_id) + AND (to_account_id IS NULL OR t.reply_to_user_id = to_account_id) + AND (since_date IS NULL OR t.created_at >= since_date) + AND (until_date IS NULL OR t.created_at <= until_date) + AND (min_likes IS NULL OR t.favorite_count >= min_likes) + AND (max_likes IS NULL OR t.favorite_count <= max_likes) + AND (min_retweets IS NULL OR t.retweet_count >= min_retweets) + AND (max_retweets IS NULL OR t.retweet_count <= max_retweets) + ORDER BY t.created_at DESC + LIMIT limit_ + ) + SELECT + t.tweet_id, + t.account_id, + t.created_at, + t.full_text, + t.retweet_count, + t.favorite_count, + t.reply_to_tweet_id, + p.avatar_media_url, + p.archive_upload_id, + a.username, + a.account_display_name + FROM matching_tweets mt + JOIN tweets t ON mt.tweet_id = t.tweet_id + JOIN account a ON t.account_id = a.account_id + LEFT JOIN LATERAL ( + SELECT p.avatar_media_url, p.archive_upload_id + FROM profile as p + WHERE p.account_id = t.account_id + ORDER BY p.archive_upload_id DESC + LIMIT 1 + ) p ON true + ORDER BY t.created_at DESC; +END; +$$ LANGUAGE plpgsql \ No newline at end of file diff --git a/sql/tables/11_liked_tweets.sql b/sql/tables/11_liked_tweets.sql index 6c9af2d..aea6c82 100644 --- a/sql/tables/11_liked_tweets.sql +++ b/sql/tables/11_liked_tweets.sql @@ -1,4 +1,7 @@ CREATE TABLE IF NOT EXISTS public.liked_tweets ( tweet_id TEXT PRIMARY KEY, - full_text TEXT NOT NULL -); \ No newline at end of file + full_text TEXT NOT NULL, + fts tsvector GENERATED ALWAYS AS (to_tsvector('english', full_text)) STORED +); + +CREATE INDEX IF NOT EXISTS text_fts ON public.liked_tweets USING gin (fts); From 777fc702d10495413728a5aefd7dae417764627f Mon Sep 17 00:00:00 2001 From: ri72miieop <106687171+ri72miieop@users.noreply.github.com> Date: Wed, 13 Nov 2024 22:23:05 +0000 Subject: [PATCH 3/3] syntax fix --- sql/functions/tes/05-tes_search_liked_tweets.sql | 2 +- sql/functions/tes/06-tes_search_tweets.sql | 2 +- supabase/migrations/20241113161757_TES.sql | 4 ++-- 3 files changed, 4 insertions(+), 4 deletions(-) diff --git a/sql/functions/tes/05-tes_search_liked_tweets.sql b/sql/functions/tes/05-tes_search_liked_tweets.sql index 9df0ec2..b1bff6d 100644 --- a/sql/functions/tes/05-tes_search_liked_tweets.sql +++ b/sql/functions/tes/05-tes_search_liked_tweets.sql @@ -115,4 +115,4 @@ BEGIN ) p ON true ORDER BY t.created_at DESC; END; -$$ LANGUAGE plpgsql \ No newline at end of file +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/sql/functions/tes/06-tes_search_tweets.sql b/sql/functions/tes/06-tes_search_tweets.sql index ef4e6fb..ed103c1 100644 --- a/sql/functions/tes/06-tes_search_tweets.sql +++ b/sql/functions/tes/06-tes_search_tweets.sql @@ -93,4 +93,4 @@ BEGIN ) p ON true ORDER BY t.created_at DESC; END; -$$ LANGUAGE plpgsql \ No newline at end of file +$$ LANGUAGE plpgsql; \ No newline at end of file diff --git a/supabase/migrations/20241113161757_TES.sql b/supabase/migrations/20241113161757_TES.sql index 0d8ed3c..d3bcfb7 100644 --- a/supabase/migrations/20241113161757_TES.sql +++ b/supabase/migrations/20241113161757_TES.sql @@ -238,7 +238,7 @@ BEGIN ) p ON true ORDER BY t.created_at DESC; END; -$$ LANGUAGE plpgsql +$$ LANGUAGE plpgsql; CREATE OR REPLACE FUNCTION tes_search_tweets( @@ -334,5 +334,5 @@ BEGIN ) p ON true ORDER BY t.created_at DESC; END; -$$ LANGUAGE plpgsql +$$ LANGUAGE plpgsql;