Skip to content

Commit

Permalink
Epoch summary corrections function and cron script (#230)
Browse files Browse the repository at this point in the history
## Description
Function compares block / transaction totals currently recorded in epoch
table with reality and performs corrections if necessary. First time the
job is run it scans epochs 0 till current and creates control table
entry, on subsequent runs it scans 2 most recent epochs looking for
discrepancies. Function is invoked from a shell script that gets
installed as a part of cron job setup in guild-operators repository
change.

---------

Co-authored-by: RdLrT <[email protected]>
  • Loading branch information
hodlonaut and rdlrt authored Aug 28, 2023
1 parent a1e42d5 commit 0eb88e1
Show file tree
Hide file tree
Showing 2 changed files with 77 additions and 0 deletions.
12 changes: 12 additions & 0 deletions files/grest/cron/jobs/epoch-summary-corrections-update.sh
Original file line number Diff line number Diff line change
@@ -0,0 +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)

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 summary corrections update..."
psql ${DB_NAME} -qbt -c "SELECT GREST.EPOCH_SUMMARY_CORRECTIONS_UPDATE();" 1>/dev/null 2>&1
echo "$(date +%F_%H:%M:%S) Job done!"
65 changes: 65 additions & 0 deletions files/grest/rpc/epoch/epoch_summary_corrections_update.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,65 @@
CREATE OR REPLACE function grest.epoch_summary_corrections_update()
RETURNS void
LANGUAGE plpgsql
AS $$
DECLARE
curr_epoch_record record := null;
latest_epoch bigint = (SELECT MAX(no) FROM epoch);
last_epoch_checked bigint = coalesce((SELECT last_value::bigint FROM grest.control_table WHERE key = 'last_epoch_summary_data_checked'), -1);
BEGIN
RAISE NOTICE 'Last validated epoch was %', last_epoch_checked;
IF last_epoch_checked < 0 THEN
RAISE NOTICE 'Inserting initial record for key last_epoch_summary_data_checked';
INSERT INTO grest.control_table values('last_epoch_summary_data_checked', 0, null);
END IF;
FOR curr_epoch_record IN (
SELECT b.epoch_no
FROM
(SELECT
no,
blk_count AS epoch_blk_count,
tx_count AS epoch_tx_count
FROM epoch
WHERE no > last_epoch_checked - 2) AS e,
(SELECT
epoch_no,
COUNT(block_no) AS block_blk_count,
SUM(tx_count) AS block_tx_count
FROM block
WHERE epoch_no > (last_epoch_checked - 2)
GROUP BY epoch_no) AS b
WHERE e.no = b.epoch_no
AND (e.epoch_blk_count != b.block_blk_count OR e.epoch_tx_count != b.block_tx_count)
ORDER BY b.epoch_no
) LOOP
RAISE NOTICE 'Need to fix up data for epoch %', curr_epoch_record;
WITH agg_table AS
( SELECT
MIN(block.epoch_no) AS epoch_no,
SUM(tx.out_sum) AS out_sum,
SUM(tx.fee) AS fee_sum,
MIN(block.time) AS start_time,
MAX(block.time) AS end_time,
COUNT(tx.id) AS tx_count,
COUNT(distinct block.block_no) AS blk_count
FROM block
LEFT JOIN tx ON block.id = tx.block_id
WHERE block.epoch_no = curr_epoch_record.epoch_no
)

UPDATE epoch
SET
out_sum = COALESCE(agg_table.out_sum, 0),
fees = COALESCE(agg_table.fee_sum, 0),
tx_count = agg_table.tx_count,
blk_count = agg_table.blk_count,
start_time = agg_table.start_time,
end_time = agg_table.end_time
FROM agg_table
WHERE no = agg_table.epoch_no ;

RAISE NOTICE 'Epoch row for epoch % corrected', curr_epoch_record;
END LOOP;
UPDATE grest.control_table SET last_value = latest_epoch::text WHERE key = 'last_epoch_summary_data_checked';
END;
$$;

0 comments on commit 0eb88e1

Please sign in to comment.