Skip to content

Commit

Permalink
fix: omit unregistered stake addresses from delegators list
Browse files Browse the repository at this point in the history
  • Loading branch information
slowbackspace committed Nov 1, 2024
1 parent 30ec8cf commit 74f9c73
Show file tree
Hide file tree
Showing 4 changed files with 81 additions and 80 deletions.
3 changes: 2 additions & 1 deletion .vscode/settings.json
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,7 @@
"cdbsync",
"dbsync",
"delegators",
"deregistration",
"Drep",
"dreps",
"elgohr",
Expand Down Expand Up @@ -38,5 +39,5 @@
},
"eslint.nodePath": ".yarn/sdks",
"typescript.tsdk": ".yarn/sdks/typescript/lib",
"typescript.enablePromptUseWorkspaceTsdk": true,
"typescript.enablePromptUseWorkspaceTsdk": true
}
4 changes: 4 additions & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,10 @@ and this project adheres to [Semantic Versioning](https://semver.org/spec/v2.0.0

## [Unreleased]

### Fixed

- Don't list unregistered stake addresses in `/governance/dreps/:drep/delegators`

## [2.2.4] - 2024-10-31

### Fixed
Expand Down
88 changes: 41 additions & 47 deletions src/sql/governance/dreps_drep_id_delegators.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,29 @@ WITH current_epoch AS (
FROM block b
ORDER BY b.id DESC
LIMIT 1
),
-- This CTE ensures that only active delegators are included by filtering out
-- any addresses with a more recent stake_deregistration than stake_registration.
active_delegators AS (
SELECT sa.view AS "address",
dv.addr_id AS "address_id",
dv.id AS "did"
FROM delegation_vote dv
JOIN drep_hash dh ON (dh.id = dv.drep_hash_id)
JOIN stake_address sa ON (sa.id = dv.addr_id)
JOIN stake_registration sr ON sr.addr_id = dv.addr_id
LEFT JOIN stake_deregistration sd ON sd.addr_id = dv.addr_id
WHERE (
($4::bytea IS NOT NULL AND dh.raw = $4) OR
($4 IS NULL AND dh.view = $5)
)
AND dv.id = (
SELECT MAX(dv_inner.id)
FROM delegation_vote dv_inner
WHERE dv_inner.addr_id = dv.addr_id
)
AND sr.tx_id > COALESCE((SELECT MAX(sd_inner.tx_id) FROM stake_deregistration sd_inner WHERE sd_inner.addr_id = dv.addr_id), 0)
GROUP BY sa.view, dv.drep_hash_id, dv.addr_id, dv.id
)
SELECT "address" AS "address",
(
Expand Down Expand Up @@ -35,56 +58,27 @@ SELECT "address" AS "address",
WHERE (w.addr_id = address_id)
)
)::TEXT AS "amount" -- cast to TEXT to avoid number overflow
FROM (
SELECT sa.view AS "address",
dv.addr_id AS "address_id",
dv.id AS "did"
FROM delegation_vote dv
JOIN drep_hash dh ON (dh.id = dv.drep_hash_id)
JOIN stake_address sa ON (sa.id = dv.addr_id)
WHERE (
($4::bytea IS NOT NULL AND dh.raw = $4) OR
($4 IS NULL AND dh.view = $5)
)
AND dv.id = (
SELECT MAX(id)
FROM delegation_vote
WHERE addr_id = dv.addr_id
)
GROUP BY sa.view,
dv.drep_hash_id,
dv.addr_id,
dv.id
ORDER BY CASE
WHEN LOWER($1) = 'desc' THEN dv.id
END DESC,
CASE
WHEN LOWER($1) <> 'desc'
OR $1 IS NULL THEN dv.id
END ASC
LIMIT CASE
WHEN $2 >= 1
AND $2 <= 100 THEN $2
ELSE 100
END OFFSET CASE
WHEN $3 > 1
AND $3 < 2147483647 THEN ($3 - 1) * (
CASE
WHEN $2 >= 1
AND $2 <= 100 THEN $2
ELSE 100
END
)
ELSE 0
END
) "sorted_limited"
GROUP BY address,
address_id,
did
FROM
active_delegators
ORDER BY CASE
WHEN LOWER($1) = 'desc' THEN did
END DESC,
CASE
WHEN LOWER($1) <> 'desc'
OR $1 IS NULL THEN did
END ASC
END ASC
LIMIT CASE
WHEN $2 >= 1
AND $2 <= 100 THEN $2
ELSE 100
END OFFSET CASE
WHEN $3 > 1
AND $3 < 2147483647 THEN ($3 - 1) * (
CASE
WHEN $2 >= 1
AND $2 <= 100 THEN $2
ELSE 100
END
)
ELSE 0
END
66 changes: 34 additions & 32 deletions src/sql/governance/unpaged/dreps_drep_id_delegators.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,29 @@ WITH current_epoch AS (
FROM block b
ORDER BY b.id DESC
LIMIT 1
),
-- This new CTE ensures that only active delegators are included by filtering out
-- any addresses with a more recent stake_deregistration than stake_registration.
active_delegators AS (
SELECT sa.view AS "address",
dv.addr_id AS "address_id",
dv.id AS "did"
FROM delegation_vote dv
JOIN drep_hash dh ON (dh.id = dv.drep_hash_id)
JOIN stake_address sa ON (sa.id = dv.addr_id)
JOIN stake_registration sr ON sr.addr_id = dv.addr_id
LEFT JOIN stake_deregistration sd ON sd.addr_id = dv.addr_id
WHERE (
($4::bytea IS NOT NULL AND dh.raw = $4) OR
($4 IS NULL AND dh.view = $5)
)
AND dv.id = (
SELECT MAX(dv_inner.id)
FROM delegation_vote dv_inner
WHERE dv_inner.addr_id = dv.addr_id
)
AND sr.tx_id > COALESCE((SELECT MAX(sd_inner.tx_id) FROM stake_deregistration sd_inner WHERE sd_inner.addr_id = dv.addr_id), 0)
GROUP BY sa.view, dv.drep_hash_id, dv.addr_id, dv.id
)
SELECT "address" AS "address",
(
Expand All @@ -21,47 +44,26 @@ SELECT "address" AS "address",
SELECT *
FROM current_epoch
)
) + (
SELECT COALESCE(SUM(amount), 0)
FROM reward_rest rr
WHERE (rr.addr_id = address_id)
AND rr.spendable_epoch <= (
SELECT *
FROM current_epoch
)
) - (
SELECT COALESCE(SUM(amount), 0)
FROM withdrawal w
WHERE (w.addr_id = address_id)
)
)::TEXT AS "amount" -- cast to TEXT to avoid number overflow
FROM (
SELECT sa.view AS "address",
dv.addr_id AS "address_id",
dv.id AS "did"
FROM delegation_vote dv
JOIN drep_hash dh ON (dh.id = dv.drep_hash_id)
JOIN stake_address sa ON (sa.id = dv.addr_id)
WHERE (
($2::bytea IS NOT NULL AND dh.raw = $2) OR
($2 IS NULL AND dh.view = $3)
)
AND dv.id = (
SELECT MAX(id)
FROM delegation_vote
WHERE addr_id = dv.addr_id
)
GROUP BY sa.view,
dv.drep_hash_id,
dv.addr_id,
dv.id
ORDER BY CASE
WHEN LOWER($1) = 'desc' THEN dv.id
END DESC,
CASE
WHEN LOWER($1) <> 'desc'
OR $1 IS NULL THEN dv.id
END ASC
) "sorted"
GROUP BY address,
address_id,
did
FROM
active_delegators
ORDER BY CASE
WHEN LOWER($1) = 'desc' THEN did
END DESC,
CASE
WHEN LOWER($1) <> 'desc'
OR $1 IS NULL THEN did
END ASC
END ASC

0 comments on commit 74f9c73

Please sign in to comment.