From 9dcdde4286ba35fe3c4dab2173a57de8e976704f Mon Sep 17 00:00:00 2001 From: Priyank <3169068+rdlrt@users.noreply.github.com> Date: Fri, 11 Aug 2023 18:48:49 +1000 Subject: [PATCH 1/4] pool_list: Add all cache fields & remove filter --- .../rpc/01_cached_tables/asset_info_cache.sql | 8 +-- .../01_cached_tables/asset_registry_cache.sql | 2 +- .../rpc/01_cached_tables/epoch_info_cache.sql | 4 +- .../rpc/01_cached_tables/pool_info_cache.sql | 12 ++-- .../stake_distribution_cache.sql | 2 +- files/grest/rpc/account/account_updates.sql | 2 +- files/grest/rpc/address/address_assets.sql | 6 +- files/grest/rpc/address/address_info.sql | 50 ++++++-------- files/grest/rpc/assets/asset_history.sql | 24 +++---- files/grest/rpc/assets/asset_nft_address.sql | 22 +++--- files/grest/rpc/assets/asset_summary.sql | 61 +++++++--------- files/grest/rpc/assets/policy_asset_info.sql | 33 ++++----- files/grest/rpc/assets/policy_asset_list.sql | 8 +-- files/grest/rpc/pool/pool_delegators.sql | 4 +- files/grest/rpc/pool/pool_history.sql | 4 +- files/grest/rpc/pool/pool_info.sql | 68 +++++++----------- files/grest/rpc/pool/pool_list.sql | 69 +++++++++++++------ files/grest/rpc/pool/pool_metadata.sql | 24 +++---- files/grest/rpc/pool/pool_relays.sql | 20 +++--- files/grest/rpc/script/datum_info.sql | 2 +- files/grest/rpc/transactions/tx_utxos.sql | 6 +- specs/results/koiosapi-guild.yaml | 39 +++++++++-- specs/results/koiosapi-mainnet.yaml | 39 +++++++++-- specs/results/koiosapi-preprod.yaml | 39 +++++++++-- specs/results/koiosapi-preview.yaml | 39 +++++++++-- specs/templates/4-api-schemas.yaml | 35 ++++++++-- specs/templates/api-main.yaml | 4 +- 27 files changed, 362 insertions(+), 264 deletions(-) diff --git a/files/grest/rpc/01_cached_tables/asset_info_cache.sql b/files/grest/rpc/01_cached_tables/asset_info_cache.sql index 9dd11d16..41be3082 100644 --- a/files/grest/rpc/01_cached_tables/asset_info_cache.sql +++ b/files/grest/rpc/01_cached_tables/asset_info_cache.sql @@ -30,7 +30,7 @@ BEGIN WHERE state = 'active' AND query ILIKE '%grest.asset_info_cache_update%' AND datname = (SELECT current_database()) - ) THEN + ) THEN RAISE EXCEPTION 'Previous asset_info_cache_update query still running but should have completed! Exiting...'; END IF; @@ -56,7 +56,7 @@ BEGIN tx_mint_meta AS ( SELECT mtm.ident, - MIN(mtm.tx_id) AS first_mint_tx_id, + MIN(mtm.tx_id) AS first_mint_tx_id, MAX(mtm.tx_id) AS last_mint_tx_id FROM ma_tx_mint AS mtm INNER JOIN tx_metadata AS tm ON tm.tx_id = mtm.tx_id @@ -74,7 +74,7 @@ BEGIN tx_mint_nometa AS ( SELECT mtm.ident, - MIN(mtm.tx_id) AS first_mint_tx_id, + MIN(mtm.tx_id) AS first_mint_tx_id, MAX(mtm.tx_id) AS last_mint_tx_id FROM ma_tx_mint AS mtm LEFT JOIN tx_mint_meta ON tx_mint_meta.ident = mtm.ident @@ -111,7 +111,7 @@ BEGIN FROM tx_mint_nometa ) - INSERT INTO grest.asset_info_cache + INSERT INTO grest.asset_info_cache SELECT ma.id, MIN(B.time) AS creation_time, diff --git a/files/grest/rpc/01_cached_tables/asset_registry_cache.sql b/files/grest/rpc/01_cached_tables/asset_registry_cache.sql index 7d1ce37f..afc2fbe3 100644 --- a/files/grest/rpc/01_cached_tables/asset_registry_cache.sql +++ b/files/grest/rpc/01_cached_tables/asset_registry_cache.sql @@ -38,7 +38,7 @@ BEGIN decimals ) VALUES( - _asset_policy, + _asset_policy, _asset_name, _name, _description, diff --git a/files/grest/rpc/01_cached_tables/epoch_info_cache.sql b/files/grest/rpc/01_cached_tables/epoch_info_cache.sql index c6a2fc00..85621dff 100644 --- a/files/grest/rpc/01_cached_tables/epoch_info_cache.sql +++ b/files/grest/rpc/01_cached_tables/epoch_info_cache.sql @@ -115,13 +115,13 @@ BEGIN EXTRACT(EPOCH FROM e.start_time) AS i_first_block_time, EXTRACT(EPOCH FROM e.end_time) AS i_last_block_time, CASE -- populated in epoch n + 2 - WHEN e.no <= _curr_epoch - 2 THEN reward_pot.amount + WHEN e.no <= _curr_epoch - 2 THEN reward_pot.amount ELSE NULL END AS i_total_rewards, CASE -- populated in epoch n + 2 WHEN e.no <= _curr_epoch THEN ROUND(reward_pot.amount / e.blk_count) ELSE NULL - END AS i_avg_blk_reward, + END AS i_avg_blk_reward, last_tx.tx_id AS i_last_tx_id, ep.min_fee_a AS p_min_fee_a, ep.min_fee_b AS p_min_fee_b, 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 39beb5f8..ca50c57d 100644 --- a/files/grest/rpc/01_cached_tables/pool_info_cache.sql +++ b/files/grest/rpc/01_cached_tables/pool_info_cache.sql @@ -55,7 +55,7 @@ BEGIN ORDER BY pr.id LIMIT 1; - IF _retiring_epoch IS NULL THEN + IF _retiring_epoch IS NULL THEN _pool_status := 'registered'; ELSIF _retiring_epoch > _current_epoch_no THEN _pool_status := 'retiring'; @@ -69,7 +69,7 @@ BEGIN tx_hash, block_time, pool_hash_id, - pool_id_bech32, + pool_id_bech32, pool_id_hex, active_epoch_no, vrf_key_hash, @@ -88,7 +88,7 @@ BEGIN SELECT _tx_id, _update_id, - encode(tx.hash::bytea, 'hex'), + encode(tx.hash::bytea, 'hex'), EXTRACT(EPOCH FROM b.time), _hash_id, ph.view, @@ -174,7 +174,7 @@ BEGIN ORDER BY pr.id LIMIT 1; - IF _retiring_epoch IS NULL THEN + IF _retiring_epoch IS NULL THEN _pool_status := 'registered'; ELSIF _retiring_epoch > _current_epoch_no THEN _pool_status := 'retiring'; @@ -222,8 +222,8 @@ BEGIN END IF; ELSIF (tg_table_name = 'pool_relay') THEN - SELECT pic.id INTO _latest_pool_update_id - FROM grest.pool_info_cache AS pic + SELECT pic.id INTO _latest_pool_update_id + FROM grest.pool_info_cache AS pic INNER JOIN public.pool_update AS pu ON pu.hash_id = pic.pool_hash_id AND pu.registered_tx_id = pic.tx_id WHERE pu.id = new.update_id; diff --git a/files/grest/rpc/01_cached_tables/stake_distribution_cache.sql b/files/grest/rpc/01_cached_tables/stake_distribution_cache.sql index 74cc44a9..e7d6960f 100644 --- a/files/grest/rpc/01_cached_tables/stake_distribution_cache.sql +++ b/files/grest/rpc/01_cached_tables/stake_distribution_cache.sql @@ -266,7 +266,7 @@ BEGIN SELECT (_current_block_height - _last_update_block_height) INTO _last_update_block_diff; -- Do nothing until there is a 180 blocks difference in height - 60 minutes theoretical time -- 185 in check because last block height considered is 5 blocks behind tip - + Raise NOTICE 'Last stake distribution update was % blocks ago...', _last_update_block_diff; IF (_last_update_block_diff >= 180 diff --git a/files/grest/rpc/account/account_updates.sql b/files/grest/rpc/account/account_updates.sql index 371829d6..3a851529 100644 --- a/files/grest/rpc/account/account_updates.sql +++ b/files/grest/rpc/account/account_updates.sql @@ -9,7 +9,7 @@ DECLARE sa_id_list integer[] DEFAULT NULL; BEGIN SELECT INTO sa_id_list - ARRAY_AGG(stake_address.id) + ARRAY_AGG(stake_address.id) FROM stake_address WHERE diff --git a/files/grest/rpc/address/address_assets.sql b/files/grest/rpc/address/address_assets.sql index badacf1d..274d0c62 100644 --- a/files/grest/rpc/address/address_assets.sql +++ b/files/grest/rpc/address/address_assets.sql @@ -45,10 +45,8 @@ BEGIN 'quantity', aa.quantity::text ) ) AS asset_list - FROM - _all_assets AS aa - GROUP BY - aa.address + FROM _all_assets AS aa + GROUP BY aa.address ) assets_grouped; END; $$; diff --git a/files/grest/rpc/address/address_info.sql b/files/grest/rpc/address/address_info.sql index e4388cba..2ac829ca 100644 --- a/files/grest/rpc/address/address_info.sql +++ b/files/grest/rpc/address/address_info.sql @@ -16,11 +16,9 @@ BEGIN DISTINCT ON (tx_out.address) tx_out.address, sa.view AS stake_address, COALESCE(tx_out.address_has_script, 'false') AS script_address - FROM - tx_out - LEFT JOIN stake_address sa ON sa.id = tx_out.stake_address_id - WHERE - tx_out.address = ANY(_addresses); + FROM tx_out + LEFT JOIN stake_address AS sa ON sa.id = tx_out.stake_address_id + WHERE tx_out.address = ANY(_addresses); RETURN QUERY WITH _all_utxos AS ( @@ -35,15 +33,12 @@ BEGIN tx_out.data_hash, tx_out.inline_datum_id, tx_out.reference_script_id - FROM - tx_out - LEFT JOIN tx_in ON tx_in.tx_out_id = tx_out.tx_id - AND tx_in.tx_out_index = tx_out.index - INNER JOIN tx ON tx.id = tx_out.tx_id - WHERE - tx_in.tx_out_id IS NULL - AND - tx_out.address = ANY(_addresses) + FROM tx_out + LEFT JOIN tx_in ON tx_in.tx_out_id = tx_out.tx_id + AND tx_in.tx_out_index = tx_out.index + INNER JOIN tx ON tx.id = tx_out.tx_id + WHERE tx_in.tx_out_id IS NULL + AND tx_out.address = ANY(_addresses) ) SELECT @@ -57,7 +52,7 @@ BEGIN ) THEN JSONB_AGG( JSONB_BUILD_OBJECT( - 'tx_hash', ENCODE(au.hash, 'hex'), + 'tx_hash', ENCODE(au.hash, 'hex'), 'tx_index', au.index, 'block_height', block.block_no, 'block_time', EXTRACT(EPOCH FROM block.time)::integer, @@ -98,12 +93,10 @@ BEGIN 'decimals', COALESCE(aic.decimals, 0), 'quantity', mtx.quantity::text )) - FROM - ma_tx_out AS mtx - 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 - WHERE - mtx.tx_out_id = au.txo_id + FROM ma_tx_out AS mtx + 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 + WHERE mtx.tx_out_id = au.txo_id ), JSONB_BUILD_ARRAY() ) @@ -112,14 +105,15 @@ BEGIN ELSE '[]'::jsonb END AS utxo_set - FROM - _known_addresses AS ka - LEFT OUTER JOIN _all_utxos AS au ON au.address = ka.address - LEFT JOIN public.block ON block.id = au.block_id - LEFT JOIN datum ON datum.id = au.inline_datum_id - LEFT JOIN script ON script.id = au.reference_script_id + FROM _known_addresses AS ka + LEFT OUTER JOIN _all_utxos AS au ON au.address = ka.address + LEFT JOIN public.block ON block.id = au.block_id + LEFT JOIN datum ON datum.id = au.inline_datum_id + LEFT JOIN script ON script.id = au.reference_script_id GROUP BY - ka.address, ka.stake_address, ka.script_address; + ka.address, + ka.stake_address, + ka.script_address; DROP TABLE _known_addresses; END; $$; diff --git a/files/grest/rpc/assets/asset_history.sql b/files/grest/rpc/assets/asset_history.sql index cef2e8b5..77833621 100644 --- a/files/grest/rpc/assets/asset_history.sql +++ b/files/grest/rpc/assets/asset_history.sql @@ -13,10 +13,8 @@ DECLARE BEGIN SELECT DECODE(_asset_policy, 'hex') INTO _asset_policy_decoded; SELECT DECODE( - CASE WHEN _asset_name IS NULL - THEN '' - ELSE - _asset_name + CASE WHEN _asset_name IS NULL THEN '' + ELSE _asset_name END, 'hex' ) INTO _asset_name_decoded; @@ -48,16 +46,15 @@ BEGIN 'key', tm.key::text, 'json', tm.json ) - ) + ) END ) AS metadata - FROM - ma_tx_mint AS mtm - INNER JOIN multi_asset AS ma ON ma.id = mtm.ident - INNER JOIN tx ON tx.id = MTM.tx_id - INNER JOIN block AS b ON b.id = tx.block_id - LEFT JOIN tx_metadata AS tm ON tm.tx_id = tx.id - WHERE ma.policy = _asset_policy_decoded + FROM ma_tx_mint AS mtm + INNER JOIN multi_asset AS ma ON ma.id = mtm.ident + INNER JOIN tx ON tx.id = MTM.tx_id + INNER JOIN block AS b ON b.id = tx.block_id + LEFT JOIN tx_metadata AS tm ON tm.tx_id = tx.id + WHERE ma.policy = _asset_policy_decoded AND ma.name = _asset_name_decoded GROUP BY ma.fingerprint, @@ -66,8 +63,7 @@ BEGIN mtm.quantity, tm.key ) AS minting_data - GROUP BY - minting_data.fingerprint; + GROUP BY minting_data.fingerprint; END; $$; diff --git a/files/grest/rpc/assets/asset_nft_address.sql b/files/grest/rpc/assets/asset_nft_address.sql index daaedab2..221d6cc4 100644 --- a/files/grest/rpc/assets/asset_nft_address.sql +++ b/files/grest/rpc/assets/asset_nft_address.sql @@ -10,27 +10,27 @@ DECLARE BEGIN SELECT DECODE(_asset_policy, 'hex') INTO _asset_policy_decoded; SELECT DECODE( - CASE WHEN _asset_name IS NULL - THEN '' - ELSE - _asset_name + CASE WHEN _asset_name IS NULL THEN '' + ELSE _asset_name END, 'hex' ) INTO _asset_name_decoded; - SELECT id INTO _asset_id - FROM - multi_asset AS ma - INNER JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id - WHERE - ma.policy = _asset_policy_decoded + SELECT id INTO _asset_id + FROM multi_asset AS ma + INNER JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id + WHERE ma.policy = _asset_policy_decoded AND ma.name = _asset_name_decoded AND aic.total_supply = 1; RETURN QUERY SELECT address FROM tx_out - WHERE id = (SELECT MAX(tx_out_id) FROM ma_tx_out WHERE ident = _asset_id); + WHERE id = ( + SELECT MAX(tx_out_id) + FROM ma_tx_out + WHERE ident = _asset_id + ); END; $$; diff --git a/files/grest/rpc/assets/asset_summary.sql b/files/grest/rpc/assets/asset_summary.sql index 04ae7d96..68ac5ba8 100644 --- a/files/grest/rpc/assets/asset_summary.sql +++ b/files/grest/rpc/assets/asset_summary.sql @@ -16,14 +16,15 @@ DECLARE BEGIN SELECT DECODE(_asset_policy, 'hex') INTO _asset_policy_decoded; SELECT DECODE( - CASE WHEN _asset_name IS NULL - THEN '' - ELSE - _asset_name + CASE WHEN _asset_name IS NULL THEN '' + ELSE _asset_name END, 'hex' ) INTO _asset_name_decoded; - SELECT id INTO _asset_id FROM multi_asset AS ma WHERE ma.policy = _asset_policy_decoded AND ma.name = _asset_name_decoded; + SELECT id INTO _asset_id + FROM multi_asset AS ma + WHERE ma.policy = _asset_policy_decoded + AND ma.name = _asset_name_decoded; RETURN QUERY with _asset_utxos AS ( SELECT @@ -32,48 +33,34 @@ BEGIN txo.index AS tx_out_idx, txo.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 - LEFT JOIN tx_in AS txi ON txi.tx_out_id = txo.tx_id - WHERE - mto.ident = _asset_id - AND - txi.tx_out_id IS NULL) - + FROM ma_tx_out AS mto + INNER JOIN tx_out AS txo ON txo.id = mto.tx_out_id + LEFT JOIN tx_in AS txi ON txi.tx_out_id = txo.tx_id + WHERE mto.ident = _asset_id + AND txi.tx_out_id IS NULL) + SELECT _asset_policy, _asset_name, ma.fingerprint, ( - SELECT - COUNT(DISTINCT(txo.tx_id)) - FROM - ma_tx_out mto - INNER JOIN tx_out txo ON txo.id = mto.tx_out_id - WHERE - ident = _asset_id + SELECT COUNT(DISTINCT(txo.tx_id)) + FROM ma_tx_out mto + INNER JOIN tx_out txo ON txo.id = mto.tx_out_id + WHERE ident = _asset_id ) AS total_transactions, ( - SELECT - COUNT(DISTINCT(_asset_utxos.sa_id)) - FROM - _asset_utxos - WHERE - _asset_utxos.sa_id IS NOT NULL + SELECT COUNT(DISTINCT(_asset_utxos.sa_id)) + FROM _asset_utxos + WHERE _asset_utxos.sa_id IS NOT NULL ) AS staked_wallets, ( - SELECT - COUNT(DISTINCT(_asset_utxos.address)) - FROM - _asset_utxos - WHERE - _asset_utxos.sa_id IS NULL + SELECT COUNT(DISTINCT(_asset_utxos.address)) + FROM _asset_utxos + WHERE _asset_utxos.sa_id IS NULL ) AS unstaked_addresses - FROM - multi_asset AS ma - WHERE - ma.id = _asset_id; + FROM multi_asset AS ma + WHERE ma.id = _asset_id; END; $$; diff --git a/files/grest/rpc/assets/policy_asset_info.sql b/files/grest/rpc/assets/policy_asset_info.sql index 5c1e910b..df3905ef 100644 --- a/files/grest/rpc/assets/policy_asset_info.sql +++ b/files/grest/rpc/assets/policy_asset_info.sql @@ -39,7 +39,7 @@ DECLARE _policy_asset_ids bigint[]; BEGIN SELECT DECODE(_asset_policy, 'hex') INTO _asset_policy_decoded; - RETURN QUERY + RETURN QUERY SELECT ENCODE(ma.name, 'hex') AS asset_name, ENCODE(ma.name, 'escape') AS asset_name_ascii, @@ -61,24 +61,19 @@ BEGIN 'decimals', arc.decimals ) END - FROM - multi_asset AS ma - INNER JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id - INNER JOIN tx ON tx.id = aic.last_mint_tx_id - LEFT JOIN grest.asset_registry_cache AS arc ON arc.asset_policy = ENCODE(ma.policy,'hex') AND arc.asset_name = ENCODE(ma.name, 'hex') - LEFT JOIN LATERAL ( - SELECT - JSONB_OBJECT_AGG( - key::text, - json - ) AS minting_tx_metadata - FROM - tx_metadata AS tm - WHERE - tm.tx_id = tx.id - ) metadata ON TRUE - WHERE - ma.policy = _asset_policy_decoded; + FROM multi_asset AS ma + INNER JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id + INNER JOIN tx ON tx.id = aic.last_mint_tx_id + LEFT JOIN grest.asset_registry_cache AS arc ON arc.asset_policy = ENCODE(ma.policy,'hex') AND arc.asset_name = ENCODE(ma.name, 'hex') + LEFT JOIN LATERAL ( + SELECT JSONB_OBJECT_AGG( + key::text, + json + ) AS minting_tx_metadata + FROM tx_metadata AS tm + WHERE tm.tx_id = tx.id + ) AS metadata ON TRUE + WHERE ma.policy = _asset_policy_decoded; END; $$; diff --git a/files/grest/rpc/assets/policy_asset_list.sql b/files/grest/rpc/assets/policy_asset_list.sql index 630b9aa2..9893a2ea 100644 --- a/files/grest/rpc/assets/policy_asset_list.sql +++ b/files/grest/rpc/assets/policy_asset_list.sql @@ -17,11 +17,9 @@ BEGIN ma.fingerprint AS fingerprint, aic.total_supply::text, aic.decimals - FROM - multi_asset AS ma - INNER JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id - WHERE - ma.policy = _asset_policy_decoded; + FROM multi_asset AS ma + INNER JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id + WHERE ma.policy = _asset_policy_decoded; END; $$; diff --git a/files/grest/rpc/pool/pool_delegators.sql b/files/grest/rpc/pool/pool_delegators.sql index df1fe119..e9145a0c 100644 --- a/files/grest/rpc/pool/pool_delegators.sql +++ b/files/grest/rpc/pool/pool_delegators.sql @@ -11,8 +11,8 @@ AS $$ DECLARE _pool_id bigint; BEGIN - RETURN QUERY - WITH + RETURN QUERY + WITH _all_delegations AS ( SELECT sa.id AS stake_address_id, diff --git a/files/grest/rpc/pool/pool_history.sql b/files/grest/rpc/pool/pool_history.sql index 5fe43755..82c3e603 100644 --- a/files/grest/rpc/pool/pool_history.sql +++ b/files/grest/rpc/pool/pool_history.sql @@ -34,8 +34,8 @@ BEGIN COALESCE(member_rewards, 0)::text, COALESCE(epoch_ros, 0) FROM grest.pool_history_cache AS phc - WHERE phc.pool_id = _pool_bech32 and - (_epoch_no IS NULL OR + WHERE phc.pool_id = _pool_bech32 and + (_epoch_no IS NULL OR phc.epoch_no = _epoch_no) ORDER by phc.epoch_no desc; END; diff --git a/files/grest/rpc/pool/pool_info.sql b/files/grest/rpc/pool/pool_info.sql index fea544df..50a12023 100644 --- a/files/grest/rpc/pool/pool_info.sql +++ b/files/grest/rpc/pool/pool_info.sql @@ -34,7 +34,7 @@ DECLARE BEGIN SELECT MAX(epoch.no) INTO _epoch_no FROM public.epoch; SELECT FLOOR(supply::bigint / ( - SELECT p_optimal_pool_count + SELECT p_optimal_pool_count FROM grest.epoch_info_cache WHERE epoch_no = _epoch_no ))::bigint INTO _saturation_limit FROM grest.totals(_epoch_no); @@ -43,12 +43,11 @@ BEGIN _all_pool_info AS ( SELECT DISTINCT ON (pic.pool_id_bech32) * - FROM - grest.pool_info_cache AS pic - WHERE - pic.pool_id_bech32 = ANY(SELECT UNNEST(_pool_bech32_ids)) + FROM grest.pool_info_cache AS pic + WHERE pic.pool_id_bech32 = ANY(SELECT UNNEST(_pool_bech32_ids)) ORDER BY - pic.pool_id_bech32, pic.tx_id DESC + pic.pool_id_bech32, + pic.tx_id DESC ) SELECT @@ -76,29 +75,21 @@ BEGIN live.stake::text, live.delegators, ROUND((live.stake / _saturation_limit) * 100, 2) - FROM - _all_pool_info AS api + FROM _all_pool_info AS api LEFT JOIN LATERAL ( ( SELECT pod.json - FROM - public.pool_offline_data AS pod - WHERE - pod.pool_id = api.pool_hash_id - AND - pod.pmr_id = api.meta_id + FROM public.pool_offline_data AS pod + WHERE pod.pool_id = api.pool_hash_id + AND pod.pmr_id = api.meta_id ) UNION ALL ( SELECT pod.json - FROM - public.pool_offline_data AS pod - WHERE - pod.pool_id = api.pool_hash_id - AND - pod.json IS NOT NULL - ORDER BY - pod.pmr_id DESC + FROM public.pool_offline_data AS pod + WHERE pod.pool_id = api.pool_hash_id + AND pod.json IS NOT NULL + ORDER BY pod.pmr_id DESC ) LIMIT 1 ) offline_data ON TRUE @@ -107,34 +98,25 @@ BEGIN SUM(COUNT(b.id)) OVER () AS cnt, b.op_cert, b.op_cert_counter - FROM - public.block AS b - INNER JOIN - public.slot_leader AS sl ON b.slot_leader_id = sl.id - WHERE - sl.pool_hash_id = api.pool_hash_id + FROM public.block AS b + INNER JOIN public.slot_leader AS sl ON b.slot_leader_id = sl.id + WHERE sl.pool_hash_id = api.pool_hash_id GROUP BY b.op_cert, b.op_cert_counter - ORDER BY - b.op_cert_counter DESC + ORDER BY b.op_cert_counter DESC LIMIT 1 ) block_data ON TRUE LEFT JOIN LATERAL( SELECT amount::lovelace AS as_sum - FROM - grest.pool_active_stake_cache AS pasc - WHERE - pasc.pool_id = api.pool_id_bech32 - AND - pasc.epoch_no = _epoch_no + FROM grest.pool_active_stake_cache AS pasc + WHERE pasc.pool_id = api.pool_id_bech32 + AND pasc.epoch_no = _epoch_no ) active_stake ON TRUE LEFT JOIN LATERAL( SELECT amount::lovelace AS es_sum - FROM - grest.epoch_active_stake_cache AS easc - WHERE - easc.epoch_no = _epoch_no + FROM grest.epoch_active_stake_cache AS easc + WHERE easc.epoch_no = _epoch_no ) epoch_stake ON TRUE LEFT JOIN LATERAL( SELECT @@ -154,10 +136,8 @@ BEGIN ELSE SUM(CASE WHEN sdc.stake_address = ANY(api.owners) THEN total_balance ELSE 0 END)::lovelace END AS pledge - FROM - grest.stake_distribution_cache AS sdc - WHERE - sdc.pool_id = api.pool_id_bech32 + FROM grest.stake_distribution_cache AS sdc + WHERE sdc.pool_id = api.pool_id_bech32 ) live ON TRUE; END; $$; diff --git a/files/grest/rpc/pool/pool_list.sql b/files/grest/rpc/pool/pool_list.sql index c656d274..3d8ce843 100644 --- a/files/grest/rpc/pool/pool_list.sql +++ b/files/grest/rpc/pool/pool_list.sql @@ -1,7 +1,19 @@ CREATE OR REPLACE FUNCTION grest.pool_list() RETURNS TABLE ( pool_id_bech32 character varying, - ticker character varying + pool_id_hex text, + active_epoch_no bigint, + margin double precision, + fixed_cost text, + pledge text, + reward_addr character varying, + owners character varying [], + relays jsonb [], + ticker character varying, + meta_url character varying, + meta_hash text, + pool_status text, + retiring_epoch word31type ) LANGUAGE plpgsql AS $$ @@ -12,36 +24,49 @@ BEGIN -- Get last pool update for each pool _pool_list AS ( SELECT - DISTINCT ON (pic.pool_id_bech32) pool_id_bech32, - pool_status - FROM - grest.pool_info_cache AS pic - ORDER BY - pic.pool_id_bech32, - pic.tx_id DESC + ph.view as pool_id_bech32, + ph.hash_raw as pool_id_hex + FROM pool_hash AS ph ), _pool_meta AS ( - SELECT - DISTINCT ON (pic.pool_id_bech32) pool_id_bech32, - pod.ticker_name - FROM - grest.pool_info_cache AS pic - LEFT JOIN public.pool_offline_data AS pod ON pod.pmr_id = pic.meta_id - WHERE pod.ticker_name IS NOT NULL + SELECT DISTINCT ON (pic.pool_id_bech32) + pic.pool_id_bech32, + pic.active_epoch_no, + pic.margin, + pic.fixed_cost, + pic.pledge, + pic.reward_addr, + pic.owners, + pic.relays, + pod.ticker_name, + pic.meta_url, + pic.meta_hash, + pic.pool_status, + pic.retiring_epoch + FROM grest.pool_info_cache AS pic + LEFT JOIN public.pool_offline_data AS pod ON pod.pmr_id = pic.meta_id ORDER BY pic.pool_id_bech32, pic.tx_id DESC ) - SELECT pl.pool_id_bech32, - pm.ticker_name - FROM - _pool_list AS pl - LEFT JOIN _pool_meta AS pm ON pl.pool_id_bech32 = pm.pool_id_bech32 - WHERE - pool_status != 'retired' + encode(pl.pool_id_hex,'hex') as pool_id_hex, + pm.active_epoch_no, + pm.margin, + pm.fixed_cost::text, + pm.pledge::text, + pm.reward_addr, + pm.owners, + pm.relays, + pm.ticker_name, + pm.meta_url, + pm.meta_hash, + pm.pool_status, + pm.retiring_epoch + FROM _pool_list AS pl + LEFT JOIN _pool_meta AS pm ON pl.pool_id_bech32 = pm.pool_id_bech32 ); END; $$; diff --git a/files/grest/rpc/pool/pool_metadata.sql b/files/grest/rpc/pool/pool_metadata.sql index 872baf18..83bc4a35 100644 --- a/files/grest/rpc/pool/pool_metadata.sql +++ b/files/grest/rpc/pool/pool_metadata.sql @@ -3,32 +3,32 @@ RETURNS TABLE ( pool_id_bech32 character varying, meta_url character varying, meta_hash text, - meta_json jsonb + meta_json jsonb, + pool_status text ) LANGUAGE plpgsql AS $$ #variable_conflict use_column BEGIN RETURN QUERY - SELECT - DISTINCT ON (pic.pool_id_bech32) pool_id_bech32, + SELECT DISTINCT ON (pic.pool_id_bech32) + ph.view AS pool_id_bech32, pic.meta_url, pic.meta_hash, - pod.json - FROM - grest.pool_info_cache AS pic - LEFT JOIN - public.pool_offline_data AS pod ON pod.pmr_id = pic.meta_id + pod.json, + pic.pool_status + FROM grest.pool_hash AS ph + LEFT JOIN grest.pool_infor_cache AS pic ON ph.view = pic.pool_id_bech32 + LEFT JOIN public.pool_offline_data AS pod ON pod.pmr_id = pic.meta_id WHERE - pic.pool_status != 'retired' - AND CASE WHEN _pool_bech32_ids IS NULL THEN TRUE WHEN _pool_bech32_ids IS NOT NULL THEN pic.pool_id_bech32 = ANY(SELECT UNNEST(_pool_bech32_ids)) END ORDER BY - pic.pool_id_bech32, pic.tx_id DESC; + ph.view, + pic.tx_id DESC; END; $$; -COMMENT ON FUNCTION grest.pool_metadata IS 'Metadata(on & off-chain) for all currently registered/retiring (not retired) pools'; -- noqa: LT01 +COMMENT ON FUNCTION grest.pool_metadata IS 'Metadata(on & off-chain) for all pools'; -- noqa: LT01 diff --git a/files/grest/rpc/pool/pool_relays.sql b/files/grest/rpc/pool/pool_relays.sql index 29fd8c28..2b3e2c09 100644 --- a/files/grest/rpc/pool/pool_relays.sql +++ b/files/grest/rpc/pool/pool_relays.sql @@ -1,23 +1,23 @@ CREATE OR REPLACE FUNCTION grest.pool_relays() RETURNS TABLE ( pool_id_bech32 character varying, - relays jsonb [] + relays jsonb [], + pool_status text ) LANGUAGE plpgsql AS $$ #variable_conflict use_column BEGIN RETURN QUERY - SELECT - DISTINCT ON (pool_id_bech32) pool_id_bech32, - relays - FROM - grest.pool_info_cache - WHERE - pool_status != 'retired' + SELECT DISTINCT ON (pool_id_bech32) + pool_id_bech32, + relays, + pool_status + FROM grest.pool_info_cache ORDER BY - pool_id_bech32, tx_id DESC; + pool_id_bech32, + tx_id DESC; END; $$; -COMMENT ON FUNCTION grest.pool_relays IS 'A list of registered relays for all currently registered/retiring (not retired) pools'; --noqa: LT01 +COMMENT ON FUNCTION grest.pool_relays IS 'A list of registered relays for all pools'; --noqa: LT01 diff --git a/files/grest/rpc/script/datum_info.sql b/files/grest/rpc/script/datum_info.sql index 663a1913..e74352fd 100644 --- a/files/grest/rpc/script/datum_info.sql +++ b/files/grest/rpc/script/datum_info.sql @@ -16,7 +16,7 @@ BEGIN ENCODE(d.hash, 'hex'), d.value, ENCODE(d.bytes, 'hex') - FROM + FROM datum AS d WHERE d.hash = ANY(_datum_hashes_decoded); diff --git a/files/grest/rpc/transactions/tx_utxos.sql b/files/grest/rpc/transactions/tx_utxos.sql index af477a70..bda74b2e 100644 --- a/files/grest/rpc/transactions/tx_utxos.sql +++ b/files/grest/rpc/transactions/tx_utxos.sql @@ -66,7 +66,7 @@ BEGIN 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 LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id - WHERE + WHERE tx_in.tx_in_id = ANY(_tx_id_list) ), @@ -97,12 +97,12 @@ BEGIN 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 LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id - WHERE + WHERE tx_out.tx_id = ANY(_tx_id_list) ) SELECT - ENCODE(atx.tx_hash, 'hex'), + ENCODE(atx.tx_hash, 'hex'), COALESCE(( SELECT JSONB_AGG(tx_inputs) FROM ( diff --git a/specs/results/koiosapi-guild.yaml b/specs/results/koiosapi-guild.yaml index 2027146d..5f08be0c 100644 --- a/specs/results/koiosapi-guild.yaml +++ b/specs/results/koiosapi-guild.yaml @@ -1279,7 +1279,7 @@ paths: "404": $ref: "#/components/responses/NotFound" summary: Pool Relays - description: A list of registered relays for all currently registered/retiring (not retired) pools + description: A list of registered relays for all pools /pool_metadata: #RPC post: tags: @@ -1300,7 +1300,7 @@ paths: "404": $ref: "#/components/responses/NotFound" summary: Pool Metadata - description: Metadata (on & off-chain) for all currently registered/retiring (not retired) pools + description: Metadata (on & off-chain) for all pools /native_script_list: #RPC get: tags: @@ -2008,15 +2008,36 @@ components: items: properties: pool_id_bech32: - type: string - nullable: true - description: Bech32 representation of pool ID - example: pool1z5uqdk7dzdxaae5633fqfcu2eqzy3a3rgtuvy087fdld7yws0xt + $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" + pool_id_hex: + $ref: "#/components/schemas/pool_info/items/properties/pool_id_hex" + active_epoch_no: + $ref: "#/components/schemas/pool_info/items/properties/active_epoch_no" + margin: + $ref: "#/components/schemas/pool_info/items/properties/margin" + fixed_cost: + $ref: "#/components/schemas/pool_info/items/properties/fixed_cost" + pledge: + $ref: "#/components/schemas/pool_info/items/properties/pledge" + reward_addr: + $ref: "#/components/schemas/pool_info/items/properties/reward_addr" + owners: + $ref: "#/components/schemas/pool_info/items/properties/margin" + relays: + $ref: "#/components/schemas/pool_info/items/properties/margin" ticker: type: string nullable: true description: Pool ticker - example: JAZZ + example: AHL + meta_url: + $ref: "#/components/schemas/pool_info/items/properties/margin" + meta_hash: + $ref: "#/components/schemas/pool_info/items/properties/margin" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/margin" + retiring_epoch: + $ref: "#/components/schemas/pool_info/items/properties/margin" pool_history_info: type: array items: @@ -2352,6 +2373,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" relays: $ref: "#/components/schemas/pool_info/items/properties/relays" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/pool_status" pool_metadata: type: array items: @@ -2365,6 +2388,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/meta_hash" meta_json: $ref: "#/components/schemas/pool_info/items/properties/meta_json" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/pool_status" epoch_info: type: array items: diff --git a/specs/results/koiosapi-mainnet.yaml b/specs/results/koiosapi-mainnet.yaml index f9d5c3e0..189df453 100644 --- a/specs/results/koiosapi-mainnet.yaml +++ b/specs/results/koiosapi-mainnet.yaml @@ -1279,7 +1279,7 @@ paths: "404": $ref: "#/components/responses/NotFound" summary: Pool Relays - description: A list of registered relays for all currently registered/retiring (not retired) pools + description: A list of registered relays for all pools /pool_metadata: #RPC post: tags: @@ -1300,7 +1300,7 @@ paths: "404": $ref: "#/components/responses/NotFound" summary: Pool Metadata - description: Metadata (on & off-chain) for all currently registered/retiring (not retired) pools + description: Metadata (on & off-chain) for all pools /native_script_list: #RPC get: tags: @@ -2008,15 +2008,36 @@ components: items: properties: pool_id_bech32: - type: string - nullable: true - description: Bech32 representation of pool ID - example: pool1z5uqdk7dzdxaae5633fqfcu2eqzy3a3rgtuvy087fdld7yws0xt + $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" + pool_id_hex: + $ref: "#/components/schemas/pool_info/items/properties/pool_id_hex" + active_epoch_no: + $ref: "#/components/schemas/pool_info/items/properties/active_epoch_no" + margin: + $ref: "#/components/schemas/pool_info/items/properties/margin" + fixed_cost: + $ref: "#/components/schemas/pool_info/items/properties/fixed_cost" + pledge: + $ref: "#/components/schemas/pool_info/items/properties/pledge" + reward_addr: + $ref: "#/components/schemas/pool_info/items/properties/reward_addr" + owners: + $ref: "#/components/schemas/pool_info/items/properties/margin" + relays: + $ref: "#/components/schemas/pool_info/items/properties/margin" ticker: type: string nullable: true description: Pool ticker - example: JAZZ + example: AHL + meta_url: + $ref: "#/components/schemas/pool_info/items/properties/margin" + meta_hash: + $ref: "#/components/schemas/pool_info/items/properties/margin" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/margin" + retiring_epoch: + $ref: "#/components/schemas/pool_info/items/properties/margin" pool_history_info: type: array items: @@ -2352,6 +2373,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" relays: $ref: "#/components/schemas/pool_info/items/properties/relays" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/pool_status" pool_metadata: type: array items: @@ -2365,6 +2388,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/meta_hash" meta_json: $ref: "#/components/schemas/pool_info/items/properties/meta_json" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/pool_status" epoch_info: type: array items: diff --git a/specs/results/koiosapi-preprod.yaml b/specs/results/koiosapi-preprod.yaml index 6d956f7c..c353851f 100644 --- a/specs/results/koiosapi-preprod.yaml +++ b/specs/results/koiosapi-preprod.yaml @@ -1279,7 +1279,7 @@ paths: "404": $ref: "#/components/responses/NotFound" summary: Pool Relays - description: A list of registered relays for all currently registered/retiring (not retired) pools + description: A list of registered relays for all pools /pool_metadata: #RPC post: tags: @@ -1300,7 +1300,7 @@ paths: "404": $ref: "#/components/responses/NotFound" summary: Pool Metadata - description: Metadata (on & off-chain) for all currently registered/retiring (not retired) pools + description: Metadata (on & off-chain) for all pools /native_script_list: #RPC get: tags: @@ -2008,15 +2008,36 @@ components: items: properties: pool_id_bech32: - type: string - nullable: true - description: Bech32 representation of pool ID - example: pool1z5uqdk7dzdxaae5633fqfcu2eqzy3a3rgtuvy087fdld7yws0xt + $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" + pool_id_hex: + $ref: "#/components/schemas/pool_info/items/properties/pool_id_hex" + active_epoch_no: + $ref: "#/components/schemas/pool_info/items/properties/active_epoch_no" + margin: + $ref: "#/components/schemas/pool_info/items/properties/margin" + fixed_cost: + $ref: "#/components/schemas/pool_info/items/properties/fixed_cost" + pledge: + $ref: "#/components/schemas/pool_info/items/properties/pledge" + reward_addr: + $ref: "#/components/schemas/pool_info/items/properties/reward_addr" + owners: + $ref: "#/components/schemas/pool_info/items/properties/margin" + relays: + $ref: "#/components/schemas/pool_info/items/properties/margin" ticker: type: string nullable: true description: Pool ticker - example: JAZZ + example: AHL + meta_url: + $ref: "#/components/schemas/pool_info/items/properties/margin" + meta_hash: + $ref: "#/components/schemas/pool_info/items/properties/margin" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/margin" + retiring_epoch: + $ref: "#/components/schemas/pool_info/items/properties/margin" pool_history_info: type: array items: @@ -2352,6 +2373,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" relays: $ref: "#/components/schemas/pool_info/items/properties/relays" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/pool_status" pool_metadata: type: array items: @@ -2365,6 +2388,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/meta_hash" meta_json: $ref: "#/components/schemas/pool_info/items/properties/meta_json" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/pool_status" epoch_info: type: array items: diff --git a/specs/results/koiosapi-preview.yaml b/specs/results/koiosapi-preview.yaml index debc78c1..6f56b8a3 100644 --- a/specs/results/koiosapi-preview.yaml +++ b/specs/results/koiosapi-preview.yaml @@ -1279,7 +1279,7 @@ paths: "404": $ref: "#/components/responses/NotFound" summary: Pool Relays - description: A list of registered relays for all currently registered/retiring (not retired) pools + description: A list of registered relays for all pools /pool_metadata: #RPC post: tags: @@ -1300,7 +1300,7 @@ paths: "404": $ref: "#/components/responses/NotFound" summary: Pool Metadata - description: Metadata (on & off-chain) for all currently registered/retiring (not retired) pools + description: Metadata (on & off-chain) for all pools /native_script_list: #RPC get: tags: @@ -2008,15 +2008,36 @@ components: items: properties: pool_id_bech32: - type: string - nullable: true - description: Bech32 representation of pool ID - example: pool1z5uqdk7dzdxaae5633fqfcu2eqzy3a3rgtuvy087fdld7yws0xt + $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" + pool_id_hex: + $ref: "#/components/schemas/pool_info/items/properties/pool_id_hex" + active_epoch_no: + $ref: "#/components/schemas/pool_info/items/properties/active_epoch_no" + margin: + $ref: "#/components/schemas/pool_info/items/properties/margin" + fixed_cost: + $ref: "#/components/schemas/pool_info/items/properties/fixed_cost" + pledge: + $ref: "#/components/schemas/pool_info/items/properties/pledge" + reward_addr: + $ref: "#/components/schemas/pool_info/items/properties/reward_addr" + owners: + $ref: "#/components/schemas/pool_info/items/properties/margin" + relays: + $ref: "#/components/schemas/pool_info/items/properties/margin" ticker: type: string nullable: true description: Pool ticker - example: JAZZ + example: AHL + meta_url: + $ref: "#/components/schemas/pool_info/items/properties/margin" + meta_hash: + $ref: "#/components/schemas/pool_info/items/properties/margin" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/margin" + retiring_epoch: + $ref: "#/components/schemas/pool_info/items/properties/margin" pool_history_info: type: array items: @@ -2352,6 +2373,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" relays: $ref: "#/components/schemas/pool_info/items/properties/relays" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/pool_status" pool_metadata: type: array items: @@ -2365,6 +2388,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/meta_hash" meta_json: $ref: "#/components/schemas/pool_info/items/properties/meta_json" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/pool_status" epoch_info: type: array items: diff --git a/specs/templates/4-api-schemas.yaml b/specs/templates/4-api-schemas.yaml index 09703f3a..af1067a8 100644 --- a/specs/templates/4-api-schemas.yaml +++ b/specs/templates/4-api-schemas.yaml @@ -116,15 +116,36 @@ schemas: items: properties: pool_id_bech32: - type: string - nullable: true - description: Bech32 representation of pool ID - example: pool1z5uqdk7dzdxaae5633fqfcu2eqzy3a3rgtuvy087fdld7yws0xt + $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" + pool_id_hex: + $ref: "#/components/schemas/pool_info/items/properties/pool_id_hex" + active_epoch_no: + $ref: "#/components/schemas/pool_info/items/properties/active_epoch_no" + margin: + $ref: "#/components/schemas/pool_info/items/properties/margin" + fixed_cost: + $ref: "#/components/schemas/pool_info/items/properties/fixed_cost" + pledge: + $ref: "#/components/schemas/pool_info/items/properties/pledge" + reward_addr: + $ref: "#/components/schemas/pool_info/items/properties/reward_addr" + owners: + $ref: "#/components/schemas/pool_info/items/properties/margin" + relays: + $ref: "#/components/schemas/pool_info/items/properties/margin" ticker: type: string nullable: true description: Pool ticker - example: JAZZ + example: AHL + meta_url: + $ref: "#/components/schemas/pool_info/items/properties/margin" + meta_hash: + $ref: "#/components/schemas/pool_info/items/properties/margin" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/margin" + retiring_epoch: + $ref: "#/components/schemas/pool_info/items/properties/margin" pool_history_info: type: array items: @@ -460,6 +481,8 @@ schemas: $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" relays: $ref: "#/components/schemas/pool_info/items/properties/relays" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/pool_status" pool_metadata: type: array items: @@ -473,6 +496,8 @@ schemas: $ref: "#/components/schemas/pool_info/items/properties/meta_hash" meta_json: $ref: "#/components/schemas/pool_info/items/properties/meta_json" + pool_status: + $ref: "#/components/schemas/pool_info/items/properties/pool_status" epoch_info: type: array items: diff --git a/specs/templates/api-main.yaml b/specs/templates/api-main.yaml index c411c04d..aad6ba54 100644 --- a/specs/templates/api-main.yaml +++ b/specs/templates/api-main.yaml @@ -1138,7 +1138,7 @@ paths: "404": $ref: "#/components/responses/NotFound" summary: Pool Relays - description: A list of registered relays for all currently registered/retiring (not retired) pools + description: A list of registered relays for all pools /pool_metadata: #RPC post: tags: @@ -1159,7 +1159,7 @@ paths: "404": $ref: "#/components/responses/NotFound" summary: Pool Metadata - description: Metadata (on & off-chain) for all currently registered/retiring (not retired) pools + description: Metadata (on & off-chain) for all pools /native_script_list: #RPC get: tags: From d1bc2df02e1388b541590cf4ee703497d5e7b4b2 Mon Sep 17 00:00:00 2001 From: Priyank <3169068+rdlrt@users.noreply.github.com> Date: Wed, 16 Aug 2023 12:47:21 +1000 Subject: [PATCH 2/4] Bump spec version and Align pool_info to be same as pool_list/pool_metadata --- files/grest/rpc/pool/pool_info.sql | 29 ++++++++++------------------- specs/results/koiosapi-guild.yaml | 2 +- specs/results/koiosapi-mainnet.yaml | 2 +- specs/results/koiosapi-preprod.yaml | 2 +- specs/results/koiosapi-preview.yaml | 2 +- specs/templates/1-api-info.yaml | 2 +- 6 files changed, 15 insertions(+), 24 deletions(-) diff --git a/files/grest/rpc/pool/pool_info.sql b/files/grest/rpc/pool/pool_info.sql index 50a12023..203f7d40 100644 --- a/files/grest/rpc/pool/pool_info.sql +++ b/files/grest/rpc/pool/pool_info.sql @@ -77,22 +77,13 @@ BEGIN ROUND((live.stake / _saturation_limit) * 100, 2) FROM _all_pool_info AS api LEFT JOIN LATERAL ( - ( - SELECT pod.json - FROM public.pool_offline_data AS pod - WHERE pod.pool_id = api.pool_hash_id - AND pod.pmr_id = api.meta_id - ) - UNION ALL - ( - SELECT pod.json - FROM public.pool_offline_data AS pod - WHERE pod.pool_id = api.pool_hash_id - AND pod.json IS NOT NULL - ORDER BY pod.pmr_id DESC - ) + SELECT pod.json + FROM public.pool_offline_data AS pod + WHERE pod.pool_id = api.pool_hash_id + AND pod.pmr_id = api.meta_id + ORDER BY pod.pmr_id DESC LIMIT 1 - ) offline_data ON TRUE + ) AS offline_data ON TRUE LEFT JOIN LATERAL ( SELECT SUM(COUNT(b.id)) OVER () AS cnt, @@ -106,18 +97,18 @@ BEGIN b.op_cert_counter ORDER BY b.op_cert_counter DESC LIMIT 1 - ) block_data ON TRUE + ) AS block_data ON TRUE LEFT JOIN LATERAL( SELECT amount::lovelace AS as_sum FROM grest.pool_active_stake_cache AS pasc WHERE pasc.pool_id = api.pool_id_bech32 AND pasc.epoch_no = _epoch_no - ) active_stake ON TRUE + ) AS active_stake ON TRUE LEFT JOIN LATERAL( SELECT amount::lovelace AS es_sum FROM grest.epoch_active_stake_cache AS easc WHERE easc.epoch_no = _epoch_no - ) epoch_stake ON TRUE + ) AS epoch_stake ON TRUE LEFT JOIN LATERAL( SELECT CASE WHEN api.pool_status = 'retired' @@ -138,7 +129,7 @@ BEGIN END AS pledge FROM grest.stake_distribution_cache AS sdc WHERE sdc.pool_id = api.pool_id_bech32 - ) live ON TRUE; + ) AS live ON TRUE; END; $$; diff --git a/specs/results/koiosapi-guild.yaml b/specs/results/koiosapi-guild.yaml index 5f08be0c..6b9736ce 100644 --- a/specs/results/koiosapi-guild.yaml +++ b/specs/results/koiosapi-guild.yaml @@ -1,7 +1,7 @@ openapi: 3.0.2 info: title: Koios API - version: 1.0.10 + version: 1.0.11rc 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/results/koiosapi-mainnet.yaml b/specs/results/koiosapi-mainnet.yaml index 189df453..1495a9bd 100644 --- a/specs/results/koiosapi-mainnet.yaml +++ b/specs/results/koiosapi-mainnet.yaml @@ -1,7 +1,7 @@ openapi: 3.0.2 info: title: Koios API - version: 1.0.10 + version: 1.0.11rc 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/results/koiosapi-preprod.yaml b/specs/results/koiosapi-preprod.yaml index c353851f..35a6ef3e 100644 --- a/specs/results/koiosapi-preprod.yaml +++ b/specs/results/koiosapi-preprod.yaml @@ -1,7 +1,7 @@ openapi: 3.0.2 info: title: Koios API - version: 1.0.10 + version: 1.0.11rc 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/results/koiosapi-preview.yaml b/specs/results/koiosapi-preview.yaml index 6f56b8a3..90010439 100644 --- a/specs/results/koiosapi-preview.yaml +++ b/specs/results/koiosapi-preview.yaml @@ -1,7 +1,7 @@ openapi: 3.0.2 info: title: Koios API - version: 1.0.10 + version: 1.0.11rc 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/1-api-info.yaml b/specs/templates/1-api-info.yaml index 656eaf17..d95261aa 100644 --- a/specs/templates/1-api-info.yaml +++ b/specs/templates/1-api-info.yaml @@ -1,6 +1,6 @@ info: title: Koios API - version: 1.0.10 + version: 1.0.11rc 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. From c1bc99a1d61fb4ba0c36e9e1a2c5af056bcbd531 Mon Sep 17 00:00:00 2001 From: Priyank <3169068+rdlrt@users.noreply.github.com> Date: Thu, 24 Aug 2023 14:14:28 +1000 Subject: [PATCH 3/4] Align *_txs to return consistent data --- files/grest/rpc/account/account_addresses.sql | 10 +- files/grest/rpc/account/account_assets.sql | 6 +- files/grest/rpc/account/account_info.sql | 13 +-- files/grest/rpc/account/account_txs.sql | 53 +++++++++ files/grest/rpc/account/account_utxos.sql | 88 +++++++++++---- files/grest/rpc/address/address_assets.sql | 16 ++- files/grest/rpc/address/address_info.sql | 6 +- files/grest/rpc/address/address_txs.sql | 39 +++---- files/grest/rpc/address/address_utxos.sql | 82 ++++++++++++++ files/grest/rpc/address/credential_txs.sql | 44 ++++---- files/grest/rpc/address/credential_utxos.sql | 80 +++++++++++--- files/grest/rpc/assets/asset_addresses.sql | 33 +++--- files/grest/rpc/assets/asset_txs.sql | 26 ++--- files/grest/rpc/assets/asset_utxos.sql | 95 ++++++++++++++++ .../rpc/assets/policy_asset_addresses.sql | 18 ++-- files/grest/rpc/blocks/block_txs.sql | 19 ++-- files/grest/rpc/transactions/utxo_info.sql | 102 ++++++++++++++++++ 17 files changed, 563 insertions(+), 167 deletions(-) create mode 100644 files/grest/rpc/account/account_txs.sql create mode 100644 files/grest/rpc/address/address_utxos.sql create mode 100644 files/grest/rpc/assets/asset_utxos.sql create mode 100644 files/grest/rpc/transactions/utxo_info.sql diff --git a/files/grest/rpc/account/account_addresses.sql b/files/grest/rpc/account/account_addresses.sql index 51f9a7b6..5cf301e4 100644 --- a/files/grest/rpc/account/account_addresses.sql +++ b/files/grest/rpc/account/account_addresses.sql @@ -27,13 +27,10 @@ BEGIN txo.address, txo.stake_address_id, txo.id - FROM - tx_out AS txo - LEFT JOIN tx_in ON txo.tx_id = tx_in.tx_out_id - AND txo.index::smallint = tx_in.tx_out_index::smallint + FROM tx_out AS txo WHERE txo.stake_address_id = ANY(sa_id_list) - AND tx_in.tx_out_id IS NULL + AND tx_out.consumed_by_tx_in_id IS NULL ) AS x ) @@ -57,8 +54,7 @@ BEGIN txo.address, txo.stake_address_id, txo.id - FROM - tx_out AS txo + FROM tx_out AS txo WHERE txo.stake_address_id = ANY(sa_id_list) LIMIT (CASE WHEN _first_only IS TRUE THEN 1 ELSE NULL END) diff --git a/files/grest/rpc/account/account_assets.sql b/files/grest/rpc/account/account_assets.sql index 06397515..2c8fd1ed 100644 --- a/files/grest/rpc/account/account_assets.sql +++ b/files/grest/rpc/account/account_assets.sql @@ -29,11 +29,9 @@ BEGIN INNER JOIN tx_out AS txo ON txo.id = mtx.tx_out_id INNER JOIN stake_address AS sa ON sa.id = txo.stake_address_id LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id - LEFT JOIN tx_in ON txo.tx_id = tx_in.tx_out_id - AND txo.index::smallint = tx_in.tx_out_index::smallint WHERE sa.id = ANY(sa_id_list) - AND tx_in.tx_out_id IS NULL + AND tx_out.consumed_by_tx_in_id IS NULL GROUP BY sa.view, ma.policy, ma.name, ma.fingerprint, aic.decimals ) @@ -61,4 +59,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.account_assets IS 'Get the native asset balance of given accounts'; -- noqa: LT01 +COMMENT ON FUNCTION grest.account_assets IS 'Get the native asset balance of given accounts'; -- noqa: LT01 \ No newline at end of file diff --git a/files/grest/rpc/account/account_info.sql b/files/grest/rpc/account/account_info.sql index e2149b5b..213e3aaa 100644 --- a/files/grest/rpc/account/account_info.sql +++ b/files/grest/rpc/account/account_info.sql @@ -109,15 +109,10 @@ BEGIN SELECT tx_out.stake_address_id, COALESCE(SUM(VALUE), 0) AS utxo - FROM - tx_out - LEFT JOIN tx_in ON tx_out.tx_id = tx_in.tx_out_id - AND tx_out.index::smallint = tx_in.tx_out_index::smallint - WHERE - tx_out.stake_address_id = ANY(sa_id_list) - AND tx_in.tx_out_id IS NULL - GROUP BY - tx_out.stake_address_id + FROM tx_out + WHERE tx_out.stake_address_id = ANY(sa_id_list) + AND tx_out.consumed_by_tx_in_id IS NULL + GROUP BY tx_out.stake_address_id ) AS utxo_t ON utxo_t.stake_address_id = status_t.id LEFT JOIN ( SELECT diff --git a/files/grest/rpc/account/account_txs.sql b/files/grest/rpc/account/account_txs.sql new file mode 100644 index 00000000..bcf8c76b --- /dev/null +++ b/files/grest/rpc/account/account_txs.sql @@ -0,0 +1,53 @@ +CREATE OR REPLACE FUNCTION grest.account_txs(_stake_address text, _after_block_height integer DEFAULT 0) +RETURNS TABLE ( + tx_hash text, + epoch_no word31type, + block_height word31type, + block_time integer +) +LANGUAGE plpgsql +AS $$ +DECLARE + _tx_id_min bigint; + _tx_id_list bigint[]; +BEGIN + SELECT INTO _tx_id_min id + FROM tx + WHERE block_id >= (SELECT id FROM block WHERE block_no >= _after_block_height ORDER BY id limit 1) + ORDER BY id limit 1; + + -- all tx_out & tx_in tx ids + SELECT INTO _tx_id_list ARRAY_AGG(tx_id) + FROM ( + SELECT tx_id + FROM tx_out + WHERE stake_address_id = ANY(SELECT id FROM stake_address WHERE view = _stake_address) + AND tx_id >= _tx_id_min + -- + UNION + -- + SELECT tx_in_id AS tx_id + FROM tx_out + LEFT JOIN tx_in ON tx_out.tx_id = tx_in.tx_out_id + AND tx_out.index = tx_in.tx_out_index + WHERE + tx_in.tx_in_id IS NOT NULL + AND tx_out.stake_address_id = ANY(SELECT id FROM stake_address WHERE view = _stake_address) + AND tx_in.tx_in_id >= _tx_id_min + ) AS tmp; + + RETURN QUERY + SELECT + DISTINCT(ENCODE(tx.hash, 'hex')) AS tx_hash, + b.epoch_no, + b.block_no AS block_height, + EXTRACT(EPOCH FROM b.time)::integer AS block_time + FROM public.tx + INNER JOIN public.block AS b ON b.id = tx.block_id + WHERE tx.id = ANY(_tx_id_list) + AND block.block_no >= _after_block_height + ORDER BY block.block_no DESC; +END; +$$; + +COMMENT ON FUNCTION grest.account_txs IS 'Get transactions associated with a given stake address'; -- noqa: LT01 diff --git a/files/grest/rpc/account/account_utxos.sql b/files/grest/rpc/account/account_utxos.sql index 2692104d..2737a375 100644 --- a/files/grest/rpc/account/account_utxos.sql +++ b/files/grest/rpc/account/account_utxos.sql @@ -1,34 +1,82 @@ -CREATE OR REPLACE FUNCTION grest.account_utxos(_stake_address text) +CREATE OR REPLACE FUNCTION grest.account_utxos(_stake_addresses text [], _extended boolean DEFAULT false) RETURNS TABLE ( tx_hash text, tx_index smallint, - address varchar, + address text, value text, + stake_address text, + payment_cred text, + epoch_no word31type, block_height word31type, - block_time integer + block_time integer, + datum_hash text, + inline_datum jsonb, + reference_script jsonb, + asset_list jsonb, + is_spent boolean ) LANGUAGE plpgsql AS $$ +DECLARE + known_addresses varchar[]; BEGIN RETURN QUERY - SELECT - ENCODE(tx.hash,'hex') AS tx_hash, - tx_out.index::smallint AS tx_index, - tx_out.address, - tx_out.value::text AS value, - b.block_no AS block_height, - EXTRACT(EPOCH FROM b.time)::integer AS block_time - FROM - tx_out - LEFT JOIN tx_in ON tx_in.tx_out_id = tx_out.tx_id - AND tx_in.tx_out_index = tx_out.index - INNER JOIN tx ON tx.id = tx_out.tx_id + SELECT + ENCODE(tx.hash, 'hex')::text AS tx_hash, + tx_out.index::smallint, + tx_out.address::text, + tx_out.value::text, + sa.view::text as stake_address, + ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + b.epoch_no, + b.block_no, + EXTRACT(EPOCH FROM b.time)::integer AS block_time, + ENCODE(tx_out.data_hash, 'hex') AS datum_hash, + (CASE + WHEN _extended = false OR tx_out.inline_datum_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'bytes', ENCODE(datum.bytes, 'hex'), + 'value', datum.value + ) + END) AS inline_datum, + (CASE + WHEN _extended = false OR tx_out.reference_script_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'hash', ENCODE(script.hash, 'hex'), + 'bytes', ENCODE(script.bytes, 'hex'), + 'value', script.json, + 'type', script.type::text, + 'size', script.serialised_size + ) + END) AS reference_script, + (CASE + WHEN _extended = false OR ma.policy IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'policy_id', ENCODE(ma.policy, 'hex'), + 'asset_name', ENCODE(ma.name, 'hex'), + 'fingerprint', ma.fingerprint, + 'decimals', aic.decimals, + 'quantity', mto.quantity::text + ) + END + ) AS asset_list, + (CASE + WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false + ELSE true + END) AS is_spent + FROM tx_out + 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 - WHERE - tx_in.tx_out_id IS NULL - AND - tx_out.stake_address_id = (SELECT id FROM stake_address WHERE view = _stake_address); + 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 + LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id + LEFT JOIN datum ON datum.id = tx_out.inline_datum_id + LEFT JOIN script ON script.id = tx_out.reference_script_id + WHERE + tx_out.stake_address_id IN (SELECT sa.id FROM stake_address AS sa WHERE sa.view = ANY(_stake_addresses)) + ; END; $$; -COMMENT ON FUNCTION grest.account_utxos IS 'Get non-empty UTxOs associated with a given stake address'; -- noqa: LT01 +COMMENT ON FUNCTION grest.address_utxos IS 'Get UTxO details for requested addresses'; -- noqa: LT01 \ No newline at end of file diff --git a/files/grest/rpc/address/address_assets.sql b/files/grest/rpc/address/address_assets.sql index 274d0c62..8f25abf7 100644 --- a/files/grest/rpc/address/address_assets.sql +++ b/files/grest/rpc/address/address_assets.sql @@ -16,16 +16,12 @@ BEGIN ma.fingerprint, COALESCE(aic.decimals, 0) AS decimals, SUM(mtx.quantity) AS quantity - FROM - ma_tx_out AS mtx - 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 - LEFT JOIN tx_in ON txo.tx_id = tx_in.tx_out_id - AND txo.index::smallint = tx_in.tx_out_index::smallint - WHERE - txo.address = ANY(_addresses) - AND tx_in.tx_out_id IS NULL + FROM ma_tx_out AS mtx + 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) + AND tx_out.consumed_by_tx_in_id IS NULL GROUP BY txo.address, ma.policy, ma.name, ma.fingerprint, aic.decimals ) diff --git a/files/grest/rpc/address/address_info.sql b/files/grest/rpc/address/address_info.sql index 2ac829ca..3c4ee367 100644 --- a/files/grest/rpc/address/address_info.sql +++ b/files/grest/rpc/address/address_info.sql @@ -34,10 +34,8 @@ BEGIN tx_out.inline_datum_id, tx_out.reference_script_id FROM tx_out - LEFT JOIN tx_in ON tx_in.tx_out_id = tx_out.tx_id - AND tx_in.tx_out_index = tx_out.index INNER JOIN tx ON tx.id = tx_out.tx_id - WHERE tx_in.tx_out_id IS NULL + WHERE tx_out.consumed_by_tx_in_id IS NULL AND tx_out.address = ANY(_addresses) ) @@ -118,4 +116,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.address_info IS 'Get bulk address info - balance, associated stake address (if any) and UTXO set'; -- noqa: LT01 +COMMENT ON FUNCTION grest.address_info IS 'Get bulk address info - balance, associated stake address (if any) and UTXO set'; -- noqa: LT01 \ No newline at end of file diff --git a/files/grest/rpc/address/address_txs.sql b/files/grest/rpc/address/address_txs.sql index 840be398..743ea71f 100644 --- a/files/grest/rpc/address/address_txs.sql +++ b/files/grest/rpc/address/address_txs.sql @@ -19,24 +19,18 @@ BEGIN -- all tx_out & tx_in tx ids SELECT INTO _tx_id_list ARRAY_AGG(tx_id) FROM ( - SELECT - tx_id - FROM - tx_out - WHERE - address = ANY(_addresses) + SELECT tx_id + FROM tx_out + WHERE address = ANY(_addresses) AND tx_id >= _tx_id_min -- UNION -- - SELECT - tx_in_id AS tx_id - FROM - tx_out - LEFT JOIN tx_in ON tx_out.tx_id = tx_in.tx_out_id - AND tx_out.index = tx_in.tx_out_index - WHERE - tx_in.tx_in_id IS NOT NULL + SELECT tx_in_id AS tx_id + FROM tx_out + LEFT JOIN tx_in ON tx_out.tx_id = tx_in.tx_out_id + AND tx_out.index = tx_in.tx_out_index + WHERE tx_in.tx_in_id IS NOT NULL AND tx_out.address = ANY(_addresses) AND tx_in.tx_in_id >= _tx_id_min ) AS tmp; @@ -44,17 +38,14 @@ BEGIN RETURN QUERY SELECT DISTINCT(ENCODE(tx.hash, 'hex')) AS tx_hash, - block.epoch_no, - block.block_no, - EXTRACT(EPOCH FROM block.time)::integer - FROM - public.tx - INNER JOIN public.block ON block.id = tx.block_id - WHERE - tx.id = ANY(_tx_id_list) + b.epoch_no, + b.block_no AS block_height, + EXTRACT(EPOCH FROM b.time)::integer AS block_time + FROM public.tx + INNER JOIN public.block AS b ON b.id = tx.block_id + WHERE tx.id = ANY(_tx_id_list) AND block.block_no >= _after_block_height - ORDER BY - block.block_no DESC; + ORDER BY block.block_no DESC; END; $$; diff --git a/files/grest/rpc/address/address_utxos.sql b/files/grest/rpc/address/address_utxos.sql new file mode 100644 index 00000000..c5b14ade --- /dev/null +++ b/files/grest/rpc/address/address_utxos.sql @@ -0,0 +1,82 @@ +CREATE OR REPLACE FUNCTION grest.address_utxos(_addresses text [], _extended boolean DEFAULT false) +RETURNS TABLE ( + tx_hash text, + tx_index smallint, + address text, + value text, + stake_address text, + payment_cred text, + epoch_no word31type, + block_height word31type, + block_time integer, + datum_hash text, + inline_datum jsonb, + reference_script jsonb, + asset_list jsonb, + is_spent boolean +) +LANGUAGE plpgsql +AS $$ +DECLARE + known_addresses varchar[]; +BEGIN + RETURN QUERY + SELECT + ENCODE(tx.hash, 'hex')::text AS tx_hash, + tx_out.index::smallint, + tx_out.address::text, + tx_out.value::text, + sa.view::text as stake_address, + ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + b.epoch_no, + b.block_no, + EXTRACT(EPOCH FROM b.time)::integer AS block_time, + ENCODE(tx_out.data_hash, 'hex') AS datum_hash, + (CASE + WHEN _extended = false OR tx_out.inline_datum_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'bytes', ENCODE(datum.bytes, 'hex'), + 'value', datum.value + ) + END) AS inline_datum, + (CASE + WHEN _extended = false OR tx_out.reference_script_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'hash', ENCODE(script.hash, 'hex'), + 'bytes', ENCODE(script.bytes, 'hex'), + 'value', script.json, + 'type', script.type::text, + 'size', script.serialised_size + ) + END) AS reference_script, + (CASE + WHEN _extended = false OR ma.policy IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'policy_id', ENCODE(ma.policy, 'hex'), + 'asset_name', ENCODE(ma.name, 'hex'), + 'fingerprint', ma.fingerprint, + 'decimals', aic.decimals, + 'quantity', mto.quantity::text + ) + END + ) AS asset_list, + (CASE + WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false + ELSE true + END) AS is_spent + FROM tx_out + 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 ma_tx_out AS mto ON mto.tx_out_id = tx_out.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 + LEFT JOIN datum ON datum.id = tx_out.inline_datum_id + LEFT JOIN script ON script.id = tx_out.reference_script_id + WHERE + tx_out.address = ANY(_addresses) + ; +END; +$$; + +COMMENT ON FUNCTION grest.address_utxos IS 'Get UTxO details for requested addresses'; -- noqa: LT01 \ No newline at end of file diff --git a/files/grest/rpc/address/credential_txs.sql b/files/grest/rpc/address/credential_txs.sql index d581858a..e3ad6a4e 100644 --- a/files/grest/rpc/address/credential_txs.sql +++ b/files/grest/rpc/address/credential_txs.sql @@ -16,34 +16,29 @@ BEGIN SELECT INTO _payment_cred_bytea ARRAY_AGG(cred_bytea) FROM ( SELECT DECODE(cred_hex, 'hex') AS cred_bytea - FROM - UNNEST(_payment_credentials) AS cred_hex + FROM UNNEST(_payment_credentials) AS cred_hex ) AS tmp; SELECT INTO _tx_id_min id - FROM tx - WHERE block_id >= (SELECT id FROM block WHERE block_no = _after_block_height) - ORDER BY id limit 1; + FROM tx + WHERE block_id >= (SELECT id FROM block WHERE block_no >= _after_block_height ORDER BY id limit 1) + ORDER BY id limit 1; -- all tx_out & tx_in tx ids SELECT INTO _tx_id_list ARRAY_AGG(tx_id) FROM ( SELECT tx_id - FROM - tx_out - WHERE - payment_cred = ANY(_payment_cred_bytea) + FROM tx_out + WHERE payment_cred = ANY(_payment_cred_bytea) AND tx_id >= _tx_id_min -- UNION -- SELECT tx_in_id AS tx_id - FROM - tx_out - LEFT JOIN tx_in ON tx_out.tx_id = tx_in.tx_out_id - AND tx_out.index = tx_in.tx_out_index - WHERE - tx_in.tx_in_id IS NOT NULL + FROM tx_out + LEFT JOIN tx_in ON tx_out.tx_id = tx_in.tx_out_id + AND tx_out.index = tx_in.tx_out_index + WHERE tx_in.tx_in_id IS NOT NULL AND tx_out.payment_cred = ANY(_payment_cred_bytea) AND tx_in.tx_in_id >= _tx_id_min ) AS tmp; @@ -51,18 +46,15 @@ BEGIN RETURN QUERY SELECT DISTINCT(ENCODE(tx.hash, 'hex')) AS tx_hash, - block.epoch_no, - block.block_no, - EXTRACT(EPOCH FROM block.time)::integer - FROM - public.tx - INNER JOIN public.block ON block.id = tx.block_id - WHERE - tx.id = ANY(_tx_id_list) + b.epoch_no, + b.block_no AS block_height, + EXTRACT(EPOCH FROM b.time)::integer AS block_time + FROM public.tx + INNER JOIN public.block AS b ON b.id = tx.block_id + WHERE tx.id = ANY(_tx_id_list) AND block.block_no >= _after_block_height - ORDER BY - block.block_no DESC; + ORDER BY block.block_no DESC; END; $$; -COMMENT ON FUNCTION grest.address_txs IS 'Get the transaction hash list of a payment credentials array, optionally filtering after specified block height (inclusive).'; --noqa: LT01 +COMMENT ON FUNCTION grest.credential_txs IS 'Get the transaction hash list of a payment credentials array, optionally filtering after specified block height (inclusive).'; --noqa: LT01 diff --git a/files/grest/rpc/address/credential_utxos.sql b/files/grest/rpc/address/credential_utxos.sql index 6d9d4677..76f71d86 100644 --- a/files/grest/rpc/address/credential_utxos.sql +++ b/files/grest/rpc/address/credential_utxos.sql @@ -1,34 +1,88 @@ -CREATE OR REPLACE FUNCTION grest.credential_utxos(_payment_credentials text []) +CREATE OR REPLACE FUNCTION grest.credential_utxos(_payment_credentials text [], _extended boolean DEFAULT false) RETURNS TABLE ( tx_hash text, tx_index smallint, - value text + address text, + value text, + stake_address text, + payment_cred text, + epoch_no word31type, + block_height word31type, + block_time integer, + datum_hash text, + inline_datum jsonb, + reference_script jsonb, + asset_list jsonb, + is_spent boolean ) LANGUAGE plpgsql AS $$ DECLARE _payment_cred_bytea bytea[]; - BEGIN SELECT INTO _payment_cred_bytea ARRAY_AGG(cred_bytea) FROM ( - SELECT - DECODE(cred_hex, 'hex') AS cred_bytea - FROM - UNNEST(_payment_credentials) AS cred_hex + SELECT DECODE(cred_hex, 'hex') AS cred_bytea + FROM UNNEST(_payment_credentials) AS cred_hex ) AS tmp; RETURN QUERY SELECT ENCODE(tx.hash, 'hex')::text AS tx_hash, tx_out.index::smallint, - tx_out.value::text AS balance + tx_out.address::text, + tx_out.value::text, + sa.view::text as stake_address, + ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + b.epoch_no, + b.block_no, + EXTRACT(EPOCH FROM b.time)::integer AS block_time, + ENCODE(tx_out.data_hash, 'hex') AS datum_hash, + (CASE + WHEN _extended = false OR tx_out.inline_datum_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'bytes', ENCODE(datum.bytes, 'hex'), + 'value', datum.value + ) + END) AS inline_datum, + (CASE + WHEN _extended = false OR tx_out.reference_script_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'hash', ENCODE(script.hash, 'hex'), + 'bytes', ENCODE(script.bytes, 'hex'), + 'value', script.json, + 'type', script.type::text, + 'size', script.serialised_size + ) + END) AS reference_script, + (CASE + WHEN _extended = false OR ma.policy IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'policy_id', ENCODE(ma.policy, 'hex'), + 'asset_name', ENCODE(ma.name, 'hex'), + 'fingerprint', ma.fingerprint, + 'decimals', aic.decimals, + 'quantity', mto.quantity::text + ) + END + ) AS asset_list, + (CASE + WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false + ELSE true + END) AS is_spent FROM tx_out - INNER JOIN tx ON tx_out.tx_id = tx.id - LEFT JOIN tx_in ON tx_out.tx_id = tx_in.tx_out_id - AND tx_out.index = tx_in.tx_out_index + 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 ma_tx_out AS mto ON mto.tx_out_id = tx_out.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 + LEFT JOIN datum ON datum.id = tx_out.inline_datum_id + LEFT JOIN script ON script.id = tx_out.reference_script_id WHERE - payment_cred = ANY(_payment_cred_bytea) - AND tx_in.tx_out_id IS NULL; + tx_out.payment_cred = ANY(_payment_cred_bytea) + ; END; $$; + +COMMENT ON FUNCTION grest.credential_utxos IS 'Get UTxO details for requested payment credentials'; -- noqa: LT01 \ No newline at end of file diff --git a/files/grest/rpc/assets/asset_addresses.sql b/files/grest/rpc/assets/asset_addresses.sql index 3344d395..8216671c 100644 --- a/files/grest/rpc/assets/asset_addresses.sql +++ b/files/grest/rpc/assets/asset_addresses.sql @@ -24,15 +24,15 @@ DECLARE _asset_id int; BEGIN SELECT DECODE(_asset_policy, 'hex') INTO _asset_policy_decoded; - SELECT DECODE( - CASE WHEN _asset_name IS NULL - THEN '' - ELSE - _asset_name - END, - 'hex' - ) INTO _asset_name_decoded; - SELECT id INTO _asset_id FROM multi_asset AS ma WHERE ma.policy = _asset_policy_decoded AND ma.name = _asset_name_decoded; + SELECT DECODE(CASE + WHEN _asset_name IS NULL THEN '' + ELSE _asset_name + END, 'hex') INTO _asset_name_decoded; + SELECT id INTO _asset_id + FROM multi_asset AS ma + WHERE ma.policy = _asset_policy_decoded + AND ma.name = _asset_name_decoded; + RETURN QUERY SELECT x.address, @@ -42,17 +42,12 @@ BEGIN SELECT txo.address, mto.quantity - FROM - ma_tx_out AS mto - INNER JOIN tx_out AS txo ON txo.id = mto.tx_out_id - LEFT JOIN tx_in ON txo.tx_id = tx_in.tx_out_id - AND txo.index::smallint = tx_in.tx_out_index::smallint - WHERE - mto.ident = _asset_id - AND tx_in.tx_out_id IS NULL + FROM ma_tx_out AS mto + INNER JOIN tx_out AS txo ON txo.id = mto.tx_out_id + WHERE mto.ident = _asset_id + AND tx_out.consumed_by_tx_in_id IS NULL ) AS x - GROUP BY - x.address; + GROUP BY x.address; END; $$; diff --git a/files/grest/rpc/assets/asset_txs.sql b/files/grest/rpc/assets/asset_txs.sql index e34fc924..01d950f2 100644 --- a/files/grest/rpc/assets/asset_txs.sql +++ b/files/grest/rpc/assets/asset_txs.sql @@ -19,14 +19,15 @@ DECLARE BEGIN SELECT DECODE(_asset_policy, 'hex') INTO _asset_policy_decoded; SELECT DECODE( - CASE WHEN _asset_name IS NULL - THEN '' - ELSE - _asset_name + CASE + WHEN _asset_name IS NULL THEN '' + ELSE _asset_name END, 'hex' ) INTO _asset_name_decoded; - SELECT id INTO _asset_id FROM multi_asset AS ma WHERE ma.policy = _asset_policy_decoded AND ma.name = _asset_name_decoded; + SELECT id INTO _asset_id + FROM multi_asset AS ma + WHERE ma.policy = _asset_policy_decoded AND ma.name = _asset_name_decoded; RETURN QUERY SELECT @@ -35,18 +36,17 @@ BEGIN tx_hashes.block_no, EXTRACT(EPOCH FROM tx_hashes.time)::integer FROM ( - SELECT DISTINCT ON (tx.hash) + SELECT DISTINCT ON (tx.hash,txo.index::smallint) tx.hash, block.epoch_no, block.block_no, block.time - FROM - ma_tx_out AS mto - INNER JOIN tx_out AS txo ON txo.id = mto.tx_out_id - INNER JOIN tx ON tx.id = txo.tx_id - INNER JOIN block ON block.id = tx.block_id - LEFT JOIN tx_in AS txi ON txo.tx_id = txi.tx_out_id - AND txo.index::smallint = txi.tx_out_index::smallint + FROM ma_tx_out AS mto + INNER JOIN tx_out AS txo ON txo.id = mto.tx_out_id + INNER JOIN tx ON tx.id = txo.tx_id + INNER JOIN block ON block.id = tx.block_id + LEFT JOIN tx_in AS txi ON txo.tx_id = txi.tx_out_id + AND txo.index::smallint = txi.tx_out_index::smallint WHERE mto.ident = _asset_id AND block.block_no >= _after_block_height diff --git a/files/grest/rpc/assets/asset_utxos.sql b/files/grest/rpc/assets/asset_utxos.sql new file mode 100644 index 00000000..6ab183cc --- /dev/null +++ b/files/grest/rpc/assets/asset_utxos.sql @@ -0,0 +1,95 @@ +CREATE OR REPLACE FUNCTION grest.asset_utxos(_asset_list text [] [], _extended boolean DEFAULT false) +RETURNS TABLE ( + tx_hash text, + tx_index smallint, + address text, + value text, + stake_address text, + payment_cred text, + epoch_no word31type, + block_height word31type, + block_time integer, + datum_hash text, + inline_datum jsonb, + reference_script jsonb, + asset_list jsonb, + is_spent boolean +) +LANGUAGE plpgsql +AS $$ +DECLARE + _asset_id_list bigint[]; +BEGIN + -- find all asset id's based ON nested array input + SELECT INTO _asset_id_list ARRAY_AGG(id) + FROM ( + SELECT DISTINCT mu.id + FROM ( + SELECT + DECODE(al->>0, 'hex') AS policy, + DECODE(al->>1, 'hex') AS name + FROM JSONB_ARRAY_ELEMENTS(TO_JSONB(_asset_list)) AS al + ) AS ald + INNER JOIN multi_asset AS mu ON mu.policy = ald.policy AND mu.name = ald.name + ) AS tmp; + + RETURN QUERY + SELECT + ENCODE(tx.hash, 'hex')::text AS tx_hash, + tx_out.index::smallint, + tx_out.address::text, + tx_out.value::text, + sa.view::text as stake_address, + ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + b.epoch_no, + b.block_no, + EXTRACT(EPOCH FROM b.time)::integer AS block_time, + ENCODE(tx_out.data_hash, 'hex') AS datum_hash, + (CASE + WHEN _extended = false OR tx_out.inline_datum_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'bytes', ENCODE(datum.bytes, 'hex'), + 'value', datum.value + ) + END) AS inline_datum, + (CASE + WHEN _extended = false OR tx_out.reference_script_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'hash', ENCODE(script.hash, 'hex'), + 'bytes', ENCODE(script.bytes, 'hex'), + 'value', script.json, + 'type', script.type::text, + 'size', script.serialised_size + ) + END) AS reference_script, + (CASE + WHEN _extended = false OR ma.policy IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'policy_id', ENCODE(ma.policy, 'hex'), + 'asset_name', ENCODE(ma.name, 'hex'), + 'fingerprint', ma.fingerprint, + 'decimals', aic.decimals, + 'quantity', mto.quantity::text + ) + END + ) AS asset_list, + (CASE + WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false + ELSE true + END) AS is_spent + FROM tx_out + 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 ma_tx_out AS mto ON mto.tx_out_id = tx_out.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 + LEFT JOIN datum ON datum.id = tx_out.inline_datum_id + LEFT JOIN script ON script.id = tx_out.reference_script_id + WHERE + mto.ident = ANY(_asset_id_list) + ; +END; +$$; + +COMMENT ON FUNCTION grest.asset_utxos IS 'Get UTxO details for requested assets'; -- noqa: LT01 diff --git a/files/grest/rpc/assets/policy_asset_addresses.sql b/files/grest/rpc/assets/policy_asset_addresses.sql index 478b1527..5287b4a1 100644 --- a/files/grest/rpc/assets/policy_asset_addresses.sql +++ b/files/grest/rpc/assets/policy_asset_addresses.sql @@ -16,8 +16,7 @@ BEGIN SELECT id, ENCODE(name, 'hex') AS asset_name - FROM - multi_asset AS ma + FROM multi_asset AS ma WHERE ma.policy = _asset_policy_decoded ) @@ -31,17 +30,14 @@ BEGIN aa.asset_name, txo.address, mto.quantity - FROM - _all_assets AS aa - INNER JOIN ma_tx_out AS mto ON mto.ident = aa.id - INNER JOIN tx_out AS txo ON txo.id = mto.tx_out_id - LEFT JOIN tx_in ON txo.tx_id = tx_in.tx_out_id - AND txo.index::smallint = tx_in.tx_out_index::smallint - WHERE - tx_in.tx_out_id IS NULL + FROM _all_assets AS aa + INNER JOIN ma_tx_out AS mto ON mto.ident = aa.id + INNER JOIN tx_out AS txo ON txo.id = mto.tx_out_id + WHERE tx_out.consumed_by_tx_in_id IS NULL ) AS x GROUP BY - x.asset_name, x.address; + x.asset_name, + x.address; END; $$; diff --git a/files/grest/rpc/blocks/block_txs.sql b/files/grest/rpc/blocks/block_txs.sql index 8bdeeaf6..daf45adf 100644 --- a/files/grest/rpc/blocks/block_txs.sql +++ b/files/grest/rpc/blocks/block_txs.sql @@ -1,7 +1,10 @@ CREATE OR REPLACE FUNCTION grest.block_txs(_block_hashes text []) RETURNS TABLE ( block_hash text, - tx_hashes text [] + tx_hash text, + epoch_no word31type, + block_height word31type, + block_time integer ) LANGUAGE plpgsql AS $$ @@ -21,13 +24,15 @@ BEGIN RETURN QUERY SELECT - encode(b.hash, 'hex'), - ARRAY_AGG(ENCODE(tx.hash::bytea, 'hex')) - FROM - public.block AS b - INNER JOIN public.tx ON tx.block_id = b.id + ENCODE(b.hash, 'hex'), + ENCODE(tx.hash, 'hex') AS tx_hash, + b.epoch_no, + b.block_no AS block_height, + EXTRACT(EPOCH FROM b.time)::integer AS block_time + FROM public.block AS b + INNER JOIN public.tx ON tx.block_id = b.id WHERE b.id = ANY(_block_ids) - GROUP BY b.hash; + ; END; $$; diff --git a/files/grest/rpc/transactions/utxo_info.sql b/files/grest/rpc/transactions/utxo_info.sql new file mode 100644 index 00000000..90ad9207 --- /dev/null +++ b/files/grest/rpc/transactions/utxo_info.sql @@ -0,0 +1,102 @@ +CREATE OR REPLACE FUNCTION grest.utxo_info(_utxo_refs text [], _extended boolean DEFAULT false) +RETURNS TABLE ( + tx_hash text, + tx_index smallint, + address text, + value text, + stake_address text, + payment_cred text, + epoch_no word31type, + block_height word31type, + block_time integer, + datum_hash text, + inline_datum jsonb, + reference_script jsonb, + asset_list jsonb, + is_spent boolean +) +LANGUAGE plpgsql +AS $$ +DECLARE + _tx_hashes_bytea bytea[]; + _tx_id_list bigint[]; +BEGIN + -- convert input _tx_hashes array into bytea array + CREATE TEMP TABLE utxo_refs AS ( + SELECT + DECODE(SPLIT_PART(ur,'#',1), 'hex') AS tx_hashes, + SPLIT_PART(ur,'#',2) AS tx_index + FROM UNNEST(_utxo_refs) AS ur + ); + + -- all tx ids + SELECT INTO _tx_id_list ARRAY_AGG(id) + FROM ( + SELECT txo.id + FROM tx_out AS txo + INNER JOIN tx ON tx.id = txo.tx_id + INNER JOIN utxo_refs AS ur ON ur.tx_hashes = tx.hash + AND ur.tx_index::smallint = txo.index + ) AS tmp; + + RETURN QUERY + SELECT + ENCODE(tx.hash, 'hex')::text AS tx_hash, + tx_out.index::smallint, + tx_out.address::text, + tx_out.value::text, + sa.view::text as stake_address, + ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + b.epoch_no, + b.block_no, + EXTRACT(EPOCH FROM b.time)::integer AS block_time, + ENCODE(tx_out.data_hash, 'hex') AS datum_hash, + (CASE + WHEN _extended = false OR tx_out.inline_datum_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'bytes', ENCODE(datum.bytes, 'hex'), + 'value', datum.value + ) + END) AS inline_datum, + (CASE + WHEN _extended = false OR tx_out.reference_script_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'hash', ENCODE(script.hash, 'hex'), + 'bytes', ENCODE(script.bytes, 'hex'), + 'value', script.json, + 'type', script.type::text, + 'size', script.serialised_size + ) + END) AS reference_script, + (CASE + WHEN _extended = false OR ma.policy IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'policy_id', ENCODE(ma.policy, 'hex'), + 'asset_name', ENCODE(ma.name, 'hex'), + 'fingerprint', ma.fingerprint, + 'decimals', aic.decimals, + 'quantity', mto.quantity::text + ) + END + ) AS asset_list, + (CASE + WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false + ELSE true + END) AS is_spent + FROM tx_out + 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 ma_tx_out AS mto ON mto.tx_out_id = tx_out.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 + LEFT JOIN datum ON datum.id = tx_out.inline_datum_id + LEFT JOIN script ON script.id = tx_out.reference_script_id + WHERE + tx_out.id = ANY(_tx_id_list) + ; + +END; +$$; + +COMMENT ON FUNCTION grest.utxo_info IS 'Get details for requested UTxO arrays (UTxOs accepted in # format).'; -- noqa: LT01 \ No newline at end of file From c8b2e20742990bfe7f77f4a47e0d9e22c3b48f03 Mon Sep 17 00:00:00 2001 From: Priyank <3169068+rdlrt@users.noreply.github.com> Date: Fri, 25 Aug 2023 18:22:12 +1000 Subject: [PATCH 4/4] Add script_utxos and fix script join conditions --- files/grest/rpc/account/account_utxos.sql | 2 +- files/grest/rpc/address/address_utxos.sql | 2 +- files/grest/rpc/address/credential_utxos.sql | 2 +- files/grest/rpc/assets/asset_utxos.sql | 2 +- files/grest/rpc/script/script_utxos.sql | 82 ++++++++++++++++++++ files/grest/rpc/transactions/utxo_info.sql | 3 +- 6 files changed, 88 insertions(+), 5 deletions(-) create mode 100644 files/grest/rpc/script/script_utxos.sql diff --git a/files/grest/rpc/account/account_utxos.sql b/files/grest/rpc/account/account_utxos.sql index 2737a375..780c0502 100644 --- a/files/grest/rpc/account/account_utxos.sql +++ b/files/grest/rpc/account/account_utxos.sql @@ -72,7 +72,7 @@ BEGIN 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 LEFT JOIN datum ON datum.id = tx_out.inline_datum_id - LEFT JOIN script ON script.id = tx_out.reference_script_id + LEFT JOIN script ON script.tx_id = tx.id WHERE tx_out.stake_address_id IN (SELECT sa.id FROM stake_address AS sa WHERE sa.view = ANY(_stake_addresses)) ; diff --git a/files/grest/rpc/address/address_utxos.sql b/files/grest/rpc/address/address_utxos.sql index c5b14ade..01f2ac6f 100644 --- a/files/grest/rpc/address/address_utxos.sql +++ b/files/grest/rpc/address/address_utxos.sql @@ -72,7 +72,7 @@ BEGIN 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 LEFT JOIN datum ON datum.id = tx_out.inline_datum_id - LEFT JOIN script ON script.id = tx_out.reference_script_id + LEFT JOIN script ON script.tx_id = tx.id WHERE tx_out.address = ANY(_addresses) ; diff --git a/files/grest/rpc/address/credential_utxos.sql b/files/grest/rpc/address/credential_utxos.sql index 76f71d86..759744c7 100644 --- a/files/grest/rpc/address/credential_utxos.sql +++ b/files/grest/rpc/address/credential_utxos.sql @@ -78,7 +78,7 @@ BEGIN 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 LEFT JOIN datum ON datum.id = tx_out.inline_datum_id - LEFT JOIN script ON script.id = tx_out.reference_script_id + LEFT JOIN script ON script.tx_id = tx.id WHERE tx_out.payment_cred = ANY(_payment_cred_bytea) ; diff --git a/files/grest/rpc/assets/asset_utxos.sql b/files/grest/rpc/assets/asset_utxos.sql index 6ab183cc..e29ffa23 100644 --- a/files/grest/rpc/assets/asset_utxos.sql +++ b/files/grest/rpc/assets/asset_utxos.sql @@ -85,7 +85,7 @@ BEGIN 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 LEFT JOIN datum ON datum.id = tx_out.inline_datum_id - LEFT JOIN script ON script.id = tx_out.reference_script_id + LEFT JOIN script ON script.tx_id = tx.id WHERE mto.ident = ANY(_asset_id_list) ; diff --git a/files/grest/rpc/script/script_utxos.sql b/files/grest/rpc/script/script_utxos.sql new file mode 100644 index 00000000..8e777d61 --- /dev/null +++ b/files/grest/rpc/script/script_utxos.sql @@ -0,0 +1,82 @@ +CREATE OR REPLACE FUNCTION grest.script_utxos(_script_hash text, _extended boolean DEFAULT false) +RETURNS TABLE ( + tx_hash text, + tx_index smallint, + address text, + value text, + stake_address text, + payment_cred text, + epoch_no word31type, + block_height word31type, + block_time integer, + datum_hash text, + inline_datum jsonb, + reference_script jsonb, + asset_list jsonb, + is_spent boolean +) +LANGUAGE plpgsql +AS $$ +DECLARE + known_addresses varchar[]; +BEGIN + RETURN QUERY + SELECT + ENCODE(tx.hash, 'hex')::text AS tx_hash, + tx_out.index::smallint, + tx_out.address::text, + tx_out.value::text, + sa.view::text as stake_address, + ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, + b.epoch_no, + b.block_no, + EXTRACT(EPOCH FROM b.time)::integer AS block_time, + ENCODE(tx_out.data_hash, 'hex') AS datum_hash, + (CASE + WHEN _extended = false OR tx_out.inline_datum_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'bytes', ENCODE(datum.bytes, 'hex'), + 'value', datum.value + ) + END) AS inline_datum, + (CASE + WHEN _extended = false OR tx_out.reference_script_id IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'hash', ENCODE(script.hash, 'hex'), + 'bytes', ENCODE(script.bytes, 'hex'), + 'value', script.json, + 'type', script.type::text, + 'size', script.serialised_size + ) + END) AS reference_script, + (CASE + WHEN _extended = false OR ma.policy IS NULL THEN NULL + ELSE JSONB_BUILD_OBJECT( + 'policy_id', ENCODE(ma.policy, 'hex'), + 'asset_name', ENCODE(ma.name, 'hex'), + 'fingerprint', ma.fingerprint, + 'decimals', aic.decimals, + 'quantity', mto.quantity::text + ) + END + ) AS asset_list, + (CASE + WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false + ELSE true + END) AS is_spent + FROM tx_out + 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 ma_tx_out AS mto ON mto.tx_out_id = tx_out.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 + LEFT JOIN datum ON datum.id = tx_out.inline_datum_id + LEFT JOIN script ON script.tx_id = tx.id + WHERE + script.hash = DECODE(_script_hash,'hex') + ; +END; +$$; + +COMMENT ON FUNCTION grest.script_utxos IS 'Get UTxO details for requested scripts'; -- noqa: LT01 \ No newline at end of file diff --git a/files/grest/rpc/transactions/utxo_info.sql b/files/grest/rpc/transactions/utxo_info.sql index 90ad9207..681debcf 100644 --- a/files/grest/rpc/transactions/utxo_info.sql +++ b/files/grest/rpc/transactions/utxo_info.sql @@ -22,6 +22,7 @@ DECLARE _tx_id_list bigint[]; BEGIN -- convert input _tx_hashes array into bytea array + DROP TABLE IF EXISTS utxo_refs; CREATE TEMP TABLE utxo_refs AS ( SELECT DECODE(SPLIT_PART(ur,'#',1), 'hex') AS tx_hashes, @@ -91,7 +92,7 @@ BEGIN 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 LEFT JOIN datum ON datum.id = tx_out.inline_datum_id - LEFT JOIN script ON script.id = tx_out.reference_script_id + LEFT JOIN script ON script.tx_id = tx.id WHERE tx_out.id = ANY(_tx_id_list) ;