Skip to content

Commit

Permalink
fix(sql): insta_rewards (dbsync) adjustment + live_size fix
Browse files Browse the repository at this point in the history
  • Loading branch information
sorki authored and 1000101 committed Mar 31, 2024
1 parent 509c843 commit 562cc20
Show file tree
Hide file tree
Showing 7 changed files with 126 additions and 24 deletions.
19 changes: 13 additions & 6 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -11,17 +11,17 @@ and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0

| :warning: WARNING |
| -------------------------------------------------------------------------------------------------------------------------------- |
| This version of `blockfrost-backend-ryo` requires `cardano-db-sync 13.1.1.3` or newer. Use version `1.7.x` for earlier releases. |
| This version of `blockfrost-backend-ryo` requires `cardano-db-sync 13.2.0.1` or newer. Use version `1.7.x` for earlier releases. |

### Added

- support for Cardano Sanchonet
- translation of cost models from numerical IDs to strings,
required for `cardano-db-sync 13.1.1.3` and newer [#130](https://github.com/blockfrost/blockfrost-backend-ryo/pull/130)
- indices improving `/assets/{asset}` when querying CIP68 assets and `/txs/{tx_hash}` with redeemers
- indices improving `/assets/{asset}` when querying CIP68 assets and `/txs/{hash}` with redeemers
- IS_LOCAL env for testing
- Parsing version 2 of CIP68 metadata (`@blockfrost/openapi` 0.1.62)
- `/txs/:hash/required_signers` endpoint
- `/txs/{hash}/required_signers` endpoint

### Changed

Expand All @@ -33,12 +33,19 @@ and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0

### Fixed

- ordering in `/assets/asset/txs`, `/assets/asset/transactions` and `/epochs/{number}/stakes`
- ordering in `/assets/{asset}/txs`, `/assets/{asset}/transactions` and `/epochs/{number}/stakes`
- port configuration via config option `dbSync.port`
- live_stake for retired pools in `/pools/{pool_id}` was always 0, instead of displaying the delegated amount
- `metadata/txs/labels/:num` and `/scripts/:hash/json` json encoding for primitive types (eg. string) (`@blockfrost/openapi` 0.1.62)
- `metadata/txs/labels/{number}` and `/scripts/{hash}/json` json encoding for primitive types (eg. string) (`@blockfrost/openapi` 0.1.62)
- `/txs/{hash}/utxos` rendering of wrong asset in collateral output [#161](https://github.com/blockfrost/blockfrost-backend-ryo/pull/161)
- In `/epochs/:num/parameters` set `min_utxo` to `coins_per_utxo_size` with a fallback to `min_utxo_value` if `coins_per_utxo_size` is null
- in `/epochs/{number}/parameters` set `min_utxo` to `coins_per_utxo_size` with a fallback to `min_utxo_value` if `coins_per_utxo_size` is null
- calculation of endpoints affected by moving MIRs into `instant_reward` table required for `cardano-db-sync 13.2.0.1`
- `/accounts/{stake_address}`
- `/pools/extended`
- `/pools/{pool_id}`
- `/network`
- calculation of `live_size` for `/pools/{pool_id}` only taking into account live pools (ommiting retired from the calculation)



## [1.7.0] - 2023-08-30
Expand Down
2 changes: 2 additions & 0 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -100,6 +100,8 @@ CREATE INDEX IF NOT EXISTS bf_idx_redeemer_tx_id ON redeemer USING btree (tx_id)
CREATE INDEX IF NOT EXISTS bf_idx_col_tx_out ON collateral_tx_out USING btree (tx_id);
CREATE INDEX IF NOT EXISTS bf_idx_ma_tx_mint_ident ON ma_tx_mint USING btree (ident);
CREATE INDEX IF NOT EXISTS bf_idx_ma_tx_out_ident ON ma_tx_out USING btree (ident);
CREATE INDEX IF NOT EXISTS bf_idx_instant_reward_addr_id USING btree (addr_id);
CREATE INDEX IF NOT EXISTS bf_idx_instant_reward_spendable_epoch USING btree (spendable_epoch);
```

### Docker
Expand Down
26 changes: 21 additions & 5 deletions src/sql/accounts/accounts_stake_address.sql
Original file line number Diff line number Diff line change
Expand Up @@ -70,17 +70,17 @@ SELECT sa.view AS "stake_address",
SELECT *
FROM queried_addr
)
) + COALESCE(rewards_sum.amount, 0) + COALESCE(refunds_sum.amount, 0) - COALESCE(withdrawals_sum.amount, 0)
) + COALESCE(rewards_sum.amount, 0) + COALESCE(instant_rewards_sum.amount, 0) + COALESCE(refunds_sum.amount, 0) - COALESCE(withdrawals_sum.amount, 0)
-- SUM of all utxos + withdrawables (rewards (all types including rewards + refunds + treasury + reserves) - withdrawals
)::TEXT AS "controlled_amount", -- cast to TEXT to avoid number overflow
COALESCE(rewards_sum.amount, 0)::TEXT AS "rewards_sum", -- cast to TEXT to avoid number overflow
(
COALESCE(rewards_sum.amount, 0) + COALESCE(instant_rewards_sum.amount, 0)
)::TEXT AS "rewards_sum", -- cast to TEXT to avoid number overflow
COALESCE(withdrawals_sum.amount, 0)::TEXT AS "withdrawals_sum", -- cast to TEXT to avoid number overflow
COALESCE(reserves_sum.amount, 0)::TEXT AS "reserves_sum", -- cast to TEXT to avoid number overflow
COALESCE(treasury_sum.amount, 0)::TEXT AS "treasury_sum", -- cast to TEXT to avoid number overflow
(
(
COALESCE(rewards_sum.amount, 0) + COALESCE(refunds_sum.amount, 0) - COALESCE(withdrawals_sum.amount, 0)
)
COALESCE(rewards_sum.amount, 0) + COALESCE(instant_rewards_sum.amount, 0) + COALESCE(refunds_sum.amount, 0) - COALESCE(withdrawals_sum.amount, 0)
)::TEXT AS "withdrawable_amount", -- cast to TEXT to avoid number overflow
(
SELECT pool_id
Expand All @@ -104,6 +104,22 @@ FROM stake_address sa
)
GROUP BY addr_id
) AS "rewards_sum" ON (rewards_sum.addr_id = sa.id)
LEFT JOIN (
SELECT addr_id,
SUM(amount) AS "amount"
FROM instant_reward
WHERE (
addr_id = (
SELECT *
FROM queried_addr
)
AND spendable_epoch <= (
SELECT *
FROM current_epoch
)
)
GROUP BY addr_id
) AS "instant_rewards_sum" ON (instant_rewards_sum.addr_id = sa.id)
LEFT JOIN (
SELECT addr_id,
SUM(amount) AS "amount"
Expand Down
27 changes: 20 additions & 7 deletions src/sql/network/network.sql
Original file line number Diff line number Diff line change
Expand Up @@ -25,6 +25,13 @@ circulating_supply AS (
SELECT *
FROM current_epoch
)
) + (
SELECT COALESCE(SUM(amount), 0)
FROM instant_reward
WHERE spendable_epoch <= (
SELECT *
FROM current_epoch
)
) - (
SELECT COALESCE(SUM(amount), 0)
FROM withdrawal
Expand All @@ -33,7 +40,7 @@ circulating_supply AS (
/*
circulating_supply = SUM of all utxos + withdrawables
withdrawables = rewards (all types including rewards + refunds + treasury + reserves) - withdrawals
*/
*/
FROM tx_out txo
LEFT JOIN tx_in txi ON (txo.tx_id = txi.tx_out_id)
AND (txo.index = txi.tx_out_index)
Expand Down Expand Up @@ -192,29 +199,34 @@ FROM (
FROM (
SELECT (
SELECT 45000000000000000
)::TEXT AS "max_supply", -- cast to TEXT to avoid number overflow
)::TEXT AS "max_supply",
-- cast to TEXT to avoid number overflow
(
SELECT *
FROM circulating_supply
)::TEXT AS "circulating_supply", -- cast to TEXT to avoid number overflow
)::TEXT AS "circulating_supply",
-- cast to TEXT to avoid number overflow
(
SELECT 45000000000000000 - reserves
FROM ada_pots
ORDER BY epoch_no desc
LIMIT 1
)::TEXT AS "total_supply", -- cast to TEXT to avoid number overflow
)::TEXT AS "total_supply",
-- cast to TEXT to avoid number overflow
(
SELECT *
FROM locked_supply
)::TEXT AS "locked_supply", -- cast to TEXT to avoid number overflow
)::TEXT AS "locked_supply",
-- cast to TEXT to avoid number overflow
(
SELECT treasury
FROM ada_pots
WHERE epoch_no = (
SELECT *
FROM current_epoch
)
)::TEXT AS "treasury_supply", -- cast to TEXT to avoid number overflow
)::TEXT AS "treasury_supply",
-- cast to TEXT to avoid number overflow
(
SELECT reserves
FROM ada_pots
Expand All @@ -231,7 +243,8 @@ FROM (
SELECT (
SELECT SUM(live_stake)
FROM live_stake_sum
)::TEXT AS "live_stake", -- cast to TEXT to avoid number overflow
)::TEXT AS "live_stake",
-- cast to TEXT to avoid number overflow
(
SELECT amount
FROM active_stake
Expand Down
18 changes: 16 additions & 2 deletions src/sql/pools/pools_extended.sql
Original file line number Diff line number Diff line change
Expand Up @@ -137,6 +137,17 @@ live_stake_accounts_rewards AS (
)
GROUP BY lsa.pool_hash_id
),
live_stake_accounts_instant_rewards AS (
SELECT lsa.pool_hash_id,
COALESCE(SUM(amount), 0) AS "amount_instant_rewards_pool"
FROM live_stake_accounts lsa
JOIN instant_reward ir ON (lsa.stake_address_id = ir.addr_id)
WHERE spendable_epoch <= (
SELECT epoch_no
FROM current_epoch
)
GROUP BY lsa.pool_hash_id
),
live_stake_accounts_refunds AS (
SELECT lsa.pool_hash_id,
COALESCE(SUM(amount), 0) AS "amount_refunds_pool"
Expand All @@ -159,16 +170,18 @@ live_stake_accounts_withdrawal AS (
live_stake_queried_pools_sum AS (
SELECT qp.pool_hash_id AS "pool_hash_id",
(
(COALESCE(amounts_pool, 0)) + (COALESCE(amount_rewards_pool, 0)) + (COALESCE(amount_refunds_pool, 0)) - (COALESCE(amount_withdrawals_pool, 0))
(COALESCE(amounts_pool, 0)) + (COALESCE(amount_rewards_pool, 0)) + (COALESCE(amount_instant_rewards_pool, 0)) + (COALESCE(amount_refunds_pool, 0)) - (COALESCE(amount_withdrawals_pool, 0))
) AS "live_stake_pool"
FROM queried_pools qp
LEFT JOIN live_stake_accounts_amounts USING (pool_hash_id)
LEFT JOIN live_stake_accounts_rewards USING (pool_hash_id)
LEFT JOIN live_stake_accounts_instant_rewards USING (pool_hash_id)
LEFT JOIN live_stake_accounts_refunds USING (pool_hash_id)
LEFT JOIN live_stake_accounts_withdrawal USING (pool_hash_id)
GROUP BY pool_hash_id,
amounts_pool,
amount_rewards_pool,
amount_instant_rewards_pool,
amount_refunds_pool,
amount_withdrawals_pool
)
Expand All @@ -185,7 +198,8 @@ SELECT qp.pool_id AS "pool_id",
)
),
0
)::TEXT AS "active_stake", -- cast to TEXT to avoid number overflow
)::TEXT AS "active_stake",
-- cast to TEXT to avoid number overflow
(
COALESCE(
(
Expand Down
43 changes: 40 additions & 3 deletions src/sql/pools/pools_pool_id.sql
Original file line number Diff line number Diff line change
Expand Up @@ -41,6 +41,13 @@ circulating_supply AS (
SELECT epoch_no
FROM current_epoch
)
) + (
SELECT COALESCE(SUM(amount), 0)
FROM instant_reward
WHERE spendable_epoch <= (
SELECT epoch_no
FROM current_epoch
)
) - (
SELECT COALESCE(SUM(amount), 0)
FROM withdrawal
Expand Down Expand Up @@ -173,6 +180,7 @@ live_stake_accounts AS (
)
OR (deregmax.tempmax IS NULL)
)
AND ap.state = 'active'
),
live_stake_accounts_amounts AS (
SELECT COALESCE(SUM(txo.value), 0) AS "amounts",
Expand All @@ -195,22 +203,32 @@ live_stake_accounts_amounts AS (
WHERE txi IS NULL
),
live_stake_accounts_rewards AS (
SELECT COALESCE(SUM(amount), 0) AS "amount_rewards",
SELECT (COALESCE(SUM(r.amount), 0)) AS "amount_rewards",
COALESCE(
SUM(
CASE
WHEN lsa.pool_id = (
SELECT pool_id
FROM queried_pool
) THEN amount
) THEN r.amount
ELSE 0
END
),
0
) AS "amount_rewards_pool"
FROM live_stake_accounts lsa
JOIN reward r ON (lsa.stake_address_id = r.addr_id)
WHERE spendable_epoch <= (
LEFT JOIN instant_reward ir ON (lsa.stake_address_id = ir.addr_id)
WHERE r.spendable_epoch <= (
SELECT epoch_no
FROM current_epoch
)
),
live_stake_accounts_instant_rewards AS (
SELECT (COALESCE(SUM(ir.amount), 0)) AS "amount_instant_rewards"
FROM live_stake_accounts lsa
JOIN instant_reward ir ON (lsa.stake_address_id = ir.addr_id)
WHERE ir.spendable_epoch <= (
SELECT epoch_no
FROM current_epoch
)
Expand Down Expand Up @@ -240,6 +258,9 @@ live_stake_sum AS (
) + (
SELECT COALESCE(amount_rewards, 0)
FROM live_stake_accounts_rewards
) + (
SELECT COALESCE(amount_instant_rewards, 0)
FROM live_stake_accounts_instant_rewards
) - (
SELECT COALESCE(amount_withdrawals, 0)
FROM live_stake_accounts_withdrawal
Expand Down Expand Up @@ -398,6 +419,22 @@ SELECT ph.view AS "pool_id",
)
),
0
) + COALESCE(
(
SELECT SUM(amount) AS "amount"
FROM instant_reward
WHERE (
addr_id IN (
SELECT *
FROM queried_addr
)
)
AND spendable_epoch <= (
SELECT epoch_no
FROM current_epoch
)
),
0
) - COALESCE(
(
SELECT SUM(amount) AS "amount"
Expand Down
15 changes: 14 additions & 1 deletion src/sql/pools/unpaged/pools_extended.sql
Original file line number Diff line number Diff line change
Expand Up @@ -122,6 +122,17 @@ live_stake_accounts_rewards AS (
)
GROUP BY lsa.pool_hash_id
),
live_stake_accounts_instant_rewards AS (
SELECT lsa.pool_hash_id,
COALESCE(SUM(amount), 0) AS "amount_instant_rewards_pool"
FROM live_stake_accounts lsa
JOIN instant_reward ir ON (lsa.stake_address_id = ir.addr_id)
WHERE spendable_epoch <= (
SELECT epoch_no
FROM current_epoch
)
GROUP BY lsa.pool_hash_id
),
live_stake_accounts_refunds AS (
SELECT lsa.pool_hash_id,
COALESCE(SUM(amount), 0) AS "amount_refunds_pool"
Expand All @@ -144,16 +155,18 @@ live_stake_accounts_withdrawal AS (
live_stake_queried_pools_sum AS (
SELECT qp.pool_hash_id AS "pool_hash_id",
(
(COALESCE(amounts_pool, 0)) + (COALESCE(amount_rewards_pool, 0)) + (COALESCE(amount_refunds_pool, 0)) - (COALESCE(amount_withdrawals_pool, 0))
(COALESCE(amounts_pool, 0)) + (COALESCE(amount_rewards_pool, 0)) + (COALESCE(amount_instant_rewards_pool, 0)) + (COALESCE(amount_refunds_pool, 0)) - (COALESCE(amount_withdrawals_pool, 0))
) AS "live_stake_pool"
FROM queried_pools qp
LEFT JOIN live_stake_accounts_amounts USING (pool_hash_id)
LEFT JOIN live_stake_accounts_rewards USING (pool_hash_id)
LEFT JOIN live_stake_accounts_instant_rewards USING (pool_hash_id)
LEFT JOIN live_stake_accounts_refunds USING (pool_hash_id)
LEFT JOIN live_stake_accounts_withdrawal USING (pool_hash_id)
GROUP BY pool_hash_id,
amounts_pool,
amount_rewards_pool,
amount_instant_rewards_pool,
amount_refunds_pool,
amount_withdrawals_pool
)
Expand Down

0 comments on commit 562cc20

Please sign in to comment.