From a9b2696de81c5ed172069d8b4e845e14c61b8ad8 Mon Sep 17 00:00:00 2001 From: 0xthrpw <0xthrpw@gmail.com> Date: Fri, 24 May 2024 23:54:44 -0400 Subject: [PATCH 1/3] ens meta table and get --- .../create_function__get_ens_metadata.sql | 43 +++++++++++++++++++ .../001/create_table__ens_metadata.sql | 26 +++++++++++ 2 files changed, 69 insertions(+) create mode 100644 db/queries/api/v1/users/profile/create_function__get_ens_metadata.sql create mode 100644 db/schema/020__tables/001/create_table__ens_metadata.sql diff --git a/db/queries/api/v1/users/profile/create_function__get_ens_metadata.sql b/db/queries/api/v1/users/profile/create_function__get_ens_metadata.sql new file mode 100644 index 0000000..caaa062 --- /dev/null +++ b/db/queries/api/v1/users/profile/create_function__get_ens_metadata.sql @@ -0,0 +1,43 @@ +--migrate:up +------------------------------------------------------------------------------- +-- Function: get_ens_metadata +-- Description: Retrieves the primary list value for a given address from the +-- account_metadata table. If not found, falls back to finding the +-- lowest token_id from view_list_nfts_with_manager_user where +-- list_user equals the address. Converts valid hex string values +-- to BIGINT. +-- Parameters: +-- - addr (VARCHAR(42)): The address for which to retrieve the ens data. +-- Returns: . +-- . +-- . +------------------------------------------------------------------------------- + +CREATE +OR REPLACE FUNCTION query.get_ens_metadata (p_address types.eth_address) RETURNS TABLE ( + username TEXT, + address types.eth_address, + avatar TEXT, + updated_at timestamp WITH TIME ZONE +) LANGUAGE plpgsql AS $$ +DECLARE + normalized_addr types.eth_address; +BEGIN + normalized_addr := public.normalize_eth_address(p_address); + RETURN QUERY + SELECT DISTINCT + metadata.name as username, + metadata.address as address, + metadata.avatar as avatar, + metadata.updated_at + FROM + public.ens_metadata as metadata + WHERE + metadata.address = normalized_addr + ORDER BY + metadata.updated_at DESC; +END; +$$; + + +--migrate:down \ No newline at end of file diff --git a/db/schema/020__tables/001/create_table__ens_metadata.sql b/db/schema/020__tables/001/create_table__ens_metadata.sql new file mode 100644 index 0000000..57852da --- /dev/null +++ b/db/schema/020__tables/001/create_table__ens_metadata.sql @@ -0,0 +1,26 @@ +CREATE TABLE + public.ens_metadata ( + "name" TEXT NOT NULL, + "address" types.eth_address NOT NULL, + "avatar" TEXT, + "display" TEXT, + "records" TEXT[], + "chains" TEXT[], + "fresh" BIGINT, + "resolver" types.eth_address, + "errors" TEXT, + created_at TIMESTAMP + WITH + TIME ZONE DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP + WITH + TIME ZONE DEFAULT CURRENT_TIMESTAMP, + PRIMARY KEY ("address", "name") + ); + +CREATE TRIGGER + update_ens_metadata_updated_at BEFORE +UPDATE + ON public.ens_metadata FOR EACH ROW +EXECUTE + FUNCTION public.update_updated_at_column(); \ No newline at end of file From 830724790d66fe16860562b51db3389de1e888b6 Mon Sep 17 00:00:00 2001 From: 0xthrpw <0xthrpw@gmail.com> Date: Thu, 30 May 2024 23:31:05 -0400 Subject: [PATCH 2/3] ens data, discover --- .../discover/create_view__latest_follows.sql | 23 ++++++++++++ ...function__get_ens_metadata_by_address.sql} | 16 ++++----- ...ate_function__get_ens_metadata_by_name.sql | 35 +++++++++++++++++++ 3 files changed, 64 insertions(+), 10 deletions(-) create mode 100644 db/queries/api/v1/discover/create_view__latest_follows.sql rename db/queries/api/v1/users/profile/{create_function__get_ens_metadata.sql => create_function__get_ens_metadata_by_address.sql} (60%) create mode 100644 db/queries/api/v1/users/profile/create_function__get_ens_metadata_by_name.sql diff --git a/db/queries/api/v1/discover/create_view__latest_follows.sql b/db/queries/api/v1/discover/create_view__latest_follows.sql new file mode 100644 index 0000000..7fd4f82 --- /dev/null +++ b/db/queries/api/v1/discover/create_view__latest_follows.sql @@ -0,0 +1,23 @@ +-- migrate:up +------------------------------------------------------------------------------- +-- View: view__latest_follows +------------------------------------------------------------------------------- +CREATE +OR REPLACE VIEW PUBLIC.view__latest_follows AS +SELECT DISTINCT '0x' || TRIM('0x01010101' FROM op) as address FROM ( + SELECT * + FROM public.efp_list_ops + WHERE opcode = 1 + GROUP BY op, chain_id, contract_address, slot + ORDER BY updated_at DESC + LIMIT 100 +) LIMIT 10; + + + +-- migrate:down +------------------------------------------------------------------------------- +-- Undo View: view__latest_follows +------------------------------------------------------------------------------- +DROP VIEW + IF EXISTS PUBLIC.view__latest_follows CASCADE; \ No newline at end of file diff --git a/db/queries/api/v1/users/profile/create_function__get_ens_metadata.sql b/db/queries/api/v1/users/profile/create_function__get_ens_metadata_by_address.sql similarity index 60% rename from db/queries/api/v1/users/profile/create_function__get_ens_metadata.sql rename to db/queries/api/v1/users/profile/create_function__get_ens_metadata_by_address.sql index caaa062..eb0ec4f 100644 --- a/db/queries/api/v1/users/profile/create_function__get_ens_metadata.sql +++ b/db/queries/api/v1/users/profile/create_function__get_ens_metadata_by_address.sql @@ -1,11 +1,6 @@ --migrate:up ------------------------------------------------------------------------------- --- Function: get_ens_metadata --- Description: Retrieves the primary list value for a given address from the --- account_metadata table. If not found, falls back to finding the --- lowest token_id from view_list_nfts_with_manager_user where --- list_user equals the address. Converts valid hex string values --- to BIGINT. +-- Function: get_ens_metadata_by_address -- Parameters: -- - addr (VARCHAR(42)): The address for which to retrieve the ens data. -- Returns: . @@ -14,8 +9,8 @@ ------------------------------------------------------------------------------- CREATE -OR REPLACE FUNCTION query.get_ens_metadata (p_address types.eth_address) RETURNS TABLE ( - username TEXT, +OR REPLACE FUNCTION query.get_ens_metadata_by_address (p_address types.eth_address) RETURNS TABLE ( + name TEXT, address types.eth_address, avatar TEXT, updated_at timestamp WITH TIME ZONE @@ -26,10 +21,10 @@ BEGIN normalized_addr := public.normalize_eth_address(p_address); RETURN QUERY SELECT DISTINCT - metadata.name as username, + metadata.name as name, metadata.address as address, metadata.avatar as avatar, - metadata.updated_at + metadata.updated_at FROM public.ens_metadata as metadata WHERE @@ -40,4 +35,5 @@ END; $$; + --migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/users/profile/create_function__get_ens_metadata_by_name.sql b/db/queries/api/v1/users/profile/create_function__get_ens_metadata_by_name.sql new file mode 100644 index 0000000..ed52d3d --- /dev/null +++ b/db/queries/api/v1/users/profile/create_function__get_ens_metadata_by_name.sql @@ -0,0 +1,35 @@ +--migrate:up +------------------------------------------------------------------------------- +-- Function: get_ens_metadata_by_name +-- Parameters: +-- - addr (VARCHAR(42)): The address for which to retrieve the ens data. +-- Returns: . +-- . +-- . +------------------------------------------------------------------------------- + +CREATE +OR REPLACE FUNCTION query.get_ens_metadata_by_name (p_name TEXT) RETURNS TABLE ( + name TEXT, + address types.eth_address, + avatar TEXT, + updated_at timestamp WITH TIME ZONE +) LANGUAGE plpgsql AS $$ +BEGIN + RETURN QUERY + SELECT DISTINCT + metadata.name as name, + metadata.address as address, + metadata.avatar as avatar, + metadata.updated_at + FROM + public.ens_metadata as metadata + WHERE + metadata.name = p_name + ORDER BY + metadata.updated_at DESC; +END; +$$; + + +--migrate:down \ No newline at end of file From 2e5f934bda52f1bc36d9e0400c47f61fc0be6293 Mon Sep 17 00:00:00 2001 From: 0xthrpw <0xthrpw@gmail.com> Date: Mon, 10 Jun 2024 23:51:24 -0400 Subject: [PATCH 3/3] fix discover trim, migration, pagination --- .../discover/create_view__latest_follows.sql | 4 +- ...te_function__get_unique_followers_page.sql | 132 ++++++++++++++++++ ...ction__get_following__record_type_page.sql | 100 +++++++++++++ .../001/create_table__ens_metadata.sql | 13 +- src/database/generated/index.ts | 20 +++ 5 files changed, 266 insertions(+), 3 deletions(-) create mode 100644 db/queries/api/v1/users/followers/create_function__get_unique_followers_page.sql create mode 100644 db/queries/api/v1/users/following/create_function__get_following__record_type_page.sql diff --git a/db/queries/api/v1/discover/create_view__latest_follows.sql b/db/queries/api/v1/discover/create_view__latest_follows.sql index 7fd4f82..f4dbb09 100644 --- a/db/queries/api/v1/discover/create_view__latest_follows.sql +++ b/db/queries/api/v1/discover/create_view__latest_follows.sql @@ -4,8 +4,8 @@ ------------------------------------------------------------------------------- CREATE OR REPLACE VIEW PUBLIC.view__latest_follows AS -SELECT DISTINCT '0x' || TRIM('0x01010101' FROM op) as address FROM ( - SELECT * +SELECT DISTINCT '0x' || LPAD(address, 40, '0') as address FROM ( + SELECT TRIM('0x01010101' FROM op) as address FROM public.efp_list_ops WHERE opcode = 1 GROUP BY op, chain_id, contract_address, slot 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 new file mode 100644 index 0000000..ccd6673 --- /dev/null +++ b/db/queries/api/v1/users/followers/create_function__get_unique_followers_page.sql @@ -0,0 +1,132 @@ +--migrate:up +------------------------------------------------------------------------------- +-- Function: get_unique_followers_page +-- Description: Retrieves a distinct limited 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. +-- - limit (INT): Number of records to retrieve +-- - offset (INT): Starting index to begin returned record set +-- 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_unique_followers_page(p_address VARCHAR(42), p_limit INT, p_offset INT) 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 +) 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; + + -- 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 + + 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 + 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 + FROM + public.view__join__efp_list_records_with_nft_manager_user_tags AS following + 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, + 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; + LIMIT p_limit + OFFSET p_offset; + +END; +$$; + + + +--migrate:down \ No newline at end of file diff --git a/db/queries/api/v1/users/following/create_function__get_following__record_type_page.sql b/db/queries/api/v1/users/following/create_function__get_following__record_type_page.sql new file mode 100644 index 0000000..e442f1b --- /dev/null +++ b/db/queries/api/v1/users/following/create_function__get_following__record_type_page.sql @@ -0,0 +1,100 @@ +--migrate:up +------------------------------------------------------------------------------- +-- Function: get_following__record_type_page +-- Description: Retrieves a limited list of addresses followed by a user from +-- the view_list_records_with_nft_manager_user_tags, ensuring +-- addresses are valid 20-byte, lower-case hexadecimals (0x +-- followed by 40 hex chars). Filters tokens by version and type, +-- excluding blocked or muted relationships. Leverages primary +-- list token ID from get_primary_list. If no primary list is +-- found, returns an empty result set. +-- Parameters: +-- - address (VARCHAR(42)): Identifier of the user to find the +-- following addresses. +-- - limit (INT): Number of records to retrieve +-- - offset (INT): Starting index to begin returned record set +-- Returns: A table with 'efp_list_nft_token_id' (BIGINT), 'record_version' +-- (types.uint8), 'record_type' (types.uint8), and 'following_address' +-- (types.eth_address), representing the list token ID, record +-- version, record type, and following address. +------------------------------------------------------------------------------- +CREATE +OR REPLACE FUNCTION query.get_following__record_type_page (p_address VARCHAR(42), p_limit INT, p_offset INT) 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 [] +) LANGUAGE plpgsql AS $$ +DECLARE + normalized_addr types.eth_address; + primary_list_token_id BIGINT; + list_storage_location_chain_id BIGINT; + list_storage_location_contract_address VARCHAR(42); + 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); + + -- 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 NULL THEN + RETURN; -- Exit the function without returning any rows + END IF; + + -- 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 + list_storage_location_chain_id, + list_storage_location_contract_address, + 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; + + -- following query + RETURN QUERY + SELECT + (primary_list_token_id)::BIGINT AS efp_list_nft_token_id, + v.record_version, + v.record_type, + PUBLIC.hexlify(v.record_data)::types.eth_address AS following_address, + COALESCE(v.tags, '{}') AS tags + FROM + public.view__join__efp_list_records_with_tags AS v + WHERE + v.chain_id = list_storage_location_chain_id AND + v.contract_address = list_storage_location_contract_address AND + v.slot = list_storage_location_storage_slot AND + -- only version 1 + v.record_version = 1 AND + -- address record type (1) + v.record_type = 1 AND + -- where the address record data field is a valid address + public.is_valid_address(v.record_data) AND + -- NOT blocked or muted + NOT EXISTS ( + SELECT 1 FROM unnest(v.tags) as tag + WHERE tag IN ('block', 'mute') + ) + ORDER BY + v.record_version ASC, + v.record_type ASC, + v.record_data 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__ens_metadata.sql b/db/schema/020__tables/001/create_table__ens_metadata.sql index 57852da..da40868 100644 --- a/db/schema/020__tables/001/create_table__ens_metadata.sql +++ b/db/schema/020__tables/001/create_table__ens_metadata.sql @@ -1,3 +1,7 @@ +-- migrate:up +------------------------------------------------------------------------------- +-- Table: ens_metadata +------------------------------------------------------------------------------- CREATE TABLE public.ens_metadata ( "name" TEXT NOT NULL, @@ -23,4 +27,11 @@ CREATE TRIGGER UPDATE ON public.ens_metadata FOR EACH ROW EXECUTE - FUNCTION public.update_updated_at_column(); \ No newline at end of file + FUNCTION public.update_updated_at_column(); + +-- migrate:down +------------------------------------------------------------------------------- +-- Undo Table: ens_metadata +------------------------------------------------------------------------------- +DROP TABLE + IF EXISTS public.ens_metadata CASCADE; \ No newline at end of file diff --git a/src/database/generated/index.ts b/src/database/generated/index.ts index 56041f3..fed564f 100644 --- a/src/database/generated/index.ts +++ b/src/database/generated/index.ts @@ -109,6 +109,20 @@ export interface EfpLists { user: string } +export interface EnsMetadata { + address: string + avatar: string | null + chains: string[] | null + created_at: Generated + display: string | null + errors: string | null + fresh: Int8 | null + name: string + records: string[] | null + resolver: string | null + updated_at: Generated +} + export interface Events { block_hash: string block_number: Int8 @@ -277,6 +291,10 @@ export interface ViewJoinEfpListRecordsWithTags { tags: string[] | null } +export interface ViewLatestFollows { + address: string | null +} + export interface DB { contracts: Contracts efp_account_metadata: EfpAccountMetadata @@ -286,6 +304,7 @@ export interface DB { efp_list_record_tags: EfpListRecordTags efp_list_records: EfpListRecords efp_lists: EfpLists + ens_metadata: EnsMetadata events: Events schema_migrations: SchemaMigrations view__events__efp_account_metadata: ViewEventsEfpAccountMetadata @@ -301,4 +320,5 @@ export interface DB { view__events__latest_record_tags: ViewEventsLatestRecordTags view__join__efp_list_records_with_nft_manager_user_tags: ViewJoinEfpListRecordsWithNftManagerUserTags view__join__efp_list_records_with_tags: ViewJoinEfpListRecordsWithTags + view__latest_follows: ViewLatestFollows }