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

[#501] fix sql error #502

Merged
Show file tree
Hide file tree
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
1 change: 1 addition & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -32,6 +32,7 @@ changes.

### Fixed

- Fix possible sql error when there would be no predefined drep voting pwoer [Issue 501](https://github.com/IntersectMBO/govtool/issues/501)
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Suggested change
- Fix possible sql error when there would be no predefined drep voting pwoer [Issue 501](https://github.com/IntersectMBO/govtool/issues/501)
- Fix possible sql error when there would be no predefined drep voting power [Issue 501](https://github.com/IntersectMBO/govtool/issues/501)

Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

typo

- Fix drep type detection when changing metadata [Issue 333](https://github.com/IntersectMBO/govtool/issues/333)
- Fix make button disble when wallet tries connect [Issue 265](https://github.com/IntersectMBO/govtool/issues/265)
- Fix drep voting power calculation [Issue 231](https://github.com/IntersectMBO/govtool/issues/231)
Expand Down
123 changes: 74 additions & 49 deletions govtool/backend/sql/get-network-metrics.sql
Original file line number Diff line number Diff line change
@@ -1,44 +1,68 @@
with current_epoch as (
select Max(no) as no
from epoch
), current_block as (
select Max(block_no) as block_no
from block
), unique_delegators as (
select count(distinct(addr_id)) as count
from delegation_vote
), total_delegations as (
select count(*) as count
from delegation_vote
), total_gov_action_proposals as (
select count(distinct(tx_id, index)) as count
from gov_action_proposal
), total_drep_votes as (
select count(*) as count
from voting_procedure
where voter_role = 'DRep'
), total_registered_dreps as (
select count(*) as count
from drep_hash
), always_abstain_voting_power as (
select coalesce(amount, 0) as amount
from drep_hash
left join drep_distr
on drep_hash.id = drep_distr.hash_id
where drep_hash.view = 'drep_always_abstain'
order by epoch_no desc
limit 1
), always_no_confidence_voting_power as (
select coalesce(amount, 0) as amount
from drep_hash
left join drep_distr
on drep_hash.id = drep_distr.hash_id
where drep_hash.view = 'drep_always_no_confidence'
order by epoch_no desc
limit 1
WITH current_epoch AS (
SELECT
Max(NO) AS no
FROM
epoch
),
current_block AS (
SELECT
Max(block_no) AS block_no
FROM
block
),
unique_delegators AS (
SELECT
count(DISTINCT (addr_id)) AS count
FROM
delegation_vote
),
total_delegations AS (
SELECT
count(*) AS count
FROM
delegation_vote
),
total_gov_action_proposals AS (
SELECT
count(DISTINCT (tx_id, INDEX)) AS count
FROM
gov_action_proposal
),
total_drep_votes AS (
SELECT
count(*) AS count
FROM
voting_procedure
WHERE
voter_role = 'DRep'
),
total_registered_dreps AS (
SELECT
count(*) AS count
FROM
drep_hash
),
always_abstain_voting_power AS (
SELECT
coalesce((
SELECT
amount
FROM drep_hash
LEFT JOIN drep_distr ON drep_hash.id = drep_distr.hash_id
WHERE
drep_hash.view = 'drep_always_abstain' ORDER BY epoch_no DESC LIMIT 1), 0) AS amount
),
always_no_confidence_voting_power AS (
SELECT
coalesce((
SELECT
amount
FROM drep_hash
LEFT JOIN drep_distr ON drep_hash.id = drep_distr.hash_id
WHERE
drep_hash.view = 'drep_always_no_confidence' ORDER BY epoch_no DESC LIMIT 1), 0) AS amount
)

select
SELECT
current_epoch.no,
current_block.block_no,
unique_delegators.count,
Expand All @@ -48,12 +72,13 @@ select
total_registered_dreps.count,
always_abstain_voting_power.amount,
always_no_confidence_voting_power.amount
from current_epoch
cross join current_block
cross join unique_delegators
cross join total_delegations
cross join total_gov_action_proposals
cross join total_drep_votes
cross join total_registered_dreps
cross join always_abstain_voting_power
cross join always_no_confidence_voting_power
FROM
current_epoch
CROSS JOIN current_block
CROSS JOIN unique_delegators
CROSS JOIN total_delegations
CROSS JOIN total_gov_action_proposals
CROSS JOIN total_drep_votes
CROSS JOIN total_registered_dreps
CROSS JOIN always_abstain_voting_power
CROSS JOIN always_no_confidence_voting_power
155 changes: 81 additions & 74 deletions govtool/backend/sql/list-proposals.sql
Original file line number Diff line number Diff line change
@@ -1,86 +1,93 @@
WITH LatestDrepDistr AS (
SELECT
*,
ROW_NUMBER() OVER(PARTITION BY hash_id ORDER BY epoch_no DESC) AS rn
FROM drep_distr
), EpochUtils AS (
ROW_NUMBER() OVER (PARTITION BY hash_id ORDER BY epoch_no DESC) AS rn
FROM
drep_distr
),
EpochUtils AS (
SELECT
(Max(end_time)-Min(end_time)) / (Max(no)-Min(no)) as epoch_duration,
Max(no) as last_epoch_no,
Max(end_time) as last_epoch_end_time
FROM epoch
), always_no_confidence_voting_power as (
select coalesce(amount, 0) as amount
from drep_hash
left join drep_distr
on drep_hash.id = drep_distr.hash_id
where drep_hash.view = 'drep_always_no_confidence'
order by epoch_no desc
limit 1
), always_abstain_voting_power as (
select coalesce(amount, 0) as amount
from drep_hash
left join drep_distr
on drep_hash.id = drep_distr.hash_id
where drep_hash.view = 'drep_always_abstain'
order by epoch_no desc
limit 1
(Max(end_time) - Min(end_time)) /(Max(NO) - Min(NO)) AS epoch_duration,
Max(NO) AS last_epoch_no,
Max(end_time) AS last_epoch_end_time
FROM
epoch
),
always_no_confidence_voting_power AS (
SELECT
coalesce((
SELECT
amount
FROM drep_hash
LEFT JOIN drep_distr ON drep_hash.id = drep_distr.hash_id
WHERE
drep_hash.view = 'drep_always_no_confidence' ORDER BY epoch_no DESC LIMIT 1), 0) AS amount
),
always_abstain_voting_power AS (
SELECT
coalesce((
SELECT
amount
FROM drep_hash
LEFT JOIN drep_distr ON drep_hash.id = drep_distr.hash_id
WHERE
drep_hash.view = 'drep_always_abstain' ORDER BY epoch_no DESC LIMIT 1), 0) AS amount
)

select
SELECT
gov_action_proposal.id,
encode(creator_tx.hash, 'hex'),
gov_action_proposal.index,
gov_action_proposal.type::text,
gov_action_proposal.description::json,
epoch_utils.last_epoch_end_time + epoch_utils.epoch_duration*(gov_action_proposal.expiration - epoch_utils.last_epoch_no),
creator_block.time, /* created date */
voting_anchor.url,
encode(voting_anchor.data_hash, 'hex'),

coalesce(Sum(ldd.amount) filter (where voting_procedure.vote::text = 'Yes'),0)
+ (case
when gov_action_proposal.type = 'NoConfidence' then always_no_confidence_voting_power.amount
else 0
end) "yes_votes",
coalesce(Sum(ldd.amount) filter (where voting_procedure.vote::text = 'No'),0) +
(case
when gov_action_proposal.type = 'NoConfidence' then 0
else always_no_confidence_voting_power.amount
end) "no_votes",
coalesce(Sum(ldd.amount) filter (where voting_procedure.vote::text = 'Abstain'),0) + always_abstain_voting_power.amount "abstain_votes"
from gov_action_proposal
cross join EpochUtils as epoch_utils
cross join always_no_confidence_voting_power
cross join always_abstain_voting_power
join tx as creator_tx
on creator_tx.id = gov_action_proposal.tx_id
join block as creator_block
on creator_block.id = creator_tx.block_id
join voting_anchor
on voting_anchor.id = gov_action_proposal.voting_anchor_id
left join voting_procedure
on voting_procedure.gov_action_proposal_id = gov_action_proposal.id
left join LatestDrepDistr ldd
on ldd.hash_id = voting_procedure.drep_voter and ldd.rn = 1

where (not ? or (concat(encode(creator_tx.hash,'hex'),'#',gov_action_proposal.index) in ?))
and gov_action_proposal.expiration > (select Max(no) from epoch)
and gov_action_proposal.ratified_epoch is null
and gov_action_proposal.enacted_epoch is null
and gov_action_proposal.expired_epoch is null
and gov_action_proposal.dropped_epoch is null

group by (
gov_action_proposal.id,
gov_action_proposal.index,
creator_tx.hash,
epoch_utils.last_epoch_end_time + epoch_utils.epoch_duration *(gov_action_proposal.expiration - epoch_utils.last_epoch_no),
creator_block.time,
epoch_utils.epoch_duration,
epoch_utils.last_epoch_no,
epoch_utils.last_epoch_end_time,
/* created date */
voting_anchor.url,
voting_anchor.data_hash,
always_no_confidence_voting_power.amount,
always_abstain_voting_power.amount
)
encode(voting_anchor.data_hash, 'hex'),
coalesce(Sum(ldd.amount) FILTER (WHERE voting_procedure.vote::text = 'Yes'), 0) +(
CASE WHEN gov_action_proposal.type = 'NoConfidence' THEN
always_no_confidence_voting_power.amount
ELSE
0
END) "yes_votes",
coalesce(Sum(ldd.amount) FILTER (WHERE voting_procedure.vote::text = 'No'), 0) +(
CASE WHEN gov_action_proposal.type = 'NoConfidence' THEN
0
ELSE
always_no_confidence_voting_power.amount
END) "no_votes",
coalesce(Sum(ldd.amount) FILTER (WHERE voting_procedure.vote::text = 'Abstain'), 0) + always_abstain_voting_power.amount "abstain_votes"
FROM
gov_action_proposal
CROSS JOIN EpochUtils AS epoch_utils
CROSS JOIN always_no_confidence_voting_power
CROSS JOIN always_abstain_voting_power
JOIN tx AS creator_tx ON creator_tx.id = gov_action_proposal.tx_id
JOIN block AS creator_block ON creator_block.id = creator_tx.block_id
JOIN voting_anchor ON voting_anchor.id = gov_action_proposal.voting_anchor_id
LEFT JOIN voting_procedure ON voting_procedure.gov_action_proposal_id = gov_action_proposal.id
LEFT JOIN LatestDrepDistr ldd ON ldd.hash_id = voting_procedure.drep_voter
AND ldd.rn = 1
WHERE (NOT ?
OR (concat(encode(creator_tx.hash, 'hex'), '#', gov_action_proposal.index) IN ?))
AND gov_action_proposal.expiration >(
SELECT
Max(NO)
FROM
epoch)
AND gov_action_proposal.ratified_epoch IS NULL
AND gov_action_proposal.enacted_epoch IS NULL
AND gov_action_proposal.expired_epoch IS NULL
AND gov_action_proposal.dropped_epoch IS NULL
GROUP BY
(gov_action_proposal.id,
gov_action_proposal.index,
creator_tx.hash,
creator_block.time,
epoch_utils.epoch_duration,
epoch_utils.last_epoch_no,
epoch_utils.last_epoch_end_time,
voting_anchor.url,
voting_anchor.data_hash,
always_no_confidence_voting_power.amount,
always_abstain_voting_power.amount)