-
Notifications
You must be signed in to change notification settings - Fork 25
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Merge branch '1.2.0a' into more-specific-tx-hashes
- Loading branch information
Showing
8 changed files
with
510 additions
and
5 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,107 @@ | ||
-- Binary format | ||
-- 1 byte variable length | ||
-- <------> <-------------------> | ||
-- ┌────────┬─────────────────────┐ | ||
-- │ header │ key │ | ||
-- └────────┴─────────────────────┘ | ||
-- 🔎 | ||
-- ╎ 7 6 5 4 3 2 1 0 | ||
-- ╎ ┌─┬─┬─┬─┬─┬─┬─┬─┐ | ||
-- ╰╌╌╌╌╌╌╌╌ |t│t│t│t│c│c│c│c│ | ||
-- └─┴─┴─┴─┴─┴─┴─┴─┘ | ||
-- | ||
-- Key Type (`t t t t . . . .`) | Key | ||
-- --- | --- | ||
-- `0000....` | CC Hot | ||
-- `0001....` | CC Cold | ||
-- `0010....` | DRep | ||
-- | ||
-- Credential Type (`. . . . c c c c`) | Semantic | ||
-- --- | --- | ||
-- `....0010` | Key Hash | ||
-- `....0011` | Script Hash | ||
|
||
CREATE OR REPLACE FUNCTION grest.cip129_cc_hot_to_hex(_cc_hot text) | ||
RETURNS bytea | ||
LANGUAGE plpgsql STABLE | ||
AS $$ | ||
BEGIN | ||
IF LENGTH(_cc_hot) = 60 THEN | ||
RETURN substring(b32_decode(_cc_hot) from 2); | ||
ELSE | ||
RETURN b32_decode(_cc_hot); | ||
END IF; | ||
END; | ||
$$; | ||
|
||
CREATE OR REPLACE FUNCTION grest.cip129_hex_to_cc_hot(_raw bytea, _is_script boolean) | ||
RETURNS text | ||
LANGUAGE plpgsql STABLE | ||
AS $$ | ||
BEGIN | ||
IF _is_script THEN | ||
RETURN b32_encode('cc_hot', ('\x03'::bytea || _raw)::text); | ||
ELSE | ||
RETURN b32_encode('cc_hot', ('\x02'::bytea || _raw)::text); | ||
END IF; | ||
END; | ||
$$; | ||
|
||
CREATE OR REPLACE FUNCTION grest.cip129_cc_cold_to_hex(_cc_cold text) | ||
RETURNS bytea | ||
LANGUAGE plpgsql STABLE | ||
AS $$ | ||
BEGIN | ||
IF LENGTH(_cc_cold) = 61 THEN | ||
RETURN substring(b32_decode(_cc_cold) from 2); | ||
ELSE | ||
RETURN b32_decode(_cc_cold); | ||
END IF; | ||
END; | ||
$$; | ||
|
||
CREATE OR REPLACE FUNCTION grest.cip129_hex_to_cc_cold(_raw bytea, _is_script boolean) | ||
RETURNS text | ||
LANGUAGE plpgsql STABLE | ||
AS $$ | ||
BEGIN | ||
IF _is_script THEN | ||
RETURN b32_encode('cc_cold', ('\x13'::bytea || _raw)::text); | ||
ELSE | ||
RETURN b32_encode('cc_cold', ('\x12'::bytea || _raw)::text); | ||
END IF; | ||
END; | ||
$$; | ||
|
||
CREATE OR REPLACE FUNCTION grest.cip129_drep_id_to_hex(_drep_id text) | ||
RETURNS bytea | ||
LANGUAGE plpgsql STABLE | ||
AS $$ | ||
BEGIN | ||
IF LENGTH(_drep_id) = 58 THEN | ||
RETURN substring(b32_decode(_drep_id) from 2); | ||
ELSE | ||
RETURN b32_decode(_drep_id); | ||
END IF; | ||
END; | ||
$$; | ||
|
||
CREATE OR REPLACE FUNCTION grest.cip129_hex_to_drep_id(_raw bytea, _is_script boolean) | ||
RETURNS text | ||
LANGUAGE plpgsql STABLE | ||
AS $$ | ||
BEGIN | ||
IF _is_script THEN | ||
RETURN b32_encode('drep', ('\x23'::bytea || _raw)::text); | ||
ELSE | ||
RETURN b32_encode('drep', ('\x22'::bytea || _raw)::text); | ||
END IF; | ||
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 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,64 @@ | ||
CREATE OR REPLACE FUNCTION grest.committee_info() | ||
RETURNS TABLE ( | ||
proposal_tx_hash text, | ||
cert_index bigint, | ||
quorum_numerator bigint, | ||
quorum_denominator bigint, | ||
members jsonb | ||
) | ||
LANGUAGE plpgsql | ||
AS $$ | ||
DECLARE | ||
gap_id bigint; | ||
BEGIN | ||
|
||
SELECT INTO gap_id id | ||
FROM public.gov_action_proposal | ||
WHERE type = 'NewCommittee' | ||
AND enacted_epoch IS NOT NULL | ||
ORDER BY enacted_epoch DESC | ||
LIMIT 1; | ||
|
||
RETURN QUERY ( | ||
SELECT | ||
CASE | ||
WHEN c.gov_action_proposal_id IS NULL THEN NULL | ||
ELSE ( | ||
SELECT ENCODE(tx.hash, 'hex') | ||
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 ( | ||
SELECT index | ||
FROM gov_action_proposal AS gap | ||
WHERE gap.id = c.gov_action_proposal_id | ||
) | ||
END, | ||
c.quorum_numerator, | ||
c.quorum_denominator, | ||
JSONB_AGG( | ||
JSONB_BUILD_OBJECT( | ||
'hex', ENCODE(ch.raw, 'hex'), | ||
'has_script', ch.has_script, | ||
'expiration_epoch', cm.expiration_epoch | ||
) | ||
) AS members | ||
FROM public.committee AS c | ||
INNER JOIN public.committee_member AS cm ON c.id = cm.committee_id | ||
INNER JOIN public.committee_hash AS ch ON cm.committee_hash_id = ch.id | ||
WHERE | ||
CASE | ||
WHEN gap_id IS NULL THEN c.gov_action_proposal_id IS NULL | ||
ELSE c.gov_action_proposal_id = gap_id | ||
END | ||
GROUP BY c.gov_action_proposal_id, c.quorum_numerator, c.quorum_denominator | ||
); | ||
|
||
END; | ||
$$; | ||
|
||
COMMENT ON FUNCTION grest.committee_info IS 'Get information about current governance committee'; --noqa: LT01 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,94 @@ | ||
CREATE OR REPLACE FUNCTION grest.drep_delegators(_drep_id text) | ||
RETURNS TABLE ( | ||
stake_address text, | ||
stake_address_hex text, | ||
script_hash text, | ||
epoch_no word31type, | ||
amount text | ||
) | ||
LANGUAGE plpgsql | ||
AS $$ | ||
DECLARE | ||
drep_idx bigint; | ||
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 | ||
last_reg_tx_id := 0; | ||
ELSE | ||
SELECT INTO last_reg_tx_id MAX(tx_id) | ||
FROM public.drep_registration | ||
WHERE drep_hash_id = drep_idx | ||
AND (deposit IS NOT NULL AND deposit >= 0); | ||
|
||
IF last_reg_tx_id IS NULL OR EXISTS ( | ||
SELECT 1 | ||
FROM public.drep_registration | ||
WHERE drep_hash_id = drep_idx | ||
AND deposit IS NOT NULL | ||
AND deposit < 0 | ||
AND tx_id > last_reg_tx_id | ||
LIMIT 1 | ||
) THEN | ||
RETURN; -- DRep not registered or de-registered, no need to continue | ||
END IF; | ||
END IF; | ||
|
||
RETURN QUERY ( | ||
WITH | ||
_all_delegations AS ( | ||
SELECT * | ||
FROM ( | ||
SELECT | ||
DISTINCT ON (last_delegation.addr_id) last_delegation.addr_id, | ||
last_delegation.tx_id, | ||
last_delegation.drep_hash_id, | ||
sd.tx_id AS dereg_tx_id | ||
FROM ( | ||
SELECT | ||
DISTINCT ON (dv1.addr_id) dv1.addr_id, | ||
dv1.tx_id, | ||
dv1.drep_hash_id | ||
FROM | ||
public.delegation_vote AS dv1 | ||
WHERE | ||
dv1.addr_id = ANY( | ||
SELECT dv2.addr_id | ||
FROM public.delegation_vote AS dv2 | ||
WHERE dv2.drep_hash_id = drep_idx | ||
AND dv2.tx_id >= last_reg_tx_id | ||
) | ||
ORDER BY | ||
dv1.addr_id, dv1.tx_id DESC | ||
) AS last_delegation | ||
LEFT JOIN stake_deregistration AS sd ON last_delegation.addr_id = sd.addr_id AND last_delegation.tx_id < sd.tx_id | ||
WHERE last_delegation.drep_hash_id = drep_idx | ||
ORDER BY | ||
last_delegation.addr_id, sd.tx_id NULLS LAST | ||
) AS all_delegations_w_dereg | ||
WHERE all_delegations_w_dereg.dereg_tx_id IS NULL | ||
) | ||
|
||
SELECT | ||
sa.view::text, | ||
ENCODE(sa.hash_raw,'hex'), | ||
ENCODE(sa.script_hash,'hex'), | ||
b.epoch_no, | ||
COALESCE(sdc.total_balance,0)::text | ||
FROM _all_delegations AS ad | ||
INNER JOIN stake_address AS sa ON ad.addr_id = sa.id | ||
INNER JOIN tx ON ad.tx_id = tx.id | ||
INNER JOIN block AS b ON tx.block_id = b.id | ||
LEFT JOIN grest.stake_distribution_cache AS sdc ON sa.view = sdc.stake_address | ||
ORDER BY b.epoch_no DESC, sa.view | ||
); | ||
|
||
END; | ||
$$; | ||
|
||
COMMENT ON FUNCTION grest.drep_delegators IS 'Return all delegators for a specific DRep'; -- noqa: LT01 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.