diff --git a/biome.json b/biome.json index 90a66fe..97311ce 100644 --- a/biome.json +++ b/biome.json @@ -37,11 +37,11 @@ }, "nursery": { "all": true, - "useImportRestrictions": "off", - "noConsole": "off", - "noUndeclaredDependencies": "off", - "useImportExtensions": "off", - "useTopLevelRegex": "off" + "noProcessEnv": "off", + "noSecrets": "off", + "useConsistentMemberAccessibility": "off", + "useExplicitType": "off", + "useImportRestrictions": "off" }, "complexity": { "all": true, @@ -55,16 +55,20 @@ "noNodejsModules": "off", "noUnusedVariables": "off", "noUndeclaredVariables": "off", + "noUndeclaredDependencies": "off", + "useImportExtensions": "off", "noUnusedImports": "off" }, "performance": { "all": true, - "noAccumulatingSpread": "off" + "noAccumulatingSpread": "off", + "useTopLevelRegex": "off" }, "suspicious": { "all": true, "noRedeclare": "off", "noConsoleLog": "off", + "noConsole": "off", "noExplicitAny": "off", "noEmptyInterface": "off", "useAwait": "off", diff --git a/bun.lockb b/bun.lockb index bc76171..91d4dc5 100755 Binary files a/bun.lockb and b/bun.lockb differ diff --git a/db/queries/api/v1/leaderboard/ranked/create_function__get_built_leaderboard.sql b/db/queries/api/v1/leaderboard/ranked/create_function__get_built_leaderboard.sql new file mode 100644 index 0000000..b8e962e --- /dev/null +++ b/db/queries/api/v1/leaderboard/ranked/create_function__get_built_leaderboard.sql @@ -0,0 +1,210 @@ +--migrate:up +------------------------------------------------------------------------------- +-- Function: get_built_leaderboard +------------------------------------------------------------------------------- +CREATE +OR REPLACE FUNCTION query.get_built_leaderboard () RETURNS TABLE ( + address types.eth_address, + name text, + avatar text, + mutuals_rank BIGINT, + followers_rank BIGINT, + following_rank BIGINT, + blocks_rank BIGINT, + top8_rank BIGINT, + mutuals BIGINT, + following BIGINT, + followers BIGINT, + blocks BIGINT, + top8 BIGINT +) LANGUAGE plpgsql AS $$ + +DECLARE + direction text; + col text; +BEGIN + +-- build a table of all list records with tags + CREATE TEMPORARY TABLE temp_all_records ( + nft_chain_id bigint, + nft_contract_address varchar(42), + token_id bigint, + owner varchar(42), + manager varchar(42), + "user" varchar(42), + record_data bytea, + record_version smallint, + record_type smallint, + tags types.efp_tag[] + ) ON COMMIT DROP; + + INSERT INTO temp_all_records SELECT r.chain_id, + r.contract_address, + l.token_id, + l.owner, + l.manager, + l."user", + r.record_data, + r.record_version, + r.record_type, + array_agg(t.tag) FILTER (WHERE t.tag IS NOT NULL) AS tags + FROM efp_list_records r + LEFT JOIN efp_list_record_tags t ON r.chain_id::bigint = t.chain_id::bigint AND r.contract_address::text = t.contract_address::text AND r.slot::bytea = t.slot::bytea AND r.record = t.record + JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = r.chain_id::bigint AND l.list_storage_location_contract_address::text = r.contract_address::text AND l.list_storage_location_slot::bytea = r.slot::bytea + JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text) + GROUP BY + r.chain_id, + r.contract_address, + l.token_id, + l.owner, + l.manager, + l."user", + r.record_version, + r.record_type, + r.record_data; + +-- ranked by followers + CREATE TEMPORARY TABLE temp_leaderboard_followers ( + address types.eth_address, + followers_count BIGINT, + followers_rank BIGINT, + PRIMARY KEY (address) + ) ON COMMIT DROP; + + INSERT INTO temp_leaderboard_followers SELECT + public.hexlify(v.record_data)::types.eth_address AS address, + COUNT(DISTINCT v.user) AS followers_count, + RANK () OVER ( + ORDER BY COUNT(DISTINCT v.user) DESC NULLS LAST + ) as followers_rank + FROM + temp_all_records AS v + WHERE + -- only list record version 1 + v.record_version = 1 AND + -- address record type (1) + v.record_type = 1 AND + -- valid address format + public.is_valid_address(v.record_data) + GROUP BY + v.record_data + ORDER BY + followers_count DESC, + v.record_data ASC; + +-- ranked by following + CREATE TEMPORARY TABLE temp_leaderboard_following ( + address types.eth_address, + following_count BIGINT, + following_rank BIGINT, + PRIMARY KEY (address) + ) ON COMMIT DROP; + + INSERT INTO temp_leaderboard_following SELECT + v.user AS address, + COUNT(DISTINCT v.record_data) AS following_count, + RANK () OVER ( + ORDER BY COUNT(DISTINCT v.record_data) DESC NULLS LAST + ) as following_rank + FROM + temp_all_records AS v + WHERE + -- only version 1 + v.record_version = 1 AND + -- address record type (1) + v.record_type = 1 AND + -- valid address format + public.is_valid_address(v.record_data) + GROUP BY + v.user + ORDER BY + following_count DESC, + v.user ASC; + +-- ranked by blocked + CREATE TEMPORARY TABLE temp_leaderboard_blocked ( + address types.eth_address, + blocked_count BIGINT, + blocked_rank BIGINT, + PRIMARY KEY (address) + ) ON COMMIT DROP; + + INSERT INTO temp_leaderboard_blocked SELECT + public.hexlify(v.record_data)::types.eth_address AS address, + COUNT(DISTINCT v.user) AS blocked_count, + RANK () OVER ( + ORDER BY COUNT(DISTINCT v.user) DESC NULLS LAST + ) as blocked_rank + FROM + temp_all_records AS v + WHERE + -- only list record version 1 + v.record_version = 1 AND + -- address record type (1) + v.record_type = 1 AND + -- valid address format + public.is_valid_address(v.record_data) AND + -- blocked + v.tags && array['block']::types.efp_tag[] + GROUP BY + v.record_data + ORDER BY + blocked_count DESC, + v.record_data ASC; + +-- ranked by top8 + CREATE TEMPORARY TABLE temp_leaderboard_top8 ( + address types.eth_address, + top8_count BIGINT, + top8_rank BIGINT, + PRIMARY KEY (address) + ) ON COMMIT DROP; + + INSERT INTO temp_leaderboard_top8 SELECT + public.hexlify(v.record_data)::types.eth_address AS address, + COUNT(DISTINCT v.user) AS top8_count, + RANK () OVER ( + ORDER BY COUNT(DISTINCT v.user) DESC NULLS LAST + ) as top8_rank + FROM + temp_all_records AS v + WHERE + v.record_version = 1 AND + v.record_type = 1 AND + public.is_valid_address(v.record_data) AND + v.tags && array['top8']::types.efp_tag[] + GROUP BY + v.record_data + ORDER BY + top8_count DESC, + v.record_data ASC; + + RETURN QUERY + SELECT efp.address, + COALESCE(ens.name) AS ens_name, + COALESCE(ens.avatar) AS ens_avatar, + mut.mutuals_rank, + fers.followers_rank, + fing.following_rank, + blocks.blocked_rank AS blocks_rank, + top8.top8_rank, + COALESCE(mut.mutuals, 0::bigint) AS mutuals, + COALESCE(fing.following_count, 0::bigint) AS following, + COALESCE(fers.followers_count, 0::bigint) AS followers, + COALESCE(blocks.blocked_count, 0::bigint) AS blocks, + COALESCE(top8.top8_count, 0::bigint) AS top8 + FROM efp_addresses efp + LEFT JOIN temp_leaderboard_followers fers(address, followers_count) ON fers.address::text = efp.address::text + LEFT JOIN temp_leaderboard_following fing(address, following_count) ON fing.address::text = efp.address::text + LEFT JOIN temp_leaderboard_blocked blocks(address, blocked_count) ON blocks.address::text = efp.address::text + LEFT JOIN temp_leaderboard_top8 top8(address, top8_count) ON top8.address::text = efp.address::text + LEFT JOIN public.efp_mutuals mut ON mut.address::text = efp.address::text + LEFT JOIN ens_metadata ens ON ens.address::text = efp.address::text + ORDER BY mut.mutuals DESC NULLS LAST; +END; +$$; + + + + +--migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/leaderboard/ranked/create_function__get_built_mutuals.sql b/db/queries/api/v1/leaderboard/ranked/create_function__get_built_mutuals.sql new file mode 100644 index 0000000..d314722 --- /dev/null +++ b/db/queries/api/v1/leaderboard/ranked/create_function__get_built_mutuals.sql @@ -0,0 +1,66 @@ +--migrate:up +------------------------------------------------------------------------------- +-- Function: get_built_mutuals +------------------------------------------------------------------------------- +CREATE +OR REPLACE FUNCTION query.get_built_mutuals () RETURNS TABLE ( + leader types.eth_address, + mutuals BIGINT, + mutuals_rank BIGINT +) LANGUAGE plpgsql AS $$ +BEGIN + +-- build a table of all list records with tags + CREATE TEMPORARY TABLE temp_all_records ( + nft_chain_id bigint, + nft_contract_address varchar(42), + token_id bigint, + owner varchar(42), + manager varchar(42), + "user" varchar(42), + record_data bytea, + record_version smallint, + record_type smallint, + tags types.efp_tag[] + ) ON COMMIT DROP; + + INSERT INTO temp_all_records SELECT r.chain_id, + r.contract_address, + l.token_id, + l.owner, + l.manager, + l."user", + r.record_data, + r.record_version, + r.record_type, + array_agg(t.tag) FILTER (WHERE t.tag IS NOT NULL) AS tags + FROM efp_list_records r + LEFT JOIN efp_list_record_tags t ON r.chain_id::bigint = t.chain_id::bigint AND r.contract_address::text = t.contract_address::text AND r.slot::bytea = t.slot::bytea AND r.record = t.record + JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = r.chain_id::bigint AND l.list_storage_location_contract_address::text = r.contract_address::text AND l.list_storage_location_slot::bytea = r.slot::bytea + JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text) + GROUP BY + r.chain_id, + r.contract_address, + l.token_id, + l.owner, + l.manager, + l."user", + r.record_version, + r.record_type, + r.record_data; + + RETURN QUERY + SELECT + hexlify(r.record_data)::types.eth_address AS leader, + count(r.record_data) AS mutuals, + rank() OVER (ORDER BY (count(r.record_data)) DESC NULLS LAST) AS mutuals_rank + FROM temp_all_records r + JOIN temp_all_records s ON s."user" = hexlify(r.record_data) AND r."user" = hexlify(s.record_data) + GROUP BY r.record_data; +END; +$$; + + + + +--migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/leaderboard/ranked/create_function__get_user_ranks.sql b/db/queries/api/v1/leaderboard/ranked/create_function__get_user_ranks.sql index 8194dca..cd71571 100644 --- a/db/queries/api/v1/leaderboard/ranked/create_function__get_user_ranks.sql +++ b/db/queries/api/v1/leaderboard/ranked/create_function__get_user_ranks.sql @@ -7,6 +7,7 @@ OR REPLACE FUNCTION query.get_user_ranks (p_address types.eth_address) RETURNS T mutuals_rank BIGINT, followers_rank BIGINT, following_rank BIGINT, + top8_rank BIGINT, blocks_rank BIGINT ) LANGUAGE plpgsql AS $$ DECLARE @@ -19,6 +20,7 @@ BEGIN v.mutuals_rank, v.followers_rank, v.following_rank, + v.top8_rank, v.blocks_rank FROM public.efp_leaderboard v WHERE v.address = normalized_addr; diff --git a/db/queries/api/v1/leaderboard/ranked/create_function__get_user_ranks_and_counts.sql b/db/queries/api/v1/leaderboard/ranked/create_function__get_user_ranks_and_counts.sql new file mode 100644 index 0000000..b9497f6 --- /dev/null +++ b/db/queries/api/v1/leaderboard/ranked/create_function__get_user_ranks_and_counts.sql @@ -0,0 +1,43 @@ +--migrate:up +------------------------------------------------------------------------------- +-- Function: get_user_ranks_and_counts +------------------------------------------------------------------------------- +CREATE +OR REPLACE FUNCTION query.get_user_ranks_and_counts (p_address types.eth_address) RETURNS TABLE ( + mutuals_rank BIGINT, + followers_rank BIGINT, + following_rank BIGINT, + top8_rank BIGINT, + blocks_rank BIGINT, + mutuals BIGINT, + following BIGINT, + followers BIGINT, + top8 BIGINT, + blocks BIGINT +) LANGUAGE plpgsql AS $$ +DECLARE + normalized_addr types.eth_address; +BEGIN + normalized_addr := public.normalize_eth_address(p_address); + RETURN QUERY + + SELECT + v.mutuals_rank, + v.followers_rank, + v.following_rank, + v.top8_rank, + v.blocks_rank, + v.mutuals, + v.following, + v.followers, + v.top8, + v.blocks + FROM public.efp_leaderboard v + WHERE v.address = normalized_addr; +END; +$$; + + + + +--migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/lists/followers/create_function__get_all_unique_followers_by_list.sql b/db/queries/api/v1/lists/followers/create_function__get_all_unique_followers_by_list.sql index e3dabc1..7b00aea 100644 --- a/db/queries/api/v1/lists/followers/create_function__get_all_unique_followers_by_list.sql +++ b/db/queries/api/v1/lists/followers/create_function__get_all_unique_followers_by_list.sql @@ -61,63 +61,135 @@ BEGIN END IF; - -- TODO: left join below query against the following query to determine if: - -- - (following) the follower is an unblocked+unmuted list record of by the primary list of p_address - -- - (blocked) the follower is blocked on the primary list of p_address - -- - (muted) the follower is muted on the primary list of p_address + CREATE TEMPORARY TABLE temp_list_records ( + nft_chain_id bigint, + nft_contract_address varchar(42), + token_id bigint, + owner varchar(42), + manager varchar(42), + "user" varchar(42), + list_storage_location_chain_id bigint, + list_storage_location_contract_address varchar(42), + list_storage_location_slot bytea, + record bytea, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at timestamp with TIME ZONE, + has_block_tag boolean, + has_mute_tag boolean + ) ON COMMIT DROP; - RETURN QUERY - SELECT - v.user AS follower, - v.token_id AS efp_list_nft_token_id, - COALESCE(v.tags, '{}') AS tags, - COALESCE(following_info.is_following, FALSE) AS is_following, - COALESCE(following_info.is_blocked, FALSE) AS is_blocked, - COALESCE(following_info.is_muted, FALSE) AS is_muted, - following_info.updated_at - FROM - public.view__join__efp_list_records_with_nft_manager_user_tags AS v - LEFT JOIN LATERAL ( - SELECT - NOT (following.has_block_tag OR following.has_mute_tag) AS is_following, - following.has_block_tag AS is_blocked, - following.has_mute_tag AS is_muted, - following.updated_at AS updated_at + INSERT INTO temp_list_records 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'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_block_tag, + CASE + WHEN 'mute'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_mute_tag + FROM view__join__efp_list_records_with_tags record_tags + LEFT JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = record_tags.chain_id::bigint AND l.list_storage_location_contract_address::text = record_tags.contract_address::text AND l.list_storage_location_slot::bytea = record_tags.slot::bytea + JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text) + WHERE + l.list_storage_location_chain_id = t_list_storage_location_chain_id AND + l.list_storage_location_contract_address = t_list_storage_location_contract_address AND + l.list_storage_location_slot = t_list_storage_location_storage_slot AND + record_tags.record_version = 1 AND + record_tags.record_type = 1; + + CREATE TEMPORARY TABLE temp_addr_follows ( + "user" types.eth_address, + token_id types.efp_list_nft_token_id, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at TIMESTAMP WITH TIME ZONE + ) ON COMMIT DROP; + + INSERT INTO temp_addr_follows SELECT + v.user AS follower, + v.token_id AS efp_list_nft_token_id, + v.record_version, + v.record_type, + v.record_data, + COALESCE(v.tags, '{}') AS tags, + v.updated_at FROM - public.view__join__efp_list_records_with_nft_manager_user_tags AS following + public.view__join__efp_list_records_with_nft_manager_user_tags AS v WHERE - following.list_storage_location_chain_id = t_list_storage_location_chain_id AND - following.list_storage_location_contract_address = t_list_storage_location_contract_address AND - following.list_storage_location_slot = t_list_storage_location_storage_slot AND - following.record_version = 1 AND - following.record_type = 1 AND - public.is_valid_address(following.record_data) AND - PUBLIC.hexlify(following.record_data)::types.eth_address = v.user - ) AS following_info ON TRUE - WHERE - -- only list record version 1 - v.record_version = 1 AND - -- address record type (1) - v.record_type = 1 AND - -- match the address parameter - v.record_data = addr_bytea AND - -- Valid record data lookup - v.user IS NOT NULL - GROUP BY - v.user, - v.token_id, - v.record_version, - v.record_type, - v.record_data, - v.tags, - following_info.is_following, - following_info.is_blocked, - following_info.is_muted, - following_info.updated_at - HAVING - (SELECT get_primary_list FROM query.get_primary_list(v.user)) = v.token_id - ORDER BY - v.user ASC; + -- only list record version 1 + v.record_version = 1 AND + -- address record type (1) + v.record_type = 1 AND + -- match the address parameter + v.record_data = addr_bytea AND + -- Valid record data lookup + v.user IS NOT NULL + GROUP BY + v.user, + v.token_id, + v.record_version, + v.record_type, + v.record_data, + v.tags, + v.updated_at + ORDER BY + v.user ASC; + + RETURN QUERY + SELECT + v.user AS follower, + v.token_id AS efp_list_nft_token_id, + COALESCE(v.tags, '{}') AS tags, + COALESCE(following_info.is_following, FALSE) AS is_following, + COALESCE(following_info.is_blocked, FALSE) AS is_blocked, + COALESCE(following_info.is_muted, FALSE) AS is_muted, + v.updated_at + FROM + temp_addr_follows AS v + LEFT JOIN LATERAL ( + SELECT + NOT (following.has_block_tag OR following.has_mute_tag) AS is_following, + following.has_block_tag AS is_blocked, + following.has_mute_tag AS is_muted, + following.updated_at AS updated_at + FROM + temp_list_records AS following + WHERE + public.is_valid_address(following.record_data) AND + PUBLIC.hexlify(following.record_data)::types.eth_address = v.user + ) AS following_info ON TRUE + GROUP BY + v.user, + v.token_id, + v.record_version, + v.record_type, + v.record_data, + v.tags, + v.updated_at, + following_info.is_following, + following_info.is_blocked, + following_info.is_muted + ORDER BY + v.user ASC; END; $$; diff --git a/db/queries/api/v1/lists/followers/create_function__get_unique_followers_by_list.sql b/db/queries/api/v1/lists/followers/create_function__get_unique_followers_by_list.sql index ab93ac4..316b8d2 100644 --- a/db/queries/api/v1/lists/followers/create_function__get_unique_followers_by_list.sql +++ b/db/queries/api/v1/lists/followers/create_function__get_unique_followers_by_list.sql @@ -61,67 +61,139 @@ BEGIN END IF; - -- TODO: left join below query against the following query to determine if: - -- - (following) the follower is an unblocked+unmuted list record of by the primary list of p_address - -- - (blocked) the follower is blocked on the primary list of p_address - -- - (muted) the follower is muted on the primary list of p_address + CREATE TEMPORARY TABLE temp_list_records ( + nft_chain_id bigint, + nft_contract_address varchar(42), + token_id bigint, + owner varchar(42), + manager varchar(42), + "user" varchar(42), + list_storage_location_chain_id bigint, + list_storage_location_contract_address varchar(42), + list_storage_location_slot bytea, + record bytea, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at timestamp with TIME ZONE, + has_block_tag boolean, + has_mute_tag boolean + ) ON COMMIT DROP; - RETURN QUERY - SELECT - v.user AS follower, - v.token_id AS efp_list_nft_token_id, - COALESCE(v.tags, '{}') AS tags, - COALESCE(following_info.is_following, FALSE) AS is_following, - COALESCE(following_info.is_blocked, FALSE) AS is_blocked, - COALESCE(following_info.is_muted, FALSE) AS is_muted, - v.updated_at - FROM - public.view__join__efp_list_records_with_nft_manager_user_tags AS v - LEFT JOIN LATERAL ( - SELECT - NOT (following.has_block_tag OR following.has_mute_tag) AS is_following, - following.has_block_tag AS is_blocked, - following.has_mute_tag AS is_muted, - following.updated_at AS updated_at + INSERT INTO temp_list_records 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'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_block_tag, + CASE + WHEN 'mute'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_mute_tag + FROM view__join__efp_list_records_with_tags record_tags + LEFT JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = record_tags.chain_id::bigint AND l.list_storage_location_contract_address::text = record_tags.contract_address::text AND l.list_storage_location_slot::bytea = record_tags.slot::bytea + JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text) + WHERE + l.list_storage_location_chain_id = t_list_storage_location_chain_id AND + l.list_storage_location_contract_address = t_list_storage_location_contract_address AND + l.list_storage_location_slot = t_list_storage_location_storage_slot AND + record_tags.record_version = 1 AND + record_tags.record_type = 1; + + CREATE TEMPORARY TABLE temp_addr_follows ( + "user" types.eth_address, + token_id types.efp_list_nft_token_id, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at TIMESTAMP WITH TIME ZONE + ) ON COMMIT DROP; + + INSERT INTO temp_addr_follows SELECT + v.user AS follower, + v.token_id AS efp_list_nft_token_id, + v.record_version, + v.record_type, + v.record_data, + COALESCE(v.tags, '{}') AS tags, + v.updated_at FROM - public.view__join__efp_list_records_with_nft_manager_user_tags AS following + public.view__join__efp_list_records_with_nft_manager_user_tags AS v WHERE - following.list_storage_location_chain_id = t_list_storage_location_chain_id AND - following.list_storage_location_contract_address = t_list_storage_location_contract_address AND - following.list_storage_location_slot = t_list_storage_location_storage_slot AND - following.record_version = 1 AND - following.record_type = 1 AND - public.is_valid_address(following.record_data) AND - PUBLIC.hexlify(following.record_data)::types.eth_address = v.user - ) AS following_info ON TRUE - WHERE - -- only list record version 1 - v.record_version = 1 AND - -- address record type (1) - v.record_type = 1 AND - -- match the address parameter - v.record_data = addr_bytea AND - -- Valid record data lookup - v.user IS NOT NULL AND - -- NOT blocked - v.has_block_tag = FALSE AND - -- NOT muted - v.has_mute_tag = FALSE - GROUP BY - v.user, - v.token_id, - v.record_version, - v.record_type, - v.record_data, - v.tags, - v.updated_at, - following_info.is_following, - following_info.is_blocked, - following_info.is_muted - HAVING - (SELECT get_primary_list FROM query.get_primary_list(v.user)) = v.token_id - ORDER BY - v.user ASC; + -- only list record version 1 + v.record_version = 1 AND + -- address record type (1) + v.record_type = 1 AND + -- match the address parameter + v.record_data = addr_bytea AND + -- Valid record data lookup + v.user IS NOT NULL AND + -- NOT blocked + v.has_block_tag = FALSE AND + -- NOT muted + v.has_mute_tag = FALSE + GROUP BY + v.user, + v.token_id, + v.record_version, + v.record_type, + v.record_data, + v.tags, + v.updated_at + ORDER BY + v.user ASC; + + RETURN QUERY + SELECT + v.user AS follower, + v.token_id AS efp_list_nft_token_id, + COALESCE(v.tags, '{}') AS tags, + COALESCE(following_info.is_following, FALSE) AS is_following, + COALESCE(following_info.is_blocked, FALSE) AS is_blocked, + COALESCE(following_info.is_muted, FALSE) AS is_muted, + v.updated_at + FROM + temp_addr_follows AS v + LEFT JOIN LATERAL ( + SELECT + NOT (following.has_block_tag OR following.has_mute_tag) AS is_following, + following.has_block_tag AS is_blocked, + following.has_mute_tag AS is_muted, + following.updated_at AS updated_at + FROM + temp_list_records AS following + WHERE + public.is_valid_address(following.record_data) AND + PUBLIC.hexlify(following.record_data)::types.eth_address = v.user + ) AS following_info ON TRUE + GROUP BY + v.user, + v.token_id, + v.record_version, + v.record_type, + v.record_data, + v.tags, + v.updated_at, + following_info.is_following, + following_info.is_blocked, + following_info.is_muted + ORDER BY + v.user ASC; END; $$; diff --git a/db/queries/api/v1/lists/followers/create_function__get_unique_followers_page_by_list.sql b/db/queries/api/v1/lists/followers/create_function__get_unique_followers_page_by_list.sql index 9b4e23c..9bb7bb7 100644 --- a/db/queries/api/v1/lists/followers/create_function__get_unique_followers_page_by_list.sql +++ b/db/queries/api/v1/lists/followers/create_function__get_unique_followers_page_by_list.sql @@ -113,8 +113,8 @@ BEGIN following_info.is_following, following_info.is_blocked, following_info.is_muted - HAVING - (SELECT get_primary_list FROM query.get_primary_list(v.user)) = v.token_id + -- HAVING + -- (SELECT get_primary_list FROM query.get_primary_list(v.user)) = v.token_id ORDER BY v.user ASC LIMIT p_limit diff --git a/db/queries/api/v1/lists/following/create_function__get_sorted_following_by_list_tags.sql b/db/queries/api/v1/lists/following/create_function__get_sorted_following_by_list_tags.sql index f381ef1..85f43fe 100644 --- a/db/queries/api/v1/lists/following/create_function__get_sorted_following_by_list_tags.sql +++ b/db/queries/api/v1/lists/following/create_function__get_sorted_following_by_list_tags.sql @@ -42,9 +42,9 @@ BEGIN LEFT JOIN public.efp_leaderboard l ON v.following_address = l.address WHERE v.tags && p_tags ORDER BY - (CASE WHEN direction = 'followers' THEN l.followers END) DESC, - (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC, - (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC; + (CASE WHEN direction = 'followers' THEN l.followers END) DESC NULLS LAST, + (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC NULLS LAST, + (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC NULLS LAST; ELSE RETURN QUERY SELECT @@ -58,9 +58,9 @@ BEGIN LEFT JOIN public.efp_leaderboard l ON v.following_address = l.address ORDER BY - (CASE WHEN direction = 'followers' THEN l.followers END) DESC, - (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC, - (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC; + (CASE WHEN direction = 'followers' THEN l.followers END) DESC NULLS LAST, + (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC NULLS LAST, + (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC NULLS LAST; END IF; END; $$; diff --git a/db/queries/api/v1/lists/recommended/create_function__get_algo_recommended_by_list.sql b/db/queries/api/v1/lists/recommended/create_function__get_algo_recommended_by_list.sql new file mode 100644 index 0000000..a201bdd --- /dev/null +++ b/db/queries/api/v1/lists/recommended/create_function__get_algo_recommended_by_list.sql @@ -0,0 +1,149 @@ +--migrate:up +------------------------------------------------------------------------------- +-- +------------------------------------------------------------------------------- +CREATE +OR REPLACE FUNCTION query.get_algo_recommended_by_list (p_list_id INT, p_limit BIGINT, p_offset BIGINT) RETURNS TABLE ( + address types.eth_address, + name TEXT, + avatar TEXT, + records TEXT, + followers BIGINT, + following BIGINT, + mutuals_rank BIGINT, + followers_rank BIGINT, + following_rank BIGINT, + top8_rank BIGINT, + blocks_rank BIGINT +) LANGUAGE plpgsql AS $$ +DECLARE + normalized_addr types.eth_address; + t_list_storage_location_chain_id BIGINT; + t_list_storage_location_contract_address VARCHAR(42); + t_list_storage_location_storage_slot types.efp_list_storage_location_slot; +BEGIN + + SELECT v.user + INTO normalized_addr + FROM public.view__join__efp_lists_with_metadata as v + WHERE token_id = p_list_id; + + -- If no primary list token id is found, return an empty result set + IF p_list_id IS NOT NULL THEN + + -- Now determine the list storage location for the primary list token id + SELECT + v.efp_list_storage_location_chain_id, + v.efp_list_storage_location_contract_address, + v.efp_list_storage_location_slot + INTO + t_list_storage_location_chain_id, + t_list_storage_location_contract_address, + t_list_storage_location_storage_slot + FROM + public.view__events__efp_list_storage_locations AS v + WHERE + v.efp_list_nft_token_id = p_list_id; + END IF; + + CREATE TEMPORARY TABLE temp_follow_records ( + nft_chain_id bigint, + nft_contract_address varchar(42), + token_id bigint, + owner varchar(42), + manager varchar(42), + "user" varchar(42), + list_storage_location_chain_id bigint, + list_storage_location_contract_address varchar(42), + list_storage_location_slot bytea, + record bytea, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at timestamp with TIME ZONE, + has_block_tag boolean, + has_mute_tag boolean + ) ON COMMIT DROP; + + INSERT INTO temp_follow_records 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'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_block_tag, + CASE + WHEN 'mute'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_mute_tag + FROM view__join__efp_list_records_with_tags record_tags + JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = record_tags.chain_id::bigint AND l.list_storage_location_contract_address::text = record_tags.contract_address::text AND l.list_storage_location_slot::bytea = record_tags.slot::bytea + JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text) + WHERE + l.list_storage_location_chain_id = t_list_storage_location_chain_id AND + l.list_storage_location_contract_address = t_list_storage_location_contract_address AND + l.list_storage_location_slot = t_list_storage_location_storage_slot AND + record_tags.record_version = 1 AND + record_tags.record_type = 1; + + RETURN QUERY + SELECT + m.address AS address, + m.name AS "name", + m.avatar AS avatar, + m.records::text, + b.followers, + b.following, + b.mutuals_rank, + b.followers_rank, + b.following_rank, + b.top8_rank, + b.blocks_rank + FROM public.efp_leaderboard b + LEFT JOIN public.ens_metadata m ON m.address = b.address + LEFT JOIN public.view__trending trending ON trending.address = b.address + WHERE + b.address <> normalized_addr AND + b.following > 0 AND + b.name IS NOT NULL AND + b.avatar IS NOT NULL AND + NOT EXISTS ( + SELECT 1 + FROM temp_follow_records l + WHERE l."user" = normalized_addr AND b.address = PUBLIC.hexlify(l.record_data)::types.eth_address + ) + GROUP BY + m.address, + m.name, + m.avatar, + m.records::text, + b.followers, + b.following, + b.mutuals_rank, + b.followers_rank, + b.following_rank, + b.top8_rank, + b.blocks_rank, + trending.count + ORDER BY trending.count DESC NULLS LAST + LIMIT p_limit + OFFSET p_offset; +END; +$$; + + + +--migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/lists/recommended/create_function__get_recommended_stack_by_list.sql b/db/queries/api/v1/lists/recommended/create_function__get_recommended_stack_by_list.sql new file mode 100644 index 0000000..f48bbd0 --- /dev/null +++ b/db/queries/api/v1/lists/recommended/create_function__get_recommended_stack_by_list.sql @@ -0,0 +1,51 @@ +--migrate:up +------------------------------------------------------------------------------- +-- +------------------------------------------------------------------------------- +CREATE +OR REPLACE FUNCTION query.get_recommended_stack_by_list (p_list_id INT, p_limit BIGINT, p_offset BIGINT) RETURNS TABLE ( + address types.eth_address, + name TEXT, + avatar TEXT, + records TEXT, + followers BIGINT, + following BIGINT, + mutuals_rank BIGINT, + followers_rank BIGINT, + following_rank BIGINT, + top8_rank BIGINT, + blocks_rank BIGINT +) LANGUAGE plpgsql AS $$ +BEGIN + RETURN QUERY + + SELECT + r.address, + m.name, + m.avatar, + m.records::text, + l.followers, + l.following, + l.mutuals_rank, + l.followers_rank, + l.following_rank, + l.top8_rank, + l.blocks_rank + FROM public.efp_recommended r + LEFT JOIN public.efp_leaderboard l ON l.address = r.address + LEFT JOIN public.ens_metadata m ON m.address = r.address + WHERE NOT EXISTS ( + SELECT 1 + FROM query.get_all_following_by_list(p_list_id) fol + WHERE r.address = fol.following_address + ) + ORDER BY r.index ASC + LIMIT p_limit + OFFSET p_offset; +END; +$$; + + + + +--migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/stats/create_function__get_unique_minters.sql b/db/queries/api/v1/stats/create_function__get_unique_minters.sql new file mode 100644 index 0000000..2df8f08 --- /dev/null +++ b/db/queries/api/v1/stats/create_function__get_unique_minters.sql @@ -0,0 +1,31 @@ +--migrate:up +------------------------------------------------------------------------------- +-- Function: get_unique_minters +------------------------------------------------------------------------------- +CREATE +OR REPLACE FUNCTION query.get_unique_minters (p_limit INT, p_offset INT) RETURNS TABLE ( + address types.eth_address, + name text, + avatar text, + list BIGINT +) LANGUAGE plpgsql AS $$ +BEGIN + RETURN QUERY + SELECT + l."user" as address, + meta.name, + meta.avatar, + MAX(l.token_id) as list + FROM public.view__join__efp_lists_with_metadata l + LEFT JOIN public.ens_metadata meta ON l."user" = meta.address + GROUP BY "user", meta.name, meta.avatar + ORDER BY list DESC + LIMIT p_limit + OFFSET p_offset; +END; +$$; + + + + +--migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/stats/create_view__events__efp_stats.sql b/db/queries/api/v1/stats/create_view__events__efp_stats.sql index 122aa43..44f2675 100644 --- a/db/queries/api/v1/stats/create_view__events__efp_stats.sql +++ b/db/queries/api/v1/stats/create_view__events__efp_stats.sql @@ -5,11 +5,19 @@ 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; + ( SELECT count(DISTINCT(record_data)) + FROM efp_list_records r + WHERE r.record_version = 1 + AND r.record_type = 1) AS address_count, + ( SELECT count(*) AS count + FROM efp_lists) AS list_count, + ( SELECT count(*) AS count + FROM events + WHERE events.event_name::text = 'ListOp'::text) AS list_op_count, + ( SELECT count(DISTINCT events.event_args ->> 'to'::text) AS count + FROM events + WHERE events.event_name::text = 'Transfer'::text AND events.event_args @> '{"from": "0x0000000000000000000000000000000000000000"}'::jsonb) AS user_count; + diff --git a/db/queries/api/v1/users/commonFollowers/create_function__get_common_followers_by_address.sql b/db/queries/api/v1/users/commonFollowers/create_function__get_common_followers_by_address.sql index e750336..bca5574 100644 --- a/db/queries/api/v1/users/commonFollowers/create_function__get_common_followers_by_address.sql +++ b/db/queries/api/v1/users/commonFollowers/create_function__get_common_followers_by_address.sql @@ -12,32 +12,154 @@ OR REPLACE FUNCTION query.get_common_followers_by_address(p_user_address types.e DECLARE normalized_u_addr types.eth_address; normalized_t_addr types.eth_address; + addr_t_bytea bytea; + u_primary_list_token_id BIGINT; + u_list_storage_location_chain_id BIGINT; + u_list_storage_location_contract_address VARCHAR(42); + u_list_storage_location_storage_slot types.efp_list_storage_location_slot; 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 v.primary_list_token_id + INTO u_primary_list_token_id + FROM public.view__events__efp_accounts_with_primary_list AS v + WHERE v.address = normalized_u_addr; + + IF u_primary_list_token_id IS NOT NULL THEN + + -- Now determine the list storage location for the primary list token id + SELECT + v.efp_list_storage_location_chain_id, + v.efp_list_storage_location_contract_address, + v.efp_list_storage_location_slot + INTO + u_list_storage_location_chain_id, + u_list_storage_location_contract_address, + u_list_storage_location_storage_slot + FROM + public.view__events__efp_list_storage_locations AS v + WHERE + v.efp_list_nft_token_id = u_primary_list_token_id; + END IF; + + addr_t_bytea := public.unhexlify(normalized_t_addr); + + + CREATE TEMPORARY TABLE temp_list_records ( + nft_chain_id bigint, + nft_contract_address varchar(42), + token_id bigint, + owner varchar(42), + manager varchar(42), + "user" varchar(42), + list_storage_location_chain_id bigint, + list_storage_location_contract_address varchar(42), + list_storage_location_slot bytea, + record bytea, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at timestamp with TIME ZONE, + has_block_tag boolean, + has_mute_tag boolean + ) ON COMMIT DROP; + INSERT INTO temp_list_records 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'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_block_tag, + CASE + WHEN 'mute'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_mute_tag + FROM view__join__efp_list_records_with_tags record_tags + LEFT JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = record_tags.chain_id::bigint AND l.list_storage_location_contract_address::text = record_tags.contract_address::text AND l.list_storage_location_slot::bytea = record_tags.slot::bytea + JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text) + WHERE + l.list_storage_location_chain_id = u_list_storage_location_chain_id AND + l.list_storage_location_contract_address = u_list_storage_location_contract_address AND + l.list_storage_location_slot = u_list_storage_location_storage_slot AND + record_tags.record_version = 1 AND + record_tags.record_type = 1; + + CREATE TEMPORARY TABLE temp_addr_follows ( + "user" types.eth_address, + token_id types.efp_list_nft_token_id, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at TIMESTAMP WITH TIME ZONE + ) ON COMMIT DROP; + + INSERT INTO temp_addr_follows SELECT + v.user AS follower, + v.token_id AS efp_list_nft_token_id, + v.record_version, + v.record_type, + v.record_data, + COALESCE(v.tags, '{}') AS tags, + v.updated_at + FROM + public.view__join__efp_list_records_with_nft_manager_user_tags AS v + WHERE + -- only list record version 1 + v.record_version = 1 AND + -- address record type (1) + v.record_type = 1 AND + -- match the address parameter + v.record_data = addr_t_bytea AND + -- Valid record data lookup + v.user IS NOT NULL AND + -- NOT blocked + v.has_block_tag = FALSE AND + -- NOT muted + v.has_mute_tag = FALSE + GROUP BY + v.user, + v.token_id, + v.record_version, + v.record_type, + v.record_data, + v.tags, + v.updated_at + ORDER BY + v.user ASC; + +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 +FROM temp_list_records 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 + FROM temp_addr_follows 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; $$; diff --git a/db/queries/api/v1/users/commonFollowers/create_function__test_get_common_followers_by_address.sql b/db/queries/api/v1/users/commonFollowers/create_function__test_get_common_followers_by_address.sql new file mode 100644 index 0000000..2be8102 --- /dev/null +++ b/db/queries/api/v1/users/commonFollowers/create_function__test_get_common_followers_by_address.sql @@ -0,0 +1,101 @@ +--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; + addr_u_bytea bytea; + addr_t_bytea bytea; + u_primary_list_token_id BIGINT; + t_primary_list_token_id BIGINT; + u_list_storage_location_chain_id BIGINT; + u_list_storage_location_contract_address VARCHAR(42); + u_list_storage_location_storage_slot types.efp_list_storage_location_slot; + t_list_storage_location_chain_id BIGINT; + t_list_storage_location_contract_address VARCHAR(42); + t_list_storage_location_storage_slot types.efp_list_storage_location_slot; +BEGIN + -- Normalize the input address to lowercase + normalized_u_addr := public.normalize_eth_address(p_user_address); + addr_u_bytea := public.unhexlify(normalized_u_addr); + + SELECT v.primary_list_token_id + INTO u_primary_list_token_id + FROM public.view__events__efp_accounts_with_primary_list AS v + WHERE v.address = normalized_u_addr; + + IF u_primary_list_token_id IS NOT NULL THEN + + -- Now determine the list storage location for the primary list token id + SELECT + v.efp_list_storage_location_chain_id, + v.efp_list_storage_location_contract_address, + v.efp_list_storage_location_slot + INTO + u_list_storage_location_chain_id, + u_list_storage_location_contract_address, + u_list_storage_location_storage_slot + FROM + public.view__events__efp_list_storage_locations AS v + WHERE + v.efp_list_nft_token_id = u_primary_list_token_id; + END IF; + + normalized_t_addr := public.normalize_eth_address(p_target_address); + addr_t_bytea := public.unhexlify(normalized_t_addr); + + SELECT v.primary_list_token_id + INTO t_primary_list_token_id + FROM public.view__events__efp_accounts_with_primary_list AS v + WHERE v.address = normalized_t_addr; + + IF t_primary_list_token_id IS NOT NULL THEN + -- Now determine the list storage location for the primary list token id + SELECT + v.efp_list_storage_location_chain_id, + v.efp_list_storage_location_contract_address, + v.efp_list_storage_location_slot + INTO + t_list_storage_location_chain_id, + t_list_storage_location_contract_address, + t_list_storage_location_storage_slot + FROM + public.view__events__efp_list_storage_locations AS v + WHERE + v.efp_list_nft_token_id = t_primary_list_token_id; + END IF; + +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 \ No newline at end of file diff --git a/db/queries/api/v1/users/followers/create_function__get_all_sorted_followers_by_address_tags.sql b/db/queries/api/v1/users/followers/create_function__get_all_sorted_followers_by_address_tags.sql new file mode 100644 index 0000000..b4f22ba --- /dev/null +++ b/db/queries/api/v1/users/followers/create_function__get_all_sorted_followers_by_address_tags.sql @@ -0,0 +1,62 @@ +--migrate:up +------------------------------------------------------------------------------- +-- +------------------------------------------------------------------------------- +CREATE +OR REPLACE FUNCTION query.get_all_sorted_followers_by_address_tags (p_address types.eth_address, p_tags types.efp_tag[], p_sort text) RETURNS TABLE ( + 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, + updated_at TIMESTAMP WITH TIME ZONE +) LANGUAGE plpgsql AS $$ +DECLARE + direction text; + normalized_addr types.eth_address; +BEGIN + direction = LOWER(p_sort); + normalized_addr := public.normalize_eth_address(p_address); + + IF cardinality(p_tags) > 0 THEN + RETURN QUERY + SELECT + v.follower, + v.efp_list_nft_token_id, + v.tags, + v.is_following, + v.is_blocked, + v.is_muted, + v.updated_at + FROM query.get_all_unique_followers(normalized_addr) v + LEFT JOIN public.efp_leaderboard l ON v.follower = l.address + WHERE v.tags && p_tags + ORDER BY + (CASE WHEN direction = 'followers' THEN l.followers END) DESC NULLS LAST, + (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC NULLS LAST, + (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC NULLS LAST; + ELSE + RETURN QUERY + SELECT + v.follower, + v.efp_list_nft_token_id, + v.tags, + v.is_following, + v.is_blocked, + v.is_muted, + v.updated_at + FROM query.get_all_unique_followers(normalized_addr) v + LEFT JOIN public.efp_leaderboard l ON v.follower = l.address + ORDER BY + (CASE WHEN direction = 'followers' THEN l.followers END) DESC NULLS LAST, + (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC NULLS LAST, + (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC NULLS LAST; + END IF; +END; +$$; + + + + +--migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/users/followers/create_function__get_all_unique_followers.sql b/db/queries/api/v1/users/followers/create_function__get_all_unique_followers.sql new file mode 100644 index 0000000..988aef3 --- /dev/null +++ b/db/queries/api/v1/users/followers/create_function__get_all_unique_followers.sql @@ -0,0 +1,199 @@ +--migrate:up +------------------------------------------------------------------------------- +-- Function: get_all_unique_followers +-- Description: Retrieves a distinct list of followers for a specified address, +-- de-duplicating by 'list_user'. This ensures each follower is +-- listed once, even if associated with multiple tokens. +-- Parameters: +-- - address (text): Address 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_all_unique_followers(p_address VARCHAR(42)) RETURNS TABLE ( + 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, + updated_at TIMESTAMP WITH TIME ZONE +) LANGUAGE plpgsql AS $$ +DECLARE + normalized_addr types.eth_address; + addr_bytea bytea; + primary_list_token_id BIGINT; + t_list_storage_location_chain_id BIGINT; + t_list_storage_location_contract_address VARCHAR(42); + t_list_storage_location_storage_slot types.efp_list_storage_location_slot; +BEGIN + -- Normalize the input address to lowercase + normalized_addr := public.normalize_eth_address(p_address); + addr_bytea := public.unhexlify(normalized_addr); + + -- Get the primary list token id + SELECT v.primary_list_token_id + INTO primary_list_token_id + FROM public.view__events__efp_accounts_with_primary_list AS v + WHERE v.address = normalized_addr; + + -- If no primary list token id is found, return an empty result set + IF primary_list_token_id IS NOT NULL THEN + + -- Now determine the list storage location for the primary list token id + SELECT + v.efp_list_storage_location_chain_id, + v.efp_list_storage_location_contract_address, + v.efp_list_storage_location_slot + INTO + t_list_storage_location_chain_id, + t_list_storage_location_contract_address, + t_list_storage_location_storage_slot + FROM + public.view__events__efp_list_storage_locations AS v + WHERE + v.efp_list_nft_token_id = primary_list_token_id; + + END IF; + + CREATE TEMPORARY TABLE temp_list_records ( + nft_chain_id bigint, + nft_contract_address varchar(42), + token_id bigint, + owner varchar(42), + manager varchar(42), + "user" varchar(42), + list_storage_location_chain_id bigint, + list_storage_location_contract_address varchar(42), + list_storage_location_slot bytea, + record bytea, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at timestamp with TIME ZONE, + has_block_tag boolean, + has_mute_tag boolean + ) ON COMMIT DROP; + + INSERT INTO temp_list_records 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'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_block_tag, + CASE + WHEN 'mute'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_mute_tag + FROM view__join__efp_list_records_with_tags record_tags + LEFT JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = record_tags.chain_id::bigint AND l.list_storage_location_contract_address::text = record_tags.contract_address::text AND l.list_storage_location_slot::bytea = record_tags.slot::bytea + JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text) + WHERE + l.list_storage_location_chain_id = t_list_storage_location_chain_id AND + l.list_storage_location_contract_address = t_list_storage_location_contract_address AND + l.list_storage_location_slot = t_list_storage_location_storage_slot AND + record_tags.record_version = 1 AND + record_tags.record_type = 1; + + CREATE TEMPORARY TABLE temp_addr_follows ( + "user" types.eth_address, + token_id types.efp_list_nft_token_id, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at TIMESTAMP WITH TIME ZONE + ) ON COMMIT DROP; + + INSERT INTO temp_addr_follows SELECT + v.user AS follower, + v.token_id AS efp_list_nft_token_id, + v.record_version, + v.record_type, + v.record_data, + COALESCE(v.tags, '{}') AS tags, + v.updated_at + FROM + public.view__join__efp_list_records_with_nft_manager_user_tags AS v + WHERE + -- only list record version 1 + v.record_version = 1 AND + -- address record type (1) + v.record_type = 1 AND + -- match the address parameter + v.record_data = addr_bytea AND + -- Valid record data lookup + v.user IS NOT NULL + GROUP BY + v.user, + v.token_id, + v.record_version, + v.record_type, + v.record_data, + v.tags, + v.updated_at + ORDER BY + v.user ASC; + + RETURN QUERY + SELECT + v.user AS follower, + v.token_id AS efp_list_nft_token_id, + COALESCE(v.tags, '{}') AS tags, + COALESCE(following_info.is_following, FALSE) AS is_following, + COALESCE(following_info.is_blocked, FALSE) AS is_blocked, + COALESCE(following_info.is_muted, FALSE) AS is_muted, + v.updated_at + FROM + temp_addr_follows AS v + LEFT JOIN LATERAL ( + SELECT + NOT (following.has_block_tag OR following.has_mute_tag) AS is_following, + following.has_block_tag AS is_blocked, + following.has_mute_tag AS is_muted, + following.updated_at AS updated_at + FROM + temp_list_records AS following + WHERE + public.is_valid_address(following.record_data) AND + PUBLIC.hexlify(following.record_data)::types.eth_address = v.user + ) AS following_info ON TRUE + GROUP BY + v.user, + v.token_id, + v.record_version, + v.record_type, + v.record_data, + v.tags, + v.updated_at, + following_info.is_following, + following_info.is_blocked, + following_info.is_muted + ORDER BY + v.user ASC; +END; +$$; + + + +--migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/users/followers/create_function__get_unique_followers.sql b/db/queries/api/v1/users/followers/create_function__get_unique_followers.sql index e8cd005..cb32828 100644 --- a/db/queries/api/v1/users/followers/create_function__get_unique_followers.sql +++ b/db/queries/api/v1/users/followers/create_function__get_unique_followers.sql @@ -62,67 +62,139 @@ BEGIN END IF; - -- TODO: left join below query against the following query to determine if: - -- - (following) the follower is an unblocked+unmuted list record of by the primary list of p_address - -- - (blocked) the follower is blocked on the primary list of p_address - -- - (muted) the follower is muted on the primary list of p_address + CREATE TEMPORARY TABLE temp_list_records ( + nft_chain_id bigint, + nft_contract_address varchar(42), + token_id bigint, + owner varchar(42), + manager varchar(42), + "user" varchar(42), + list_storage_location_chain_id bigint, + list_storage_location_contract_address varchar(42), + list_storage_location_slot bytea, + record bytea, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at timestamp with TIME ZONE, + has_block_tag boolean, + has_mute_tag boolean + ) ON COMMIT DROP; - RETURN QUERY - SELECT - v.user AS follower, - v.token_id AS efp_list_nft_token_id, - COALESCE(v.tags, '{}') AS tags, - COALESCE(following_info.is_following, FALSE) AS is_following, - COALESCE(following_info.is_blocked, FALSE) AS is_blocked, - COALESCE(following_info.is_muted, FALSE) AS is_muted, - v.updated_at - FROM - public.view__join__efp_list_records_with_nft_manager_user_tags AS v - LEFT JOIN LATERAL ( - SELECT - NOT (following.has_block_tag OR following.has_mute_tag) AS is_following, - following.has_block_tag AS is_blocked, - following.has_mute_tag AS is_muted + INSERT INTO temp_list_records 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'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_block_tag, + CASE + WHEN 'mute'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_mute_tag + FROM view__join__efp_list_records_with_tags record_tags + LEFT JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = record_tags.chain_id::bigint AND l.list_storage_location_contract_address::text = record_tags.contract_address::text AND l.list_storage_location_slot::bytea = record_tags.slot::bytea + JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text) + WHERE + l.list_storage_location_chain_id = t_list_storage_location_chain_id AND + l.list_storage_location_contract_address = t_list_storage_location_contract_address AND + l.list_storage_location_slot = t_list_storage_location_storage_slot AND + record_tags.record_version = 1 AND + record_tags.record_type = 1; + + CREATE TEMPORARY TABLE temp_addr_follows ( + "user" types.eth_address, + token_id types.efp_list_nft_token_id, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at TIMESTAMP WITH TIME ZONE + ) ON COMMIT DROP; + + INSERT INTO temp_addr_follows SELECT + v.user AS follower, + v.token_id AS efp_list_nft_token_id, + v.record_version, + v.record_type, + v.record_data, + COALESCE(v.tags, '{}') AS tags, + v.updated_at FROM - public.view__join__efp_list_records_with_nft_manager_user_tags AS following + public.view__join__efp_list_records_with_nft_manager_user_tags AS v WHERE - following.list_storage_location_chain_id = t_list_storage_location_chain_id AND - following.list_storage_location_contract_address = t_list_storage_location_contract_address AND - following.list_storage_location_slot = t_list_storage_location_storage_slot AND - following.record_version = 1 AND - following.record_type = 1 AND - public.is_valid_address(following.record_data) AND - PUBLIC.hexlify(following.record_data)::types.eth_address = v.user - ) AS following_info ON TRUE - WHERE - -- only list record version 1 - v.record_version = 1 AND - -- address record type (1) - v.record_type = 1 AND - -- match the address parameter - v.record_data = addr_bytea AND - -- Valid record data lookup - v.user IS NOT NULL AND - -- NOT blocked - v.has_block_tag = FALSE AND - -- NOT muted - v.has_mute_tag = FALSE - GROUP BY - v.user, - v.token_id, - v.record_version, - v.record_type, - v.record_data, - v.tags, - v.updated_at, - following_info.is_following, - following_info.is_blocked, - following_info.is_muted - HAVING - (SELECT get_primary_list FROM query.get_primary_list(v.user)) = v.token_id - ORDER BY - v.updated_at DESC, - v.user ASC; + -- only list record version 1 + v.record_version = 1 AND + -- address record type (1) + v.record_type = 1 AND + -- match the address parameter + v.record_data = addr_bytea AND + -- Valid record data lookup + v.user IS NOT NULL AND + -- NOT blocked + v.has_block_tag = FALSE AND + -- NOT muted + v.has_mute_tag = FALSE + GROUP BY + v.user, + v.token_id, + v.record_version, + v.record_type, + v.record_data, + v.tags, + v.updated_at + ORDER BY + v.user ASC; + + RETURN QUERY + SELECT + v.user AS follower, + v.token_id AS efp_list_nft_token_id, + COALESCE(v.tags, '{}') AS tags, + COALESCE(following_info.is_following, FALSE) AS is_following, + COALESCE(following_info.is_blocked, FALSE) AS is_blocked, + COALESCE(following_info.is_muted, FALSE) AS is_muted, + v.updated_at + FROM + temp_addr_follows AS v + LEFT JOIN LATERAL ( + SELECT + NOT (following.has_block_tag OR following.has_mute_tag) AS is_following, + following.has_block_tag AS is_blocked, + following.has_mute_tag AS is_muted, + following.updated_at AS updated_at + FROM + temp_list_records AS following + WHERE + public.is_valid_address(following.record_data) AND + PUBLIC.hexlify(following.record_data)::types.eth_address = v.user + ) AS following_info ON TRUE + GROUP BY + v.user, + v.token_id, + v.record_version, + v.record_type, + v.record_data, + v.tags, + v.updated_at, + following_info.is_following, + following_info.is_blocked, + following_info.is_muted + ORDER BY + v.user ASC; END; $$; diff --git a/db/queries/api/v1/users/followers/create_function__get_unique_followers_page.sql b/db/queries/api/v1/users/followers/create_function__get_unique_followers_page.sql index 18e8dc0..268cfc9 100644 --- a/db/queries/api/v1/users/followers/create_function__get_unique_followers_page.sql +++ b/db/queries/api/v1/users/followers/create_function__get_unique_followers_page.sql @@ -117,8 +117,8 @@ BEGIN following_info.is_following, following_info.is_blocked, following_info.is_muted - HAVING - (SELECT get_primary_list FROM query.get_primary_list(v.user)) = v.token_id + -- HAVING + -- (SELECT get_primary_list FROM query.get_primary_list(v.user)) = v.token_id ORDER BY v.user ASC LIMIT p_limit diff --git a/db/queries/api/v1/users/following/create_function__get_all_sorted_following_by_address_tags.sql b/db/queries/api/v1/users/following/create_function__get_all_sorted_following_by_address_tags.sql new file mode 100644 index 0000000..94eb5ea --- /dev/null +++ b/db/queries/api/v1/users/following/create_function__get_all_sorted_following_by_address_tags.sql @@ -0,0 +1,59 @@ +--migrate:up +------------------------------------------------------------------------------- +-- +------------------------------------------------------------------------------- +CREATE +OR REPLACE FUNCTION query.get_all_sorted_following_by_address_tags (p_address types.eth_address, p_tags types.efp_tag[], p_sort text) RETURNS TABLE ( + efp_list_nft_token_id BIGINT, + record_version types.uint8, + record_type types.uint8, + following_address types.eth_address, + tags types.efp_tag [], + updated_at TIMESTAMP WITH TIME ZONE +) LANGUAGE plpgsql AS $$ +DECLARE + direction text; + normalized_addr types.eth_address; +BEGIN + direction = LOWER(p_sort); + normalized_addr := public.normalize_eth_address(p_address); + + IF cardinality(p_tags) > 0 THEN + RETURN QUERY + SELECT + v.efp_list_nft_token_id, + v.record_version, + v.record_type, + v.following_address, + v.tags, + v.updated_at + FROM query.get_all_following__record_type_001(normalized_addr) v + LEFT JOIN public.efp_leaderboard l ON v.following_address = l.address + WHERE v.tags && p_tags + ORDER BY + (CASE WHEN direction = 'followers' THEN l.followers END) DESC NULLS LAST, + (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC NULLS LAST, + (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC NULLS LAST; + ELSE + RETURN QUERY + SELECT + v.efp_list_nft_token_id, + v.record_version, + v.record_type, + v.following_address, + v.tags, + v.updated_at + FROM query.get_all_following__record_type_001(normalized_addr) v + LEFT JOIN public.efp_leaderboard l ON v.following_address = l.address + ORDER BY + (CASE WHEN direction = 'followers' THEN l.followers END) DESC NULLS LAST, + (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC NULLS LAST, + (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC NULLS LAST; + END IF; +END; +$$; + + + + +--migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/users/following/create_function__get_sorted_following_by_address_tags.sql b/db/queries/api/v1/users/following/create_function__get_sorted_following_by_address_tags.sql index 10e4045..179aa9d 100644 --- a/db/queries/api/v1/users/following/create_function__get_sorted_following_by_address_tags.sql +++ b/db/queries/api/v1/users/following/create_function__get_sorted_following_by_address_tags.sql @@ -31,9 +31,9 @@ BEGIN LEFT JOIN public.efp_leaderboard l ON v.following_address = l.address WHERE v.tags && p_tags ORDER BY - (CASE WHEN direction = 'followers' THEN l.followers END) DESC, - (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC, - (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC; + (CASE WHEN direction = 'followers' THEN l.followers END) DESC NULLS LAST, + (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC NULLS LAST, + (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC NULLS LAST; ELSE RETURN QUERY SELECT @@ -46,9 +46,9 @@ BEGIN FROM query.get_following__record_type_001(normalized_addr) v LEFT JOIN public.efp_leaderboard l ON v.following_address = l.address ORDER BY - (CASE WHEN direction = 'followers' THEN l.followers END) DESC, - (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC, - (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC; + (CASE WHEN direction = 'followers' THEN l.followers END) DESC NULLS LAST, + (CASE WHEN direction = 'earliest' THEN v.updated_at END) ASC NULLS LAST, + (CASE WHEN direction = 'latest' THEN v.updated_at END) DESC NULLS LAST; END IF; END; $$; diff --git a/db/queries/api/v1/users/recommended/create_function__get_algo_recommended_by_address.sql b/db/queries/api/v1/users/recommended/create_function__get_algo_recommended_by_address.sql new file mode 100644 index 0000000..ddd9ed4 --- /dev/null +++ b/db/queries/api/v1/users/recommended/create_function__get_algo_recommended_by_address.sql @@ -0,0 +1,123 @@ +--migrate:up +------------------------------------------------------------------------------- +-- +------------------------------------------------------------------------------- +CREATE +OR REPLACE FUNCTION query.get_algo_recommended_by_address (p_address types.eth_address, p_limit BIGINT, p_offset BIGINT) RETURNS TABLE ( + address types.eth_address, + name TEXT, + avatar TEXT, + records TEXT, + followers BIGINT, + following BIGINT, + mutuals_rank BIGINT, + followers_rank BIGINT, + following_rank BIGINT, + top8_rank BIGINT, + blocks_rank BIGINT +) LANGUAGE plpgsql AS $$ +DECLARE + normalized_addr types.eth_address; +BEGIN + + normalized_addr := public.normalize_eth_address(p_address); + + CREATE TEMPORARY TABLE temp_follow_records ( + nft_chain_id bigint, + nft_contract_address varchar(42), + token_id bigint, + owner varchar(42), + manager varchar(42), + "user" varchar(42), + list_storage_location_chain_id bigint, + list_storage_location_contract_address varchar(42), + list_storage_location_slot bytea, + record bytea, + record_version smallint, + record_type smallint, + record_data bytea, + tags types.efp_tag[], + updated_at timestamp with TIME ZONE, + has_block_tag boolean, + has_mute_tag boolean + ) ON COMMIT DROP; + + INSERT INTO temp_follow_records 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'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_block_tag, + CASE + WHEN 'mute'::text = ANY (record_tags.tags::text[]) THEN true + ELSE false + END AS has_mute_tag + FROM view__join__efp_list_records_with_tags record_tags + JOIN view__join__efp_lists_with_metadata l ON l.list_storage_location_chain_id = record_tags.chain_id::bigint AND l.list_storage_location_contract_address::text = record_tags.contract_address::text AND l.list_storage_location_slot::bytea = record_tags.slot::bytea + JOIN efp_account_metadata meta ON l."user"::text = meta.address::text AND l.token_id::bigint = convert_hex_to_bigint(meta.value::text) + WHERE + l."user" = normalized_addr AND + record_tags.record_version = 1 AND + record_tags.record_type = 1; + + RETURN QUERY + SELECT + m.address AS address, + m.name AS "name", + m.avatar AS avatar, + m.records::text, + b.followers, + b.following, + b.mutuals_rank, + b.followers_rank, + b.following_rank, + b.top8_rank, + b.blocks_rank + FROM public.efp_leaderboard b + LEFT JOIN public.ens_metadata m ON m.address = b.address + LEFT JOIN public.view__trending trending ON trending.address = b.address + WHERE + b.address <> normalized_addr AND + b.following > 0 AND + b.name IS NOT NULL AND + b.avatar IS NOT NULL AND + NOT EXISTS ( + SELECT 1 + FROM temp_follow_records l + WHERE l."user" = normalized_addr AND b.address = PUBLIC.hexlify(l.record_data)::types.eth_address + ) + GROUP BY + m.address, + m.name, + m.avatar, + m.records::text, + b.followers, + b.following, + b.mutuals_rank, + b.followers_rank, + b.following_rank, + b.top8_rank, + b.blocks_rank, + trending.count + ORDER BY trending.count DESC NULLS LAST + LIMIT p_limit + OFFSET p_offset; +END; +$$; + + + +--migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/users/recommended/create_function__get_recommended_stack_by_address.sql b/db/queries/api/v1/users/recommended/create_function__get_recommended_stack_by_address.sql new file mode 100644 index 0000000..bd1fefd --- /dev/null +++ b/db/queries/api/v1/users/recommended/create_function__get_recommended_stack_by_address.sql @@ -0,0 +1,55 @@ +--migrate:up +------------------------------------------------------------------------------- +-- +------------------------------------------------------------------------------- +CREATE +OR REPLACE FUNCTION query.get_recommended_stack_by_address (p_address types.eth_address, p_limit BIGINT, p_offset BIGINT) RETURNS TABLE ( + address types.eth_address, + name TEXT, + avatar TEXT, + records TEXT, + followers BIGINT, + following BIGINT, + mutuals_rank BIGINT, + followers_rank BIGINT, + following_rank BIGINT, + top8_rank BIGINT, + blocks_rank BIGINT +) LANGUAGE plpgsql AS $$ +DECLARE + normalized_addr types.eth_address; +BEGIN + normalized_addr := public.normalize_eth_address(p_address); + + RETURN QUERY + + SELECT + r.address, + m.name, + m.avatar, + m.records::text, + l.followers, + l.following, + l.mutuals_rank, + l.followers_rank, + l.following_rank, + l.top8_rank, + l.blocks_rank + FROM public.efp_recommended r + LEFT JOIN public.efp_leaderboard l ON l.address = r.address + LEFT JOIN public.ens_metadata m ON m.address = r.address + WHERE NOT EXISTS ( + SELECT 1 + FROM query.get_all_following__record_type_001(normalized_addr) fol + WHERE r.address = fol.following_address + ) + ORDER BY r.index ASC + LIMIT p_limit + OFFSET p_offset; +END; +$$; + + + + +--migrate:down \ No newline at end of file diff --git a/db/schema/020__tables/001/create_table__efp_addresses.sql b/db/schema/020__tables/001/create_table__efp_addresses.sql new file mode 100644 index 0000000..20854c2 --- /dev/null +++ b/db/schema/020__tables/001/create_table__efp_addresses.sql @@ -0,0 +1,16 @@ +-- migrate:up +------------------------------------------------------------------------------- +-- Table: efp_addresses +------------------------------------------------------------------------------- +CREATE TABLE + public.efp_addresses ( + "address" types.eth_address NOT NULL PRIMARY KEY + ); + + +-- migrate:down +------------------------------------------------------------------------------- +-- Undo Table: efp_addresses +------------------------------------------------------------------------------- +DROP TABLE + IF EXISTS public.efp_addresses CASCADE; \ No newline at end of file diff --git a/db/schema/020__tables/001/create_table__efp_mutuals.sql b/db/schema/020__tables/001/create_table__efp_mutuals.sql new file mode 100644 index 0000000..432e071 --- /dev/null +++ b/db/schema/020__tables/001/create_table__efp_mutuals.sql @@ -0,0 +1,17 @@ +-- migrate:up +------------------------------------------------------------------------------- +-- Table: efp_mutuals +------------------------------------------------------------------------------- +CREATE TABLE + public.efp_mutuals ( + "address" types.eth_address NOT NULL PRIMARY KEY, + "mutuals_rank" BIGINT, + "mutuals" BIGINT DEFAULT 0 + ); + +-- migrate:down +------------------------------------------------------------------------------- +-- Undo Table: efp_mutuals +------------------------------------------------------------------------------- +DROP TABLE + IF EXISTS public.efp_mutuals CASCADE; \ No newline at end of file diff --git a/db/schema/020__tables/001/create_table__efp_recent_activity.sql b/db/schema/020__tables/001/create_table__efp_recent_activity.sql new file mode 100644 index 0000000..2a4895a --- /dev/null +++ b/db/schema/020__tables/001/create_table__efp_recent_activity.sql @@ -0,0 +1,34 @@ +-- migrate:up +------------------------------------------------------------------------------- +-- Table: efp_recent_activity +------------------------------------------------------------------------------- +CREATE TABLE + public.efp_recent_activity ( + "address" types.eth_address NOT NULL, + "name" TEXT, + "avatar" TEXT, + "followers" BIGINT DEFAULT 0, + "following" BIGINT DEFAULT 0, + "_index" BIGINT DEFAULT 0, + created_at TIMESTAMP + WITH + TIME ZONE DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP + WITH + TIME ZONE DEFAULT CURRENT_TIMESTAMP, + PRIMARY KEY ("address") + ); + +CREATE TRIGGER + update_efp_recent_activity_updated_at BEFORE +UPDATE + ON public.efp_recent_activity FOR EACH ROW +EXECUTE + FUNCTION public.update_updated_at_column(); + +-- migrate:down +------------------------------------------------------------------------------- +-- Undo Table: efp_recent_activity +------------------------------------------------------------------------------- +DROP TABLE + IF EXISTS public.efp_recent_activity CASCADE; \ No newline at end of file diff --git a/db/schema/050__views/004/events__efp_leaderboard_mutuals/create_view__events__efp_leaderboard_mutuals.sql b/db/schema/050__views/004/events__efp_leaderboard_mutuals/create_view__events__efp_leaderboard_mutuals.sql index 031ee59..6d499e0 100644 --- a/db/schema/050__views/004/events__efp_leaderboard_mutuals/create_view__events__efp_leaderboard_mutuals.sql +++ b/db/schema/050__views/004/events__efp_leaderboard_mutuals/create_view__events__efp_leaderboard_mutuals.sql @@ -11,6 +11,7 @@ FROM public.view__join__efp_list_records_with_nft_manager_user_tags r INNER JOIN public.view__join__efp_list_records_with_nft_manager_user_tags t ON r."user" = public.hexlify(t.record_data) AND t."user" = public.hexlify(r.record_data) +WHERE r.has_block_tag = 'false' AND r.has_mute_tag = 'false' AND t.has_block_tag = 'false' AND t.has_mute_tag = 'false' GROUP BY r.record_data; diff --git a/db/schema/050__views/005/create_view__trending.sql b/db/schema/050__views/005/create_view__trending.sql new file mode 100644 index 0000000..c72b265 --- /dev/null +++ b/db/schema/050__views/005/create_view__trending.sql @@ -0,0 +1,26 @@ +-- migrate:up +------------------------------------------------------------------------------- +-- View: view__trending +------------------------------------------------------------------------------- +CREATE OR REPLACE VIEW PUBLIC.view__trending AS +SELECT + public.hexlify(record_tags.record_data) as address, + ens.name, + ens.avatar, + count(record_tags.record_data) +FROM public.view__join__efp_list_records_with_tags record_tags +LEFT JOIN public.ens_metadata ens ON public.hexlify(record_tags.record_data) = ens.address +WHERE NOW() - record_tags.updated_at::timestamptz <= interval '6 hours' +GROUP BY 1,2,3 +ORDER BY 4 DESC; + + + + + +-- migrate:down +------------------------------------------------------------------------------- +-- Undo View: view__trending +------------------------------------------------------------------------------- +DROP VIEW + IF EXISTS PUBLIC.view__trending CASCADE; \ No newline at end of file diff --git a/environment.d.ts b/environment.d.ts index 5ecd5c2..6db50c1 100644 --- a/environment.d.ts +++ b/environment.d.ts @@ -23,6 +23,7 @@ interface EnvironmentVariables { readonly SNITCH_ID: string readonly START_BLOCK: string readonly BATCH_SIZE: number + readonly RECOVER_HISTORY: string } declare module 'bun' { diff --git a/package.json b/package.json index 01cd978..01ca695 100644 --- a/package.json +++ b/package.json @@ -42,7 +42,7 @@ "viem": "^2.5.0" }, "devDependencies": { - "@biomejs/biome": "^1.7.3", + "@biomejs/biome": "^1.9.4", "@total-typescript/ts-reset": "^0.5.1", "@types/bun": "^1.0.4", "@types/node": "^20.11.6", diff --git a/src/database/generated/index.ts b/src/database/generated/index.ts index 99bc3aa..b70d856 100644 --- a/src/database/generated/index.ts +++ b/src/database/generated/index.ts @@ -41,6 +41,10 @@ export interface EfpAccountMetadata { value: string } +export interface EfpAddresses { + address: string +} + export interface EfpLeaderboard { address: string avatar: string | null @@ -127,6 +131,12 @@ export interface EfpLists { user: string } +export interface EfpMutuals { + address: string + mutuals: Generated + mutuals_rank: Int8 | null +} + export interface EfpPoapLinks { claimant: string | null claimed: boolean @@ -135,6 +145,17 @@ export interface EfpPoapLinks { updated_at: Generated } +export interface EfpRecentActivity { + _index: Generated + address: string + avatar: string | null + created_at: Generated + followers: Generated + following: Generated + name: string | null + updated_at: Generated +} + export interface EfpRecommended { address: string avatar: string | null @@ -189,6 +210,7 @@ export interface ViewEfpStats { address_count: Int8 | null list_count: Int8 | null list_op_count: Int8 | null + user_count: Int8 | null } export interface ViewEventsEfpAccountMetadata { @@ -411,9 +433,17 @@ export interface ViewLatestLeaders { updated_at: Timestamp | null } +export interface ViewTrending { + address: string | null + avatar: string | null + count: Int8 | null + name: string | null +} + export interface DB { contracts: Contracts efp_account_metadata: EfpAccountMetadata + efp_addresses: EfpAddresses efp_leaderboard: EfpLeaderboard efp_list_metadata: EfpListMetadata efp_list_nfts: EfpListNfts @@ -421,7 +451,9 @@ export interface DB { efp_list_record_tags: EfpListRecordTags efp_list_records: EfpListRecords efp_lists: EfpLists + efp_mutuals: EfpMutuals efp_poap_links: EfpPoapLinks + efp_recent_activity: EfpRecentActivity efp_recommended: EfpRecommended ens_metadata: EnsMetadata events: Events @@ -447,4 +479,5 @@ export interface DB { view__join__efp_lists_with_metadata: ViewJoinEfpListsWithMetadata view__latest_follows: ViewLatestFollows view__latest_leaders: ViewLatestLeaders + view__trending: ViewTrending } diff --git a/src/env.ts b/src/env.ts index 2aac248..02a60cf 100644 --- a/src/env.ts +++ b/src/env.ts @@ -20,6 +20,7 @@ export const env = Object.freeze({ SNITCH_ID: getEnvVariable('SNITCH_ID'), START_BLOCK: getEnvVariable('START_BLOCK'), BATCH_SIZE: getEnvVariable('BATCH_SIZE'), + RECOVER_HISTORY: getEnvVariable('RECOVER_HISTORY'), EFP_CONTRACTS: { ACCOUNT_METADATA: getEnvVariable('EFP_CONTRACT_ACCOUNT_METADATA'), LIST_MINTER: getEnvVariable('EFP_CONTRACT_LINT_MINTER'), diff --git a/src/pubsub/publisher/contract-event-publisher.ts b/src/pubsub/publisher/contract-event-publisher.ts index f48d99b..3e7d611 100644 --- a/src/pubsub/publisher/contract-event-publisher.ts +++ b/src/pubsub/publisher/contract-event-publisher.ts @@ -132,13 +132,15 @@ export class ContractEventPublisher implements EventPublisher { * It sets up a listener for contract events and dispatches them to all subscribers. */ async start(): Promise { - // Fetch and process historical events - const latestBlock = await this.client.getBlockNumber() - const batchSize = 10000n - for (let fromBlock = BigInt(env.START_BLOCK); fromBlock <= latestBlock; fromBlock += batchSize) { - const toBlock = fromBlock + batchSize - 1n - logger.info(`Fetching historical events for ${this.contractName} from block ${fromBlock} to ${toBlock}`) - await this.fetchHistoricalEvents(fromBlock, toBlock) + if (env.RECOVER_HISTORY === 'true') { + // Fetch and process historical events + const latestBlock = await this.client.getBlockNumber() + const batchSize = 10000n + for (let fromBlock = BigInt(env.START_BLOCK); fromBlock <= latestBlock; fromBlock += batchSize) { + const toBlock = fromBlock + batchSize - 1n + logger.info(`Fetching historical events for ${this.contractName} from block ${fromBlock} to ${toBlock}`) + await this.fetchHistoricalEvents(fromBlock, toBlock) + } } // This Action will batch up all the event logs found within the pollingInterval, and invoke them via onLogs. diff --git a/src/pubsub/publisher/event-interleaver.ts b/src/pubsub/publisher/event-interleaver.ts index 4ebd0cb..f1e1fac 100644 --- a/src/pubsub/publisher/event-interleaver.ts +++ b/src/pubsub/publisher/event-interleaver.ts @@ -152,7 +152,7 @@ export class EventInterleaver implements EventPublisher, EventSubscriber { const now = new Date() const batchSize = env.BATCH_SIZE // Muted by user - // biome-ignore lint/nursery/noEvolvingTypes: + // biome-ignore lint/suspicious/noEvolvingTypes: let batch = [] // drain the queue of "ready" events