Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add an query as example to retrieve delegators and their stake #609

Closed
Closed
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
24 changes: 24 additions & 0 deletions doc/interesting-queries.md
Original file line number Diff line number Diff line change
Expand Up @@ -285,6 +285,30 @@ select stake_address.view as stake_address, epoch_stake.epoch_no, epoch_stake.am
...
```

### Get delegators, their latest address and live-stake of a pool

```sql
with
delegates as (
select stake_address, pool_address, stake_address_id from (
select row_number() over(PARTITION BY d.addr_id order by d.addr_id, d.id desc) row_number, sa."view" stake_address, ph."view" pool_address, d.addr_id stake_address_id
from delegation d
join pool_hash ph on ph.id = d.pool_hash_id
join stake_address sa on sa.id = d.addr_id
join delegation alldelegations on alldelegations.addr_id=d.addr_id
where
ph.view='pool180fejev4xgwe2y53ky0pxvgxr3wcvkweu6feq5mdljfzcsmtg6u'
) inner_query
where row_number=1 and pool_address='pool180fejev4xgwe2y53ky0pxvgxr3wcvkweu6feq5mdljfzcsmtg6u'
),
delegator_addresses as (
select row_number() over(PARTITION BY txo.stake_address_id order by txo.stake_address_id, txo.tx_id desc) row_number, encode(tx.hash, 'hex') tx_hash_view, stake_address, txo.address , pool_address, txo.stake_address_id, txo.value from delegates
join tx_out txo on txo.stake_address_id = delegates.stake_address_id
join tx on tx.id =txo.tx_id
)
select *, (select sum(value) from utxo_view uv where uv.stake_address_id = delegator_addresses.stake_address_id) from delegator_addresses where row_number = 1
```

### Get the total orphaned rewards.
Orphaned rewards for epoch `N` are rewards that acrue to a stake address that was registered in
before the end of epoch `N - 2` but for which the stake address has been de-registered before the
Expand Down