Skip to content

Commit

Permalink
replace all stake_address view reference with raw hash and cip5 bech3…
Browse files Browse the repository at this point in the history
…2 utility function
  • Loading branch information
Scitz0 committed Sep 12, 2024
1 parent a06b74c commit a63d0a2
Show file tree
Hide file tree
Showing 21 changed files with 146 additions and 93 deletions.
20 changes: 10 additions & 10 deletions files/grest/rpc/01_cached_tables/stake_distribution_cache.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
CREATE TABLE IF NOT EXISTS grest.stake_distribution_cache (
stake_address varchar PRIMARY KEY,
stake_address_raw addr29type PRIMARY KEY,
pool_id varchar,
total_balance numeric,
utxo numeric,
Expand Down Expand Up @@ -31,7 +31,7 @@ BEGIN
accounts_with_delegated_pools AS (
SELECT DISTINCT ON (stake_address.id)
stake_address.id AS stake_address_id,
stake_address.view AS stake_address,
stake_address.hash_raw AS stake_address_raw,
pool_hash_id
FROM stake_address
INNER JOIN delegation ON delegation.addr_id = stake_address.id
Expand Down Expand Up @@ -172,7 +172,7 @@ BEGIN
-- INSERT QUERY START
INSERT INTO grest.stake_distribution_cache
SELECT
awdp.stake_address,
awdp.stake_address_raw,
pi.pool_id,
COALESCE(aas.amount, 0) + COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) + COALESCE(adir.amount, 0) - COALESCE(adw.withdrawals, 0) AS total_balance,
COALESCE(aas.amount, 0) + COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) + COALESCE(adir.amount, 0) - COALESCE(adw.withdrawals, 0) - COALESCE(atrew.rewards, 0) - COALESCE(atir.amount, 0) + COALESCE(atw.withdrawals, 0) AS utxo,
Expand All @@ -190,7 +190,7 @@ BEGIN
LEFT JOIN account_delta_rewards AS adr ON adr.stake_address_id = awdp.stake_address_id
LEFT JOIN account_delta_instant_rewards AS adir ON adir.stake_address_id = awdp.stake_address_id
LEFT JOIN account_delta_withdrawals AS adw ON adw.stake_address_id = awdp.stake_address_id
ON CONFLICT (stake_address) DO
ON CONFLICT (stake_address_raw) DO
UPDATE
SET pool_id = excluded.pool_id,
total_balance = excluded.total_balance,
Expand All @@ -211,9 +211,9 @@ BEGIN

-- Clean up de-registered accounts
DELETE FROM grest.stake_distribution_cache
WHERE stake_address IN (
WHERE stake_address_raw IN (
SELECT DISTINCT ON (sa.id)
sa.view
sa.hash_raw
FROM stake_address AS sa
INNER JOIN stake_deregistration AS sd ON sa.id = sd.addr_id
WHERE NOT EXISTS (
Expand All @@ -227,15 +227,15 @@ BEGIN
-- Clean up accounts registered to retired-at-least-once-since pools
RAISE NOTICE 'DANGLING delegation cleanup from SDC commencing';
DELETE FROM grest.stake_distribution_cache
WHERE stake_address in (
SELECT z.stake_address
WHERE stake_address_raw in (
SELECT z.stake_address_raw
FROM (
SELECT
(
SELECT max(d.id)
FROM delegation d
INNER JOIN stake_address sd ON sd.view = sdc.stake_address AND sd.id = d.addr_id) AS last_deleg,
sdc.stake_address
INNER JOIN stake_address sd ON sd.hash_raw = sdc.stake_address_raw AND sd.id = d.addr_id) AS last_deleg,
sdc.stake_address_raw
FROM grest.stake_distribution_cache AS sdc
) AS z
WHERE grest.is_dangling_delegation(z.last_deleg)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -32,7 +32,7 @@ BEGIN
newly_registered_accounts AS (
SELECT DISTINCT ON (stake_address.id)
stake_address.id AS stake_address_id,
stake_address.view AS stake_address,
stake_address.hash_raw AS stake_address_raw,
pool_hash_id
FROM stake_address
INNER JOIN delegation ON delegation.addr_id = stake_address.id
Expand Down Expand Up @@ -67,16 +67,16 @@ BEGIN
-- INSERT QUERY START
INSERT INTO grest.stake_distribution_cache
SELECT
nra.stake_address,
nra.stake_address_raw,
ai.delegated_pool AS pool_id,
ai.total_balance::lovelace,
ai.utxo::lovelace,
ai.rewards::lovelace,
ai.withdrawals::lovelace,
ai.rewards_available::lovelace
FROM newly_registered_accounts AS nra,
LATERAL grest.account_info(array[nra.stake_address]) AS ai
ON CONFLICT (stake_address) DO
LATERAL grest.account_info(array[(SELECT grest.cip5_hex_to_stake_addr(nra.stake_address_raw))]) AS ai
ON CONFLICT (stake_address_raw) DO
UPDATE
SET
pool_id = EXCLUDED.pool_id,
Expand Down
4 changes: 2 additions & 2 deletions files/grest/rpc/03_utilities/cip129.sql
Original file line number Diff line number Diff line change
@@ -1,8 +1,8 @@
-- Binary format
-- 1 byte variable length
-- 1 byte variable length
-- <------> <------------------->
-- ┌────────┬─────────────────────┐
-- │ header │ key │
-- │ header │ key
-- └────────┴─────────────────────┘
-- 🔎
-- ╎ 7 6 5 4 3 2 1 0
Expand Down
16 changes: 16 additions & 0 deletions files/grest/rpc/03_utilities/cip5.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
-- CIP References
-- 0005: Common bech32 prefixes https://cips.cardano.org/cip/CIP-0005
-- 0019: Cardano Addresses https://cips.cardano.org/cip/CIP-0019

CREATE OR REPLACE FUNCTION grest.cip5_hex_to_stake_addr(hex bytea)
RETURNS text
LANGUAGE plpgsql STABLE
AS $$
BEGIN
IF SUBSTRING(hex from 2 for 1) = '0' THEN
RETURN b32_encode('stake_test', hex::text);
ELSE
RETURN b32_encode('stake', hex::text);
END IF;
END;
$$;
9 changes: 6 additions & 3 deletions files/grest/rpc/account/account_addresses.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,7 +13,10 @@ BEGIN
FROM
stake_address
WHERE
stake_address.VIEW = ANY(_stake_addresses);
stake_address.hash_raw = ANY(
SELECT ARRAY_AGG(DECODE(b32_decode(n), 'hex'))
FROM UNNEST(_stake_addresses) AS n
);

IF _first_only IS NOT TRUE AND _empty IS NOT TRUE THEN
RETURN QUERY
Expand All @@ -34,7 +37,7 @@ BEGIN
)

SELECT
sa.view AS stake_address,
grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_address,
JSONB_AGG(txo_addr.address) AS addresses
FROM
txo_addr
Expand All @@ -60,7 +63,7 @@ BEGIN
)

SELECT
sa.view AS stake_address,
grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_address,
JSONB_AGG(txo_addr.address) AS addresses
FROM
txo_addr
Expand Down
13 changes: 8 additions & 5 deletions files/grest/rpc/account/account_assets.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,7 @@ BEGIN

WITH _all_assets AS (
SELECT
sa.view,
sa.hash_raw,
ma.policy,
ma.name,
ma.fingerprint,
Expand All @@ -25,21 +25,24 @@ BEGIN
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id
INNER JOIN tx_out AS txo ON txo.id = mtx.tx_out_id
INNER JOIN stake_address AS sa ON sa.id = txo.stake_address_id
WHERE sa.view = ANY(_stake_addresses)
WHERE sa.hash_raw = ANY(
SELECT ARRAY_AGG(DECODE(b32_decode(n), 'hex'))
FROM UNNEST(_stake_addresses) AS n
)
AND txo.consumed_by_tx_id IS NULL
GROUP BY
sa.view, ma.policy, ma.name, ma.fingerprint, aic.decimals
sa.hash_raw, ma.policy, ma.name, ma.fingerprint, aic.decimals
)

SELECT
aa.view AS stake_address,
grest.cip5_hex_to_stake_addr(aa.hash_raw) AS stake_address,
ENCODE(aa.policy, 'hex') AS policy_id,
ENCODE(aa.name, 'hex') AS asset_name,
aa.fingerprint AS fingerprint,
aa.decimals AS decimals,
aa.quantity::text AS quantity
FROM _all_assets AS aa
ORDER BY aa.view;
ORDER BY aa.hash_raw;
END;
$$;

Expand Down
13 changes: 8 additions & 5 deletions files/grest/rpc/account/account_history.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,12 +13,15 @@ BEGIN
FROM
stake_address
WHERE
stake_address.view = ANY(_stake_addresses);
stake_address.hash_raw = ANY(
SELECT ARRAY_AGG(DECODE(b32_decode(n), 'hex'))
FROM UNNEST(_stake_addresses) AS n
);

IF _epoch_no IS NOT NULL THEN
RETURN QUERY
SELECT
sa.view AS stake_address,
grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_address,
JSONB_AGG(
JSONB_BUILD_OBJECT(
'pool_id', ph.view,
Expand All @@ -35,11 +38,11 @@ BEGIN
AND
sa.id = ANY(sa_id_list)
GROUP BY
sa.view;
sa.hash_raw;
ELSE
RETURN QUERY
SELECT
sa.view AS stake_address,
grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_address,
JSONB_AGG(
JSONB_BUILD_OBJECT(
'pool_id', ph.view,
Expand All @@ -54,7 +57,7 @@ BEGIN
WHERE
sa.id = ANY(sa_id_list)
GROUP BY
sa.view;
sa.hash_raw;
END IF;
END;
$$;
Expand Down
9 changes: 6 additions & 3 deletions files/grest/rpc/account/account_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -21,12 +21,15 @@ BEGIN
SELECT INTO sa_id_list
array_agg(id)
FROM stake_address
WHERE stake_address.view = ANY(_stake_addresses);
WHERE stake_address.hash_raw = ANY(
SELECT ARRAY_AGG(DECODE(b32_decode(n), 'hex'))
FROM UNNEST(_stake_addresses) AS n
);

RETURN QUERY

SELECT
status_t.view AS stake_address,
grest.cip5_hex_to_stake_addr(status_t.hash_raw) AS stake_address,
CASE WHEN status_t.registered = TRUE THEN
'registered'
ELSE
Expand All @@ -46,7 +49,7 @@ BEGIN
(
SELECT
sa.id,
sa.view,
sa.hash_raw,
EXISTS (
SELECT TRUE FROM stake_registration AS sr
WHERE sr.addr_id = sa.id
Expand Down
24 changes: 15 additions & 9 deletions files/grest/rpc/account/account_info_cached.sql
Original file line number Diff line number Diff line change
Expand Up @@ -23,12 +23,15 @@ BEGIN
FROM
stake_address
WHERE
stake_address.view = ANY(_stake_addresses);
stake_address.hash_raw = ANY(
SELECT ARRAY_AGG(DECODE(b32_decode(n), 'hex'))
FROM UNNEST(_stake_addresses) AS n
);

RETURN QUERY

SELECT
sdc.stake_address,
grest.cip5_hex_to_stake_addr(sdc.stake_address_raw),
CASE WHEN status_t.registered = TRUE THEN
'registered'
ELSE
Expand All @@ -48,7 +51,7 @@ BEGIN
LEFT JOIN (
SELECT
sas.id,
sas.view,
sas.hash_raw,
EXISTS (
SELECT TRUE FROM stake_registration
WHERE
Expand All @@ -73,7 +76,7 @@ BEGIN
) AS deposit
FROM public.stake_address AS sas
WHERE sas.id = ANY(sa_id_list)
) AS status_t ON sdc.stake_address = status_t.view
) AS status_t ON sdc.stake_address_raw = status_t.hash_raw
LEFT JOIN (
SELECT
dv.addr_id,
Expand Down Expand Up @@ -115,7 +118,10 @@ BEGIN
GROUP BY
t.addr_id
) AS treasury_t ON treasury_t.addr_id = status_t.id
WHERE sdc.stake_address = ANY(_stake_addresses)
WHERE sdc.stake_address_raw = ANY(
SELECT ARRAY_AGG(DECODE(b32_decode(n), 'hex'))
FROM UNNEST(_stake_addresses) AS n
)

UNION ALL

Expand All @@ -135,13 +141,13 @@ BEGIN
FROM
(
SELECT
sa.view AS stake_address,
sa.hash_raw AS stake_address_raw,
sa.id AS addr_id
FROM stake_address AS sa
WHERE view = ANY(_stake_addresses)
AND NOT EXISTS (SELECT null FROM grest.stake_distribution_cache AS sdc WHERE sdc.stake_address = sa.view)
WHERE sa.id = ANY(sa_id_list)
AND NOT EXISTS (SELECT null FROM grest.stake_distribution_cache AS sdc WHERE sdc.stake_address_raw = sa.hash_raw)
) AS z
, LATERAL grest.account_info(array[z.stake_address]) AS ai
, LATERAL grest.account_info(array[(SELECT grest.cip5_hex_to_stake_addr(z.stake_address_raw))]) AS ai
;

END;
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/account/account_list.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,7 @@ RETURNS TABLE (
LANGUAGE sql STABLE
AS $$
SELECT
sa.view::text,
grest.cip5_hex_to_stake_addr(sa.hash_raw),
ENCODE(sa.hash_raw,'hex'),
ENCODE(sa.script_hash,'hex')
FROM stake_address AS sa
Expand Down
14 changes: 8 additions & 6 deletions files/grest/rpc/account/account_rewards.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,12 +13,15 @@ BEGIN
FROM
stake_address
WHERE
stake_address.VIEW = ANY(_stake_addresses);
stake_address.hash_raw = ANY(
SELECT ARRAY_AGG(DECODE(b32_decode(n), 'hex'))
FROM UNNEST(_stake_addresses) AS n
);

IF _epoch_no IS NULL THEN
RETURN QUERY
SELECT
sa.view,
grest.cip5_hex_to_stake_addr(sa.hash_raw),
JSONB_AGG(
JSONB_BUILD_OBJECT(
'earned_epoch', r.earned_epoch,
Expand All @@ -34,11 +37,11 @@ BEGIN
INNER JOIN stake_address AS sa ON sa.id = r.addr_id
WHERE
r.addr_id = ANY(sa_id_list)
GROUP BY sa.id;
GROUP BY sa.hash_raw;
ELSE
RETURN QUERY
SELECT
sa.view,
grest.cip5_hex_to_stake_addr(sa.hash_raw),
JSONB_AGG(
JSONB_BUILD_OBJECT(
'earned_epoch', r.earned_epoch,
Expand All @@ -55,8 +58,7 @@ BEGIN
WHERE
r.addr_id = ANY(sa_id_list)
AND r.earned_epoch = _epoch_no
GROUP BY
sa.id;
GROUP BY sa.hash_raw;
END IF;
END;
$$;
Expand Down
Loading

0 comments on commit a63d0a2

Please sign in to comment.