diff --git a/files/grest/rpc/00_blockchain/reserve_withdrawals.sql b/files/grest/rpc/00_blockchain/reserve_withdrawals.sql index 70ca1aa9..b12b2522 100644 --- a/files/grest/rpc/00_blockchain/reserve_withdrawals.sql +++ b/files/grest/rpc/00_blockchain/reserve_withdrawals.sql @@ -19,7 +19,7 @@ AS $$ ENCODE(b.hash,'hex'), b.block_no, r.amount::text, - sa.view, + grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_address, earned_epoch, spendable_epoch FROM reserve AS r diff --git a/files/grest/rpc/00_blockchain/treasury_withdrawals.sql b/files/grest/rpc/00_blockchain/treasury_withdrawals.sql index aafdfb16..a5959e1c 100644 --- a/files/grest/rpc/00_blockchain/treasury_withdrawals.sql +++ b/files/grest/rpc/00_blockchain/treasury_withdrawals.sql @@ -19,7 +19,7 @@ AS $$ ENCODE(b.hash,'hex'), b.block_no, t.amount::text, - sa.view, + grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_address, earned_epoch, spendable_epoch FROM treasury AS t diff --git a/files/grest/rpc/01_cached_tables/active_stake_cache.sql b/files/grest/rpc/01_cached_tables/active_stake_cache.sql index e77dd3eb..ba56d7d5 100644 --- a/files/grest/rpc/01_cached_tables/active_stake_cache.sql +++ b/files/grest/rpc/01_cached_tables/active_stake_cache.sql @@ -1,5 +1,5 @@ CREATE TABLE IF NOT EXISTS grest.pool_active_stake_cache ( - pool_id varchar NOT NULL, + pool_id bigint NOT NULL, epoch_no bigint NOT NULL, amount lovelace NOT NULL, PRIMARY KEY (pool_id, epoch_no) @@ -64,15 +64,14 @@ BEGIN -- POOL ACTIVE STAKE CACHE INSERT INTO grest.pool_active_stake_cache SELECT - pool_hash.view AS pool_id, + epoch_stake.pool_id AS pool_id, epoch_stake.epoch_no, SUM(epoch_stake.amount) AS amount FROM public.epoch_stake - INNER JOIN public.pool_hash ON pool_hash.id = epoch_stake.pool_id WHERE epoch_stake.epoch_no >= _last_active_stake_validated_epoch AND epoch_stake.epoch_no <= _epoch_no GROUP BY - pool_hash.view, + epoch_stake.pool_id, epoch_stake.epoch_no ON CONFLICT ( pool_id, diff --git a/files/grest/rpc/01_cached_tables/pool_history_cache.sql b/files/grest/rpc/01_cached_tables/pool_history_cache.sql index 46196e1d..a167da81 100644 --- a/files/grest/rpc/01_cached_tables/pool_history_cache.sql +++ b/files/grest/rpc/01_cached_tables/pool_history_cache.sql @@ -1,7 +1,7 @@ DROP TABLE IF EXISTS grest.pool_history_cache; CREATE TABLE grest.pool_history_cache ( - pool_id varchar, + pool_id bigint, epoch_no int8 NULL, active_stake lovelace NULL, active_stake_pct numeric NULL, @@ -21,7 +21,7 @@ COMMENT ON TABLE grest.pool_history_cache IS 'A history of pool performance incl CREATE OR REPLACE FUNCTION grest.get_pool_history_data_bulk(_epoch_no_to_insert_from word31type, _pool_bech32 text [] DEFAULT null, _epoch_no_until word31type DEFAULT null) RETURNS TABLE ( - pool_id_bech32 text, + pool_id bigint, epoch_no bigint, active_stake lovelace, active_stake_pct numeric, @@ -41,7 +41,10 @@ AS $$ DECLARE _pool_ids bigint []; BEGIN - _pool_ids := (SELECT array_agg(id) from pool_hash ph where ph.view = ANY(_pool_bech32)); + _pool_ids := (SELECT ARRAY_AGG(id) from pool_hash ph where ph.hash_raw = ANY( + SELECT ARRAY_AGG(DECODE(b32_decode(pool),'hex')) + FROM UNNEST(_pool_bech32) AS pool + ); RETURN QUERY @@ -93,7 +96,7 @@ BEGIN activeandfees AS ( SELECT - ph.view AS pool_id, + es.pool_id AS pool_id, es.epoch_no, SUM(es.amount) AS active_stake, COUNT(1) AS delegator_cnt, @@ -134,84 +137,82 @@ BEGIN ), 2 ) AS saturation_pct FROM epoch_stake AS es - INNER JOIN pool_hash AS ph ON es.pool_id = ph.id WHERE es.epoch_no >= _epoch_no_to_insert_from AND (_epoch_no_until is null or es.epoch_no < _epoch_no_until) - AND (_pool_bech32 is null or ph.view = ANY(_pool_bech32)) - GROUP BY es.pool_id, ph.view, es.epoch_no + AND (_pool_bech32 is null or es.pool_id = ANY(_pool_ids)) + GROUP BY es.pool_id, es.epoch_no ) - SELECT - actf.pool_id::text, - actf.epoch_no::bigint, - actf.active_stake::lovelace, - actf.active_stake_pct, - actf.saturation_pct, - COALESCE(b.block_cnt, 0) AS block_cnt, - actf.delegator_cnt, - actf.pool_fee_variable::double precision, - actf.pool_fee_fixed, - -- for debugging: m.memtotal, - -- for debugging: l.leadertotal, - CASE COALESCE(b.block_cnt, 0) - WHEN 0 THEN - 0 - ELSE - -- special CASE for WHEN reward information is not available yet - CASE COALESCE(l.leadertotal, 0) + COALESCE(m.memtotal, 0) - WHEN 0 THEN NULL - ELSE - CASE - WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN COALESCE(l.leadertotal, 0) - ELSE ROUND(actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable)) - END - END - END AS pool_fees, - CASE COALESCE(b.block_cnt, 0) - WHEN 0 THEN - 0 - ELSE - -- special CASE for WHEN reward information is not available yet - CASE COALESCE(l.leadertotal, 0) + COALESCE(m.memtotal, 0) - WHEN 0 THEN NULL + SELECT + actf.pool_id::text, + actf.epoch_no::bigint, + actf.active_stake::lovelace, + actf.active_stake_pct, + actf.saturation_pct, + COALESCE(b.block_cnt, 0) AS block_cnt, + actf.delegator_cnt, + actf.pool_fee_variable::double precision, + actf.pool_fee_fixed, + -- for debugging: m.memtotal, + -- for debugging: l.leadertotal, + CASE COALESCE(b.block_cnt, 0) + WHEN 0 THEN + 0 + ELSE + -- special CASE for WHEN reward information is not available yet + CASE COALESCE(l.leadertotal, 0) + COALESCE(m.memtotal, 0) + WHEN 0 THEN NULL ELSE CASE - WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN COALESCE(m.memtotal, 0) - ELSE ROUND(COALESCE(m.memtotal, 0) + (COALESCE(l.leadertotal, 0) - (actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable)))) + WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN COALESCE(l.leadertotal, 0) + ELSE ROUND(actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable)) END - END - END AS deleg_rewards, - CASE COALESCE(b.block_cnt, 0) - WHEN 0 THEN 0 + END + END AS pool_fees, + CASE COALESCE(b.block_cnt, 0) + WHEN 0 THEN + 0 + ELSE + -- special CASE for WHEN reward information is not available yet + CASE COALESCE(l.leadertotal, 0) + COALESCE(m.memtotal, 0) + WHEN 0 THEN NULL ELSE - CASE COALESCE(m.memtotal, 0) - WHEN 0 THEN NULL - ELSE COALESCE(m.memtotal, 0) + CASE + WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN COALESCE(m.memtotal, 0) + ELSE ROUND(COALESCE(m.memtotal, 0) + (COALESCE(l.leadertotal, 0) - (actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable)))) END - END::double precision AS member_rewards, - CASE COALESCE(b.block_cnt, 0) - WHEN 0 THEN 0 - ELSE - -- special CASE for WHEN reward information is not available yet - CASE COALESCE(l.leadertotal, 0) + COALESCE(m.memtotal, 0) - WHEN 0 THEN NULL - ELSE - CASE - WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN ROUND((((POW((LEAST(((COALESCE(m.memtotal, 0)) / (NULLIF(actf.active_stake, 0))), 1000) + 1), 73) - 1)) * 100)::numeric, 9) - -- using LEAST AS a way to prevent overflow, in CASE of dodgy database data (e.g. giant rewards / tiny active stake) - ELSE ROUND((((POW((LEAST((((COALESCE(m.memtotal, 0) + (COALESCE(l.leadertotal, 0) - (actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) - + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable))))) / (NULLIF(actf.active_stake, 0))), 1000) + 1), 73) - 1)) * 100)::numeric, 9) - END - END - END AS epoch_ros - FROM pool_hash AS ph - INNER JOIN activeandfees AS actf ON actf.pool_id = ph.view - LEFT JOIN blockcounts AS b ON ph.id = b.pool_hash_id - AND actf.epoch_no = b.epoch_no - LEFT JOIN leadertotals AS l ON ph.id = l.pool_id - AND actf.epoch_no = l.earned_epoch - LEFT JOIN membertotals AS m ON ph.id = m.pool_id - AND actf.epoch_no = m.earned_epoch; + END + END AS deleg_rewards, + CASE COALESCE(b.block_cnt, 0) + WHEN 0 THEN 0 + ELSE + CASE COALESCE(m.memtotal, 0) + WHEN 0 THEN NULL + ELSE COALESCE(m.memtotal, 0) + END + END::double precision AS member_rewards, + CASE COALESCE(b.block_cnt, 0) + WHEN 0 THEN 0 + ELSE + -- special CASE for WHEN reward information is not available yet + CASE COALESCE(l.leadertotal, 0) + COALESCE(m.memtotal, 0) + WHEN 0 THEN NULL + ELSE + CASE + WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN ROUND((((POW((LEAST(((COALESCE(m.memtotal, 0)) / (NULLIF(actf.active_stake, 0))), 1000) + 1), 73) - 1)) * 100)::numeric, 9) + -- using LEAST AS a way to prevent overflow, in CASE of dodgy database data (e.g. giant rewards / tiny active stake) + ELSE ROUND((((POW((LEAST((((COALESCE(m.memtotal, 0) + (COALESCE(l.leadertotal, 0) - (actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) + + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable))))) / (NULLIF(actf.active_stake, 0))), 1000) + 1), 73) - 1)) * 100)::numeric, 9) + END + END + END AS epoch_ros + FROM activeandfees AS actf + LEFT JOIN blockcounts AS b ON actf.pool_id = b.pool_hash_id + AND actf.epoch_no = b.epoch_no + LEFT JOIN leadertotals AS l ON actf.pool_id = l.pool_id + AND actf.epoch_no = l.earned_epoch + LEFT JOIN membertotals AS m ON actf.pool_id = m.pool_id + AND actf.epoch_no = m.earned_epoch; END; $$; diff --git a/files/grest/rpc/01_cached_tables/pool_info_cache.sql b/files/grest/rpc/01_cached_tables/pool_info_cache.sql index dd589cd3..150b45a9 100644 --- a/files/grest/rpc/01_cached_tables/pool_info_cache.sql +++ b/files/grest/rpc/01_cached_tables/pool_info_cache.sql @@ -7,8 +7,6 @@ CREATE TABLE grest.pool_info_cache ( tx_hash text, block_time numeric, pool_hash_id bigint NOT NULL, - pool_id_bech32 character varying NOT NULL, - pool_id_hex text NOT NULL, active_epoch_no bigint NOT NULL, vrf_key_hash text NOT NULL, margin double precision NOT NULL, @@ -96,17 +94,15 @@ BEGIN encode(tx.hash::bytea, 'hex'), EXTRACT(EPOCH FROM b.time), _hash_id, - ph.view, - encode(ph.hash_raw::bytea, 'hex'), _active_epoch_no, - encode(_vrf_key_hash::bytea, 'hex'), + ENCODE(_vrf_key_hash::bytea, 'hex'), _margin, _fixed_cost, _pledge, _deposit, - sa.view, + grest.cip5_hex_to_stake_addr(sa.hash_raw), ARRAY( - SELECT sa.view + SELECT grest.cip5_hex_to_stake_addr(sa.hash_raw) FROM public.pool_owner AS po INNER JOIN public.stake_address AS sa ON sa.id = po.addr_id WHERE po.pool_update_id = _update_id diff --git a/files/grest/rpc/01_cached_tables/stake_distribution_cache.sql b/files/grest/rpc/01_cached_tables/stake_distribution_cache.sql index 67c5f565..7aee259d 100644 --- a/files/grest/rpc/01_cached_tables/stake_distribution_cache.sql +++ b/files/grest/rpc/01_cached_tables/stake_distribution_cache.sql @@ -1,6 +1,6 @@ CREATE TABLE IF NOT EXISTS grest.stake_distribution_cache ( stake_address_raw addr29type PRIMARY KEY, - pool_id varchar, + pool_id bigint, total_balance numeric, utxo numeric, rewards numeric, @@ -65,7 +65,7 @@ BEGIN pool_ids AS ( SELECT awdp.stake_address_id, - pool_hash.view AS pool_id + pool_hash.id AS pool_id FROM pool_hash INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.pool_hash_id = pool_hash.id ), diff --git a/files/grest/rpc/account/account_history.sql b/files/grest/rpc/account/account_history.sql index d8a44cf7..498ed977 100644 --- a/files/grest/rpc/account/account_history.sql +++ b/files/grest/rpc/account/account_history.sql @@ -24,7 +24,7 @@ BEGIN grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_address, JSONB_AGG( JSONB_BUILD_OBJECT( - 'pool_id', ph.view, + 'pool_id', b32_encode('pool', ph.hash_raw::text), 'epoch_no', es.epoch_no::bigint, 'active_stake', es.amount::text ) @@ -45,7 +45,7 @@ BEGIN grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_address, JSONB_AGG( JSONB_BUILD_OBJECT( - 'pool_id', ph.view, + 'pool_id', b32_encode('pool', ph.hash_raw::text), 'epoch_no', es.epoch_no::bigint, 'active_stake', es.amount::text ) diff --git a/files/grest/rpc/account/account_info.sql b/files/grest/rpc/account/account_info.sql index 06bca00d..c41ad4bf 100644 --- a/files/grest/rpc/account/account_info.sql +++ b/files/grest/rpc/account/account_info.sql @@ -91,7 +91,7 @@ BEGIN LEFT JOIN ( SELECT delegation.addr_id, - pool_hash.view AS delegated_pool + b32_encode('pool', DECODE(ph.hash_raw,'hex')::text) AS delegated_pool FROM delegation INNER JOIN pool_hash ON pool_hash.id = delegation.pool_hash_id WHERE delegation.addr_id = ANY(sa_id_list) diff --git a/files/grest/rpc/account/account_rewards.sql b/files/grest/rpc/account/account_rewards.sql index d9f6b648..12a9a998 100644 --- a/files/grest/rpc/account/account_rewards.sql +++ b/files/grest/rpc/account/account_rewards.sql @@ -28,7 +28,7 @@ BEGIN 'spendable_epoch', r.spendable_epoch, 'amount', r.amount::text, 'type', r.type, - 'pool_id', ph.view + 'pool_id', b32_encode('pool', DECODE(ph.hash_raw,'hex')::text) ) ) AS rewards FROM @@ -48,7 +48,7 @@ BEGIN 'spendable_epoch', r.spendable_epoch, 'amount', r.amount::text, 'type', r.type, - 'pool_id', ph.view + 'pool_id', b32_encode('pool', DECODE(ph.hash_raw,'hex')::text) ) ) AS rewards FROM diff --git a/files/grest/rpc/address/address_utxos.sql b/files/grest/rpc/address/address_utxos.sql index b317e9e1..5cbc4363 100644 --- a/files/grest/rpc/address/address_utxos.sql +++ b/files/grest/rpc/address/address_utxos.sql @@ -47,7 +47,7 @@ BEGIN tx_out.index::smallint, tx_out.address::text, tx_out.value::text, - sa.view::text as stake_address, + grest.cip5_hex_to_stake_addr(sa.hash_raw)::text as stake_address, ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, b.epoch_no, b.block_no, diff --git a/files/grest/rpc/address/credential_utxos.sql b/files/grest/rpc/address/credential_utxos.sql index 5c160941..57bfe179 100644 --- a/files/grest/rpc/address/credential_utxos.sql +++ b/files/grest/rpc/address/credential_utxos.sql @@ -53,7 +53,7 @@ BEGIN tx_out.index::smallint, tx_out.address::text, tx_out.value::text, - sa.view::text as stake_address, + grest.cip5_hex_to_stake_addr(sa.hash_raw)::text as stake_address, ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, b.epoch_no, b.block_no, diff --git a/files/grest/rpc/assets/asset_utxos.sql b/files/grest/rpc/assets/asset_utxos.sql index 17392559..25d5df08 100644 --- a/files/grest/rpc/assets/asset_utxos.sql +++ b/files/grest/rpc/assets/asset_utxos.sql @@ -66,7 +66,7 @@ BEGIN tx_out.index::smallint, tx_out.address::text, tx_out.value::text, - sa.view::text as stake_address, + grest.cip5_hex_to_stake_addr(sa.hash_raw)::text as stake_address, ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, b.epoch_no, b.block_no, diff --git a/files/grest/rpc/assets/policy_asset_addresses.sql b/files/grest/rpc/assets/policy_asset_addresses.sql index 32974095..62642c32 100644 --- a/files/grest/rpc/assets/policy_asset_addresses.sql +++ b/files/grest/rpc/assets/policy_asset_addresses.sql @@ -28,7 +28,7 @@ BEGIN SELECT atoc.ma_id, txo.address, - sa.view AS stake_address, + grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_address, atoc.quantity FROM grest.asset_tx_out_cache AS atoc LEFT JOIN multi_asset AS ma ON ma.id = atoc.ma_id @@ -47,7 +47,7 @@ BEGIN SELECT ENCODE(ma.name, 'hex') AS asset_name, txo.address, - sa.view AS stake_address, + grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_address, SUM(mto.quantity)::text FROM multi_asset AS ma LEFT JOIN ma_tx_out AS mto ON mto.ident = ma.id @@ -58,7 +58,7 @@ BEGIN GROUP BY ma.name, txo.address, - sa.view; + sa.hash_raw; END IF; END; $$; diff --git a/files/grest/rpc/blocks/block_info.sql b/files/grest/rpc/blocks/block_info.sql index 2aa94a92..496fcbf8 100644 --- a/files/grest/rpc/blocks/block_info.sql +++ b/files/grest/rpc/blocks/block_info.sql @@ -59,7 +59,7 @@ BEGIN b.vrf_key, ENCODE(b.op_cert::bytea, 'hex') AS op_cert, b.op_cert_counter, - ph.view AS pool, + b32_encode('pool', DECODE(ph.hash_raw,'hex')::text) AS pool, b.proto_major, b.proto_minor, block_data.total_output::text, diff --git a/files/grest/rpc/blocks/blocks.sql b/files/grest/rpc/blocks/blocks.sql index 77141539..12696b73 100644 --- a/files/grest/rpc/blocks/blocks.sql +++ b/files/grest/rpc/blocks/blocks.sql @@ -27,7 +27,7 @@ AS $$ EXTRACT(EPOCH FROM b.time)::integer AS block_time, b.tx_count, b.vrf_key, - ph.view AS pool, + b32_encode('pool', DECODE(ph.hash_raw,'hex')::text) AS pool, b.proto_major, b.proto_minor, b.op_cert_counter, diff --git a/files/grest/rpc/governance/drep_delegators.sql b/files/grest/rpc/governance/drep_delegators.sql index a4594c40..80d759d9 100644 --- a/files/grest/rpc/governance/drep_delegators.sql +++ b/files/grest/rpc/governance/drep_delegators.sql @@ -80,7 +80,7 @@ BEGIN ) SELECT - sa.view::text, + grest.cip5_hex_to_stake_addr(sa.hash_raw)::text, ENCODE(sa.hash_raw,'hex'), ENCODE(sa.script_hash,'hex'), b.epoch_no, @@ -90,7 +90,7 @@ BEGIN INNER JOIN tx ON ad.tx_id = tx.id INNER JOIN block AS b ON tx.block_id = b.id LEFT JOIN grest.stake_distribution_cache AS sdc ON sa.view = sdc.stake_address - ORDER BY b.epoch_no DESC, sa.view + ORDER BY b.epoch_no DESC, grest.cip5_hex_to_stake_addr(sa.hash_raw) ); END; diff --git a/files/grest/rpc/governance/proposal_list.sql b/files/grest/rpc/governance/proposal_list.sql index 3910d3ef..362e1117 100644 --- a/files/grest/rpc/governance/proposal_list.sql +++ b/files/grest/rpc/governance/proposal_list.sql @@ -33,7 +33,7 @@ AS $$ gap.type, gap.description, gap.deposit::text, - sa.view, + grest.cip5_hex_to_stake_addr(sa.hash_raw), b.epoch_no, gap.ratified_epoch, gap.enacted_epoch, @@ -51,7 +51,7 @@ AS $$ ELSE JSONB_BUILD_OBJECT( 'stake_address', ( - SELECT sa2.view + SELECT grest.cip5_hex_to_stake_addr(sa2.hash_raw) FROM stake_address AS sa2 WHERE sa2.id = tw.stake_address_id ), diff --git a/files/grest/rpc/governance/proposal_votes.sql b/files/grest/rpc/governance/proposal_votes.sql index c6beee12..472c54ce 100644 --- a/files/grest/rpc/governance/proposal_votes.sql +++ b/files/grest/rpc/governance/proposal_votes.sql @@ -25,7 +25,7 @@ BEGIN vp.voter_role::text, CASE WHEN dh.raw IS NOT NULL THEN grest.cip129_hex_to_drep_id(dh.raw, dh.has_script) - WHEN ph.view IS NOT NULL THEN ph.view + WHEN ph.id IS NOT NULL THEN b32_encode('pool', DECODE(ph.hash_raw,'hex')::text) WHEN ch.raw IS NOT NULL THEN grest.cip129_hex_to_cc_hot(ch.raw, ch.has_script) ELSE '' -- shouldn't happen diff --git a/files/grest/rpc/governance/voter_proposal_list.sql b/files/grest/rpc/governance/voter_proposal_list.sql index e76ed037..d6401b42 100644 --- a/files/grest/rpc/governance/voter_proposal_list.sql +++ b/files/grest/rpc/governance/voter_proposal_list.sql @@ -35,7 +35,7 @@ BEGIN IF STARTS_WITH(_voter_id, 'drep') THEN SELECT INTO _drep_id id FROM public.drep_hash WHERE raw = DECODE((SELECT grest.cip129_drep_id_to_hex(_voter_id)), 'hex') AND has_script = grest.cip129_drep_id_has_script(_voter_id); ELSIF STARTS_WITH(_voter_id, 'pool') THEN - SELECT INTO _spo_id id FROM public.pool_hash WHERE view = _voter_id; + SELECT INTO _spo_id id FROM public.pool_hash WHERE hash_raw = DECODE(b32_decode(_voter_id),'hex'); ELSIF STARTS_WITH(_voter_id, 'cc_hot') THEN SELECT INTO _committee_member_id id FROM public.committee_hash WHERE raw = DECODE((SELECT grest.cip129_cc_hot_to_hex(_voter_id)), 'hex') AND has_script = grest.cip129_cc_hot_has_script(_voter_id); END IF; @@ -63,7 +63,7 @@ BEGIN gap.type, gap.description, gap.deposit::text, - sa.view, + grest.cip5_hex_to_stake_addr(sa.hash_raw), b.epoch_no, gap.ratified_epoch, gap.enacted_epoch, @@ -81,7 +81,7 @@ BEGIN ELSE JSONB_BUILD_OBJECT( 'stake_address', ( - SELECT sa2.view + SELECT grest.cip5_hex_to_stake_addr(sa2.hash_raw) FROM stake_address AS sa2 WHERE sa2.id = tw.stake_address_id ), diff --git a/files/grest/rpc/pool/pool_blocks.sql b/files/grest/rpc/pool/pool_blocks.sql index e1299b89..9ea6e087 100644 --- a/files/grest/rpc/pool/pool_blocks.sql +++ b/files/grest/rpc/pool/pool_blocks.sql @@ -18,7 +18,7 @@ AS $$ EXTRACT(EPOCH FROM b.time)::integer FROM public.block AS b INNER JOIN public.slot_leader AS sl ON b.slot_leader_id = sl.id - WHERE sl.pool_hash_id = (SELECT id FROM public.pool_hash WHERE view = _pool_bech32) + WHERE sl.pool_hash_id = (SELECT id FROM public.pool_hash WHERE hash_raw = DECODE(b32_decode(_pool_bech32),'hex')) AND (_epoch_no IS NULL OR b.epoch_no = _epoch_no); $$; diff --git a/files/grest/rpc/pool/pool_delegators.sql b/files/grest/rpc/pool/pool_delegators.sql index 992c131a..6dab740a 100644 --- a/files/grest/rpc/pool/pool_delegators.sql +++ b/files/grest/rpc/pool/pool_delegators.sql @@ -38,7 +38,7 @@ BEGIN sa.id AS stake_address_id, sa.hash_raw AS stake_address_raw FROM delegation AS d - INNER JOIN pool_hash AS ph ON d.pool_hash_id = ph.id AND ph.view = _pool_bech32 + INNER JOIN pool_hash AS ph ON d.pool_hash_id = ph.id AND ph.hash_raw = DECODE(b32_decode(_pool_bech32),'hex') INNER JOIN stake_address AS sa ON d.addr_id = sa.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) @@ -81,7 +81,7 @@ AS $$ DECLARE _pool_id bigint; BEGIN - SELECT id INTO _pool_id FROM pool_hash WHERE pool_hash.view = _pool_bech32; + SELECT id INTO _pool_id FROM pool_hash WHERE pool_hash.hash_raw = DECODE(b32_decode(_pool_bech32),'hex'); RETURN QUERY WITH diff --git a/files/grest/rpc/pool/pool_delegators_history.sql b/files/grest/rpc/pool/pool_delegators_history.sql index 59dba62b..9d93de7b 100644 --- a/files/grest/rpc/pool/pool_delegators_history.sql +++ b/files/grest/rpc/pool/pool_delegators_history.sql @@ -10,7 +10,7 @@ AS $$ DECLARE _pool_id bigint; BEGIN - SELECT id INTO _pool_id FROM pool_hash WHERE pool_hash.view = _pool_bech32; + SELECT id INTO _pool_id FROM pool_hash WHERE pool_hash.hash_raw = DECODE(b32_decode(_pool_bech32),'hex'); IF _epoch_no IS NULL THEN RETURN QUERY SELECT diff --git a/files/grest/rpc/pool/pool_info.sql b/files/grest/rpc/pool/pool_info.sql index f20d55fa..16cb1786 100644 --- a/files/grest/rpc/pool/pool_info.sql +++ b/files/grest/rpc/pool/pool_info.sql @@ -49,17 +49,19 @@ BEGIN pic.pool_status, pic.retiring_epoch, pic.meta_id, - ph.view, + b32_encode('pool', ph.hash_raw::text) AS pool_id_bech32, ph.hash_raw FROM grest.pool_info_cache AS pic INNER JOIN public.pool_hash AS ph ON ph.id = pic.pool_hash_id - WHERE ph.view = ANY(SELECT UNNEST(_pool_bech32_ids)) + WHERE ph.hash_raw = ANY( + SELECT ARRAY_AGG(DECODE(b32_decode(p),'hex')) + FROM UNNEST(_pool_bech32_ids) AS p) ORDER BY pic.pool_hash_id, pic.tx_id DESC ) SELECT - ph.view AS pool_id_bech32, + api.pool_id_bech32, ENCODE(ph.hash_raw::bytea, 'hex') AS pool_id_hex, pu.active_epoch_no, ENCODE(pu.vrf_key_hash, 'hex') AS vrf_key_hash, @@ -122,7 +124,7 @@ BEGIN LEFT JOIN LATERAL( SELECT amount::lovelace AS as_sum FROM grest.pool_active_stake_cache AS pasc - WHERE pasc.pool_id = api.view + WHERE pasc.pool_id = api.pool_hash_id AND pasc.epoch_no = _epoch_no ) AS active_stake ON TRUE LEFT JOIN LATERAL( @@ -156,7 +158,7 @@ BEGIN ELSE 0 END)::lovelace END AS pledge - FROM grest.pool_delegators_list(api.view) AS pool_delegs + FROM grest.pool_delegators_list(api.pool_id_bech32) AS pool_delegs ) AS live ON TRUE; END; $$; diff --git a/files/grest/rpc/pool/pool_list.sql b/files/grest/rpc/pool/pool_list.sql index a13d63ad..e6476e40 100644 --- a/files/grest/rpc/pool/pool_list.sql +++ b/files/grest/rpc/pool/pool_list.sql @@ -19,7 +19,7 @@ RETURNS TABLE ( LANGUAGE sql STABLE AS $$ SELECT DISTINCT ON (pic.pool_hash_id) - ph.view AS pool_id_bech32, + b32_encode('pool', ph.hash_raw::text) AS pool_id_bech32, ENCODE(ph.hash_raw,'hex') as pool_id_hex, pu.active_epoch_no, pu.margin, diff --git a/files/grest/rpc/pool/pool_metadata.sql b/files/grest/rpc/pool/pool_metadata.sql index e2fcf732..a074f299 100644 --- a/files/grest/rpc/pool/pool_metadata.sql +++ b/files/grest/rpc/pool/pool_metadata.sql @@ -10,8 +10,8 @@ AS $$ #variable_conflict use_column BEGIN RETURN QUERY - SELECT DISTINCT ON (ph.view) - ph.view AS pool_id_bech32, + SELECT DISTINCT ON (ph.id) + b32_encode('pool', ph.hash_raw::text) AS pool_id_bech32, pmr.url AS meta_url, ENCODE(pmr.hash, 'hex') AS meta_hash, ocpd.json AS meta_json @@ -21,10 +21,12 @@ BEGIN WHERE CASE WHEN _pool_bech32_ids IS NULL THEN TRUE - WHEN _pool_bech32_ids IS NOT NULL THEN ph.view = ANY(SELECT UNNEST(_pool_bech32_ids)) + WHEN _pool_bech32_ids IS NOT NULL THEN ph.hash_raw = ANY( + SELECT ARRAY_AGG(DECODE(b32_decode(p),'hex')) + FROM UNNEST(_pool_bech32_ids) AS p) END ORDER BY - ph.view, + ph.hash_raw, pmr.registered_tx_id DESC; END; $$; diff --git a/files/grest/rpc/pool/pool_registrations.sql b/files/grest/rpc/pool/pool_registrations.sql index dcff9f99..9f974300 100644 --- a/files/grest/rpc/pool/pool_registrations.sql +++ b/files/grest/rpc/pool/pool_registrations.sql @@ -11,7 +11,7 @@ RETURNS TABLE ( LANGUAGE sql STABLE AS $$ SELECT - ph.view, + b32_encode('pool', ph.hash_raw::text), ENCODE(tx.hash,'hex'), ENCODE(b.hash,'hex'), b.block_no, diff --git a/files/grest/rpc/pool/pool_relays.sql b/files/grest/rpc/pool/pool_relays.sql index e821bb9a..cb365e30 100644 --- a/files/grest/rpc/pool/pool_relays.sql +++ b/files/grest/rpc/pool/pool_relays.sql @@ -5,8 +5,8 @@ RETURNS TABLE ( ) LANGUAGE sql STABLE AS $$ - SELECT DISTINCT ON (ph.view) - ph.view AS pool_id_bech32, + SELECT DISTINCT ON (ph.id) + b32_encode('pool', ph.hash_raw::text) AS pool_id_bech32, JSONB_AGG(JSONB_BUILD_OBJECT ( 'ipv4', pr.ipv4, 'ipv6', pr.ipv6, @@ -17,9 +17,9 @@ AS $$ FROM public.pool_hash AS ph LEFT JOIN public.pool_update AS pu ON pu.hash_id = ph.id LEFT JOIN public.pool_relay AS pr ON pu.id = pr.update_id - GROUP BY ph.view,pu.registered_tx_id + GROUP BY ph.hash_raw,pu.registered_tx_id ORDER BY - ph.view, + ph.hash_raw, pu.registered_tx_id DESC ; $$; diff --git a/files/grest/rpc/pool/pool_retirements.sql b/files/grest/rpc/pool/pool_retirements.sql index ea9a9b5a..67c3bb9c 100644 --- a/files/grest/rpc/pool/pool_retirements.sql +++ b/files/grest/rpc/pool/pool_retirements.sql @@ -11,7 +11,7 @@ RETURNS TABLE ( LANGUAGE sql STABLE AS $$ SELECT - ph.view, + b32_encode('pool', ph.hash_raw::text), ENCODE(tx.hash,'hex'), ENCODE(b.hash,'hex'), b.block_no, diff --git a/files/grest/rpc/pool/pool_updates.sql b/files/grest/rpc/pool/pool_updates.sql index 3fe1f631..14c0368e 100644 --- a/files/grest/rpc/pool/pool_updates.sql +++ b/files/grest/rpc/pool/pool_updates.sql @@ -30,7 +30,7 @@ BEGIN SELECT ENCODE(tx.hash::bytea, 'hex') AS tx_hash, EXTRACT(EPOCH FROM b.time)::integer AS block_time, - ph.view AS pool_id_bech32, + b32_encode('pool', ph.hash_raw::text) AS pool_id_bech32, ENCODE(ph.hash_raw::bytea, 'hex') AS pool_id_hex, pu.active_epoch_no, ENCODE(pu.vrf_key_hash, 'hex') AS vrf_key_hash, @@ -65,13 +65,13 @@ BEGIN LEFT JOIN public.pool_metadata_ref AS pmr ON pu.meta_id = pmr.id LEFT JOIN public.off_chain_pool_data AS ocpd ON pu.meta_id = ocpd.pmr_id WHERE _pool_bech32 IS NULL - OR ph.view = _pool_bech32 - GROUP BY tx.hash, b.time, ph.view, ph.hash_raw, pu.active_epoch_no, pu.vrf_key_hash, pu.margin, pu.fixed_cost, pu.pledge, sa.view, pmr.url, pmr.hash, ocpd.json), + OR ph.hash_raw = DECODE(b32_decode(_pool_bech32),'hex') + GROUP BY tx.hash, b.time, ph.hash_raw, ph.hash_raw, pu.active_epoch_no, pu.vrf_key_hash, pu.margin, pu.fixed_cost, pu.pledge, sa.view, pmr.url, pmr.hash, ocpd.json), pool_dereg AS ( SELECT ENCODE(tx.hash::bytea, 'hex') AS tx_hash, EXTRACT(EPOCH FROM b.time)::integer AS block_time, - ph.view AS pool_id_bech32, + b32_encode('pool', ph.hash_raw::text) AS pool_id_bech32, ENCODE(ph.hash_raw::bytea, 'hex') AS pool_id_hex, NULL::bigint AS active_epoch_no, NULL AS vrf_key_hash, @@ -91,7 +91,7 @@ BEGIN INNER JOIN public.tx ON tx.id = pr.announced_tx_id INNER JOIN public.block AS b ON b.id = tx.block_id WHERE _pool_bech32 IS NULL - OR ph.view = _pool_bech32) + OR ph.hash_raw = DECODE(b32_decode(_pool_bech32),'hex')) SELECT * FROM pool_reg UNION SELECT * FROM pool_dereg ORDER BY diff --git a/files/grest/rpc/pool/pool_votes.sql b/files/grest/rpc/pool/pool_votes.sql index d61e1c50..b8e8f321 100644 --- a/files/grest/rpc/pool/pool_votes.sql +++ b/files/grest/rpc/pool/pool_votes.sql @@ -25,7 +25,7 @@ AS $$ INNER JOIN public.tx vote_tx on vp.tx_id = vote_tx.id INNER JOIN public.block AS b ON vote_tx.block_id = b.id LEFT JOIN public.voting_anchor AS va ON vp.voting_anchor_id = va.id - WHERE ph.view = _pool_bech32 + WHERE ph.hash_raw = DECODE(b32_decode(_pool_bech32),'hex') ORDER BY vote_tx.id DESC; $$; diff --git a/files/grest/rpc/transactions/tx_info.sql b/files/grest/rpc/transactions/tx_info.sql index 8161675b..cc815165 100644 --- a/files/grest/rpc/transactions/tx_info.sql +++ b/files/grest/rpc/transactions/tx_info.sql @@ -438,7 +438,7 @@ BEGIN 'type', 'pool_delegation', 'info', JSONB_BUILD_OBJECT( 'stake_address', sa.view, - 'pool_id_bech32', ph.view, + 'pool_id_bech32', b32_encode('pool', ph.hash_raw::text), 'pool_id_hex', ENCODE(ph.hash_raw, 'hex') ) ) AS data @@ -521,7 +521,7 @@ BEGIN 'index', pr.cert_index, 'type', 'pool_retire', 'info', JSONB_BUILD_OBJECT( - 'pool_id_bech32', ph.view, + 'pool_id_bech32', b32_encode('pool', ph.hash_raw::text), 'pool_id_hex', ENCODE(ph.hash_raw, 'hex'), 'retiring epoch', pr.retiring_epoch ) @@ -539,7 +539,7 @@ BEGIN 'index', pu.cert_index, 'type', 'pool_update', 'info', JSONB_BUILD_OBJECT( - 'pool_id_bech32', ph.view, + 'pool_id_bech32', b32_encode('pool', ph.hash_raw::text), 'pool_id_hex', ENCODE(ph.hash_raw, 'hex'), 'active_epoch_no', pu.active_epoch_no, 'vrf_key_hash', ENCODE(pu.vrf_key_hash, 'hex'), @@ -571,7 +571,7 @@ BEGIN LEFT JOIN public.pool_metadata_ref AS pmr ON pu.meta_id = pmr.id WHERE _certs IS TRUE AND pu.registered_tx_id = ANY(_tx_id_list) - GROUP BY pu.registered_tx_id, pu.cert_index, ph.view, ph.hash_raw, pu.active_epoch_no, pu.vrf_key_hash, pu.margin, pu.fixed_cost, pu.pledge, sa.view, pmr.url, pmr.hash + GROUP BY pu.registered_tx_id, pu.cert_index, ph.hash_raw, pu.active_epoch_no, pu.vrf_key_hash, pu.margin, pu.fixed_cost, pu.pledge, sa.view, pmr.url, pmr.hash -- UNION ALL -- @@ -848,7 +848,7 @@ BEGIN 'proposal_tx_hash', ENCODE(tx.hash, 'hex'), 'proposal_index', gap.index, 'voter_role', vp.voter_role, - 'voter', COALESCE(ENCODE(ch.raw, 'hex'), dh.view, ph.view), + 'voter', COALESCE(ENCODE(ch.raw, 'hex'), dh.view, b32_encode('pool', ph.hash_raw::text)), 'voter_hex', COALESCE(ENCODE(ch.raw, 'hex'), ENCODE(dh.raw, 'hex'), ENCODE(ph.hash_raw, 'hex')), 'vote', vp.vote ) AS data