Skip to content

Commit

Permalink
Replace pool view references
Browse files Browse the repository at this point in the history
  • Loading branch information
rdlrt committed Sep 13, 2024
1 parent a63d0a2 commit 488b062
Show file tree
Hide file tree
Showing 17 changed files with 105 additions and 105 deletions.
7 changes: 3 additions & 4 deletions files/grest/rpc/01_cached_tables/active_stake_cache.sql
Original file line number Diff line number Diff line change
@@ -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)
Expand Down Expand Up @@ -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,
Expand Down
147 changes: 74 additions & 73 deletions files/grest/rpc/01_cached_tables/pool_history_cache.sql
Original file line number Diff line number Diff line change
@@ -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,
Expand All @@ -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,
Expand All @@ -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

Expand Down Expand Up @@ -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,
Expand Down Expand Up @@ -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;
$$;
Expand Down
4 changes: 0 additions & 4 deletions files/grest/rpc/01_cached_tables/pool_info_cache.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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,
Expand Down Expand Up @@ -96,8 +94,6 @@ 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'),
_margin,
Expand Down
4 changes: 2 additions & 2 deletions files/grest/rpc/01_cached_tables/stake_distribution_cache.sql
Original file line number Diff line number Diff line change
@@ -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,
Expand Down Expand Up @@ -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
),
Expand Down
4 changes: 2 additions & 2 deletions files/grest/rpc/account/account_history.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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', DECODE(ph.hash_raw,'hex')::text),
'epoch_no', es.epoch_no::bigint,
'active_stake', es.amount::text
)
Expand All @@ -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', DECODE(ph.hash_raw,'hex')::text),
'epoch_no', es.epoch_no::bigint,
'active_stake', es.amount::text
)
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/account/account_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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)
Expand Down
4 changes: 2 additions & 2 deletions files/grest/rpc/account/account_rewards.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/blocks/block_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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,
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/blocks/blocks.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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,
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/governance/proposal_votes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/governance/voter_proposal_list.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/pool/pool_blocks.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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);
$$;

Expand Down
4 changes: 2 additions & 2 deletions files/grest/rpc/pool/pool_delegators.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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)
Expand Down Expand Up @@ -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
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/pool/pool_delegators_history.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
Loading

0 comments on commit 488b062

Please sign in to comment.