Skip to content

Commit

Permalink
Dont include epoch_params in epoch_info_cache, update references acco…
Browse files Browse the repository at this point in the history
…rdingly
  • Loading branch information
rdlrt committed Sep 7, 2023
1 parent 7c17dbf commit c6465fd
Show file tree
Hide file tree
Showing 6 changed files with 56 additions and 150 deletions.
4 changes: 2 additions & 2 deletions files/grest/cron/jobs/epoch-info-cache-update.sh
Original file line number Diff line number Diff line change
@@ -1,12 +1,12 @@
#!/bin/bash
DB_NAME=cexplorer

tip=$(psql ${DB_NAME} -qbt -c "select extract(epoch from time)::integer from block order by id desc limit 1;" | xargs)
tip=$(psql ${DB_NAME} -qbt -c "SELECT EXTRACT(EPOCH FROM time)::integer FROM block ORDER BY id DESC LIMIT 1;" | xargs)

if [[ $(( $(date +%s) - tip )) -gt 300 ]]; then
echo "$(date +%F_%H:%M:%S) Skipping as database has not received a new block in past 300 seconds!" && exit 1
fi

echo "$(date +%F_%H:%M:%S) Running epoch info cache update..."
psql ${DB_NAME} -qbt -c "SELECT GREST.EPOCH_INFO_CACHE_UPDATE();" 1>/dev/null 2>&1
psql ${DB_NAME} -qbt -c "SELECT grest.epoch_info_cache_update();" 1>/dev/null 2>&1
echo "$(date +%F_%H:%M:%S) Job done!"
60 changes: 1 addition & 59 deletions files/grest/rpc/01_cached_tables/epoch_info_cache.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,37 +9,8 @@ CREATE TABLE IF NOT EXISTS grest.epoch_info_cache (
i_total_rewards lovelace,
i_avg_blk_reward lovelace,
i_last_tx_id bigint,
p_min_fee_a word31type,
p_min_fee_b word31type,
p_max_block_size word31type,
p_max_tx_size word31type,
p_max_bh_size word31type,
p_key_deposit lovelace,
p_pool_deposit lovelace,
p_max_epoch word31type,
p_optimal_pool_count word31type,
p_influence double precision,
p_monetary_expand_rate double precision,
p_treasury_growth_rate double precision,
p_decentralisation double precision,
p_extra_entropy text,
p_protocol_major word31type,
p_protocol_minor word31type,
p_min_utxo_value lovelace,
p_min_pool_cost lovelace,
p_nonce text,
p_block_hash text,
p_cost_models character varying,
p_price_mem double precision,
p_price_step double precision,
p_max_tx_ex_mem word64type,
p_max_tx_ex_steps word64type,
p_max_block_ex_mem word64type,
p_max_block_ex_steps word64type,
p_max_val_size word64type,
p_collateral_percent word31type,
p_max_collateral_inputs word31type,
p_coins_per_utxo_size lovelace
);

COMMENT ON TABLE grest.epoch_info_cache IS 'Contains detailed info for epochs including protocol parameters';
Expand Down Expand Up @@ -123,37 +94,8 @@ BEGIN
ELSE NULL
END AS i_avg_blk_reward,
last_tx.tx_id AS i_last_tx_id,
ep.min_fee_a AS p_min_fee_a,
ep.min_fee_b AS p_min_fee_b,
ep.max_block_size AS p_max_block_size,
ep.max_tx_size AS p_max_tx_size,
ep.max_bh_size AS p_max_bh_size,
ep.key_deposit AS p_key_deposit,
ep.pool_deposit AS p_pool_deposit,
ep.max_epoch AS p_max_epoch,
ep.optimal_pool_count AS p_optimal_pool_count,
ep.influence AS p_influence,
ep.monetary_expand_rate AS p_monetary_expand_rate,
ep.treasury_growth_rate AS p_treasury_growth_rate,
ep.decentralisation AS p_decentralisation,
ENCODE(ep.extra_entropy, 'hex') AS p_extra_entropy,
ep.protocol_major AS p_protocol_major,
ep.protocol_minor AS p_protocol_minor,
ep.min_utxo_value AS p_min_utxo_value,
ep.min_pool_cost AS p_min_pool_cost,
ENCODE(ep.nonce, 'hex') AS p_nonce,
ENCODE(b.hash, 'hex') AS p_block_hash,
cm.costs AS p_cost_models,
ep.price_mem AS p_price_mem,
ep.price_step AS p_price_step,
ep.max_tx_ex_mem AS p_max_tx_ex_mem,
ep.max_tx_ex_steps AS p_max_tx_ex_steps,
ep.max_block_ex_mem AS p_max_block_ex_mem,
ep.max_block_ex_steps AS p_max_block_ex_steps,
ep.max_val_size AS p_max_val_size,
ep.collateral_percent AS p_collateral_percent,
ep.max_collateral_inputs AS p_max_collateral_inputs,
ep.coins_per_utxo_size AS p_coins_per_utxo_size
ENCODE(b.hash, 'hex') AS p_block_hash
FROM epoch AS e
LEFT JOIN epoch_param AS ep ON ep.epoch_no = e.no
LEFT JOIN cost_model AS cm ON cm.id = ep.cost_model_id
Expand Down
10 changes: 5 additions & 5 deletions files/grest/rpc/01_cached_tables/pool_history_cache.sql
Original file line number Diff line number Diff line change
Expand Up @@ -39,9 +39,9 @@ BEGIN
IF (
SELECT COUNT(key) != 1
FROM GREST.CONTROL_TABLE
WHERE key = 'epoch_info_cache_last_updated'
WHERE key = 'last_active_stake_validated_epoch'
) THEN
RAISE EXCEPTION 'Epoch Info Cache not yet populated! Exiting...';
RAISE EXCEPTION 'Active stake cache not yet populated! Exiting...';
END IF;

IF _epoch_no_to_insert_from IS NULL THEN
Expand Down Expand Up @@ -153,9 +153,9 @@ BEGIN
ROUND(
(act.amount / (
SELECT supply::bigint / (
SELECT eic.p_optimal_pool_count
FROM grest.epoch_info_cache AS eic
WHERE eic.epoch_no = act.epoch_no
SELECT ep.optimal_pool_count
FROM epoch_param AS ep
WHERE ep.epoch_no = act.epoch_no
)
FROM grest.totals (act.epoch_no)
) * 100
Expand Down
7 changes: 3 additions & 4 deletions files/grest/rpc/epoch/epoch_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -44,17 +44,16 @@ BEGIN
eas.amount::text AS active_stake,
ei.i_total_rewards::text AS total_rewards,
ei.i_avg_blk_reward::text AS avg_blk_reward
FROM
grest.epoch_info_cache AS ei
LEFT JOIN grest.epoch_active_stake_cache AS eas ON eas.epoch_no = ei.epoch_no
FROM grest.epoch_info_cache AS ei
LEFT JOIN grest.epoch_active_stake_cache AS eas ON eas.epoch_no = ei.epoch_no
WHERE
CASE WHEN _epoch_no IS NULL THEN
ei.epoch_no <= (SELECT MAX(epoch.no) FROM public.epoch)
ELSE
ei.epoch_no = _epoch_no
END
AND
(_include_next_epoch OR ei.i_first_block_time::integer is not null);
(_include_next_epoch OR ei.i_first_block_time::integer IS NOT NULL);
END;
$$;

Expand Down
119 changes: 42 additions & 77 deletions files/grest/rpc/epoch/epoch_params.sql
Original file line number Diff line number Diff line change
Expand Up @@ -21,7 +21,7 @@ RETURNS TABLE (
min_pool_cost text,
nonce text,
block_hash text,
cost_models character varying,
cost_models jsonb,
price_mem double precision,
price_step double precision,
max_tx_ex_mem word64type,
Expand All @@ -36,87 +36,52 @@ RETURNS TABLE (
LANGUAGE plpgsql
AS $$
BEGIN
IF _epoch_no IS NULL THEN
RETURN QUERY
RETURN QUERY
SELECT
ei.epoch_no,
ei.p_min_fee_a AS min_fee_a,
ei.p_min_fee_b AS min_fee_b,
ei.p_max_block_size AS max_block_size,
ei.p_max_tx_size AS max_tx_size,
ei.p_max_bh_size AS max_bh_size,
ei.p_key_deposit::text AS key_deposit,
ei.p_pool_deposit::text AS pool_deposit,
ei.p_max_epoch AS max_epoch,
ei.p_optimal_pool_count AS optimal_pool_count,
ei.p_influence AS influence,
ei.p_monetary_expand_rate AS monetary_expand_rate,
ei.p_treasury_growth_rate AS treasury_growth_rate,
ei.p_decentralisation AS decentralisation,
ei.p_extra_entropy AS extra_entropy,
ei.p_protocol_major AS protocol_major,
ei.p_protocol_minor AS protocol_minor,
ei.p_min_utxo_value::text AS min_utxo_value,
ei.p_min_pool_cost::text AS min_pool_cost,
ep.epoch_no,
ep.min_fee_a AS min_fee_a,
ep.min_fee_b AS min_fee_b,
ep.max_block_size AS max_block_size,
ep.max_tx_size AS max_tx_size,
ep.max_bh_size AS max_bh_size,
ep.key_deposit::text AS key_deposit,
ep.pool_deposit::text AS pool_deposit,
ep.max_epoch AS max_epoch,
ep.optimal_pool_count AS optimal_pool_count,
ep.influence AS influence,
ep.monetary_expand_rate AS monetary_expand_rate,
ep.treasury_growth_rate AS treasury_growth_rate,
ep.decentralisation AS decentralisation,
ENCODE(ep.extra_entropy, 'hex') AS extra_entropy,
ep.protocol_major AS protocol_major,
ep.protocol_minor AS protocol_minor,
ep.min_utxo_value::text AS min_utxo_value,
ep.min_pool_cost::text AS min_pool_cost,
ei.p_nonce AS nonce,
ei.p_block_hash AS block_hash,
ei.p_cost_models AS cost_models,
ei.p_price_mem AS price_mem,
ei.p_price_step AS price_step,
ei.p_max_tx_ex_mem AS max_tx_ex_mem,
ei.p_max_tx_ex_steps AS max_tx_ex_steps,
ei.p_max_block_ex_mem AS max_block_ex_mem,
ei.p_max_block_ex_steps AS max_block_ex_steps,
ei.p_max_val_size AS max_val_size,
ei.p_collateral_percent AS collateral_percent,
ei.p_max_collateral_inputs AS max_collateral_inputs,
ei.p_coins_per_utxo_size::text AS coins_per_utxo_size
FROM
grest.epoch_info_cache AS ei
WHERE
ei.epoch_no <= (SELECT MAX(epoch.no) FROM public.epoch)
cm.costs AS cost_models,
ep.price_mem AS price_mem,
ep.price_step AS price_step,
ep.max_tx_ex_mem AS max_tx_ex_mem,
ep.max_tx_ex_steps AS max_tx_ex_steps,
ep.max_block_ex_mem AS max_block_ex_mem,
ep.max_block_ex_steps AS max_block_ex_steps,
ep.max_val_size AS max_val_size,
ep.collateral_percent AS collateral_percent,
ep.max_collateral_inputs AS max_collateral_inputs,
ep.coins_per_utxo_size::text AS coins_per_utxo_size
FROM epoch_param AS ep
LEFT JOIN grest.epoch_info_cache AS ei ON ei.epoch_no = ep.epoch_no
LEFT JOIN cost_model AS cm ON cm.id = ep.cost_model_id
WHERE
CASE
WHEN _epoch_no IS NULL THEN
ep.epoch_no <= (SELECT MAX(epoch.no) FROM public.epoch)
ELSE
ep.epoch_no = _epoch_no
END
ORDER BY
ei.epoch_no DESC;
ELSE
RETURN QUERY
SELECT
ei.epoch_no,
ei.p_min_fee_a AS min_fee_a,
ei.p_min_fee_b AS min_fee_b,
ei.p_max_block_size AS max_block_size,
ei.p_max_tx_size AS max_tx_size,
ei.p_max_bh_size AS max_bh_size,
ei.p_key_deposit::text AS key_deposit,
ei.p_pool_deposit::text AS pool_deposit,
ei.p_max_epoch AS max_epoch,
ei.p_optimal_pool_count AS optimal_pool_count,
ei.p_influence AS influence,
ei.p_monetary_expand_rate AS monetary_expand_rate,
ei.p_treasury_growth_rate AS treasury_growth_rate,
ei.p_decentralisation AS decentralisation,
ei.p_extra_entropy AS extra_entropy,
ei.p_protocol_major AS protocol_major,
ei.p_protocol_minor AS protocol_minor,
ei.p_min_utxo_value::text AS min_utxo_value,
ei.p_min_pool_cost::text AS min_pool_cost,
ei.p_nonce AS nonce,
ei.p_block_hash AS block_hash,
ei.p_cost_models AS cost_models,
ei.p_price_mem AS price_mem,
ei.p_price_step AS price_step,
ei.p_max_tx_ex_mem AS max_tx_ex_mem,
ei.p_max_tx_ex_steps AS max_tx_ex_steps,
ei.p_max_block_ex_mem AS max_block_ex_mem,
ei.p_max_block_ex_steps AS max_block_ex_steps,
ei.p_max_val_size AS max_val_size,
ei.p_collateral_percent AS collateral_percent,
ei.p_max_collateral_inputs AS max_collateral_inputs,
ei.p_coins_per_utxo_size::text AS coins_per_utxo_size
FROM
grest.epoch_info_cache AS ei
WHERE
ei.epoch_no = _epoch_no;
END IF;
END;
$$;

Expand Down
6 changes: 3 additions & 3 deletions files/grest/rpc/pool/pool_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -34,9 +34,9 @@ DECLARE
BEGIN
SELECT MAX(epoch.no) INTO _epoch_no FROM public.epoch;
SELECT FLOOR(supply::bigint / (
SELECT p_optimal_pool_count
FROM grest.epoch_info_cache
WHERE epoch_no = _epoch_no
SELECT ep.optimal_pool_count
FROM epoch_param AS ep
WHERE ep.epoch_no = _epoch_no
))::bigint INTO _saturation_limit FROM grest.totals(_epoch_no);
RETURN QUERY
WITH
Expand Down

0 comments on commit c6465fd

Please sign in to comment.