Skip to content

Commit

Permalink
Added pool_delegations_list variant that calculates bare minimum dele…
Browse files Browse the repository at this point in the history
…gator data needed by pool_info endpoint, to improve performance of the latter
  • Loading branch information
hodlonaut committed May 15, 2024
1 parent d4dfb66 commit bc1be67
Show file tree
Hide file tree
Showing 2 changed files with 68 additions and 1 deletion.
67 changes: 67 additions & 0 deletions files/grest/rpc/pool/pool_delegators.sql
Original file line number Diff line number Diff line change
Expand Up @@ -66,3 +66,70 @@ END;
$$;

COMMENT ON FUNCTION grest.pool_delegators IS 'Return information about live delegators for a given pool.'; --noqa: LT01




CREATE OR REPLACE FUNCTION grest.pool_delegators_list(_pool_bech32 text)
RETURNS TABLE (
stake_address character varying,
amount text
)
LANGUAGE plpgsql
AS $$
#variable_conflict use_column
DECLARE
_pool_id bigint;
BEGIN
SELECT id INTO _pool_id FROM pool_hash WHERE pool_hash.view = _pool_bech32;

RETURN QUERY
WITH
_all_delegations AS (
SELECT
sa.id AS stake_address_id,
sdc.stake_address,
(
CASE WHEN sdc.total_balance >= 0
THEN sdc.total_balance
ELSE 0
END
) AS total_balance
FROM grest.stake_distribution_cache AS sdc
INNER JOIN public.stake_address AS sa ON sa.view = sdc.stake_address
WHERE sdc.pool_id = _pool_bech32

UNION ALL

-- combine with registered delegations not in stake-dist-cache yet
SELECT
z.stake_address_id, z.stake_address, SUM(acc_info.value::numeric) AS total_balance
FROM
(
SELECT
sa.id AS stake_address_id,
sa.view AS stake_address
FROM delegation AS d
INNER JOIN stake_address AS sa ON d.addr_id = sa.id and d.pool_hash_id = _pool_id
AND NOT EXISTS (SELECT null FROM delegation AS d2 WHERE d2.addr_id = d.addr_id AND d2.id > d.id)
AND NOT EXISTS (SELECT null FROM stake_deregistration AS sd WHERE sd.addr_id = d.addr_id AND sd.tx_id > d.tx_id)
-- AND NOT grest.is_dangling_delegation(d.id)
AND NOT EXISTS (SELECT null FROM grest.stake_distribution_cache AS sdc WHERE sdc.stake_address = sa.view)
) z,
LATERAL grest.account_utxos(array[z.stake_address], false) AS acc_info
GROUP BY
z.stake_address_id,
z.stake_address
)

SELECT
ad.stake_address,
ad.total_balance::text
FROM _all_delegations AS ad;

END;
$$;


COMMENT ON FUNCTION grest.pool_delegators_list IS 'Return brief variant of information about live delegators for a given pool, needed by pool_info endpoint.'; --noqa: LT01

2 changes: 1 addition & 1 deletion files/grest/rpc/pool/pool_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -127,7 +127,7 @@ BEGIN
ELSE
SUM(CASE WHEN pool_delegs.stake_address = ANY(api.owners) THEN amount::numeric ELSE 0 END)::lovelace
END AS pledge
FROM grest.pool_delegators(api.pool_id_bech32) AS pool_delegs
FROM grest.pool_delegators_list(api.pool_id_bech32) AS pool_delegs
) AS live ON TRUE;
END;
$$;
Expand Down

0 comments on commit bc1be67

Please sign in to comment.