From c6465fd25e65626b69a3b2795263f663e9482429 Mon Sep 17 00:00:00 2001 From: Priyank <3169068+rdlrt@users.noreply.github.com> Date: Thu, 7 Sep 2023 17:53:35 +1000 Subject: [PATCH] Dont include epoch_params in epoch_info_cache, update references accordingly --- .../cron/jobs/epoch-info-cache-update.sh | 4 +- .../rpc/01_cached_tables/epoch_info_cache.sql | 60 +-------- .../01_cached_tables/pool_history_cache.sql | 10 +- files/grest/rpc/epoch/epoch_info.sql | 7 +- files/grest/rpc/epoch/epoch_params.sql | 119 +++++++----------- files/grest/rpc/pool/pool_info.sql | 6 +- 6 files changed, 56 insertions(+), 150 deletions(-) diff --git a/files/grest/cron/jobs/epoch-info-cache-update.sh b/files/grest/cron/jobs/epoch-info-cache-update.sh index 19012f81..c63aa739 100644 --- a/files/grest/cron/jobs/epoch-info-cache-update.sh +++ b/files/grest/cron/jobs/epoch-info-cache-update.sh @@ -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!" diff --git a/files/grest/rpc/01_cached_tables/epoch_info_cache.sql b/files/grest/rpc/01_cached_tables/epoch_info_cache.sql index 85621dff..fe89319d 100644 --- a/files/grest/rpc/01_cached_tables/epoch_info_cache.sql +++ b/files/grest/rpc/01_cached_tables/epoch_info_cache.sql @@ -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'; @@ -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 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 9644e847..e4a0951b 100644 --- a/files/grest/rpc/01_cached_tables/pool_history_cache.sql +++ b/files/grest/rpc/01_cached_tables/pool_history_cache.sql @@ -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 @@ -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 diff --git a/files/grest/rpc/epoch/epoch_info.sql b/files/grest/rpc/epoch/epoch_info.sql index da9e5018..471235fd 100644 --- a/files/grest/rpc/epoch/epoch_info.sql +++ b/files/grest/rpc/epoch/epoch_info.sql @@ -44,9 +44,8 @@ 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) @@ -54,7 +53,7 @@ BEGIN 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; $$; diff --git a/files/grest/rpc/epoch/epoch_params.sql b/files/grest/rpc/epoch/epoch_params.sql index 9807a468..93534925 100644 --- a/files/grest/rpc/epoch/epoch_params.sql +++ b/files/grest/rpc/epoch/epoch_params.sql @@ -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, @@ -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; $$; diff --git a/files/grest/rpc/pool/pool_info.sql b/files/grest/rpc/pool/pool_info.sql index 203f7d40..b295c4b0 100644 --- a/files/grest/rpc/pool/pool_info.sql +++ b/files/grest/rpc/pool/pool_info.sql @@ -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