Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

ens meta table and get #3

Open
wants to merge 3 commits into
base: develop
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
23 changes: 23 additions & 0 deletions db/queries/api/v1/discover/create_view__latest_follows.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
-- migrate:up
-------------------------------------------------------------------------------
-- View: view__latest_follows
-------------------------------------------------------------------------------
CREATE
OR REPLACE VIEW PUBLIC.view__latest_follows AS
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
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;
Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
@@ -0,0 +1,39 @@
--migrate:up
-------------------------------------------------------------------------------
-- Function: get_ens_metadata_by_address
-- Parameters:
-- - addr (VARCHAR(42)): The address for which to retrieve the ens data.
-- Returns: .
-- .
-- .
-------------------------------------------------------------------------------

CREATE
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
) 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 name,
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
Original file line number Diff line number Diff line change
@@ -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
37 changes: 37 additions & 0 deletions db/schema/020__tables/001/create_table__ens_metadata.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,37 @@
-- migrate:up
-------------------------------------------------------------------------------
-- Table: ens_metadata
-------------------------------------------------------------------------------
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();

-- migrate:down
-------------------------------------------------------------------------------
-- Undo Table: ens_metadata
-------------------------------------------------------------------------------
DROP TABLE
IF EXISTS public.ens_metadata CASCADE;
Loading
Loading