diff --git a/files/grest/.sqlfluff b/files/grest/.sqlfluff index 55ed4bb6..1a16aea2 100644 --- a/files/grest/.sqlfluff +++ b/files/grest/.sqlfluff @@ -7,7 +7,7 @@ extended_capitalisation_policy = upper idented_joins = True indented_using_on = False tab_space_size = 2 -large_file_skip_byte_limit=35000 +large_file_skip_byte_limit=50000 [sqlfluff:indentation] tab_space_size = 2 diff --git a/files/grest/rpc/000_utilities/cip129.sql b/files/grest/rpc/000_utilities/cip129.sql index 38411446..a08bf389 100644 --- a/files/grest/rpc/000_utilities/cip129.sql +++ b/files/grest/rpc/000_utilities/cip129.sql @@ -142,7 +142,7 @@ END; $$; CREATE OR REPLACE FUNCTION grest.cip129_from_gov_action_id(_proposal_id text) -RETURNS text[] +RETURNS text [] LANGUAGE plpgsql STABLE AS $$ DECLARE diff --git a/files/grest/rpc/000_utilities/cip5.sql b/files/grest/rpc/000_utilities/cip5.sql index 103043ef..1aaaaf33 100644 --- a/files/grest/rpc/000_utilities/cip5.sql +++ b/files/grest/rpc/000_utilities/cip5.sql @@ -16,4 +16,4 @@ BEGIN RETURN b32_encode('stake', _raw::text); END IF; END; -$$; \ No newline at end of file +$$; diff --git a/files/grest/rpc/01_cached_tables/pool_history_cache.sql b/files/grest/rpc/01_cached_tables/pool_history_cache.sql index 9e32ae66..8269a80a 100644 --- a/files/grest/rpc/01_cached_tables/pool_history_cache.sql +++ b/files/grest/rpc/01_cached_tables/pool_history_cache.sql @@ -219,7 +219,7 @@ $$; COMMENT ON FUNCTION grest.get_pool_history_data_bulk IS 'Pool block production and reward history from a given epoch until optional later epoch, for all or particular subset of pools'; -- noqa: LT01 -CREATE OR REPLACE FUNCTION grest.pool_history_cache_update(_epoch_no_to_insert_from bigint DEFAULT NULL) +CREATE OR REPLACE FUNCTION grest.pool_history_cache_update(_epoch_no_to_insert_from bigint DEFAULT null) RETURNS void LANGUAGE plpgsql AS $$ diff --git a/files/grest/rpc/01_cached_tables/pool_info_cache.sql b/files/grest/rpc/01_cached_tables/pool_info_cache.sql index 23c89dc1..e7ed2ba1 100644 --- a/files/grest/rpc/01_cached_tables/pool_info_cache.sql +++ b/files/grest/rpc/01_cached_tables/pool_info_cache.sql @@ -63,7 +63,7 @@ BEGIN _pool_status := 'retired'; END IF; - DELETE FROM grest.pool_info_cache WHERE pool_hash_id = _hash_id; + -- not sure why we would want to delete all historic update records: DELETE FROM grest.pool_info_cache WHERE pool_hash_id = _hash_id; INSERT INTO grest.pool_info_cache ( tx_id, diff --git a/files/grest/rpc/02_indexes/13_3_00.sql b/files/grest/rpc/02_indexes/13_3_00.sql index 789ca696..24835024 100644 --- a/files/grest/rpc/02_indexes/13_3_00.sql +++ b/files/grest/rpc/02_indexes/13_3_00.sql @@ -1,4 +1,4 @@ -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 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_reward_rest_addr_id ON reward_rest (addr_id); -CREATE INDEX IF NOT EXISTS idx_reward_rest_spendable_epoch ON reward_rest (spendable_epoch); \ No newline at end of file +CREATE INDEX IF NOT EXISTS idx_reward_rest_spendable_epoch ON reward_rest (spendable_epoch); diff --git a/files/grest/rpc/02_indexes/13_5_0_2.sql b/files/grest/rpc/02_indexes/13_5_0_2.sql index 9e26961a..462c4ba0 100644 --- a/files/grest/rpc/02_indexes/13_5_0_2.sql +++ b/files/grest/rpc/02_indexes/13_5_0_2.sql @@ -1,3 +1,3 @@ DROP INDEX IF EXISTS idx_stake_address_view; CREATE INDEX IF NOT EXISTS idx_stake_address_hash_raw ON stake_address (hash_raw); -CREATE INDEX IF NOT EXISTS idx_drep_hash_raw ON drep_hash (raw); \ No newline at end of file +CREATE INDEX IF NOT EXISTS idx_drep_hash_raw ON drep_hash (raw); diff --git a/files/grest/rpc/02_indexes/13_6_0_1.sql b/files/grest/rpc/02_indexes/13_6_0_1.sql new file mode 100644 index 00000000..483dc939 --- /dev/null +++ b/files/grest/rpc/02_indexes/13_6_0_1.sql @@ -0,0 +1,4 @@ +CREATE INDEX IF NOT EXISTS idx_address_address ON address USING hash (address); +CREATE INDEX IF NOT EXISTS idx_tx_out_stake_address_id ON tx_out(stake_address_id) ; +CREATE INDEX IF NOT EXISTS idx_tx_out_address_id ON tx_out(address_id) ; +CREATE INDEX IF NOT EXISTS idx_address_stake_address_id ON address(stake_address_id) ; diff --git a/files/grest/rpc/account/account_addresses.sql b/files/grest/rpc/account/account_addresses.sql index acffa3cb..62c5b6b4 100644 --- a/files/grest/rpc/account/account_addresses.sql +++ b/files/grest/rpc/account/account_addresses.sql @@ -27,10 +27,11 @@ BEGIN FROM ( SELECT - txo.address, + a.address, txo.stake_address_id, txo.id FROM tx_out AS txo + INNER JOIN address AS a ON a.id = txo.address_id WHERE txo.stake_address_id = ANY(sa_id_list) AND txo.consumed_by_tx_id IS NULL ) AS x @@ -53,10 +54,11 @@ BEGIN FROM ( SELECT - txo.address, + a.address, txo.stake_address_id, txo.id FROM tx_out AS txo + INNER JOIN address AS a ON a.id = txo.address_id WHERE txo.stake_address_id = ANY(sa_id_list) LIMIT (CASE WHEN _first_only IS TRUE THEN 1 ELSE NULL END) ) AS x diff --git a/files/grest/rpc/account/account_info.sql b/files/grest/rpc/account/account_info.sql index 1e4f19b7..0096be7d 100644 --- a/files/grest/rpc/account/account_info.sql +++ b/files/grest/rpc/account/account_info.sql @@ -87,6 +87,11 @@ BEGIN FROM delegation_vote AS dv1 WHERE dv1.addr_id = dv.addr_id AND dv1.id > dv.id) + AND NOT EXISTS ( + SELECT TRUE + FROM stake_deregistration + WHERE stake_deregistration.addr_id = dv.addr_id + AND stake_deregistration.tx_id > dv.tx_id) ) AS vote_t ON vote_t.addr_id = status_t.id LEFT JOIN ( SELECT diff --git a/files/grest/rpc/account/account_rewards.sql b/files/grest/rpc/account/account_rewards.sql index 761edd95..1c4157c0 100644 --- a/files/grest/rpc/account/account_rewards.sql +++ b/files/grest/rpc/account/account_rewards.sql @@ -18,44 +18,47 @@ BEGIN FROM UNNEST(_stake_addresses) AS n ); - IF _epoch_no IS NULL THEN - RETURN QUERY + RETURN QUERY + SELECT + grest.cip5_hex_to_stake_addr(all_rewards.stake_address_raw)::varchar, + JSONB_AGG( + JSONB_BUILD_OBJECT( + 'earned_epoch', all_rewards.earned_epoch, + 'spendable_epoch', all_rewards.spendable_epoch, + 'amount', all_rewards.amount::text, + 'type', all_rewards.type, + 'pool_id', CASE WHEN all_rewards.pool_id_raw IS NULL THEN NULL ELSE b32_encode('pool', all_rewards.pool_id_raw::text) END + ) + ) AS rewards + FROM ( SELECT - grest.cip5_hex_to_stake_addr(sa.hash_raw)::varchar, - JSONB_AGG( - JSONB_BUILD_OBJECT( - 'earned_epoch', r.earned_epoch, - 'spendable_epoch', r.spendable_epoch, - 'amount', r.amount::text, - 'type', r.type, - 'pool_id', b32_encode('pool', ph.hash_raw::text) - ) - ) AS rewards + sa.hash_raw as stake_address_raw, + r.type, + r.amount, + r.earned_epoch, + r.spendable_epoch, + ph.hash_raw as pool_id_raw FROM reward AS r - LEFT JOIN pool_hash AS ph ON r.pool_id = ph.id + INNER JOIN pool_hash AS ph ON r.pool_id = ph.id INNER JOIN stake_address AS sa ON sa.id = r.addr_id WHERE r.addr_id = ANY(sa_id_list) - GROUP BY sa.hash_raw; - ELSE - RETURN QUERY + AND CASE WHEN _epoch_no IS NULL THEN TRUE ELSE r.earned_epoch = _epoch_no END + -- + UNION ALL + -- SELECT - grest.cip5_hex_to_stake_addr(sa.hash_raw)::varchar, - JSONB_AGG( - JSONB_BUILD_OBJECT( - 'earned_epoch', r.earned_epoch, - 'spendable_epoch', r.spendable_epoch, - 'amount', r.amount::text, - 'type', r.type, - 'pool_id', b32_encode('pool', ph.hash_raw::text) - ) - ) AS rewards - FROM reward AS r - LEFT JOIN pool_hash AS ph ON r.pool_id = ph.id - INNER JOIN stake_address AS sa ON sa.id = r.addr_id - WHERE r.addr_id = ANY(sa_id_list) - AND r.earned_epoch = _epoch_no - GROUP BY sa.hash_raw; - END IF; + sa.hash_raw as stake_address_raw, + rr.type, + rr.amount, + rr.earned_epoch, + rr.spendable_epoch, + null as pool_id_raw + FROM reward_rest AS rr + INNER JOIN stake_address AS sa ON sa.id = rr.addr_id + WHERE rr.addr_id = ANY(sa_id_list) + AND CASE WHEN _epoch_no IS NULL THEN TRUE ELSE rr.earned_epoch = _epoch_no END + ) as all_rewards + GROUP BY all_rewards.stake_address_raw; END; $$; diff --git a/files/grest/rpc/account/account_utxos.sql b/files/grest/rpc/account/account_utxos.sql index e86f39f0..4beefcf3 100644 --- a/files/grest/rpc/account/account_utxos.sql +++ b/files/grest/rpc/account/account_utxos.sql @@ -54,10 +54,10 @@ BEGIN SELECT ENCODE(tx.hash, 'hex')::text AS tx_hash, tx_out.index::smallint, - tx_out.address::text, + a.address::text, tx_out.value::text, grest.cip5_hex_to_stake_addr(sa.hash_raw) as stake_address, - ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + ENCODE(a.payment_cred, 'hex') AS payment_cred, b.epoch_no, b.block_no, EXTRACT(EPOCH FROM b.time)::integer AS block_time, @@ -89,6 +89,7 @@ BEGIN END) AS is_spent FROM tx_out INNER JOIN tx ON tx_out.tx_id = tx.id + INNER JOIN address AS a ON a.id = tx_out.address_id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN block AS b ON b.id = tx.block_id LEFT JOIN datum ON datum.id = tx_out.inline_datum_id diff --git a/files/grest/rpc/address/address_assets.sql b/files/grest/rpc/address/address_assets.sql index fe990662..2e443c75 100644 --- a/files/grest/rpc/address/address_assets.sql +++ b/files/grest/rpc/address/address_assets.sql @@ -14,7 +14,7 @@ BEGIN WITH _all_assets AS ( SELECT - txo.address, + a.address, ma.policy, ma.name, ma.fingerprint, @@ -24,10 +24,11 @@ BEGIN INNER JOIN multi_asset AS ma ON ma.id = mtx.ident LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id INNER JOIN tx_out AS txo ON txo.id = mtx.tx_out_id - WHERE txo.address = ANY(_addresses) + INNER JOIN address AS a ON a.id = txo.address_id + WHERE a.address = ANY(_addresses) AND txo.consumed_by_tx_id IS NULL GROUP BY - txo.address, ma.policy, ma.name, ma.fingerprint, aic.decimals + a.address, ma.policy, ma.name, ma.fingerprint, aic.decimals ) SELECT diff --git a/files/grest/rpc/address/address_info.sql b/files/grest/rpc/address/address_info.sql index c5c9bb2f..84057380 100644 --- a/files/grest/rpc/address/address_info.sql +++ b/files/grest/rpc/address/address_info.sql @@ -13,12 +13,13 @@ DECLARE BEGIN CREATE TEMPORARY TABLE _known_addresses AS SELECT - DISTINCT ON (tx_out.address) tx_out.address, + DISTINCT ON (tx_out.address_id) a.address, sa.hash_raw AS stake_address_raw, - COALESCE(tx_out.address_has_script, 'false') AS script_address + COALESCE(a.has_script, 'false') AS script_address FROM tx_out + INNER JOIN address AS a ON a.id = tx_out.address_id LEFT JOIN stake_address AS sa ON sa.id = tx_out.stake_address_id - WHERE tx_out.address = ANY(_addresses); + WHERE a.address = ANY(_addresses); RETURN QUERY WITH _all_utxos AS ( @@ -26,7 +27,7 @@ BEGIN tx.id, tx.hash, tx_out.id AS txo_id, - tx_out.address, + a.address, tx_out.value, tx_out.index, tx.block_id, @@ -34,9 +35,10 @@ BEGIN tx_out.inline_datum_id, tx_out.reference_script_id FROM tx_out + INNER JOIN address AS a ON a.id = tx_out.address_id INNER JOIN tx ON tx.id = tx_out.tx_id WHERE tx_out.consumed_by_tx_id IS NULL - AND tx_out.address = ANY(_addresses) + AND a.address = ANY(_addresses) ) SELECT diff --git a/files/grest/rpc/address/address_txs.sql b/files/grest/rpc/address/address_txs.sql index c8ccb464..6efb4f5d 100644 --- a/files/grest/rpc/address/address_txs.sql +++ b/files/grest/rpc/address/address_txs.sql @@ -21,15 +21,17 @@ BEGIN FROM ( SELECT tx_id FROM tx_out - WHERE address = ANY (_addresses) + INNER JOIN address AS a on a.id = tx_out.address_id + WHERE a.address = ANY (_addresses) AND tx_id >= _tx_id_min -- UNION -- SELECT consumed_by_tx_id FROM tx_out + INNER JOIN address AS a ON a.id = tx_out.address_id WHERE tx_out.consumed_by_tx_id IS NOT NULL - AND tx_out.address = ANY(_addresses) + AND a.address = ANY(_addresses) AND tx_out.consumed_by_tx_id >= _tx_id_min ) AS tmp; diff --git a/files/grest/rpc/address/address_utxos.sql b/files/grest/rpc/address/address_utxos.sql index 5cbc4363..d281f91f 100644 --- a/files/grest/rpc/address/address_utxos.sql +++ b/files/grest/rpc/address/address_utxos.sql @@ -35,20 +35,21 @@ BEGIN ) END) as assets FROM tx_out AS txo + INNER JOIN address AS a ON a.id = txo.address_id INNER JOIN ma_tx_out AS mto ON mto.tx_out_id = txo.id LEFT JOIN multi_asset AS ma ON ma.id = mto.ident LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id - WHERE txo.address = ANY(_addresses) + WHERE a.address = ANY(_addresses) AND txo.consumed_by_tx_id IS NULL GROUP BY txo.id ) SELECT ENCODE(tx.hash, 'hex')::text AS tx_hash, tx_out.index::smallint, - tx_out.address::text, + a.address::text, tx_out.value::text, grest.cip5_hex_to_stake_addr(sa.hash_raw)::text as stake_address, - ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + ENCODE(a.payment_cred, 'hex') AS payment_cred, b.epoch_no, b.block_no, EXTRACT(EPOCH FROM b.time)::integer AS block_time, @@ -79,13 +80,14 @@ BEGIN ELSE true END) AS is_spent FROM tx_out + INNER JOIN address AS a ON a.id = tx_out.address_id INNER JOIN tx ON tx_out.tx_id = tx.id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN block AS b ON b.id = tx.block_id LEFT JOIN datum ON datum.id = tx_out.inline_datum_id LEFT JOIN script ON script.id = tx_out.reference_script_id LEFT JOIN _assets ON tx_out.id = _assets.id - WHERE tx_out.address = ANY(_addresses) + WHERE a.address = ANY(_addresses) AND tx_out.consumed_by_tx_id IS NULL ; END; diff --git a/files/grest/rpc/address/credential_txs.sql b/files/grest/rpc/address/credential_txs.sql index ee50321c..bc534e9a 100644 --- a/files/grest/rpc/address/credential_txs.sql +++ b/files/grest/rpc/address/credential_txs.sql @@ -29,15 +29,17 @@ BEGIN FROM ( SELECT tx_id FROM tx_out - WHERE payment_cred = ANY(_payment_cred_bytea) + INNER JOIN address AS a ON tx_out.address_id = a.id + WHERE a.payment_cred = ANY(_payment_cred_bytea) AND tx_id >= _tx_id_min -- UNION -- SELECT consumed_by_tx_id AS tx_id FROM tx_out + INNER JOIN address AS a ON tx_out.address_id = a.id WHERE tx_out.consumed_by_tx_id IS NOT NULL - AND tx_out.payment_cred = ANY(_payment_cred_bytea) + AND a.payment_cred = ANY(_payment_cred_bytea) AND tx_out.consumed_by_tx_id >= _tx_id_min ) AS tmp; diff --git a/files/grest/rpc/address/credential_utxos.sql b/files/grest/rpc/address/credential_utxos.sql index 57bfe179..0495f132 100644 --- a/files/grest/rpc/address/credential_utxos.sql +++ b/files/grest/rpc/address/credential_utxos.sql @@ -41,20 +41,21 @@ BEGIN ) END) as assets FROM tx_out AS txo + INNER JOIN address AS a ON a.id = txo.address_id INNER JOIN ma_tx_out AS mto ON mto.tx_out_id = txo.id LEFT JOIN multi_asset AS ma ON ma.id = mto.ident LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id - WHERE txo.payment_cred = ANY(_payment_cred_bytea) + WHERE a.payment_cred = ANY(_payment_cred_bytea) AND txo.consumed_by_tx_id IS NULL GROUP BY txo.id ) SELECT ENCODE(tx.hash, 'hex')::text AS tx_hash, tx_out.index::smallint, - tx_out.address::text, + a.address::text, tx_out.value::text, grest.cip5_hex_to_stake_addr(sa.hash_raw)::text as stake_address, - ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + ENCODE(a.payment_cred, 'hex') AS payment_cred, b.epoch_no, b.block_no, EXTRACT(EPOCH FROM b.time)::integer AS block_time, @@ -85,13 +86,14 @@ BEGIN ELSE true END) AS is_spent FROM tx_out + INNER JOIN address AS a ON a.id = tx_out.address_id INNER JOIN tx ON tx_out.tx_id = tx.id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN block AS b ON b.id = tx.block_id LEFT JOIN datum ON datum.id = tx_out.inline_datum_id LEFT JOIN script ON script.id = tx_out.reference_script_id LEFT JOIN _assets ON tx_out.id = _assets.id - WHERE tx_out.payment_cred = ANY(_payment_cred_bytea) + WHERE a.payment_cred = ANY(_payment_cred_bytea) AND tx_out.consumed_by_tx_id IS NULL ; END; diff --git a/files/grest/rpc/assets/asset_addresses.sql b/files/grest/rpc/assets/asset_addresses.sql index 466bdc48..2cfdb63f 100644 --- a/files/grest/rpc/assets/asset_addresses.sql +++ b/files/grest/rpc/assets/asset_addresses.sql @@ -33,11 +33,12 @@ BEGIN FROM ( SELECT - txo.address, + a.address, sa.hash_raw AS stake_address_raw, atoc.quantity FROM grest.asset_tx_out_cache AS atoc LEFT JOIN tx_out AS txo ON atoc.txo_id = txo.id + INNER JOIN address AS a ON a.id = txo.address_id LEFT JOIN stake_address AS sa ON txo.stake_address_id = sa.id WHERE atoc.ma_id = _asset_id AND txo.consumed_by_tx_id IS NULL @@ -52,11 +53,12 @@ BEGIN FROM ( SELECT - txo.address, + a.address, sa.hash_raw AS stake_address_raw, mto.quantity FROM ma_tx_out AS mto LEFT JOIN tx_out AS txo ON txo.id = mto.tx_out_id + INNER JOIN address AS a ON a.id = txo.address_id LEFT JOIN stake_address AS sa ON txo.stake_address_id = sa.id WHERE mto.ident = _asset_id AND txo.consumed_by_tx_id IS NULL diff --git a/files/grest/rpc/assets/asset_nft_address.sql b/files/grest/rpc/assets/asset_nft_address.sql index 2c5ca3f5..b812af16 100644 --- a/files/grest/rpc/assets/asset_nft_address.sql +++ b/files/grest/rpc/assets/asset_nft_address.sql @@ -27,9 +27,10 @@ BEGIN IF EXISTS (SELECT * FROM ma_tx_mint WHERE ident = _asset_id and quantity < 0 LIMIT 1) THEN RETURN QUERY SELECT - txo.address, + a.address, grest.cip5_hex_to_stake_addr(sa.hash_raw)::varchar AS stake_address FROM tx_out AS txo + INNER JOIN address AS a ON a.id = txo.address_id LEFT JOIN stake_address AS sa ON txo.stake_address_id = sa.id WHERE txo.id = ( SELECT MAX(tx_out_id) @@ -39,9 +40,10 @@ BEGIN ELSE RETURN QUERY SELECT - txo.address, + a.address, grest.cip5_hex_to_stake_addr(sa.hash_raw)::varchar AS stake_address FROM tx_out AS txo + INNER JOIN address AS a ON a.id = txo.address_id INNER JOIN ma_tx_out mto ON mto.tx_out_id = txo.id LEFT JOIN stake_address AS sa ON txo.stake_address_id = sa.id WHERE mto.ident = _asset_id diff --git a/files/grest/rpc/assets/asset_summary.sql b/files/grest/rpc/assets/asset_summary.sql index 4c77e222..39cd8231 100644 --- a/files/grest/rpc/assets/asset_summary.sql +++ b/files/grest/rpc/assets/asset_summary.sql @@ -32,10 +32,11 @@ BEGIN txo.tx_id AS tx_id, txo.id AS tx_out_id, txo.index AS tx_out_idx, - txo.address AS address, + a.address AS address, txo.stake_address_id AS sa_id FROM ma_tx_out AS mto INNER JOIN tx_out AS txo ON txo.id = mto.tx_out_id + INNER JOIN address AS a ON a.id = txo.address_id WHERE mto.ident = _asset_id AND txo.consumed_by_tx_id IS NULL) diff --git a/files/grest/rpc/assets/asset_utxos.sql b/files/grest/rpc/assets/asset_utxos.sql index 25d5df08..f957f0a2 100644 --- a/files/grest/rpc/assets/asset_utxos.sql +++ b/files/grest/rpc/assets/asset_utxos.sql @@ -64,10 +64,10 @@ BEGIN SELECT ENCODE(tx.hash, 'hex')::text AS tx_hash, tx_out.index::smallint, - tx_out.address::text, + a.address::text, tx_out.value::text, grest.cip5_hex_to_stake_addr(sa.hash_raw)::text as stake_address, - ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + ENCODE(a.payment_cred, 'hex') AS payment_cred, b.epoch_no, b.block_no, EXTRACT(EPOCH FROM b.time)::integer AS block_time, @@ -99,6 +99,7 @@ BEGIN END) AS is_spent FROM tx_out INNER JOIN tx ON tx_out.tx_id = tx.id + INNER JOIN address AS a ON a.id = tx_out.address_id INNER JOIN _assets ON tx_out.id = _assets.id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN block AS b ON b.id = tx.block_id diff --git a/files/grest/rpc/assets/policy_asset_addresses.sql b/files/grest/rpc/assets/policy_asset_addresses.sql index 6dc0f3ab..09bff22e 100644 --- a/files/grest/rpc/assets/policy_asset_addresses.sql +++ b/files/grest/rpc/assets/policy_asset_addresses.sql @@ -27,12 +27,13 @@ BEGIN ( SELECT atoc.ma_id, - txo.address, + a.address, grest.cip5_hex_to_stake_addr(sa.hash_raw)::varchar AS stake_address, atoc.quantity FROM grest.asset_tx_out_cache AS atoc LEFT JOIN multi_asset AS ma ON ma.id = atoc.ma_id LEFT JOIN tx_out AS txo ON txo.id = atoc.txo_id + INNER JOIN address AS a ON a.id = txo.address_id LEFT JOIN stake_address AS sa ON txo.stake_address_id = sa.id WHERE ma.policy = DECODE(_asset_policy, 'hex') AND txo.consumed_by_tx_id IS NULL @@ -46,18 +47,19 @@ BEGIN RETURN QUERY SELECT ENCODE(ma.name, 'hex') AS asset_name, - txo.address, + a.address, grest.cip5_hex_to_stake_addr(sa.hash_raw)::varchar AS stake_address, SUM(mto.quantity)::text FROM multi_asset AS ma LEFT JOIN ma_tx_out AS mto ON mto.ident = ma.id LEFT JOIN tx_out AS txo ON txo.id = mto.tx_out_id + INNER JOIN address AS a ON a.id = txo.address_id LEFT JOIN stake_address AS sa ON txo.stake_address_id = sa.id WHERE ma.policy = DECODE(_asset_policy, 'hex') AND txo.consumed_by_tx_id IS NULL GROUP BY ma.name, - txo.address, + a.address, sa.hash_raw; END IF; END; diff --git a/files/grest/rpc/governance/proposal_voting_summary.sql b/files/grest/rpc/governance/proposal_voting_summary.sql index 713493e2..a7beee6c 100644 --- a/files/grest/rpc/governance/proposal_voting_summary.sql +++ b/files/grest/rpc/governance/proposal_voting_summary.sql @@ -1,4 +1,3 @@ - CREATE OR REPLACE FUNCTION grest.proposal_voting_summary(_proposal_id text) RETURNS TABLE ( proposal_type text, @@ -10,6 +9,7 @@ RETURNS TABLE ( drep_no_vote_power lovelace, drep_no_pct numeric, drep_abstain_votes_cast integer, + drep_always_no_confidence_vote_power lovelace, pool_yes_votes_cast integer, pool_yes_vote_power lovelace, pool_yes_pct numeric, @@ -17,6 +17,10 @@ RETURNS TABLE ( pool_no_vote_power lovelace, pool_no_pct numeric, pool_abstain_votes_cast integer, + pool_passive_always_abstain_votes_assigned integer, + pool_passive_always_abstain_vote_power lovelace, + pool_passive_always_no_confidence_votes_assigned integer, + pool_passive_always_no_confidence_vote_power lovelace, committee_yes_votes_cast integer, committee_yes_pct numeric, committee_no_votes_cast integer, @@ -110,9 +114,6 @@ BEGIN SUM(voting_power) AS tot_pool_power FROM proposal_epoch_data AS ped INNER JOIN pool_stat ON pool_stat.epoch_no = ped.epoch_of_interest - -- if hard fork initiation, then need to use full SPO voting power otherwise just voted SPO power - WHERE ((ped.proposal_type = 'HardForkInitiation') or EXISTS (SELECT 1 FROM latest_votes vp where vp.voter_role = 'SPO' - AND vp.gov_action_proposal_id = ped.gov_action_proposal_id AND vp.pool_voter = pool_stat.pool_hash_id)) GROUP BY ped.gov_action_proposal_id, pool_stat.epoch_no ), active_prop_pool_votes AS ( @@ -126,6 +127,46 @@ BEGIN INNER JOIN pool_stat ON vp.pool_voter = pool_stat.pool_hash_id AND pool_stat.epoch_no = ped.epoch_of_interest GROUP BY ped.gov_action_proposal_id, vote ), + -- below snippet is cut down version of pool_info endpoint sql, not sure how easy it was to re-use? + _all_non_voted_pool_info AS ( + SELECT DISTINCT ON (pic.pool_hash_id) + pic.pool_hash_id, + pic.update_id, + b32_encode('pool', ph.hash_raw::text) AS pool_id_bech32, + ph.hash_raw + FROM grest.pool_info_cache AS pic + INNER JOIN proposal_epoch_data ped ON true + INNER JOIN public.pool_hash AS ph ON ph.id = pic.pool_hash_id + INNER JOIN pool_update AS pu ON pu.id = pic.update_id AND pu.active_epoch_no <= ped.epoch_of_interest + -- exclude all pools that voted for this proposal + WHERE NOT EXISTS (SELECT NULL FROM proposal_epoch_data ped INNER JOIN + latest_votes AS VP ON vp.voter_role = 'SPO' AND vp.gov_action_proposal_id = ped.gov_action_proposal_id + AND vp.pool_voter = pic.pool_hash_id) + ORDER BY + pic.pool_hash_id, + pic.tx_id DESC + ), + passive_prop_pool_votes AS ( + SELECT + ped.gov_action_proposal_id, + (case when dh.view = 'drep_always_abstain' then 'Abstain' else 'No' end) as vote, -- else = drep_always_no_confidence currently + sum(pstat.voting_power) passive_pool_vote_total, + count(*) AS pool_votes_cast + FROM _all_non_voted_pool_info AS api + INNER JOIN proposal_epoch_data AS ped ON true + INNER JOIN public.pool_update AS pu ON pu.id = api.update_id + INNER JOIN public.stake_address AS sa ON pu.reward_addr_id = sa.id + INNER JOIN delegation_vote AS dv on dv.addr_id = sa.id + AND dv.tx_id = (SELECT max(tx_id) FROM delegation_vote dv2 WHERE dv2.addr_id = sa.id + AND tx_id <= + (SELECT COALESCE(t.id, (SELECT id FROM tx t2 ORDER BY id DESC LIMIT 1)) FROM tx t INNER JOIN block b + ON t.block_id = b.id AND b.epoch_no = ped.epoch_of_interest ORDER BY t.id DESC LIMIT 1)) + INNER JOIN drep_hash AS dh on dh.id = dv.drep_hash_id + and dh.view like 'drep_always%' + INNER JOIN pool_stat AS pstat ON api.pool_hash_id = pstat.pool_hash_id + and pstat.epoch_no = ped.epoch_of_interest + GROUP BY ped.gov_action_proposal_id, dh.view + ), committee_votes AS ( SELECT ped.gov_action_proposal_id, @@ -168,22 +209,47 @@ BEGIN y.proposal_type::text AS proposal_type, y.epoch_of_interest AS epoch_no, y.drep_yes_votes_cast::integer, - y.drep_yes_vote_power::lovelace, - ROUND(y.drep_yes_vote_power * 100 / y.drep_non_abstain_total, 2) AS drep_yes_pct, + (CASE + WHEN y.proposal_type IN ('NoConfidence') THEN y.drep_yes_vote_power + y.drep_no_confidence_vote_power + ELSE y.drep_yes_vote_power + END)::lovelace AS drep_yes_vote_power, + (CASE + WHEN y.proposal_type IN ('NoConfidence') THEN ROUND((y.drep_yes_vote_power + drep_no_confidence_vote_power) * 100 / y.drep_non_abstain_total, 2) + ELSE ROUND(y.drep_yes_vote_power * 100 / y.drep_non_abstain_total, 2) + END) AS drep_yes_pct, + y.drep_no_votes_cast::integer, - (y.drep_non_abstain_total - y.drep_yes_vote_power)::lovelace AS drep_no_vote_power, - ROUND((y.drep_non_abstain_total - y.drep_yes_vote_power) * 100 / y.drep_non_abstain_total, 2) AS drep_no_pct, - (SELECT COALESCE(SUM(active_drep_votes_cast), 0)::integer FROM active_prop_drep_votes WHERE vote = 'Abstain') AS drep_abstain_votes_cast, + + (CASE + WHEN y.proposal_type IN ('NoConfidence') THEN (y.drep_non_abstain_total - y.drep_yes_vote_power - y.drep_no_confidence_vote_power) + ELSE (y.drep_non_abstain_total - y.drep_yes_vote_power) + END)::lovelace AS drep_no_vote_power, + + (CASE + WHEN y.proposal_type IN ('NoConfidence') THEN ROUND((y.drep_non_abstain_total - y.drep_yes_vote_power - y.drep_no_confidence_vote_power) * 100 / y.drep_non_abstain_total, 2) + ELSE ROUND((y.drep_non_abstain_total - y.drep_yes_vote_power) * 100 / y.drep_non_abstain_total, 2) + END) AS drep_no_pct, + + (SELECT COALESCE(SUM(active_drep_votes_cast), 0)::integer + FROM active_prop_drep_votes WHERE vote = 'Abstain') + AS drep_abstain_votes_cast, + + y.drep_no_confidence_vote_power::lovelace AS drep_always_no_confidence_vote_power, + (CASE WHEN y.proposal_type IN ('ParameterChange', 'TreasuryWithdrawals', 'NewConstitution') THEN 0 ELSE y.pool_yes_votes_cast END)::integer AS pool_yes_votes_cast, + (CASE WHEN y.proposal_type IN ('ParameterChange', 'TreasuryWithdrawals', 'NewConstitution') THEN 0 + WHEN y.proposal_type IN ('NoConfidence') THEN y.pool_yes_vote_power + y.pool_passive_always_no_confidence_vote_power ELSE y.pool_yes_vote_power END)::lovelace AS pool_yes_vote_power, + (CASE WHEN y.proposal_type IN ('ParameterChange', 'TreasuryWithdrawals', 'NewConstitution') THEN 0 + WHEN y.proposal_type IN ('NoConfidence') THEN ROUND((y.pool_yes_vote_power + y.pool_passive_always_no_confidence_vote_power) * 100 / y.pool_non_abstain_total, 2) ELSE ROUND(y.pool_yes_vote_power * 100 / y.pool_non_abstain_total, 2) END) AS pool_yes_pct, (CASE @@ -192,13 +258,19 @@ BEGIN END)::integer AS pool_no_votes_cast, (CASE WHEN y.proposal_type IN ('ParameterChange', 'TreasuryWithdrawals', 'NewConstitution') THEN 0 + WHEN y.proposal_type IN ('NoConfidence') THEN (y.pool_non_abstain_total - y.pool_yes_vote_power - y.pool_passive_always_no_confidence_vote_power) ELSE (y.pool_non_abstain_total - y.pool_yes_vote_power) END)::lovelace AS pool_no_vote_power, (CASE WHEN y.proposal_type IN ('ParameterChange', 'TreasuryWithdrawals', 'NewConstitution') THEN 0 + WHEN y.proposal_type IN ('NoConfidence') THEN ROUND((y.pool_non_abstain_total - y.pool_yes_vote_power - y.pool_passive_always_no_confidence_vote_power) * 100 / y.pool_non_abstain_total, 2) ELSE ROUND((y.pool_non_abstain_total - y.pool_yes_vote_power) * 100 / y.pool_non_abstain_total, 2) END) AS pool_no_pct, (SELECT COALESCE(SUM(pool_votes_cast), 0)::integer FROM active_prop_pool_votes WHERE vote = 'Abstain') AS pool_abstain_votes_cast, + y.pool_passive_always_abstain_votes_assigned::integer, + y.pool_passive_always_abstain_vote_power::lovelace, + y.pool_passive_always_no_confidence_votes_assigned::integer, + y.pool_passive_always_no_confidence_vote_power::lovelace, y.committee_yes_votes_cast::integer, (CASE WHEN y.proposal_type IN ('NoConfidence', 'NewCommittee') THEN 0 @@ -237,6 +309,9 @@ BEGIN FROM active_prop_drep_votes AS c2 WHERE c2.gov_action_proposal_id = c1.gov_action_proposal_id AND c2.vote = 'No' ) + always_no_conf AS drep_no_vote_power, + + always_no_conf AS drep_no_confidence_vote_power, + ( SELECT coalesce(SUM(active_drep_vote_total),0) FROM active_prop_drep_votes AS c2 @@ -256,7 +331,34 @@ BEGIN SELECT coalesce(SUM(active_pool_vote_total), 0) FROM active_prop_pool_votes c3 WHERE c3.gov_action_proposal_id = c1.gov_action_proposal_id AND c3.vote = 'Abstain' - ) AS pool_non_abstain_total, + ) + + - ( SELECT COALESCE(SUM(passive_pool_vote_total), 0) + FROM passive_prop_pool_votes p3 + WHERE p3.gov_action_proposal_id = c1.gov_action_proposal_id AND p3.vote = 'Abstain') + + AS pool_non_abstain_total, + + ( SELECT COALESCE(SUM(passive_pool_vote_total), 0) + FROM passive_prop_pool_votes p3 + WHERE p3.gov_action_proposal_id = c1.gov_action_proposal_id AND p3.vote = 'Abstain') + AS pool_passive_always_abstain_vote_power, + + ( SELECT COALESCE(SUM(pool_votes_cast), 0) + FROM passive_prop_pool_votes p3 + WHERE p3.gov_action_proposal_id = c1.gov_action_proposal_id AND p3.vote = 'Abstain') + AS pool_passive_always_abstain_votes_assigned, + + ( SELECT COALESCE(SUM(passive_pool_vote_total), 0) + FROM passive_prop_pool_votes p3 + WHERE p3.gov_action_proposal_id = c1.gov_action_proposal_id AND p3.vote = 'No') + AS pool_passive_always_no_confidence_vote_power, + + ( SELECT COALESCE(SUM(pool_votes_cast), 0) + FROM passive_prop_pool_votes p3 + WHERE p3.gov_action_proposal_id = c1.gov_action_proposal_id AND p3.vote = 'No') + AS pool_passive_always_no_confidence_votes_assigned, + ( SELECT coalesce(SUM(pool_votes_cast), 0) FROM active_prop_pool_votes AS c2 @@ -289,4 +391,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.proposal_votes IS 'Get a summary of votes cast on specified governance action'; -- noqa: LT01 +COMMENT ON FUNCTION grest.proposal_voting_summary IS 'Get a summary of votes cast on specified governance action'; -- noqa: LT01 diff --git a/files/grest/rpc/pool/pool_info.sql b/files/grest/rpc/pool/pool_info.sql index 7f6ba7e3..4eadb5e5 100644 --- a/files/grest/rpc/pool/pool_info.sql +++ b/files/grest/rpc/pool/pool_info.sql @@ -9,6 +9,7 @@ RETURNS TABLE ( pledge text, deposit text, reward_addr varchar, + reward_addr_delegated_drep text, owners varchar [], relays jsonb [], meta_url varchar, @@ -24,7 +25,8 @@ RETURNS TABLE ( live_pledge text, live_stake text, live_delegators bigint, - live_saturation numeric + live_saturation numeric, + voting_power text ) LANGUAGE plpgsql AS $$ @@ -53,6 +55,10 @@ BEGIN ph.hash_raw FROM grest.pool_info_cache AS pic INNER JOIN public.pool_hash AS ph ON ph.id = pic.pool_hash_id + -- consider only activated updates or all updates if none were activated so far + AND ( (pic.active_epoch_no <= _epoch_no) + OR ( NOT EXISTS (SELECT 1 from grest.pool_info_cache AS pic2 where pic2.pool_hash_id = pic.pool_hash_id + AND pic2.active_epoch_no <= _epoch_no) ) ) WHERE ph.hash_raw = ANY( SELECT DECODE(b32_decode(p),'hex') FROM UNNEST(_pool_bech32_ids) AS p) @@ -70,6 +76,7 @@ BEGIN pu.pledge::text, pu.deposit::text, grest.cip5_hex_to_stake_addr(sa.hash_raw)::varchar AS reward_addr, + COALESCE(grest.cip129_hex_to_drep_id(dh.raw, dh.has_script), dh.view::text) AS reward_addr_delegated_drep, ARRAY( SELECT grest.cip5_hex_to_stake_addr(sa.hash_raw)::varchar FROM public.pool_owner AS po @@ -100,13 +107,19 @@ BEGIN live.pledge::text, live.stake::text, live.delegators, - ROUND((live.stake / _saturation_limit) * 100, 2) + ROUND((live.stake / _saturation_limit) * 100, 2), + pst.voting_power::text FROM _all_pool_info AS api LEFT JOIN public.pool_hash AS ph ON ph.id = api.pool_hash_id LEFT JOIN public.pool_update AS pu ON pu.id = api.update_id LEFT JOIN public.stake_address AS sa ON pu.reward_addr_id = sa.id + LEFT JOIN delegation_vote AS dv on dv.addr_id = sa.id + AND NOT EXISTS (SELECT 1 FROM delegation_vote dv2 WHERE dv2.addr_id = sa.id AND dv2.tx_id > dv.tx_id) + LEFT JOIN drep_hash AS dh ON dh.id = dv.drep_hash_id + -- could add this condition too since delegations elsewhere are meaningless: and dh.view like 'drep_always%' LEFT JOIN public.pool_metadata_ref AS pmr ON pmr.id = api.meta_id LEFT JOIN public.off_chain_pool_data AS ocpd ON api.meta_id = ocpd.pmr_id + LEFT JOIN public.pool_stat AS pst ON pst.pool_hash_id = api.pool_hash_id AND pst.epoch_no = _epoch_no LEFT JOIN LATERAL ( SELECT SUM(COUNT(b.id)) OVER () AS cnt, diff --git a/files/grest/rpc/script/script_utxos.sql b/files/grest/rpc/script/script_utxos.sql index d5120bb3..e6076c44 100644 --- a/files/grest/rpc/script/script_utxos.sql +++ b/files/grest/rpc/script/script_utxos.sql @@ -46,10 +46,10 @@ BEGIN SELECT ENCODE(tx.hash, 'hex')::text AS tx_hash, tx_out.index::smallint, - tx_out.address::text, + a.address::text, tx_out.value::text, grest.cip5_hex_to_stake_addr(sa.hash_raw) as stake_address, - ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + ENCODE(a.payment_cred, 'hex') AS payment_cred, b.epoch_no, b.block_no, EXTRACT(EPOCH FROM b.time)::integer AS block_time, @@ -81,6 +81,7 @@ BEGIN END) AS is_spent FROM tx_out INNER JOIN tx ON tx_out.tx_id = tx.id + INNER JOIN address AS a ON a.id = tx_out.address_id INNER JOIN script ON script.tx_id = tx.id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN datum ON datum.id = tx_out.inline_datum_id diff --git a/files/grest/rpc/transactions/tx_cbor.sql b/files/grest/rpc/transactions/tx_cbor.sql index 33f86e9d..932ace53 100644 --- a/files/grest/rpc/transactions/tx_cbor.sql +++ b/files/grest/rpc/transactions/tx_cbor.sql @@ -1,14 +1,25 @@ CREATE OR REPLACE FUNCTION grest.tx_cbor(_tx_hashes text []) RETURNS TABLE ( tx_hash text, + block_hash text, + block_height word31type, + epoch_no word31type, + absolute_slot word63type, + tx_timestamp integer, cbor text ) LANGUAGE sql STABLE AS $$ SELECT - ENCODE(tx.hash::bytea, 'hex') AS tx_hash, - ENCODE(tx_cbor.bytes::bytea, 'hex') AS tx_cbor + ENCODE(tx.hash::bytea, 'hex'), + ENCODE(block.hash, 'hex'), + block.block_no, + block.epoch_no, + block.slot_no, + EXTRACT(EPOCH FROM block.time)::integer, + ENCODE(tx_cbor.bytes::bytea, 'hex') FROM public.tx + INNER JOIN block ON block.id = tx.block_id LEFT JOIN public.tx_cbor ON tx.id = tx_cbor.tx_id WHERE tx.hash::bytea = ANY( SELECT diff --git a/files/grest/rpc/transactions/tx_info.sql b/files/grest/rpc/transactions/tx_info.sql index 7b5707f7..f27244b4 100644 --- a/files/grest/rpc/transactions/tx_info.sql +++ b/files/grest/rpc/transactions/tx_info.sql @@ -88,8 +88,8 @@ BEGIN _all_collateral_inputs AS ( SELECT collateral_tx_in.tx_in_id AS tx_id, - tx_out.address AS payment_addr_bech32, - ENCODE(tx_out.payment_cred, 'hex') AS payment_addr_cred, + a.address AS payment_addr_bech32, + ENCODE(a.payment_cred, 'hex') AS payment_addr_cred, grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_addr, ENCODE(tx.hash, 'hex') AS tx_hash, tx_out.index AS tx_index, @@ -109,7 +109,7 @@ BEGIN (CASE WHEN tx_out.inline_datum_id IS NULL THEN NULL ELSE JSONB_BUILD_OBJECT( - 'bytes', ENCODE(datum.bytes, 'hex'), + 'bytes', CASE WHEN _bytecode IS TRUE THEN ENCODE(datum.bytes, 'hex') ELSE NULL END, 'value', datum.value ) END @@ -118,7 +118,7 @@ BEGIN ELSE JSONB_BUILD_OBJECT( 'hash', ENCODE(script.hash, 'hex'), - 'bytes', ENCODE(script.bytes, 'hex'), + 'bytes', CASE WHEN _bytecode IS TRUE THEN ENCODE(script.bytes, 'hex') ELSE NULL END, 'value', script.json, 'type', script.type::text, 'size', script.serialised_size @@ -129,6 +129,7 @@ BEGIN INNER JOIN tx_out ON tx_out.tx_id = collateral_tx_in.tx_out_id AND tx_out.index = collateral_tx_in.tx_out_index INNER JOIN tx ON tx_out.tx_id = tx.id + INNER JOIN address AS a ON a.id = tx_out.address_id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN ma_tx_out AS mto ON _assets IS TRUE AND mto.tx_out_id = tx_out.id LEFT JOIN multi_asset AS ma ON _assets IS TRUE AND ma.id = mto.ident @@ -136,15 +137,15 @@ BEGIN LEFT JOIN datum ON _scripts IS TRUE AND datum.id = tx_out.inline_datum_id LEFT JOIN script ON _scripts IS TRUE AND script.id = tx_out.reference_script_id WHERE - (_inputs IS TRUE AND _scripts IS TRUE) + (_inputs IS TRUE) AND collateral_tx_in.tx_in_id = ANY(_tx_id_list) ), _all_reference_inputs AS ( SELECT reference_tx_in.tx_in_id AS tx_id, - tx_out.address AS payment_addr_bech32, - ENCODE(tx_out.payment_cred, 'hex') AS payment_addr_cred, + a.address AS payment_addr_bech32, + ENCODE(a.payment_cred, 'hex') AS payment_addr_cred, grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_addr, ENCODE(tx.hash, 'hex') AS tx_hash, tx_out.index AS tx_index, @@ -164,7 +165,7 @@ BEGIN (CASE WHEN tx_out.inline_datum_id IS NULL THEN NULL ELSE JSONB_BUILD_OBJECT( - 'bytes', ENCODE(datum.bytes, 'hex'), + 'bytes', CASE WHEN _bytecode IS TRUE THEN ENCODE(datum.bytes, 'hex') ELSE NULL END, 'value', datum.value ) END @@ -173,7 +174,7 @@ BEGIN ELSE JSONB_BUILD_OBJECT( 'hash', ENCODE(script.hash, 'hex'), - 'bytes', ENCODE(script.bytes, 'hex'), + 'bytes', CASE WHEN _bytecode IS TRUE THEN ENCODE(script.bytes, 'hex') ELSE NULL END, 'value', script.json, 'type', script.type::text, 'size', script.serialised_size @@ -184,6 +185,7 @@ BEGIN INNER JOIN tx_out ON tx_out.tx_id = reference_tx_in.tx_out_id AND tx_out.index = reference_tx_in.tx_out_index INNER JOIN tx ON tx_out.tx_id = tx.id + INNER JOIN address AS a ON a.id = tx_out.address_id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN ma_tx_out AS mto ON _assets IS TRUE AND mto.tx_out_id = tx_out.id LEFT JOIN multi_asset AS ma ON _assets IS TRUE AND ma.id = mto.ident @@ -191,15 +193,15 @@ BEGIN LEFT JOIN datum ON _scripts IS TRUE AND datum.id = tx_out.inline_datum_id LEFT JOIN script ON _scripts IS TRUE AND script.id = tx_out.reference_script_id WHERE - (_inputs IS TRUE AND _scripts IS TRUE) + (_inputs IS TRUE) AND reference_tx_in.tx_in_id = ANY(_tx_id_list) ), _all_inputs AS ( SELECT tx_out.consumed_by_tx_id AS tx_id, - tx_out.address AS payment_addr_bech32, - ENCODE(tx_out.payment_cred, 'hex') AS payment_addr_cred, + a.address AS payment_addr_bech32, + ENCODE(a.payment_cred, 'hex') AS payment_addr_cred, grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_addr, ENCODE(tx.hash, 'hex') AS tx_hash, tx_out.index AS tx_index, @@ -219,7 +221,7 @@ BEGIN (CASE WHEN tx_out.inline_datum_id IS NULL THEN NULL ELSE JSONB_BUILD_OBJECT( - 'bytes', ENCODE(datum.bytes, 'hex'), + 'bytes', CASE WHEN _bytecode IS TRUE THEN ENCODE(datum.bytes, 'hex') ELSE NULL END, 'value', datum.value ) END @@ -228,7 +230,7 @@ BEGIN ELSE JSONB_BUILD_OBJECT( 'hash', ENCODE(script.hash, 'hex'), - 'bytes', ENCODE(script.bytes, 'hex'), + 'bytes', CASE WHEN _bytecode IS TRUE THEN ENCODE(script.bytes, 'hex') ELSE NULL END, 'value', script.json, 'type', script.type::text, 'size', script.serialised_size @@ -237,6 +239,7 @@ BEGIN ) AS reference_script FROM tx_out INNER JOIN tx ON tx_out.tx_id = tx.id + INNER JOIN address AS a ON a.id = tx_out.address_id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN ma_tx_out AS mto ON _assets IS TRUE AND mto.tx_out_id = tx_out.id LEFT JOIN multi_asset AS ma ON _assets IS TRUE AND ma.id = mto.ident @@ -250,8 +253,8 @@ BEGIN _all_collateral_outputs AS ( SELECT tx_out.tx_id, - tx_out.address AS payment_addr_bech32, - ENCODE(tx_out.payment_cred, 'hex') AS payment_addr_cred, + a.address AS payment_addr_bech32, + ENCODE(a.payment_cred, 'hex') AS payment_addr_cred, grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_addr, ENCODE(tx.hash, 'hex') AS tx_hash, tx_out.index AS tx_index, @@ -260,7 +263,7 @@ BEGIN (CASE WHEN tx_out.inline_datum_id IS NULL THEN NULL ELSE JSONB_BUILD_OBJECT( - 'bytes', ENCODE(datum.bytes, 'hex'), + 'bytes', CASE WHEN _bytecode IS TRUE THEN ENCODE(datum.bytes, 'hex') ELSE NULL END, 'value', datum.value ) END @@ -269,7 +272,7 @@ BEGIN ELSE JSONB_BUILD_OBJECT( 'hash', ENCODE(script.hash, 'hex'), - 'bytes', ENCODE(script.bytes, 'hex'), + 'bytes', CASE WHEN _bytecode IS TRUE THEN ENCODE(script.bytes, 'hex') ELSE NULL END, 'value', script.json, 'type', script.type::text, 'size', script.serialised_size @@ -280,18 +283,18 @@ BEGIN FROM collateral_tx_out AS tx_out INNER JOIN tx ON tx_out.tx_id = tx.id + INNER JOIN address AS a ON a.id = tx_out.address_id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN datum ON _scripts IS TRUE AND datum.id = tx_out.inline_datum_id LEFT JOIN script ON _scripts IS TRUE AND script.id = tx_out.reference_script_id - WHERE _scripts IS TRUE - AND tx_out.tx_id = ANY(_tx_id_list) + WHERE tx_out.tx_id = ANY(_tx_id_list) ), _all_outputs AS ( SELECT tx_out.tx_id, - tx_out.address AS payment_addr_bech32, - ENCODE(tx_out.payment_cred, 'hex') AS payment_addr_cred, + a.address AS payment_addr_bech32, + ENCODE(a.payment_cred, 'hex') AS payment_addr_cred, grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_addr, ENCODE(tx.hash, 'hex') AS tx_hash, tx_out.index AS tx_index, @@ -311,7 +314,7 @@ BEGIN (CASE WHEN tx_out.inline_datum_id IS NULL THEN NULL ELSE JSONB_BUILD_OBJECT( - 'bytes', ENCODE(datum.bytes, 'hex'), + 'bytes', CASE WHEN _bytecode IS TRUE THEN ENCODE(datum.bytes, 'hex') ELSE NULL END, 'value', datum.value ) END @@ -320,7 +323,7 @@ BEGIN ELSE JSONB_BUILD_OBJECT( 'hash', ENCODE(script.hash, 'hex'), - 'bytes', ENCODE(script.bytes, 'hex'), + 'bytes', CASE WHEN _bytecode IS TRUE THEN ENCODE(script.bytes, 'hex') ELSE NULL END, 'value', script.json, 'type', script.type::text, 'size', script.serialised_size @@ -329,6 +332,7 @@ BEGIN ) AS reference_script FROM tx_out INNER JOIN tx ON tx_out.tx_id = tx.id + INNER JOIN address AS a ON a.id = tx_out.address_id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN ma_tx_out AS mto ON _assets IS TRUE AND mto.tx_out_id = tx_out.id LEFT JOIN multi_asset AS ma ON _assets IS TRUE AND ma.id = mto.ident @@ -944,7 +948,7 @@ BEGIN 'asset_list', COALESCE(JSONB_AGG(asset_list) FILTER (WHERE asset_list IS NOT NULL), JSONB_BUILD_ARRAY()) ) AS tx_collateral_inputs FROM _all_collateral_inputs AS aci - WHERE (_inputs IS TRUE AND _scripts IS TRUE) AND aci.tx_id = atx.id + WHERE (_inputs IS TRUE) AND aci.tx_id = atx.id GROUP BY payment_addr_bech32, payment_addr_cred, stake_addr, aci.tx_hash, tx_index, value, datum_hash, inline_datum, reference_script ) AS tmp ), JSONB_BUILD_ARRAY()), @@ -965,7 +969,7 @@ BEGIN 'asset_list', asset_descr ) AS tx_collateral_outputs FROM _all_collateral_outputs AS aco - WHERE _scripts IS TRUE AND aco.tx_id = atx.id + WHERE aco.tx_id = atx.id GROUP BY payment_addr_bech32, payment_addr_cred, stake_addr, aco.tx_hash, tx_index, value, datum_hash, inline_datum, reference_script, asset_descr LIMIT 1 -- there can only be one collateral output ), @@ -988,7 +992,7 @@ BEGIN 'asset_list', COALESCE(JSONB_AGG(asset_list) FILTER (WHERE asset_list IS NOT NULL), JSONB_BUILD_ARRAY()) ) AS tx_reference_inputs FROM _all_reference_inputs AS ari - WHERE (_inputs IS TRUE AND _scripts IS TRUE) AND ari.tx_id = atx.id + WHERE (_inputs IS TRUE) AND ari.tx_id = atx.id GROUP BY payment_addr_bech32, payment_addr_cred, stake_addr, ari.tx_hash, tx_index, value, datum_hash, inline_datum, reference_script ) AS tmp ), JSONB_BUILD_ARRAY()), diff --git a/files/grest/rpc/transactions/tx_utxos.sql b/files/grest/rpc/transactions/tx_utxos.sql index 6ac76a61..6556d1b0 100644 --- a/files/grest/rpc/transactions/tx_utxos.sql +++ b/files/grest/rpc/transactions/tx_utxos.sql @@ -39,8 +39,8 @@ BEGIN _all_inputs AS ( SELECT tx_out.consumed_by_tx_id AS tx_id, - tx_out.address AS payment_addr_bech32, - ENCODE(tx_out.payment_cred, 'hex') AS payment_addr_cred, + a.address AS payment_addr_bech32, + ENCODE(a.payment_cred, 'hex') AS payment_addr_cred, grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_addr, ENCODE(tx.hash, 'hex') AS tx_hash, tx_out.index AS tx_index, @@ -58,6 +58,7 @@ BEGIN ) AS asset_list FROM tx_out INNER JOIN tx ON tx_out.tx_id = tx.id + INNER JOIN address AS a ON a.id = tx_out.address_id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN ma_tx_out AS mto ON mto.tx_out_id = tx_out.id LEFT JOIN multi_asset AS ma ON ma.id = mto.ident @@ -68,8 +69,8 @@ BEGIN _all_outputs AS ( SELECT tx_out.tx_id, - tx_out.address AS payment_addr_bech32, - ENCODE(tx_out.payment_cred, 'hex') AS payment_addr_cred, + a.address AS payment_addr_bech32, + ENCODE(a.payment_cred, 'hex') AS payment_addr_cred, grest.cip5_hex_to_stake_addr(sa.hash_raw) AS stake_addr, ENCODE(tx.hash, 'hex') AS tx_hash, tx_out.index AS tx_index, @@ -87,6 +88,7 @@ BEGIN ) AS asset_list FROM tx_out INNER JOIN tx ON tx_out.tx_id = tx.id + INNER JOIN address AS a ON a.id = tx_out.address_id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN ma_tx_out AS mto ON mto.tx_out_id = tx_out.id LEFT JOIN multi_asset AS ma ON ma.id = mto.ident diff --git a/files/grest/rpc/transactions/utxo_info.sql b/files/grest/rpc/transactions/utxo_info.sql index b1129cc1..e7ee77e4 100644 --- a/files/grest/rpc/transactions/utxo_info.sql +++ b/files/grest/rpc/transactions/utxo_info.sql @@ -64,10 +64,10 @@ BEGIN SELECT ENCODE(tx.hash, 'hex')::text AS tx_hash, tx_out.index::smallint, - tx_out.address::text, + a.address::text, tx_out.value::text, grest.cip5_hex_to_stake_addr(sa.hash_raw) as stake_address, - ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + ENCODE(a.payment_cred, 'hex') AS payment_cred, b.epoch_no, b.block_no, EXTRACT(EPOCH FROM b.time)::integer AS block_time, @@ -99,6 +99,7 @@ BEGIN END) AS is_spent FROM tx_out INNER JOIN tx ON tx_out.tx_id = tx.id + INNER JOIN address AS a ON a.id = tx_out.address_id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN block AS b ON b.id = tx.block_id LEFT JOIN datum ON datum.id = tx_out.inline_datum_id diff --git a/specs/results/koiosapi-guild.yaml b/specs/results/koiosapi-guild.yaml index 7cbda1c5..075252b5 100644 --- a/specs/results/koiosapi-guild.yaml +++ b/specs/results/koiosapi-guild.yaml @@ -8,7 +8,7 @@ info: license: name: Creative Commons Attribution 4.0 International url: https://github.com/cardano-community/koios-artifacts/blob/main/LICENSE - version: v1.2.1 + version: v1.3.0 description: | Koios is best described as a Decentralized and Elastic RESTful query layer for exploring data on Cardano blockchain to consume within applications/wallets/explorers/etc. This page not only provides an OpenAPI Spec for live implementation, but also ability to execute live demo from client browser against each endpoint with pre-filled examples. @@ -3157,6 +3157,12 @@ components: - 'null' description: Pool reward address example: stake1uy6yzwsxxc28lfms0qmpxvyz9a7y770rtcqx9y96m42cttqwvp4m5 + reward_addr_delegated_drep: + type: + - 'null' + - string + description: Reward address' current delegation status to DRep ID in CIP-129 Bech32 format + example: drep1yfhyq6tztjksqqpd5lglc3zr2tn8vylgjh9xzz7n2p4l4lgk3qam3 owners: type: - array @@ -3296,6 +3302,12 @@ components: - 'null' description: Pool live saturation (decimal format) example: 94.52 + voting_power: + type: + - string + - 'null' + description: Current voting power (lovelaces) of this stake pool + example: "123456789" pool_snapshot: type: array items: @@ -4310,7 +4322,9 @@ components: enum: [member, leader, treasury, reserves] example: member pool_id: - $ref: "#/components/schemas/pool_list/items/properties/pool_id_bech32" + anyOf: + - type: 'null' + - $ref: "#/components/schemas/pool_list/items/properties/pool_id_bech32" account_updates: description: Array of account updates information type: array @@ -4764,9 +4778,9 @@ components: expiration: $ref: "#/components/schemas/proposal_list/items/properties/expiration" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" withdrawal: $ref: "#/components/schemas/proposal_list/items/properties/withdrawal" param_proposal: @@ -4777,6 +4791,16 @@ components: properties: tx_hash: $ref: "#/components/schemas/tx_info/items/properties/tx_hash" + block_hash: + $ref: "#/components/schemas/blocks/items/properties/hash" + block_height: + $ref: "#/components/schemas/blocks/items/properties/block_height" + epoch_no: + $ref: "#/components/schemas/blocks/items/properties/epoch_no" + absolute_slot: + $ref: "#/components/schemas/blocks/items/properties/abs_slot" + tx_timestamp: + $ref: "#/components/schemas/tx_info/items/properties/tx_timestamp" cbor: type: string description: CBOR encoded raw transaction. @@ -5323,11 +5347,11 @@ components: deposit: $ref: "#/components/schemas/drep_info/items/properties/deposit" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" meta_json: - $ref: "#/components/schemas/drep_metadata/items/properties/json" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_json" drep_votes: description: List of all votes casted by requested delegated representative (DRep) type: array @@ -5349,9 +5373,9 @@ components: description: Actual Vote casted example: "Yes" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" pool_votes: description: List of all votes casted by requested pool type: array @@ -5428,11 +5452,11 @@ components: - 'null' description: Shows the epoch at which this governance action is expected to expire. meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" meta_json: - $ref: "#/components/schemas/drep_metadata/items/properties/json" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_json" meta_comment: $ref: "#/components/schemas/drep_metadata/items/properties/comment" meta_language: @@ -5498,8 +5522,12 @@ components: example: 39.28 drep_abstain_votes_cast: type: number - description: Percentage of 'abstain' votes from dreps + description: Number of active 'abstain' votes from dreps example: 5 + drep_always_no_confidence_vote_power: + type: number + description: Power of votes delegated to 'always_no_confidence' predefined drep + example: 9999 pool_yes_votes_cast: type: number description: Number of 'yes' votes casted by pools @@ -5527,6 +5555,23 @@ components: pool_abstain_votes_cast: type: number description: Percentage of 'abstain' votes from pools + example: 0 + pool_passive_always_abstain_votes_assigned: + type: number + description: Number of non-voting SPO pool reward addresses delegating to 'always_abstain' drep + example: 1 + pool_passive_always_abstain_vote_power: + type: number + description: Combined power of non-voting SPO pool votes where reward addresses delegate to 'always_abstain' + example: 12312312 + pool_passive_always_no_confidence_votes_assigned: + type: number + description: Number of non-voting SPO pool reward addresses delegating to 'always_no_confidence' drep + example: 10 + pool_passive_always_no_confidence_vote_power: + type: number + description: Combined power of non-voting SPO pool votes where reward addresses delegate to 'always_no_confidence' + example: 321321 committee_yes_votes_cast: type: number description: Number of 'yes' votes casted by committee @@ -5571,9 +5616,9 @@ components: vote: $ref: "#/components/schemas/drep_votes/items/properties/vote" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" committee_info: description: Current governance committee type: object diff --git a/specs/results/koiosapi-mainnet.yaml b/specs/results/koiosapi-mainnet.yaml index d3563a92..bc318a68 100644 --- a/specs/results/koiosapi-mainnet.yaml +++ b/specs/results/koiosapi-mainnet.yaml @@ -8,7 +8,7 @@ info: license: name: Creative Commons Attribution 4.0 International url: https://github.com/cardano-community/koios-artifacts/blob/main/LICENSE - version: v1.2.1 + version: v1.3.0 description: | Koios is best described as a Decentralized and Elastic RESTful query layer for exploring data on Cardano blockchain to consume within applications/wallets/explorers/etc. This page not only provides an OpenAPI Spec for live implementation, but also ability to execute live demo from client browser against each endpoint with pre-filled examples. @@ -3157,6 +3157,12 @@ components: - 'null' description: Pool reward address example: stake1uy6yzwsxxc28lfms0qmpxvyz9a7y770rtcqx9y96m42cttqwvp4m5 + reward_addr_delegated_drep: + type: + - 'null' + - string + description: Reward address' current delegation status to DRep ID in CIP-129 Bech32 format + example: drep1yfhyq6tztjksqqpd5lglc3zr2tn8vylgjh9xzz7n2p4l4lgk3qam3 owners: type: - array @@ -3296,6 +3302,12 @@ components: - 'null' description: Pool live saturation (decimal format) example: 94.52 + voting_power: + type: + - string + - 'null' + description: Current voting power (lovelaces) of this stake pool + example: "123456789" pool_snapshot: type: array items: @@ -4310,7 +4322,9 @@ components: enum: [member, leader, treasury, reserves] example: member pool_id: - $ref: "#/components/schemas/pool_list/items/properties/pool_id_bech32" + anyOf: + - type: 'null' + - $ref: "#/components/schemas/pool_list/items/properties/pool_id_bech32" account_updates: description: Array of account updates information type: array @@ -4764,9 +4778,9 @@ components: expiration: $ref: "#/components/schemas/proposal_list/items/properties/expiration" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" withdrawal: $ref: "#/components/schemas/proposal_list/items/properties/withdrawal" param_proposal: @@ -4777,6 +4791,16 @@ components: properties: tx_hash: $ref: "#/components/schemas/tx_info/items/properties/tx_hash" + block_hash: + $ref: "#/components/schemas/blocks/items/properties/hash" + block_height: + $ref: "#/components/schemas/blocks/items/properties/block_height" + epoch_no: + $ref: "#/components/schemas/blocks/items/properties/epoch_no" + absolute_slot: + $ref: "#/components/schemas/blocks/items/properties/abs_slot" + tx_timestamp: + $ref: "#/components/schemas/tx_info/items/properties/tx_timestamp" cbor: type: string description: CBOR encoded raw transaction. @@ -5323,11 +5347,11 @@ components: deposit: $ref: "#/components/schemas/drep_info/items/properties/deposit" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" meta_json: - $ref: "#/components/schemas/drep_metadata/items/properties/json" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_json" drep_votes: description: List of all votes casted by requested delegated representative (DRep) type: array @@ -5349,9 +5373,9 @@ components: description: Actual Vote casted example: "Yes" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" pool_votes: description: List of all votes casted by requested pool type: array @@ -5428,11 +5452,11 @@ components: - 'null' description: Shows the epoch at which this governance action is expected to expire. meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" meta_json: - $ref: "#/components/schemas/drep_metadata/items/properties/json" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_json" meta_comment: $ref: "#/components/schemas/drep_metadata/items/properties/comment" meta_language: @@ -5498,8 +5522,12 @@ components: example: 39.28 drep_abstain_votes_cast: type: number - description: Percentage of 'abstain' votes from dreps + description: Number of active 'abstain' votes from dreps example: 5 + drep_always_no_confidence_vote_power: + type: number + description: Power of votes delegated to 'always_no_confidence' predefined drep + example: 9999 pool_yes_votes_cast: type: number description: Number of 'yes' votes casted by pools @@ -5527,6 +5555,23 @@ components: pool_abstain_votes_cast: type: number description: Percentage of 'abstain' votes from pools + example: 0 + pool_passive_always_abstain_votes_assigned: + type: number + description: Number of non-voting SPO pool reward addresses delegating to 'always_abstain' drep + example: 1 + pool_passive_always_abstain_vote_power: + type: number + description: Combined power of non-voting SPO pool votes where reward addresses delegate to 'always_abstain' + example: 12312312 + pool_passive_always_no_confidence_votes_assigned: + type: number + description: Number of non-voting SPO pool reward addresses delegating to 'always_no_confidence' drep + example: 10 + pool_passive_always_no_confidence_vote_power: + type: number + description: Combined power of non-voting SPO pool votes where reward addresses delegate to 'always_no_confidence' + example: 321321 committee_yes_votes_cast: type: number description: Number of 'yes' votes casted by committee @@ -5571,9 +5616,9 @@ components: vote: $ref: "#/components/schemas/drep_votes/items/properties/vote" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" committee_info: description: Current governance committee type: object diff --git a/specs/results/koiosapi-preprod.yaml b/specs/results/koiosapi-preprod.yaml index 8f0179e2..c54efb05 100644 --- a/specs/results/koiosapi-preprod.yaml +++ b/specs/results/koiosapi-preprod.yaml @@ -8,7 +8,7 @@ info: license: name: Creative Commons Attribution 4.0 International url: https://github.com/cardano-community/koios-artifacts/blob/main/LICENSE - version: v1.2.1 + version: v1.3.0 description: | Koios is best described as a Decentralized and Elastic RESTful query layer for exploring data on Cardano blockchain to consume within applications/wallets/explorers/etc. This page not only provides an OpenAPI Spec for live implementation, but also ability to execute live demo from client browser against each endpoint with pre-filled examples. @@ -3157,6 +3157,12 @@ components: - 'null' description: Pool reward address example: stake1uy6yzwsxxc28lfms0qmpxvyz9a7y770rtcqx9y96m42cttqwvp4m5 + reward_addr_delegated_drep: + type: + - 'null' + - string + description: Reward address' current delegation status to DRep ID in CIP-129 Bech32 format + example: drep1yfhyq6tztjksqqpd5lglc3zr2tn8vylgjh9xzz7n2p4l4lgk3qam3 owners: type: - array @@ -3296,6 +3302,12 @@ components: - 'null' description: Pool live saturation (decimal format) example: 94.52 + voting_power: + type: + - string + - 'null' + description: Current voting power (lovelaces) of this stake pool + example: "123456789" pool_snapshot: type: array items: @@ -4310,7 +4322,9 @@ components: enum: [member, leader, treasury, reserves] example: member pool_id: - $ref: "#/components/schemas/pool_list/items/properties/pool_id_bech32" + anyOf: + - type: 'null' + - $ref: "#/components/schemas/pool_list/items/properties/pool_id_bech32" account_updates: description: Array of account updates information type: array @@ -4764,9 +4778,9 @@ components: expiration: $ref: "#/components/schemas/proposal_list/items/properties/expiration" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" withdrawal: $ref: "#/components/schemas/proposal_list/items/properties/withdrawal" param_proposal: @@ -4777,6 +4791,16 @@ components: properties: tx_hash: $ref: "#/components/schemas/tx_info/items/properties/tx_hash" + block_hash: + $ref: "#/components/schemas/blocks/items/properties/hash" + block_height: + $ref: "#/components/schemas/blocks/items/properties/block_height" + epoch_no: + $ref: "#/components/schemas/blocks/items/properties/epoch_no" + absolute_slot: + $ref: "#/components/schemas/blocks/items/properties/abs_slot" + tx_timestamp: + $ref: "#/components/schemas/tx_info/items/properties/tx_timestamp" cbor: type: string description: CBOR encoded raw transaction. @@ -5323,11 +5347,11 @@ components: deposit: $ref: "#/components/schemas/drep_info/items/properties/deposit" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" meta_json: - $ref: "#/components/schemas/drep_metadata/items/properties/json" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_json" drep_votes: description: List of all votes casted by requested delegated representative (DRep) type: array @@ -5349,9 +5373,9 @@ components: description: Actual Vote casted example: "Yes" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" pool_votes: description: List of all votes casted by requested pool type: array @@ -5428,11 +5452,11 @@ components: - 'null' description: Shows the epoch at which this governance action is expected to expire. meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" meta_json: - $ref: "#/components/schemas/drep_metadata/items/properties/json" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_json" meta_comment: $ref: "#/components/schemas/drep_metadata/items/properties/comment" meta_language: @@ -5498,8 +5522,12 @@ components: example: 39.28 drep_abstain_votes_cast: type: number - description: Percentage of 'abstain' votes from dreps + description: Number of active 'abstain' votes from dreps example: 5 + drep_always_no_confidence_vote_power: + type: number + description: Power of votes delegated to 'always_no_confidence' predefined drep + example: 9999 pool_yes_votes_cast: type: number description: Number of 'yes' votes casted by pools @@ -5527,6 +5555,23 @@ components: pool_abstain_votes_cast: type: number description: Percentage of 'abstain' votes from pools + example: 0 + pool_passive_always_abstain_votes_assigned: + type: number + description: Number of non-voting SPO pool reward addresses delegating to 'always_abstain' drep + example: 1 + pool_passive_always_abstain_vote_power: + type: number + description: Combined power of non-voting SPO pool votes where reward addresses delegate to 'always_abstain' + example: 12312312 + pool_passive_always_no_confidence_votes_assigned: + type: number + description: Number of non-voting SPO pool reward addresses delegating to 'always_no_confidence' drep + example: 10 + pool_passive_always_no_confidence_vote_power: + type: number + description: Combined power of non-voting SPO pool votes where reward addresses delegate to 'always_no_confidence' + example: 321321 committee_yes_votes_cast: type: number description: Number of 'yes' votes casted by committee @@ -5571,9 +5616,9 @@ components: vote: $ref: "#/components/schemas/drep_votes/items/properties/vote" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" committee_info: description: Current governance committee type: object diff --git a/specs/results/koiosapi-preview.yaml b/specs/results/koiosapi-preview.yaml index c443228e..3f9dcd1b 100644 --- a/specs/results/koiosapi-preview.yaml +++ b/specs/results/koiosapi-preview.yaml @@ -8,7 +8,7 @@ info: license: name: Creative Commons Attribution 4.0 International url: https://github.com/cardano-community/koios-artifacts/blob/main/LICENSE - version: v1.2.1 + version: v1.3.0 description: | Koios is best described as a Decentralized and Elastic RESTful query layer for exploring data on Cardano blockchain to consume within applications/wallets/explorers/etc. This page not only provides an OpenAPI Spec for live implementation, but also ability to execute live demo from client browser against each endpoint with pre-filled examples. @@ -3157,6 +3157,12 @@ components: - 'null' description: Pool reward address example: stake1uy6yzwsxxc28lfms0qmpxvyz9a7y770rtcqx9y96m42cttqwvp4m5 + reward_addr_delegated_drep: + type: + - 'null' + - string + description: Reward address' current delegation status to DRep ID in CIP-129 Bech32 format + example: drep1yfhyq6tztjksqqpd5lglc3zr2tn8vylgjh9xzz7n2p4l4lgk3qam3 owners: type: - array @@ -3296,6 +3302,12 @@ components: - 'null' description: Pool live saturation (decimal format) example: 94.52 + voting_power: + type: + - string + - 'null' + description: Current voting power (lovelaces) of this stake pool + example: "123456789" pool_snapshot: type: array items: @@ -4310,7 +4322,9 @@ components: enum: [member, leader, treasury, reserves] example: member pool_id: - $ref: "#/components/schemas/pool_list/items/properties/pool_id_bech32" + anyOf: + - type: 'null' + - $ref: "#/components/schemas/pool_list/items/properties/pool_id_bech32" account_updates: description: Array of account updates information type: array @@ -4764,9 +4778,9 @@ components: expiration: $ref: "#/components/schemas/proposal_list/items/properties/expiration" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" withdrawal: $ref: "#/components/schemas/proposal_list/items/properties/withdrawal" param_proposal: @@ -4777,6 +4791,16 @@ components: properties: tx_hash: $ref: "#/components/schemas/tx_info/items/properties/tx_hash" + block_hash: + $ref: "#/components/schemas/blocks/items/properties/hash" + block_height: + $ref: "#/components/schemas/blocks/items/properties/block_height" + epoch_no: + $ref: "#/components/schemas/blocks/items/properties/epoch_no" + absolute_slot: + $ref: "#/components/schemas/blocks/items/properties/abs_slot" + tx_timestamp: + $ref: "#/components/schemas/tx_info/items/properties/tx_timestamp" cbor: type: string description: CBOR encoded raw transaction. @@ -5323,11 +5347,11 @@ components: deposit: $ref: "#/components/schemas/drep_info/items/properties/deposit" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" meta_json: - $ref: "#/components/schemas/drep_metadata/items/properties/json" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_json" drep_votes: description: List of all votes casted by requested delegated representative (DRep) type: array @@ -5349,9 +5373,9 @@ components: description: Actual Vote casted example: "Yes" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" pool_votes: description: List of all votes casted by requested pool type: array @@ -5428,11 +5452,11 @@ components: - 'null' description: Shows the epoch at which this governance action is expected to expire. meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" meta_json: - $ref: "#/components/schemas/drep_metadata/items/properties/json" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_json" meta_comment: $ref: "#/components/schemas/drep_metadata/items/properties/comment" meta_language: @@ -5498,8 +5522,12 @@ components: example: 39.28 drep_abstain_votes_cast: type: number - description: Percentage of 'abstain' votes from dreps + description: Number of active 'abstain' votes from dreps example: 5 + drep_always_no_confidence_vote_power: + type: number + description: Power of votes delegated to 'always_no_confidence' predefined drep + example: 9999 pool_yes_votes_cast: type: number description: Number of 'yes' votes casted by pools @@ -5527,6 +5555,23 @@ components: pool_abstain_votes_cast: type: number description: Percentage of 'abstain' votes from pools + example: 0 + pool_passive_always_abstain_votes_assigned: + type: number + description: Number of non-voting SPO pool reward addresses delegating to 'always_abstain' drep + example: 1 + pool_passive_always_abstain_vote_power: + type: number + description: Combined power of non-voting SPO pool votes where reward addresses delegate to 'always_abstain' + example: 12312312 + pool_passive_always_no_confidence_votes_assigned: + type: number + description: Number of non-voting SPO pool reward addresses delegating to 'always_no_confidence' drep + example: 10 + pool_passive_always_no_confidence_vote_power: + type: number + description: Combined power of non-voting SPO pool votes where reward addresses delegate to 'always_no_confidence' + example: 321321 committee_yes_votes_cast: type: number description: Number of 'yes' votes casted by committee @@ -5571,9 +5616,9 @@ components: vote: $ref: "#/components/schemas/drep_votes/items/properties/vote" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" committee_info: description: Current governance committee type: object diff --git a/specs/templates/1-api-info.yaml b/specs/templates/1-api-info.yaml index de45e8c3..e35eb0a7 100644 --- a/specs/templates/1-api-info.yaml +++ b/specs/templates/1-api-info.yaml @@ -7,7 +7,7 @@ info: license: name: Creative Commons Attribution 4.0 International url: https://github.com/cardano-community/koios-artifacts/blob/main/LICENSE - version: v1.2.1 + version: v1.3.0 description: | Koios is best described as a Decentralized and Elastic RESTful query layer for exploring data on Cardano blockchain to consume within applications/wallets/explorers/etc. This page not only provides an OpenAPI Spec for live implementation, but also ability to execute live demo from client browser against each endpoint with pre-filled examples. diff --git a/specs/templates/4-api-schemas.yaml b/specs/templates/4-api-schemas.yaml index d30da201..d2f6fa97 100644 --- a/specs/templates/4-api-schemas.yaml +++ b/specs/templates/4-api-schemas.yaml @@ -322,6 +322,12 @@ schemas: - 'null' description: Pool reward address example: stake1uy6yzwsxxc28lfms0qmpxvyz9a7y770rtcqx9y96m42cttqwvp4m5 + reward_addr_delegated_drep: + type: + - 'null' + - string + description: Reward address' current delegation status to DRep ID in CIP-129 Bech32 format + example: drep1yfhyq6tztjksqqpd5lglc3zr2tn8vylgjh9xzz7n2p4l4lgk3qam3 owners: type: - array @@ -461,6 +467,12 @@ schemas: - 'null' description: Pool live saturation (decimal format) example: 94.52 + voting_power: + type: + - string + - 'null' + description: Current voting power (lovelaces) of this stake pool + example: "123456789" pool_snapshot: type: array items: @@ -1475,7 +1487,9 @@ schemas: enum: [member, leader, treasury, reserves] example: member pool_id: - $ref: "#/components/schemas/pool_list/items/properties/pool_id_bech32" + anyOf: + - type: 'null' + - $ref: "#/components/schemas/pool_list/items/properties/pool_id_bech32" account_updates: description: Array of account updates information type: array @@ -1929,9 +1943,9 @@ schemas: expiration: $ref: "#/components/schemas/proposal_list/items/properties/expiration" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" withdrawal: $ref: "#/components/schemas/proposal_list/items/properties/withdrawal" param_proposal: @@ -1942,6 +1956,16 @@ schemas: properties: tx_hash: $ref: "#/components/schemas/tx_info/items/properties/tx_hash" + block_hash: + $ref: "#/components/schemas/blocks/items/properties/hash" + block_height: + $ref: "#/components/schemas/blocks/items/properties/block_height" + epoch_no: + $ref: "#/components/schemas/blocks/items/properties/epoch_no" + absolute_slot: + $ref: "#/components/schemas/blocks/items/properties/abs_slot" + tx_timestamp: + $ref: "#/components/schemas/tx_info/items/properties/tx_timestamp" cbor: type: string description: CBOR encoded raw transaction. @@ -2488,11 +2512,11 @@ schemas: deposit: $ref: "#/components/schemas/drep_info/items/properties/deposit" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" meta_json: - $ref: "#/components/schemas/drep_metadata/items/properties/json" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_json" drep_votes: description: List of all votes casted by requested delegated representative (DRep) type: array @@ -2514,9 +2538,9 @@ schemas: description: Actual Vote casted example: "Yes" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" pool_votes: description: List of all votes casted by requested pool type: array @@ -2593,11 +2617,11 @@ schemas: - 'null' description: Shows the epoch at which this governance action is expected to expire. meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" meta_json: - $ref: "#/components/schemas/drep_metadata/items/properties/json" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_json" meta_comment: $ref: "#/components/schemas/drep_metadata/items/properties/comment" meta_language: @@ -2663,8 +2687,12 @@ schemas: example: 39.28 drep_abstain_votes_cast: type: number - description: Percentage of 'abstain' votes from dreps + description: Number of active 'abstain' votes from dreps example: 5 + drep_always_no_confidence_vote_power: + type: number + description: Power of votes delegated to 'always_no_confidence' predefined drep + example: 9999 pool_yes_votes_cast: type: number description: Number of 'yes' votes casted by pools @@ -2692,6 +2720,23 @@ schemas: pool_abstain_votes_cast: type: number description: Percentage of 'abstain' votes from pools + example: 0 + pool_passive_always_abstain_votes_assigned: + type: number + description: Number of non-voting SPO pool reward addresses delegating to 'always_abstain' drep + example: 1 + pool_passive_always_abstain_vote_power: + type: number + description: Combined power of non-voting SPO pool votes where reward addresses delegate to 'always_abstain' + example: 12312312 + pool_passive_always_no_confidence_votes_assigned: + type: number + description: Number of non-voting SPO pool reward addresses delegating to 'always_no_confidence' drep + example: 10 + pool_passive_always_no_confidence_vote_power: + type: number + description: Combined power of non-voting SPO pool votes where reward addresses delegate to 'always_no_confidence' + example: 321321 committee_yes_votes_cast: type: number description: Number of 'yes' votes casted by committee @@ -2736,9 +2781,9 @@ schemas: vote: $ref: "#/components/schemas/drep_votes/items/properties/vote" meta_url: - $ref: "#/components/schemas/drep_metadata/items/properties/url" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_url" meta_hash: - $ref: "#/components/schemas/drep_metadata/items/properties/hash" + $ref: "#/components/schemas/drep_metadata/items/properties/meta_hash" committee_info: description: Current governance committee type: object diff --git a/tests/setup-tests.sh b/tests/setup-tests.sh index 7dae71e9..4a1feaeb 100755 --- a/tests/setup-tests.sh +++ b/tests/setup-tests.sh @@ -13,7 +13,7 @@ cat <<-EOF To run the endpoint validation tests, use the below: schemathesis run --request-timeout 25000 ../specs/results/koiosapi-guild.yaml --hypothesis-phases=explicit --hypothesis-verbosity quiet \\ - -b http://127.0.0.1:8053/api/v1 -c all --validate-schema=true -H "Content-Type: application/json" --experimental=openapi-3.1 --exclude-checks ignored_auths + -b http://127.0.0.1:8053/api/v1 -c all --validate-schema=true -H "Content-Type: application/json" --experimental=openapi-3.1 --exclude-checks ignored_auth where http://127.0.0.1:8053/api/v1 is the URL of instance you want to test, and guild.koios.rest is the target enviornment for testing.