Skip to content

Commit

Permalink
Koios v1.2.0 Release (#300)
Browse files Browse the repository at this point in the history
## Description
<!--- Describe your changes -->
- [x] Implement CIP-129
- [x] Add index for drep (raw instead of encoded)
- [x] Add `has_script` to drep endpoints 
- [x] Add `proposal_id` to `committee_info`, `drep_votes`,
`proposal_list`, `proposal_votes`
- [x] Use `_cc_hot_id` as input for committee_votes
- [x] Use `_voter_id` as input for voter_proposal_list
- [x] Add `delegated_drep` and `deposit` to `account_info_cached`
- [x] Add `proposal_voting_summary`
- [x] Bump Koios Release

---------

Co-authored-by: Ola <[email protected]>
Co-authored-by: Greg B <[email protected]>
  • Loading branch information
3 people authored Aug 30, 2024
1 parent 41bcff5 commit 4f94b40
Show file tree
Hide file tree
Showing 25 changed files with 1,341 additions and 431 deletions.
3 changes: 2 additions & 1 deletion files/grest/rpc/02_indexes/13_3_00.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
CREATE INDEX IF NOT EXISTS pool_stat_pool_hash_id ON pool_stat(pool_hash_id);
CREATE INDEX IF NOT EXISTS pool_stat_epoch_no ON pool_stat(epoch_no);
CREATE INDEX IF NOT EXISTS idx_drep_hash_view ON drep_hash (view);
-- CREATE INDEX IF NOT EXISTS idx_drep_hash_view ON drep_hash (view);
CREATE INDEX IF NOT EXISTS idx_drep_hash_raw ON drep_hash (raw);
CREATE INDEX IF NOT EXISTS idx_reward_rest_addr_id ON reward_rest (addr_id);
CREATE INDEX IF NOT EXISTS idx_reward_rest_spendable_epoch ON reward_rest (spendable_epoch);
35 changes: 29 additions & 6 deletions files/grest/rpc/03_utilities/cip129.sql
Original file line number Diff line number Diff line change
Expand Up @@ -22,12 +22,12 @@
-- `....0011` | Script Hash

CREATE OR REPLACE FUNCTION grest.cip129_cc_hot_to_hex(_cc_hot text)
RETURNS bytea
RETURNS text
LANGUAGE plpgsql STABLE
AS $$
BEGIN
IF LENGTH(_cc_hot) = 60 THEN
RETURN substring(b32_decode(_cc_hot) from 2);
RETURN SUBSTRING(b32_decode(_cc_hot) from 3);
ELSE
RETURN b32_decode(_cc_hot);
END IF;
Expand All @@ -48,12 +48,12 @@ END;
$$;

CREATE OR REPLACE FUNCTION grest.cip129_cc_cold_to_hex(_cc_cold text)
RETURNS bytea
RETURNS text
LANGUAGE plpgsql STABLE
AS $$
BEGIN
IF LENGTH(_cc_cold) = 61 THEN
RETURN substring(b32_decode(_cc_cold) from 2);
RETURN SUBSTRING(b32_decode(_cc_cold) from 3);
ELSE
RETURN b32_decode(_cc_cold);
END IF;
Expand All @@ -74,12 +74,12 @@ END;
$$;

CREATE OR REPLACE FUNCTION grest.cip129_drep_id_to_hex(_drep_id text)
RETURNS bytea
RETURNS text
LANGUAGE plpgsql STABLE
AS $$
BEGIN
IF LENGTH(_drep_id) = 58 THEN
RETURN substring(b32_decode(_drep_id) from 2);
RETURN SUBSTRING(b32_decode(_drep_id) from 3);
ELSE
RETURN b32_decode(_drep_id);
END IF;
Expand All @@ -99,9 +99,32 @@ BEGIN
END;
$$;

CREATE OR REPLACE FUNCTION grest.cip129_from_gov_action_id(_proposal_id text)
RETURNS text[]
LANGUAGE plpgsql STABLE
AS $$
DECLARE
proposal_id_hex text;
BEGIN
SELECT INTO proposal_id_hex b32_decode(_proposal_id);
RETURN ARRAY[LEFT(proposal_id_hex, 64), ('x' || RIGHT(proposal_id_hex, -64))::bit(8)::int::text];
END;
$$;

CREATE OR REPLACE FUNCTION grest.cip129_to_gov_action_id(_tx_hash bytea, _index bigint)
RETURNS text
LANGUAGE plpgsql STABLE
AS $$
BEGIN
RETURN b32_encode('gov_action', (_tx_hash || DECODE(LPAD(TO_HEX(_index), 2, '0'), 'hex'))::text);
END;
$$;

COMMENT ON FUNCTION grest.cip129_cc_hot_to_hex IS 'Returns binary hex from Constitutional Committee Hot Credential ID in old or new (CIP-129) format'; -- noqa: LT01
COMMENT ON FUNCTION grest.cip129_hex_to_cc_hot IS 'Returns Constitutional Committee Hot Credential ID in CIP-129 format from raw binary hex'; -- noqa: LT01
COMMENT ON FUNCTION grest.cip129_cc_cold_to_hex IS 'Returns binary hex from Constitutional Committee Cold Credential ID in old or new (CIP-129) format'; -- noqa: LT01
COMMENT ON FUNCTION grest.cip129_hex_to_cc_cold IS 'Returns Constitutional Committee Cold Credential ID in CIP-129 format from raw binary hex'; -- noqa: LT01
COMMENT ON FUNCTION grest.cip129_drep_id_to_hex IS 'Returns binary hex from DRep Credential ID in old or new (CIP-129) format'; -- noqa: LT01
COMMENT ON FUNCTION grest.cip129_hex_to_drep_id IS 'Returns DRep Credential ID in CIP-129 format from raw binary hex'; -- noqa: LT01
COMMENT ON FUNCTION grest.cip129_from_gov_action_id IS 'Returns string array containing transaction hash and certificate index from Governance Action Proposal ID in CIP-129 format'; -- noqa: LT01
COMMENT ON FUNCTION grest.cip129_to_gov_action_id IS 'Returns Governance Action Proposal ID in CIP-129 format from transaction hash appended by index of certificate within the transaction'; -- noqa: LT01
4 changes: 2 additions & 2 deletions files/grest/rpc/account/account_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,7 +3,7 @@ RETURNS TABLE (
stake_address varchar,
status text,
delegated_pool varchar,
delegated_drep varchar,
delegated_drep text,
total_balance text,
utxo text,
rewards text,
Expand Down Expand Up @@ -75,7 +75,7 @@ BEGIN
LEFT JOIN (
SELECT
dv.addr_id,
dh.view AS delegated_drep
COALESCE(grest.cip129_hex_to_drep_id(dh.raw, dh.has_script), dh.view::text) AS delegated_drep
FROM delegation_vote AS dv
INNER JOIN drep_hash AS dh ON dh.id = dv.drep_hash_id
WHERE dv.addr_id = ANY(sa_id_list)
Expand Down
32 changes: 31 additions & 1 deletion files/grest/rpc/account/account_info_cached.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,11 +3,13 @@ RETURNS TABLE (
stake_address varchar,
status text,
delegated_pool varchar,
delegated_drep text,
total_balance text,
utxo text,
rewards text,
withdrawals text,
rewards_available text,
deposit text,
reserves text,
treasury text
)
Expand All @@ -33,11 +35,13 @@ BEGIN
'not registered'
END AS status,
sdc.pool_id AS pool_id,
vote_t.delegated_drep,
sdc.total_balance::text,
sdc.utxo::text,
sdc.rewards::text,
sdc.withdrawals::text,
sdc.rewards_available::text,
COALESCE(status_t.deposit,0)::text AS deposit,
COALESCE(reserves_t.reserves, 0)::text AS reserves,
COALESCE(treasury_t.treasury, 0)::text AS treasury
FROM grest.stake_distribution_cache AS sdc
Expand All @@ -55,10 +59,34 @@ BEGIN
WHERE stake_deregistration.addr_id = stake_registration.addr_id
AND stake_deregistration.tx_id > stake_registration.tx_id
)
) AS registered
) AS registered,
(
SELECT sr.deposit FROM stake_registration AS sr
WHERE sr.addr_id = sas.id
AND NOT EXISTS (
SELECT TRUE
FROM stake_deregistration AS sd
WHERE
sd.addr_id = sr.addr_id
AND sd.tx_id > sr.tx_id
)
) AS deposit
FROM public.stake_address AS sas
WHERE sas.id = ANY(sa_id_list)
) AS status_t ON sdc.stake_address = status_t.view
LEFT JOIN (
SELECT
dv.addr_id,
COALESCE(grest.cip129_hex_to_drep_id(dh.raw, dh.has_script), dh.view::text) AS delegated_drep
FROM delegation_vote AS dv
INNER JOIN drep_hash AS dh ON dh.id = dv.drep_hash_id
WHERE dv.addr_id = ANY(sa_id_list)
AND NOT EXISTS (
SELECT TRUE
FROM delegation_vote AS dv1
WHERE dv1.addr_id = dv.addr_id
AND dv1.id > dv.id)
) AS vote_t ON vote_t.addr_id = status_t.id
LEFT JOIN (
SELECT
r.addr_id,
Expand Down Expand Up @@ -95,11 +123,13 @@ BEGIN
z.stake_address,
ai.status,
ai.delegated_pool AS pool_id,
ai.delegated_drep,
ai.total_balance::text,
ai.utxo::text,
ai.rewards::text,
ai.withdrawals::text,
ai.rewards_available::text,
ai.deposit,
ai.reserves,
ai.treasury
FROM
Expand Down
12 changes: 12 additions & 0 deletions files/grest/rpc/governance/committee_info.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
CREATE OR REPLACE FUNCTION grest.committee_info()
RETURNS TABLE (
proposal_id text,
proposal_tx_hash text,
proposal_index bigint,
quorum_numerator bigint,
Expand Down Expand Up @@ -32,6 +33,15 @@ BEGIN

RETURN QUERY (
SELECT
CASE
WHEN c.gov_action_proposal_id IS NULL THEN NULL
ELSE (
SELECT grest.cip129_to_gov_action_id(tx.hash, gap.index)
FROM gov_action_proposal AS gap
INNER JOIN tx on gap.tx_id = tx.id
WHERE gap.id = c.gov_action_proposal_id
)
END,
CASE
WHEN c.gov_action_proposal_id IS NULL THEN NULL
ELSE (
Expand Down Expand Up @@ -65,8 +75,10 @@ BEGIN
ELSE
'authorized'
END,
'cc_cold_id', (SELECT grest.cip129_hex_to_cc_cold(ch_cold.raw, ch_cold.has_script)),
'cc_cold_hex', ENCODE(ch_cold.raw, 'hex'),
'cc_cold_has_script', ch_cold.has_script,
'cc_hot_id', CASE WHEN hot_key.raw IS NULL THEN NULL ELSE (SELECT grest.cip129_hex_to_cc_hot(hot_key.raw, hot_key.has_script)) END,
'cc_hot_hex', CASE WHEN hot_key.raw IS NULL THEN NULL ELSE ENCODE(hot_key.raw, 'hex') END,
'cc_hot_has_script', CASE WHEN hot_key.has_script IS NULL THEN NULL ELSE hot_key.has_script END,
'expiration_epoch', cm.expiration_epoch
Expand Down
10 changes: 6 additions & 4 deletions files/grest/rpc/governance/committee_votes.sql
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
CREATE OR REPLACE FUNCTION grest.committee_votes(_committee_hash text DEFAULT NULL)
CREATE OR REPLACE FUNCTION grest.committee_votes(_cc_hot_id text DEFAULT NULL)
RETURNS TABLE (
proposal_id text,
proposal_tx_hash text,
proposal_index integer,
vote_tx_hash text,
Expand All @@ -11,6 +12,7 @@ RETURNS TABLE (
LANGUAGE sql STABLE
AS $$
SELECT
grest.cip129_to_gov_action_id(prop_tx.hash, gap.index),
ENCODE(prop_tx.hash, 'hex'),
gap.index,
ENCODE(vote_tx.hash, 'hex'),
Expand All @@ -27,11 +29,11 @@ AS $$
LEFT JOIN public.voting_anchor AS va ON vp.voting_anchor_id = va.id
WHERE
CASE
WHEN _committee_hash IS NULL THEN TRUE
ELSE ch.raw = DECODE(_committee_hash, 'hex')
WHEN _cc_hot_id IS NULL THEN TRUE
ELSE ch.raw = DECODE((SELECT grest.cip129_cc_hot_to_hex(_cc_hot_id)), 'hex')
END
ORDER BY
vote_tx.id DESC;
$$;

COMMENT ON FUNCTION grest.committee_votes IS 'Get all committee votes cast by given committee member or collective'; -- noqa: LT01
COMMENT ON FUNCTION grest.committee_votes IS 'Get all committee votes cast by given committee member or collective, or all if omitted'; -- noqa: LT01
12 changes: 8 additions & 4 deletions files/grest/rpc/governance/drep_delegators.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,14 +13,18 @@ DECLARE
last_reg_tx_id bigint;
BEGIN

SELECT INTO drep_idx id
FROM public.drep_hash
WHERE view = _drep_id;

IF STARTS_WITH(_drep_id,'drep_') THEN
-- predefined DRep roles
SELECT INTO drep_idx id
FROM public.drep_hash
WHERE view = _drep_id;

last_reg_tx_id := 0;
ELSE
SELECT INTO drep_idx id
FROM public.drep_hash
WHERE raw = DECODE((SELECT grest.cip129_drep_id_to_hex(_drep_id)), 'hex');

SELECT INTO last_reg_tx_id MAX(tx_id)
FROM public.drep_registration
WHERE drep_hash_id = drep_idx
Expand Down
35 changes: 30 additions & 5 deletions files/grest/rpc/governance/drep_info.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
CREATE OR REPLACE FUNCTION grest.drep_info(_drep_ids text [])
RETURNS TABLE (
drep_id character varying,
drep_id text,
hex text,
has_script boolean,
registered boolean,
Expand All @@ -15,6 +15,7 @@ LANGUAGE plpgsql
AS $$
DECLARE
curr_epoch word31type;
drep_ids_raw hash28type[];
drep_list bigint[];
drep_activity word64type;
BEGIN
Expand All @@ -23,14 +24,34 @@ BEGIN

SELECT INTO drep_activity ep.drep_activity FROM public.epoch_param AS ep WHERE ep.epoch_no = curr_epoch;

SELECT INTO drep_ids_raw ARRAY_REMOVE(ARRAY_AGG(
CASE
WHEN STARTS_WITH(n,'drep_') THEN NULL
ELSE
DECODE(grest.cip129_drep_id_to_hex(n), 'hex')
END
), NULL) FROM UNNEST(_drep_ids) AS n;

-- all DRep ids
SELECT INTO drep_list ARRAY_AGG(id)
FROM (
SELECT id
FROM public.drep_hash
WHERE view = ANY(_drep_ids)
WHERE raw = ANY(drep_ids_raw)
) AS tmp;

IF 'drep_always_abstain' = ANY(_drep_ids) THEN
SELECT INTO drep_list ARRAY_APPEND(drep_list, id)
FROM public.drep_hash
WHERE view = 'drep_always_abstain';
END IF;

IF 'drep_always_no_confidence' = ANY(_drep_ids) THEN
SELECT INTO drep_list ARRAY_APPEND(drep_list, id)
FROM public.drep_hash
WHERE view = 'drep_always_no_confidence';
END IF;

RETURN QUERY (
WITH

Expand Down Expand Up @@ -95,8 +116,12 @@ BEGIN
INNER JOIN block AS b ON tx.block_id = b.id
)

SELECT
DISTINCT ON (dh.view) dh.view AS drep_id,
SELECT DISTINCT ON (dh.view)
CASE
WHEN dh.raw IS NULL THEN dh.view
ELSE
grest.cip129_hex_to_drep_id(dh.raw, dh.has_script)
END AS drep_id,
ENCODE(dh.raw, 'hex')::text AS hex,
dh.has_script AS has_script,
(CASE WHEN starts_with(dh.view,'drep_') OR (COALESCE(dr.deposit, 0) >= 0 AND dr.drep_hash_id IS NOT NULL) THEN TRUE ELSE FALSE END) AS registered,
Expand All @@ -119,4 +144,4 @@ BEGIN
END;
$$;

COMMENT ON FUNCTION grest.drep_info IS 'Get bulk DRep info from bech32 formatted DRep IDs, incl predefined roles ''drep_always_abstain'' and ''drep_always_no_confidence'''; -- noqa: LT01
COMMENT ON FUNCTION grest.drep_info IS 'Get bulk DRep info from bech32 formatted DRep IDs (CIP-5 | CIP-129), incl predefined roles ''drep_always_abstain'' and ''drep_always_no_confidence'''; -- noqa: LT01
8 changes: 4 additions & 4 deletions files/grest/rpc/governance/drep_list.sql
Original file line number Diff line number Diff line change
@@ -1,14 +1,14 @@
CREATE OR REPLACE FUNCTION grest.drep_list()
RETURNS TABLE (
drep_id character varying,
drep_id text,
hex text,
has_script boolean,
registered boolean
)
LANGUAGE sql STABLE
AS $$
SELECT
DISTINCT ON (dh.view) dh.view AS drep_id,
SELECT DISTINCT ON (dh.raw)
grest.cip129_hex_to_drep_id(dh.raw, dh.has_script) AS drep_id,
ENCODE(dh.raw, 'hex')::text AS hex,
dh.has_script AS has_script,
(CASE
Expand All @@ -18,7 +18,7 @@ AS $$
FROM public.drep_hash AS dh
INNER JOIN public.drep_registration AS dr ON dh.id = dr.drep_hash_id
ORDER BY
dh.view, dr.tx_id DESC;
dh.raw, dr.tx_id DESC;
$$;

COMMENT ON FUNCTION grest.asset_list IS 'Get a raw listing of all active delegated representatives, aka DReps'; --noqa: LT01
Loading

0 comments on commit 4f94b40

Please sign in to comment.