Skip to content

Commit

Permalink
CIP-129 RC, no schema updates
Browse files Browse the repository at this point in the history
  • Loading branch information
Scitz0 committed Aug 25, 2024
1 parent 1af4394 commit 88d2c44
Show file tree
Hide file tree
Showing 10 changed files with 120 additions and 88 deletions.
2 changes: 1 addition & 1 deletion files/grest/rpc/governance/committee_votes.sql
Original file line number Diff line number Diff line change
Expand Up @@ -26,7 +26,7 @@ AS $$
WHERE
CASE
WHEN _cc_hot_id IS NULL THEN TRUE
ELSE ch.raw = (SELECT grest.cip129_cc_hot_to_hex(_cc_hot_id))
ELSE ch.raw = DECODE((SELECT grest.cip129_cc_hot_to_hex(_cc_hot_id)), 'hex')
END
ORDER BY
vote_tx.id DESC;
Expand Down
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 raw = (SELECT grest.cip129_drep_id_to_hex(_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
32 changes: 27 additions & 5 deletions files/grest/rpc/governance/drep_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -22,7 +22,13 @@ 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_AGG(grest.cip129_drep_id_to_hex(n)) FROM UNNEST(_drep_ids) AS n;
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)
Expand All @@ -32,6 +38,18 @@ BEGIN
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 @@ -96,8 +114,12 @@ BEGIN
INNER JOIN block AS b ON tx.block_id = b.id
)

SELECT DISTINCT ON (dh.raw)
grest.cip129_hex_to_drep_id(dh.raw, dh.has_script) 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,
(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,
(CASE WHEN (dr.deposit < 0) OR starts_with(dh.view,'drep_') THEN NULL ELSE ds.deposit END)::text AS deposit,
(CASE WHEN starts_with(dh.view,'drep_') THEN TRUE ELSE COALESCE(dr.deposit, 0) >= 0 AND ds.active END) AS active,
Expand All @@ -112,10 +134,10 @@ BEGIN
LEFT JOIN _drep_state AS ds ON dh.id = ds.drep
WHERE dh.id = ANY(drep_list)
ORDER BY
dh.raw, dr.tx_id DESC
dh.view, dr.tx_id DESC
);

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
12 changes: 4 additions & 8 deletions files/grest/rpc/governance/drep_list.sql
Original file line number Diff line number Diff line change
@@ -1,24 +1,20 @@
CREATE OR REPLACE FUNCTION grest.drep_list()
RETURNS TABLE (
drep_id character varying,
hex text,
has_script boolean,
drep_id text,
registered boolean
)
LANGUAGE sql STABLE
AS $$
SELECT
DISTINCT ON (dh.view) dh.view AS drep_id,
ENCODE(dh.raw, 'hex')::text AS hex,
dh.has_script AS has_script,
SELECT DISTINCT ON (dh.raw)
grest.cip129_hex_to_drep_id(dh.raw, dh.has_script) AS drep_id,
(CASE
WHEN coalesce(dr.deposit, 0) >= 0 THEN TRUE
ELSE FALSE
END) AS registered
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
58 changes: 33 additions & 25 deletions files/grest/rpc/governance/drep_metadata.sql
Original file line number Diff line number Diff line change
@@ -1,36 +1,44 @@
CREATE OR REPLACE FUNCTION grest.drep_metadata(_drep_ids text [])
RETURNS TABLE (
drep_id character varying,
hex text,
url text,
drep_id text,
url character varying,
hash text,
json jsonb,
bytes text,
warning text,
language text,
comment text,
warning character varying,
language character varying,
comment character varying,
is_valid boolean
)
LANGUAGE sql STABLE
LANGUAGE plpgsql
AS $$
SELECT
DISTINCT ON (dh.view) dh.view AS drep_id,
ENCODE(dh.raw, 'hex')::text AS hex,
va.url,
ENCODE(va.data_hash, 'hex') AS hash,
ocvd.json,
ENCODE(ocvd.bytes,'hex')::text AS bytes,
ocvd.warning AS warning,
ocvd.language AS language,
ocvd.comment AS comment,
COALESCE(is_valid, true) AS is_valid
FROM public.drep_hash AS dh
INNER JOIN public.drep_registration AS dr ON dh.id = dr.drep_hash_id
LEFT JOIN public.voting_anchor AS va ON dr.voting_anchor_id = va.id
LEFT JOIN public.off_chain_vote_data AS ocvd ON va.id = ocvd.voting_anchor_id
WHERE dh.view = ANY(_drep_ids)
ORDER BY
dh.view, dr.tx_id DESC;
DECLARE
drep_ids_raw hash28type[];
BEGIN

SELECT INTO drep_ids_raw ARRAY_AGG(DECODE(grest.cip129_drep_id_to_hex(n), 'hex')) FROM UNNEST(_drep_ids) AS n;

RETURN QUERY (
SELECT DISTINCT ON (dh.raw)
grest.cip129_hex_to_drep_id(dh.raw, dh.has_script) AS drep_id,
va.url,
ENCODE(va.data_hash, 'hex') AS hash,
ocvd.json,
ENCODE(ocvd.bytes,'hex')::text AS bytes,
ocvd.warning AS warning,
ocvd.language AS language,
ocvd.comment AS comment,
COALESCE(ocvd.is_valid, true) AS is_valid
FROM public.drep_hash AS dh
INNER JOIN public.drep_registration AS dr ON dh.id = dr.drep_hash_id
LEFT JOIN public.voting_anchor AS va ON dr.voting_anchor_id = va.id
LEFT JOIN public.off_chain_vote_data AS ocvd ON va.id = ocvd.voting_anchor_id
WHERE dh.raw = ANY(drep_ids_raw)
ORDER BY
dh.raw, dr.tx_id DESC
);

END;
$$;

COMMENT ON FUNCTION grest.drep_metadata IS 'Get bulk DRep metadata from bech32 formatted DRep IDs'; -- noqa: LT01
8 changes: 3 additions & 5 deletions files/grest/rpc/governance/drep_updates.sql
Original file line number Diff line number Diff line change
@@ -1,7 +1,6 @@
CREATE OR REPLACE FUNCTION grest.drep_updates(_drep_id text DEFAULT NULL)
RETURNS TABLE (
drep_id character varying,
hex text,
drep_id text,
update_tx_hash text,
cert_index integer,
block_time integer,
Expand All @@ -14,8 +13,7 @@ RETURNS TABLE (
LANGUAGE sql STABLE
AS $$
SELECT
dh.view AS drep_id,
ENCODE(dh.raw, 'hex')::text AS hex,
grest.cip129_hex_to_drep_id(dh.raw, dh.has_script) AS drep_id,
ENCODE(tx.hash, 'hex')::text AS update_tx_hash,
dr.cert_index,
EXTRACT(EPOCH FROM b.time)::integer AS block_time,
Expand All @@ -37,7 +35,7 @@ AS $$
WHERE
CASE
WHEN _drep_id IS NULL THEN TRUE
ELSE dh.view = _drep_id
ELSE dh.raw = DECODE((SELECT grest.cip129_drep_id_to_hex(_drep_id)), 'hex')
END
ORDER BY
block_time DESC;
Expand Down
8 changes: 3 additions & 5 deletions files/grest/rpc/governance/drep_votes.sql
Original file line number Diff line number Diff line change
@@ -1,7 +1,6 @@
CREATE OR REPLACE FUNCTION grest.drep_votes(_drep_id text)
RETURNS TABLE (
proposal_tx_hash text,
proposal_index integer,
proposal_id text,
vote_tx_hash text,
block_time integer,
vote text,
Expand All @@ -11,8 +10,7 @@ RETURNS TABLE (
LANGUAGE sql STABLE
AS $$
SELECT
ENCODE(prop_tx.hash, 'hex'),
gap.index,
grest.cip129_to_gov_action_id(prop_tx.hash, gap.index),
ENCODE(vote_tx.hash, 'hex'),
EXTRACT(EPOCH FROM b.time)::integer,
vp.vote,
Expand All @@ -25,7 +23,7 @@ AS $$
INNER JOIN public.tx vote_tx on vp.tx_id = vote_tx.id
INNER JOIN public.block AS b ON vote_tx.block_id = b.id
LEFT JOIN public.voting_anchor AS va ON vp.voting_anchor_id = va.id
WHERE dh.view = _drep_id
WHERE dh.raw = DECODE((SELECT grest.cip129_drep_id_to_hex(_drep_id)), 'hex')
ORDER BY
vote_tx.id DESC;
$$;
Expand Down
6 changes: 2 additions & 4 deletions files/grest/rpc/governance/proposal_list.sql
Original file line number Diff line number Diff line change
@@ -1,8 +1,7 @@
CREATE OR REPLACE FUNCTION grest.proposal_list()
RETURNS TABLE (
block_time integer,
proposal_tx_hash text,
proposal_index integer,
proposal_id text,
proposal_type text,
proposal_description jsonb,
deposit text,
Expand All @@ -26,8 +25,7 @@ LANGUAGE sql STABLE
AS $$
SELECT
EXTRACT(EPOCH FROM b.time)::integer,
ENCODE(tx.hash, 'hex'),
gap.index,
grest.cip129_to_gov_action_id(tx.hash, gap.index),
gap.type,
gap.description,
gap.deposit::text,
Expand Down
51 changes: 30 additions & 21 deletions files/grest/rpc/governance/proposal_votes.sql
Original file line number Diff line number Diff line change
@@ -1,25 +1,31 @@
CREATE OR REPLACE FUNCTION grest.proposal_votes(_proposal_tx_hash text, _proposal_index integer)
CREATE OR REPLACE FUNCTION grest.proposal_votes(_proposal_id text)
RETURNS TABLE (
block_time integer,
voter_role text,
has_script boolean,
voter text,
voter_hex text,
vote text,
meta_url text,
voter_id text,
vote vote,
meta_url character varying,
meta_hash text
)
LANGUAGE sql STABLE
LANGUAGE plpgsql
AS $$
SELECT z.*
DECLARE
proposal text[];
BEGIN

SELECT INTO proposal grest.cip129_from_gov_action_id(_proposal_id);

RETURN QUERY (
SELECT z.*
FROM (
SELECT
distinct on (COALESCE(ENCODE(ch.raw, 'hex'), dh.view, ph.view))
SELECT DISTINCT ON (COALESCE(dh.raw, ph.hash_raw, ch.raw))
EXTRACT(EPOCH FROM vote_block.time)::integer AS block_time,
vp.voter_role,
COALESCE(dh.has_script, COALESCE(ch.has_script), false) AS has_script,
COALESCE(ENCODE(ch.raw, 'hex'), dh.view, ph.view) as voter,
COALESCE(ENCODE(ch.raw, 'hex'), ENCODE(dh.raw, 'hex'), ENCODE(ph.hash_raw, 'hex')) as voter_hex,
CASE
WHEN dh.raw IS NOT NULL THEN grest.cip129_hex_to_drep_id(dh.raw, dh.has_script)
WHEN ph.view IS NOT NULL THEN ph.view
WHEN ch.raw IS NOT NULL THEN grest.cip129_hex_to_cc_hot(ch.raw, ch.has_script)
ELSE
'' -- shouldn't happen
END,
vp.vote,
va.url,
ENCODE(va.data_hash, 'hex')
Expand All @@ -28,22 +34,25 @@ AS $$
INNER JOIN public.tx ON gap.tx_id = tx.id
INNER JOIN public.tx AS vote_tx ON vp.tx_id = vote_tx.id
INNER JOIN public.block AS vote_block ON vote_tx.block_id = vote_block.id
LEFT JOIN public.drep_hash AS dh ON vp.drep_voter = dh.id
LEFT JOIN public.drep_hash AS dh ON vp.drep_voter = dh.id
LEFT JOIN public.pool_hash AS ph ON vp.pool_voter = ph.id
LEFT JOIN public.committee_hash AS ch ON vp.committee_voter = ch.id
LEFT JOIN public.voting_anchor AS va ON vp.voting_anchor_id = va.id
WHERE tx.hash = DECODE(_proposal_tx_hash, 'hex')
AND gap.index = _proposal_index
-- will we need a similar filters to the one below for pool and committee member retirements?
WHERE tx.hash = DECODE(proposal[1], 'hex')
AND gap.index = proposal[2]::smallint
-- TODO: will we need a similar filters to the one below for pool and committee member retirements?
AND (
CASE
WHEN dh.view IS NOT NULL THEN ((SELECT coalesce(dreg.deposit, 0) FROM drep_registration AS dreg WHERE dreg.drep_hash_id = dh.id ORDER BY id DESC LIMIT 1) >= 0)
ELSE true
END)
ORDER by
COALESCE(ENCODE(ch.raw, 'hex'), dh.view, ph.view),
COALESCE(dh.raw, ph.hash_raw, ch.raw),
block_time DESC
) z ORDER BY block_time desc;
) z ORDER BY block_time desc
);

END;
$$;

COMMENT ON FUNCTION grest.proposal_votes IS 'Get all votes cast on specified governance action'; -- noqa: LT01
19 changes: 9 additions & 10 deletions files/grest/rpc/governance/voter_proposal_list.sql
Original file line number Diff line number Diff line change
@@ -1,8 +1,7 @@
CREATE OR REPLACE FUNCTION grest.voter_proposal_list(_credential text)
CREATE OR REPLACE FUNCTION grest.voter_proposal_list(_voter_id text)
RETURNS TABLE (
block_time integer,
proposal_tx_hash text,
proposal_index bigint,
proposal_id text,
proposal_type govactiontype,
proposal_description jsonb,
deposit text,
Expand Down Expand Up @@ -31,11 +30,12 @@ DECLARE
_gap_id_list bigint[];
BEGIN

SELECT INTO _drep_id id FROM public.drep_hash WHERE raw = DECODE(_credential, 'hex');
IF _drep_id IS NULL THEN
SELECT INTO _spo_id id FROM public.pool_hash WHERE hash_raw = DECODE(_credential, 'hex');
ELSIF _spo_id IS NULL THEN
SELECT INTO _committee_member_id id FROM public.committee_hash WHERE raw = DECODE(_credential, 'hex');
IF STARTS_WITH(_voter_id, 'drep') THEN
SELECT INTO _drep_id id FROM public.drep_hash WHERE raw = DECODE((SELECT grest.cip129_drep_id_to_hex(_voter_id)), 'hex');
ELSIF STARTS_WITH(_voter_id, 'pool') THEN
SELECT INTO _spo_id id FROM public.pool_hash WHERE view = _voter_id;
ELSIF STARTS_WITH(_voter_id, 'cc_hot') THEN
SELECT INTO _committee_member_id id FROM public.committee_hash WHERE raw = DECODE((SELECT grest.cip129_cc_hot_to_hex(_voter_id)), 'hex');
END IF;

SELECT INTO _gap_id_list ARRAY_AGG(gov_action_proposal_id)
Expand All @@ -55,8 +55,7 @@ BEGIN
RETURN QUERY (
SELECT
EXTRACT(EPOCH FROM b.time)::integer,
ENCODE(tx.hash, 'hex'),
gap.index,
grest.cip129_to_gov_action_id(tx.hash, gap.index),
gap.type,
gap.description,
gap.deposit::text,
Expand Down

0 comments on commit 88d2c44

Please sign in to comment.