Skip to content

Commit

Permalink
Merge pull request #170 from ri72miieop/TES
Browse files Browse the repository at this point in the history
TES: db functions to support browser extension features
  • Loading branch information
TheExGenesis authored Nov 18, 2024
2 parents 49d0ed6 + 05eddf3 commit 7accf41
Show file tree
Hide file tree
Showing 8 changed files with 675 additions and 2 deletions.
47 changes: 47 additions & 0 deletions sql/functions/tes/01-tes_get_tweets_on_this_day.sql
Original file line number Diff line number Diff line change
@@ -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;
19 changes: 19 additions & 0 deletions sql/functions/tes/02-tes_get_tweet_counts_by_date.sql
Original file line number Diff line number Diff line change
@@ -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;
20 changes: 20 additions & 0 deletions sql/functions/tes/03-tes_get_moots.sql
Original file line number Diff line number Diff line change
@@ -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;
32 changes: 32 additions & 0 deletions sql/functions/tes/04-tes_get_followers.sql
Original file line number Diff line number Diff line change
@@ -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;
118 changes: 118 additions & 0 deletions sql/functions/tes/05-tes_search_liked_tweets.sql
Original file line number Diff line number Diff line change
@@ -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;
96 changes: 96 additions & 0 deletions sql/functions/tes/06-tes_search_tweets.sql
Original file line number Diff line number Diff line change
@@ -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;
7 changes: 5 additions & 2 deletions sql/tables/11_liked_tweets.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,7 @@
CREATE TABLE IF NOT EXISTS public.liked_tweets (
tweet_id TEXT PRIMARY KEY,
full_text TEXT NOT NULL
);
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);
Loading

0 comments on commit 7accf41

Please sign in to comment.