Skip to content

Commit

Permalink
Merge branch 'develop' into staging
Browse files Browse the repository at this point in the history
  • Loading branch information
0xthrpw committed Aug 16, 2024
2 parents 5dff61c + f975472 commit 70b8ebb
Show file tree
Hide file tree
Showing 13 changed files with 355 additions and 8 deletions.
24 changes: 24 additions & 0 deletions db/queries/api/v1/discover/create_view__discover.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,24 @@
-- migrate:up
-------------------------------------------------------------------------------
-- View: view__discover
-------------------------------------------------------------------------------
CREATE
OR REPLACE VIEW PUBLIC.view__discover AS
SELECT
DISTINCT r.address,
l.name,
l.avatar,
l.followers,
l.following
FROM public.view__latest_follows r
LEFT JOIN public.efp_leaderboard l ON l.address = r.address;




-- migrate:down
-------------------------------------------------------------------------------
-- Undo View: view__discover
-------------------------------------------------------------------------------
DROP VIEW
IF EXISTS PUBLIC.view__discover CASCADE;
Original file line number Diff line number Diff line change
Expand Up @@ -18,15 +18,15 @@ SELECT
ORDER BY fing.following_count DESC NULLS LAST
) as following_rank,
RANK () OVER (
ORDER BY blocks.blocks_count DESC NULLS LAST
ORDER BY blocks.blocked_count DESC NULLS LAST
) as blocks_rank,
COALESCE(mut.mutuals, 0 ) as mutuals,
COALESCE(fers.followers_count, 0 ) as followers,
COALESCE(fing.following_count, 0 ) as following,
COALESCE(blocks.blocks_count, 0 ) as blocks
COALESCE(blocks.blocked_count, 0 ) as blocks
FROM query.get_leaderboard_followers(10000) fers
LEFT OUTER JOIN query.get_leaderboard_following(10000) fing ON fing.address = fers.address
LEFT OUTER JOIN query.get_leaderboard_blocks(10000) blocks ON blocks.address = fers.address
LEFT OUTER JOIN query.get_leaderboard_blocked(10000) blocks ON blocks.address = fers.address
LEFT OUTER JOIN public.view__events__efp_leaderboard_mutuals mut ON mut.leader = fers.address
LEFT OUTER JOIN public.ens_metadata ens ON ens.address::text = fers.address::text
ORDER BY mut.mutuals DESC NULLS LAST;
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
--migrate:up
-------------------------------------------------------------------------------
-- Function: search_leaderboard
-- Description: allows users to search for specific leaderboard records
-- Parameters:
-- - p_term (TEXT): The search term.
-- Returns: A set of records from the efp_leaderboard table
-------------------------------------------------------------------------------

CREATE
OR REPLACE FUNCTION query.search_leaderboard (p_term TEXT) RETURNS TABLE (
address types.eth_address,
name TEXT,
avatar TEXT,
mutuals_rank BIGINT,
followers_rank BIGINT,
following_rank BIGINT,
blocks_rank BIGINT,
mutuals BIGINT,
following BIGINT,
followers BIGINT,
blocks BIGINT,
updated_at TIMESTAMP WITH TIME ZONE
) LANGUAGE plpgsql AS $$
BEGIN
RETURN QUERY

SELECT
lb.address,
lb.name,
lb.avatar,
lb.mutuals_rank,
lb.followers_rank,
lb.following_rank,
lb.blocks_rank,
lb.mutuals,
lb.following,
lb.followers,
lb.blocks,
lb.updated_at
FROM public.efp_leaderboard lb
WHERE lb.address ~ p_term
OR lb.name ~ p_term;
END;
$$;


--migrate:down
Original file line number Diff line number Diff line change
Expand Up @@ -52,7 +52,7 @@ BEGIN
COALESCE(NOT (record.has_block_tag OR record.has_mute_tag), FALSE) AS is_following,
COALESCE(record.has_block_tag, FALSE) AS is_blocked,
COALESCE(record.has_mute_tag, FALSE) AS is_muted
FROM public.view__join__efp_list_records_with_nft_manager_user_tags as record
FROM public.view__join__efp_list_records_with_nft_manager_user_tags_no_prim as record
WHERE
lsl_storage_slot = record.list_storage_location_slot AND
lsl_contract_address = record.list_storage_location_contract_address AND
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -102,11 +102,11 @@ BEGIN
-- match the address parameter
v.record_data = addr_bytea AND
-- Valid record data lookup
v.user IS NOT NULL --AND
v.user IS NOT NULL AND
-- NOT blocked
-- v.has_block_tag = FALSE AND
v.has_block_tag = FALSE AND
-- NOT muted
-- v.has_mute_tag = FALSE
v.has_mute_tag = FALSE
GROUP BY
v.user,
v.token_id,
Expand Down
22 changes: 22 additions & 0 deletions db/queries/api/v1/stats/create_view__events__efp_stats.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
-- migrate:up
-------------------------------------------------------------------------------
-- View: view__efp_stats
-------------------------------------------------------------------------------
CREATE
OR REPLACE VIEW PUBLIC.view__efp_stats AS
SELECT
COUNT(DISTINCT (public.hexlify(record_data))) as address_count,
MAX (token_id) as list_count,
COUNT(*) as list_op_count
FROM
public.view__join__efp_list_records_with_nft_manager_user_tags_no_prim;




-- migrate:down
-------------------------------------------------------------------------------
-- Undo View: view__efp_stats
-------------------------------------------------------------------------------
DROP VIEW
IF EXISTS PUBLIC.view__efp_stats CASCADE;
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
--migrate:up
-------------------------------------------------------------------------------
-- Function: get_common_followers_by_address
-------------------------------------------------------------------------------
CREATE
OR REPLACE FUNCTION query.get_common_followers_by_address(p_user_address types.eth_address, p_target_address types.eth_address) RETURNS TABLE (
address types.eth_address,
name TEXT,
avatar TEXT,
mutuals_rank BIGINT
) LANGUAGE plpgsql AS $$
DECLARE
normalized_u_addr types.eth_address;
normalized_t_addr types.eth_address;
BEGIN
-- Normalize the input address to lowercase
normalized_u_addr := public.normalize_eth_address(p_user_address);
normalized_t_addr := public.normalize_eth_address(p_target_address);

RETURN QUERY

SELECT
public.hexlify(r.record_data)::types.eth_address as address,
l.name,
l.avatar,
l.mutuals_rank as mutuals_rank
FROM public.view__join__efp_list_records_with_nft_manager_user_tags r
INNER JOIN public.efp_leaderboard l ON l.address = public.hexlify(r.record_data)
AND r.user = normalized_u_addr -- user 1
AND r.has_block_tag = FALSE
AND r.has_block_tag = FALSE
AND EXISTS(
SELECT 1
FROM public.view__join__efp_list_records_with_nft_manager_user_tags r2
WHERE r2.user = public.hexlify(r.record_data)
AND public.hexlify(r2.record_data) = normalized_t_addr -- user 2
AND r2.has_block_tag = FALSE
AND r2.has_block_tag = FALSE
);

END;
$$;


--migrate:down
Original file line number Diff line number Diff line change
@@ -0,0 +1,68 @@
--migrate:up
-------------------------------------------------------------------------------
-- Function: get_user_follower_state
-- Description: Retrieves the state of relationship between two addresses,
-- whether the address is following, blocking or muting the list
-- holder.
-- Parameters:
-- - list_id (INT): The primary list id used to identify and filter followers.
-- Returns: A table with
-- 'follower' (types.eth_address),
-- 'efp_list_nft_token_id' (types.efp_list_nft_token_id),
-- tags (types.efp_tag []),
-- 'is_following' (BOOLEAN),
-- 'is_blocked' (BOOLEAN),
-- 'is_muted' (BOOLEAN),
-- representing the list token ID, list user, and tags.
-------------------------------------------------------------------------------
CREATE
OR REPLACE FUNCTION query.get_user_follower_state(account_addr types.eth_address, p_follower_address VARCHAR(42)) RETURNS TABLE (
is_follower BOOLEAN,
is_blocking BOOLEAN,
is_muting BOOLEAN
) LANGUAGE plpgsql AS $$
DECLARE
follower_addr types.eth_address;
follower_list_id BIGINT;
lsl_chain_id BIGINT;
lsl_contract_address VARCHAR(42);
lsl_storage_slot types.efp_list_storage_location_slot;
BEGIN
follower_addr := public.normalize_eth_address(p_follower_address);

SELECT v.primary_list_token_id
INTO follower_list_id
FROM public.view__events__efp_accounts_with_primary_list AS v
WHERE v.address = follower_addr;

SELECT
v.efp_list_storage_location_chain_id,
v.efp_list_storage_location_contract_address,
v.efp_list_storage_location_slot
INTO
lsl_chain_id,
lsl_contract_address,
lsl_storage_slot
FROM
public.view__events__efp_list_storage_locations AS v
WHERE
v.efp_list_nft_token_id = follower_list_id;
RETURN QUERY

SELECT
COALESCE(NOT (record.has_block_tag OR record.has_mute_tag), FALSE) AS is_follower,
COALESCE(record.has_block_tag, FALSE) AS is_blocking,
COALESCE(record.has_mute_tag, FALSE) AS is_muting
FROM public.view__join__efp_list_records_with_nft_manager_user_tags as record
WHERE
lsl_storage_slot = record.list_storage_location_slot AND
lsl_contract_address = record.list_storage_location_contract_address AND
lsl_chain_id = record.list_storage_location_chain_id AND
hexlify(record_data) = account_addr AND
token_id = follower_list_id;
END;
$$;



--migrate:down
22 changes: 22 additions & 0 deletions db/schema/020__tables/001/create_table__efp_recommended.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
-- migrate:up
-------------------------------------------------------------------------------
-- Table: efp_recommended
-------------------------------------------------------------------------------
CREATE TABLE
public.efp_recommended (
"name" TEXT NOT NULL,
"address" types.eth_address NOT NULL,
"avatar" TEXT,
"class" TEXT,
created_at TIMESTAMP
WITH
TIME ZONE DEFAULT CURRENT_TIMESTAMP,
PRIMARY KEY ("address")
);

-- migrate:down
-------------------------------------------------------------------------------
-- Undo Table: efp_recommended
-------------------------------------------------------------------------------
DROP TABLE
IF EXISTS public.efp_recommended CASCADE;
Original file line number Diff line number Diff line change
@@ -0,0 +1,44 @@
-- migrate:up
-------------------------------------------------------------------------------
-- View: view__join__efp_list_records_with_nft_manager_user_tags_no_prim
-------------------------------------------------------------------------------
CREATE
OR REPLACE VIEW PUBLIC.view__join__efp_list_records_with_nft_manager_user_tags_no_prim AS
SELECT
l.nft_chain_id,
l.nft_contract_address,
l.token_id,
l.owner,
l.manager,
l.user,
l.list_storage_location_chain_id,
l.list_storage_location_contract_address,
l.list_storage_location_slot,
record_tags.record,
record_tags.record_version,
record_tags.record_type,
record_tags.record_data,
record_tags.tags,
record_tags.updated_at,
CASE
WHEN 'block' = ANY (record_tags.tags) THEN TRUE
ELSE FALSE
END AS has_block_tag,
CASE
WHEN 'mute' = ANY (record_tags.tags) THEN TRUE
ELSE FALSE
END AS has_mute_tag
FROM
PUBLIC.view__join__efp_list_records_with_tags AS record_tags
LEFT JOIN PUBLIC.efp_lists AS l ON l.list_storage_location_chain_id = record_tags.chain_id
AND l.list_storage_location_contract_address = record_tags.contract_address
AND l.list_storage_location_slot = record_tags.slot;



-- migrate:down
-------------------------------------------------------------------------------
-- Undo View: view__join__efp_list_records_with_nft_manager_user_tags_no_prim
-------------------------------------------------------------------------------
DROP VIEW
IF EXISTS PUBLIC.view__join__efp_list_records_with_nft_manager_user_tags_no_prim CASCADE;
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,7 @@ OR REPLACE VIEW PUBLIC.view__latest_follows AS
SELECT public.hexlify(record_data) as address
FROM public.view__join__efp_list_records_with_nft_manager_user_tags
ORDER BY updated_at DESC
LIMIT 10;
LIMIT 15;



Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
-- migrate:up
-------------------------------------------------------------------------------
-- View: view__events__efp_recommended
-------------------------------------------------------------------------------
CREATE
OR REPLACE VIEW PUBLIC.view__events__efp_recommended AS
(SELECT * FROM public.efp_recommended WHERE class = 'A' ORDER BY random() LIMIT 10)
UNION
(SELECT * FROM public.efp_recommended WHERE class = 'B' ORDER BY random() LIMIT 5)
UNION
(SELECT * FROM public.efp_recommended WHERE class = 'C' ORDER BY random() LIMIT 5);


-- migrate:down
-------------------------------------------------------------------------------
-- Undo View: view__events__efp_recommended
-------------------------------------------------------------------------------
DROP VIEW
IF EXISTS PUBLIC.view__events__efp_recommended CASCADE;
Loading

0 comments on commit 70b8ebb

Please sign in to comment.