Skip to content

Commit

Permalink
Merge branch 'alpha' into dbsyncscript
Browse files Browse the repository at this point in the history
  • Loading branch information
rdlrt committed Oct 12, 2021
2 parents 692cf3e + 395c20c commit 8dd445d
Show file tree
Hide file tree
Showing 2 changed files with 33 additions and 15 deletions.
2 changes: 1 addition & 1 deletion files/grest/rpc/assets/asset_address_list.sql
Expand Up @@ -17,7 +17,7 @@ BEGIN
SELECT
DECODE(_asset_policy, 'hex') INTO _asset_policy_decoded;
SELECT
DECODE(_asset_name, 'hex') INTO _asset_name_decoded;
DECODE(_asset_name::text,'escape') INTO _asset_name_decoded;
RETURN QUERY
SELECT
TXO.ADDRESS,
Expand Down
46 changes: 32 additions & 14 deletions files/grest/rpc/cached_tables/stake_distribution_cache.sql
Expand Up @@ -29,8 +29,7 @@ DECLARE
_last_accounted_block_id bigint;
BEGIN
SELECT
INTO _last_accounted_block_height,
_last_accounted_block_id block_no,
block_no,
id
FROM
PUBLIC.BLOCK
Expand All @@ -40,7 +39,8 @@ BEGIN
SELECT
MAX(BLOCK_NO) - 5
FROM
PUBLIC.BLOCK);
PUBLIC.BLOCK) INTO _last_accounted_block_height,
_last_accounted_block_id;
INSERT INTO GREST.STAKE_DISTRIBUTION_CACHE
SELECT
STAKE_ADDRESS,
Expand All @@ -60,15 +60,18 @@ BEGIN
END AS REWARDS_AVAILABLE,
COALESCE(RESERVES_T.RESERVES, 0) AS RESERVES,
COALESCE(TREASURY_T.TREASURY, 0) AS TREASURY
FROM (
SELECT
FROM ( SELECT DISTINCT ON (STAKE_ADDRESS.ID)
STAKE_ADDRESS.ID,
STAKE_ADDRESS.VIEW AS STAKE_ADDRESS,
POOL_HASH.VIEW AS POOL_ID
POOL_HASH.VIEW AS POOL_ID,
BLOCK.EPOCH_NO AS LATEST_WITHDRAWAL_EPOCH
FROM
STAKE_ADDRESS
INNER JOIN DELEGATION ON DELEGATION.ADDR_ID = STAKE_ADDRESS.ID
INNER JOIN POOL_HASH ON POOL_HASH.ID = DELEGATION.POOL_HASH_ID
LEFT JOIN WITHDRAWAL ON WITHDRAWAL.ADDR_ID = STAKE_ADDRESS.ID
LEFT JOIN TX ON TX.ID = WITHDRAWAL.TX_ID
LEFT JOIN BLOCK ON BLOCK.ID = TX.BLOCK_ID
WHERE
NOT EXISTS (
SELECT
Expand All @@ -85,7 +88,10 @@ BEGIN
STAKE_DEREGISTRATION
WHERE
STAKE_DEREGISTRATION.ADDR_ID = DELEGATION.ADDR_ID
AND STAKE_DEREGISTRATION.TX_ID > DELEGATION.TX_ID)) T1
AND STAKE_DEREGISTRATION.TX_ID > DELEGATION.TX_ID)
ORDER BY
STAKE_ADDRESS.ID,
BLOCK.EPOCH_NO DESC) T1
LEFT JOIN LATERAL (
SELECT
COALESCE(SUM(TX_OUT.VALUE), 0) AS UTXO
Expand Down Expand Up @@ -128,17 +134,23 @@ BEGIN
COALESCE(SUM(RESERVE.AMOUNT), 0) AS RESERVES
FROM
RESERVE
INNER JOIN TX ON TX.ID = RESERVE.TX_ID
INNER JOIN BLOCK ON BLOCK.ID = TX.BLOCK_ID
WHERE
RESERVE.ADDR_ID = T1.ID
AND BLOCK.EPOCH_NO >= T1.LATEST_WITHDRAWAL_EPOCH
GROUP BY
T1.ID) RESERVES_T ON TRUE
LEFT JOIN LATERAL (
SELECT
COALESCE(SUM(TREASURY.AMOUNT), 0) AS TREASURY
FROM
TREASURY
INNER JOIN TX ON TX.ID = TREASURY.TX_ID
INNER JOIN BLOCK ON BLOCK.ID = TX.BLOCK_ID
WHERE
TREASURY.ADDR_ID = T1.ID
AND BLOCK.EPOCH_NO >= T1.LATEST_WITHDRAWAL_EPOCH
GROUP BY
T1.ID) TREASURY_T ON TRUE
ON CONFLICT (STAKE_ADDRESS)
Expand Down Expand Up @@ -169,11 +181,6 @@ ON CONFLICT (STAKE_ADDRESS)
END;
$$;

-- Run the first time update
CALL GREST.UPDATE_STAKE_DISTRIBUTION_CACHE ();

CREATE INDEX IF NOT EXISTS idx_pool_id ON GREST.STAKE_DISTRIBUTION_CACHE (POOL_ID);

DROP FUNCTION IF EXISTS GREST.UPDATE_STAKE_DISTRIBUTION_CACHE_CHECK CASCADE;

CREATE FUNCTION GREST.UPDATE_STAKE_DISTRIBUTION_CACHE_CHECK ()
Expand All @@ -183,6 +190,7 @@ CREATE FUNCTION GREST.UPDATE_STAKE_DISTRIBUTION_CACHE_CHECK ()
DECLARE
_last_update_block_height integer DEFAULT NULL;
_current_block_height integer DEFAULT NULL;
_last_update_block_diff integer DEFAULT NULL;
BEGIN
SELECT
last_value
Expand All @@ -196,11 +204,21 @@ BEGIN
PUBLIC.BLOCK
WHERE
BLOCK_NO IS NOT NULL INTO _current_block_height;
-- Do nothing until there is a 90 blocks difference in height (95 in check because lbh considered is 5 blocks behind tip)
IF (_current_block_height - _last_update_block_height) >= 95 THEN
SELECT
(_current_block_height - _last_update_block_height) INTO _last_update_block_diff;
-- Do nothing until there is a 180 blocks difference in height - 60 minutes theoretical time
-- 185 in check because lbh considered is 5 blocks behind tip
IF _last_update_block_diff >= 185 THEN
RAISE NOTICE 'Last stake distribution update was % blocks ago, re-running...', _last_update_block_diff;
CALL GREST.UPDATE_STAKE_DISTRIBUTION_CACHE ();
END IF;
RETURN;
END;
$$;

-- Run the first time update if needed
SELECT
GREST.UPDATE_STAKE_DISTRIBUTION_CACHE_CHECK ();

CREATE INDEX IF NOT EXISTS idx_pool_id ON GREST.STAKE_DISTRIBUTION_CACHE (POOL_ID);

0 comments on commit 8dd445d

Please sign in to comment.