From b68c8943ce0484e95edebe4dc1da8e009a911ce2 Mon Sep 17 00:00:00 2001 From: RdLrT <3169068+rdlrt@users.noreply.github.com> Date: Sat, 4 May 2024 15:48:23 +1000 Subject: [PATCH] Koios v1.1.1rc (#269) ## Description Todo: - [x] Update active_stake_cache, no longer requires maintaining account active stake lookup, remove log scan references - [x] Perf improvement for address_txs for 90% of addresses (postgres filtering nuance) - [x] Update cip67_strip_label - [x] Reduce asset info cache rollback to 250 - [x] Update specs (view updates already covered in previous commits, didnt see much to do beyond bumping version) - [x] Retire stake_distribution_new_accounts_update (current query is overkill) - [x] Adapt as per 13.2.0.1 schema - [x] Replace consumed_by_tx_in_id - [x] Replace pool_offline_data - [x] Update epoch references (no longer need 2 epoch wait time) for cache - [x] Remove leftover tx_in references - [x] MIRs (both extract from reserves as well as treasury) are no longer in rewards table, but moved to it's own `instant_rewards` table - update endpoints impacted (I think that's primarily SDC only) - [x] Update `reserve_withdrawals` and `treasury_withdrawals` to include `earned` and `spendable` epochs - [x] Add an endpoint for asset/policy mint history - [x] Retire asset_address_list and asset_policy_info (was deprecated 3 versions ago, and usage-wise had only a single hit in past 48 hours on mainnet) - [x] Fix script_utxos ->> asset_list - [x] New endpoint + cron job to get current protocol parameters - [x] Add is_dangling_delegation check - [x] Specs Testing on guildnet - [x] Update changelog Bugs from testing: - [x] Fix script_utxos, asset_list was not being returned as array , closes #272 - [x] Include burn asset transactions in asset_txs , closes #276 - [x] tx_info: Fix spend_redeemers CTE Join condition, closes #275 - [x] Update Changelog/specs post testing results --------- Co-authored-by: KoT_B_KocMoce <49576827+hodlonaut@users.noreply.github.com> Co-authored-by: XRAY | Robot <38279597+xray-robot@users.noreply.github.com> Co-authored-by: Scitz0 Co-authored-by: Greg Beresnev --- .../cron/jobs/active-stake-cache-update.sh | 34 +- .../cron/jobs/asset-info-cache-update.sh | 6 +- .../grest/cron/jobs/asset-txo-cache-update.sh | 2 +- .../cron/jobs/cli-protocol-params-update.sh | 33 ++ .../cron/jobs/epoch-info-cache-update.sh | 2 +- .../jobs/epoch-summary-corrections-update.sh | 2 +- .../cron/jobs/pool-history-cache-update.sh | 2 +- .../stake-distribution-new-accounts-update.sh | 12 - .../cron/jobs/stake-distribution-update.sh | 2 +- files/grest/cron/jobs/stake-snapshot-cache.sh | 12 - .../rpc/00_blockchain/reserve_withdrawals.sql | 13 +- files/grest/rpc/00_blockchain/tip.sql | 2 +- .../00_blockchain/treasury_withdrawals.sql | 13 +- .../01_cached_tables/active_stake_cache.sql | 46 +- .../01_cached_tables/asset_cache_control.sql | 40 +- .../rpc/01_cached_tables/asset_info_cache.sql | 4 +- .../rpc/01_cached_tables/asset_txo_cache.sql | 4 +- .../01_cached_tables/pool_history_cache.sql | 77 ++-- .../stake_distribution_cache.sql | 99 ++-- .../stake_distribution_new_accounts.sql | 38 +- .../01_cached_tables/stake_snapshot_cache.sql | 428 ------------------ files/grest/rpc/02_indexes/13_1_00.sql | 1 - files/grest/rpc/03_utilities/cip67.sql | 7 +- .../rpc/03_utilities/cli_protocol_params.sql | 8 + .../03_utilities/is_dangling_delegation.sql | 41 ++ files/grest/rpc/account/account_addresses.sql | 2 +- files/grest/rpc/account/account_assets.sql | 2 +- files/grest/rpc/account/account_info.sql | 49 +- .../grest/rpc/account/account_info_cached.sql | 78 +++- files/grest/rpc/account/account_list.sql | 2 +- files/grest/rpc/account/account_txs.sql | 6 +- files/grest/rpc/account/account_utxos.sql | 6 +- files/grest/rpc/address/address_assets.sql | 2 +- files/grest/rpc/address/address_info.sql | 2 +- files/grest/rpc/address/address_txs.sql | 19 +- files/grest/rpc/address/address_utxos.sql | 6 +- files/grest/rpc/address/credential_txs.sql | 6 +- files/grest/rpc/address/credential_utxos.sql | 6 +- files/grest/rpc/assets/asset_addresses.sql | 20 +- files/grest/rpc/assets/asset_list.sql | 2 +- files/grest/rpc/assets/asset_nft_address.sql | 2 +- files/grest/rpc/assets/asset_summary.sql | 2 +- .../grest/rpc/assets/asset_token_registry.sql | 5 +- files/grest/rpc/assets/asset_txs.sql | 9 +- files/grest/rpc/assets/asset_utxos.sql | 6 +- .../rpc/assets/policy_asset_addresses.sql | 10 +- files/grest/rpc/assets/policy_asset_info.sql | 23 +- files/grest/rpc/assets/policy_asset_mints.sql | 32 ++ files/grest/rpc/blocks/block_tx_info.sql | 41 +- files/grest/rpc/blocks/blocks.sql | 2 +- files/grest/rpc/pool/pool_delegators.sql | 29 +- files/grest/rpc/pool/pool_info.sql | 19 +- files/grest/rpc/pool/pool_list.sql | 4 +- files/grest/rpc/pool/pool_metadata.sql | 4 +- files/grest/rpc/pool/pool_updates.sql | 4 +- files/grest/rpc/script/script_utxos.sql | 47 +- files/grest/rpc/transactions/tx_info.sql | 57 ++- files/grest/rpc/transactions/tx_utxos.sql | 19 +- files/grest/rpc/transactions/utxo_info.sql | 2 +- files/grest/rpc/v0/account.sql | 4 +- files/grest/rpc/v0/address.sql | 4 +- files/grest/rpc/v0/pool.sql | 10 +- files/grest/rpc/v0/views.sql | 2 +- specs/results/koiosapi-guild.yaml | 237 ++++++---- specs/results/koiosapi-mainnet.yaml | 237 ++++++---- specs/results/koiosapi-preprod.yaml | 239 ++++++---- specs/results/koiosapi-preview.yaml | 237 ++++++---- specs/templates/1-api-info.yaml | 52 +-- specs/templates/2-api-params.yaml | 10 + specs/templates/4-api-schemas.yaml | 82 +++- specs/templates/api-main.yaml | 93 ++-- specs/templates/example-map.json | 8 +- specs/wiretap/wiretap-report.json | 1 + 73 files changed, 1376 insertions(+), 1293 deletions(-) create mode 100755 files/grest/cron/jobs/cli-protocol-params-update.sh delete mode 100755 files/grest/cron/jobs/stake-distribution-new-accounts-update.sh delete mode 100755 files/grest/cron/jobs/stake-snapshot-cache.sh delete mode 100644 files/grest/rpc/01_cached_tables/stake_snapshot_cache.sql create mode 100644 files/grest/rpc/03_utilities/cli_protocol_params.sql create mode 100644 files/grest/rpc/03_utilities/is_dangling_delegation.sql create mode 100644 files/grest/rpc/assets/policy_asset_mints.sql create mode 100644 specs/wiretap/wiretap-report.json diff --git a/files/grest/cron/jobs/active-stake-cache-update.sh b/files/grest/cron/jobs/active-stake-cache-update.sh index d85dd4e4..15fa5014 100755 --- a/files/grest/cron/jobs/active-stake-cache-update.sh +++ b/files/grest/cron/jobs/active-stake-cache-update.sh @@ -3,9 +3,9 @@ DB_NAME=cexplorer tip=$(psql ${DB_NAME} -qbt -c "select extract(epoch from time)::integer from block order by id desc limit 1;" | xargs) -if [[ $(( $(date +%s) - tip )) -gt 300 ]]; then - echo "$(date +%F_%H:%M:%S) Skipping as database has not received a new block in past 300 seconds!" && exit 1 -fi +[[ $(( $(date +%s) - tip )) -gt 300 ]] && + echo "$(date +%F_%H:%M:%S) Skipping as database has not received a new block in past 300 seconds!" && + exit 1 echo "$(date +%F_%H:%M:%S) Running active stake cache update..." @@ -14,30 +14,12 @@ echo "$(date +%F_%H:%M:%S) Running active stake cache update..." echo "No update needed, exiting..." && exit 0 -# This could break due to upstream changes on db-sync (based on log format) -last_epoch_stakes_log=$(grep -r 'Inserted.*.EpochStake for EpochNo ' "$(dirname "$0")"/../../logs/dbsync-*.json "$(dirname "$0")"/../../logs/archive/dbsync-*.json 2>/dev/null | sed -e 's#.*.Inserted ##' -e 's#EpochStake for EpochNo##' -e 's#\"}.*.$##' | sort -k2 -n | tail -1) -[[ -z ${last_epoch_stakes_log} ]] && - echo "Could not find any 'Handling stakes' log entries, exiting..." && - exit 1 - -logs_last_epoch_stakes_count=$(echo "${last_epoch_stakes_log}" | cut -d\ -f1) -logs_last_epoch_no=$(echo "${last_epoch_stakes_log}" | cut -d\ -f3) +db_next_epoch_no=$(psql ${DB_NAME} -qbt -c "SELECT MAX(NO)+1 from EPOCH;" | tr -cd '[:alnum:]') +db_epoch_stakes_no=$(psql ${DB_NAME} -qbt -c "SELECT MAX(epoch_no) FROM EPOCH_STAKE;" | tr -cd '[:alnum:]') -db_last_epoch_no=$(psql ${DB_NAME} -qbt -c "SELECT MAX(NO) from EPOCH;" | tr -cd '[:alnum:]') -[[ "${db_last_epoch_no}" != "${logs_last_epoch_no}" ]] && - echo "Mismatch between last epoch in logs and database, exiting..." && +[[ ${db_next_epoch_no} -gt ${db_epoch_stakes_no} ]] && + echo "Epoch Stake is not populated for epoch ${db_next_epoch_no}, exiting..." && exit 1 -# Count current epoch entries processed by db-sync -db_epoch_stakes_count=$(psql ${DB_NAME} -qbt -c "SELECT COUNT(1) FROM EPOCH_STAKE WHERE epoch_no = ${db_last_epoch_no};" | tr -cd '[:alnum:]') - -# Check if db-sync completed handling stakes -[[ "${db_epoch_stakes_count}" != "${logs_last_epoch_stakes_count}" ]] && - echo "Logs last epoch stakes count: ${logs_last_epoch_stakes_count}" && - echo "DB last epoch stakes count: ${db_epoch_stakes_count}" && - echo "db-sync stakes handling still incomplete, exiting..." && - exit 0 - -# Stakes have been validated, run the cache update -psql ${DB_NAME} -qbt -c "SELECT GREST.active_stake_cache_update(${db_last_epoch_no});" 1>/dev/null 2>&1 +psql ${DB_NAME} -qbt -c "SELECT GREST.active_stake_cache_update(${db_epoch_stakes_no});" 1>/dev/null echo "$(date +%F_%H:%M:%S) Job done!" diff --git a/files/grest/cron/jobs/asset-info-cache-update.sh b/files/grest/cron/jobs/asset-info-cache-update.sh index 3b6afc47..a8cc204b 100755 --- a/files/grest/cron/jobs/asset-info-cache-update.sh +++ b/files/grest/cron/jobs/asset-info-cache-update.sh @@ -7,6 +7,10 @@ if [[ $(( $(date +%s) - tip )) -gt 300 ]]; then echo "$(date +%F_%H:%M:%S) Skipping as database has not received a new block in past 300 seconds!" && exit 1 fi +asset_registry_exists=$(psql ${DB_NAME} -qbt -c "select last_value from grest.control_table where key='asset_registry_commit';" | xargs) + +[[ -z "${asset_registry_exists}" ]] && echo "$(date +%F_%H:%M:%S) Skipping as asset registry cache does not seem to be populated!" && exit 1 + echo "$(date +%F_%H:%M:%S) Running asset info cache update..." -psql ${DB_NAME} -qbt -c "SELECT grest.asset_info_cache_update();" 1>/dev/null 2>&1 +psql ${DB_NAME} -qbt -c "SELECT grest.asset_info_cache_update();" 1>/dev/null echo "$(date +%F_%H:%M:%S) Job done!" diff --git a/files/grest/cron/jobs/asset-txo-cache-update.sh b/files/grest/cron/jobs/asset-txo-cache-update.sh index 43ee7c74..d0af529f 100755 --- a/files/grest/cron/jobs/asset-txo-cache-update.sh +++ b/files/grest/cron/jobs/asset-txo-cache-update.sh @@ -8,5 +8,5 @@ if [[ $(( $(date +%s) - tip )) -gt 300 ]]; then fi echo "$(date +%F_%H:%M:%S) Running asset txo cache update..." -psql ${DB_NAME} -qbt -c "SELECT grest.asset_txo_cache_update();" 1>/dev/null 2>&1 +psql ${DB_NAME} -qbt -c "SELECT grest.asset_txo_cache_update();" 1>/dev/null echo "$(date +%F_%H:%M:%S) Job done!" diff --git a/files/grest/cron/jobs/cli-protocol-params-update.sh b/files/grest/cron/jobs/cli-protocol-params-update.sh new file mode 100755 index 00000000..f90e9b5a --- /dev/null +++ b/files/grest/cron/jobs/cli-protocol-params-update.sh @@ -0,0 +1,33 @@ +#!/bin/bash +DB_NAME=cexplorer +CCLI="${HOME}"/.local/bin/cardano-cli +SOCKET="$(dirname "$0")"/../../sockets/node.socket + +echo "$(date +%F_%H:%M:%S) - START - CLI Protocol Parameters Update" +nwmagic=$(psql ${DB_NAME} -qbt -c "SELECT networkmagic FROM grest.genesis()" | xargs) +last_epoch=$(psql ${DB_NAME} -qbt -c "SELECT last_value FROM grest.control_table WHERE key='cli_protocol_params'" | xargs) +current_epoch=$(psql ${DB_NAME} -qbt -c "SELECT epoch_no FROM grest.tip()" | xargs) + +if [[ -z ${current_epoch} ]] || ! [[ ${current_epoch} =~ ^[0-9]+$ ]]; then + echo "$(date +%F_%H:%M:%S) - Unable to fetch epoch_no from grest.tip" + echo "$(date +%F_%H:%M:%S) - Error message: ${current_epoch}" + exit 1 +fi + +[[ -n ${last_epoch} && ${last_epoch} -eq ${current_epoch} ]] && echo "$(date +%F_%H:%M:%S) - END - CLI Protocol Parameters Update, no update necessary." && exit 0 + +prot_params="$(${CCLI} query protocol-parameters --testnet-magic "${nwmagic}" --socket-path "${SOCKET}" 2>&1)" + +if grep -q "Network.Socket.connect" <<< "${prot_params}"; then + echo "$(date +%F_%H:%M:%S) - Node socket path wrongly configured or node not running, please verify that socket set in env file match what is used to run the node" + echo "$(date +%F_%H:%M:%S) - Error message: ${prot_params}" + exit 1 +elif [[ -z "${prot_params}" ]] || ! jq -er . <<< "${prot_params}" &>/dev/null; then + echo "$(date +%F_%H:%M:%S) - Failed to query protocol parameters, ensure your node is running with correct genesis (the node needs to be in sync to 1 epoch after the hardfork)" + echo "$(date +%F_%H:%M:%S) - Error message: ${prot_params}" + exit 1 +fi + +psql ${DB_NAME} -qb -c "INSERT INTO grest.control_table (key, last_value, artifacts) VALUES ('cli_protocol_params','${current_epoch}','${prot_params}') ON CONFLICT(key) DO UPDATE SET last_value='${current_epoch}', artifacts='${prot_params}'" + +echo "$(date +%F_%H:%M:%S) - END - CLI Protocol Parameters Update, updated for epoch ${current_epoch}." diff --git a/files/grest/cron/jobs/epoch-info-cache-update.sh b/files/grest/cron/jobs/epoch-info-cache-update.sh index c63aa739..f0590029 100755 --- a/files/grest/cron/jobs/epoch-info-cache-update.sh +++ b/files/grest/cron/jobs/epoch-info-cache-update.sh @@ -8,5 +8,5 @@ if [[ $(( $(date +%s) - tip )) -gt 300 ]]; then fi echo "$(date +%F_%H:%M:%S) Running epoch info cache update..." -psql ${DB_NAME} -qbt -c "SELECT grest.epoch_info_cache_update();" 1>/dev/null 2>&1 +psql ${DB_NAME} -qbt -c "SELECT grest.epoch_info_cache_update();" 1>/dev/null echo "$(date +%F_%H:%M:%S) Job done!" diff --git a/files/grest/cron/jobs/epoch-summary-corrections-update.sh b/files/grest/cron/jobs/epoch-summary-corrections-update.sh index 7bc9c9e4..0587d84f 100755 --- a/files/grest/cron/jobs/epoch-summary-corrections-update.sh +++ b/files/grest/cron/jobs/epoch-summary-corrections-update.sh @@ -8,5 +8,5 @@ if [[ $(( $(date +%s) - tip )) -gt 300 ]]; then fi echo "$(date +%F_%H:%M:%S) Running epoch summary corrections update..." -psql ${DB_NAME} -qbt -c "SELECT GREST.EPOCH_SUMMARY_CORRECTIONS_UPDATE();" 1>/dev/null 2>&1 +psql ${DB_NAME} -qbt -c "SELECT GREST.EPOCH_SUMMARY_CORRECTIONS_UPDATE();" 1>/dev/null echo "$(date +%F_%H:%M:%S) Job done!" diff --git a/files/grest/cron/jobs/pool-history-cache-update.sh b/files/grest/cron/jobs/pool-history-cache-update.sh index 7bc75ee4..61a79e4a 100755 --- a/files/grest/cron/jobs/pool-history-cache-update.sh +++ b/files/grest/cron/jobs/pool-history-cache-update.sh @@ -8,5 +8,5 @@ if [[ $(( $(date +%s) - tip )) -gt 300 ]]; then fi echo "$(date +%F_%H:%M:%S) Running pool history cache update..." -psql ${DB_NAME} -qbt -c "SELECT GREST.pool_history_cache_update();" 1>/dev/null 2>&1 +psql ${DB_NAME} -qbt -c "SELECT GREST.pool_history_cache_update();" 1>/dev/null echo "$(date +%F_%H:%M:%S) Job done!" diff --git a/files/grest/cron/jobs/stake-distribution-new-accounts-update.sh b/files/grest/cron/jobs/stake-distribution-new-accounts-update.sh deleted file mode 100755 index 70f3d0d9..00000000 --- a/files/grest/cron/jobs/stake-distribution-new-accounts-update.sh +++ /dev/null @@ -1,12 +0,0 @@ -#!/bin/bash -DB_NAME=cexplorer - -tip=$(psql ${DB_NAME} -qbt -c "select extract(epoch from time)::integer from block order by id desc limit 1;" | xargs) - -if [[ $(( $(date +%s) - tip )) -gt 300 ]]; then - echo "$(date +%F_%H:%M:%S) Skipping as database has not received a new block in past 300 seconds!" && exit 1 -fi - -echo "$(date +%F_%H:%M:%S) Running stake distribution update for new accounts..." -psql ${DB_NAME} -qbt -c "CALL GREST.UPDATE_NEWLY_REGISTERED_ACCOUNTS_STAKE_DISTRIBUTION_CACHE();" 1>/dev/null 2>&1 -echo "$(date +%F_%H:%M:%S) Job done!" diff --git a/files/grest/cron/jobs/stake-distribution-update.sh b/files/grest/cron/jobs/stake-distribution-update.sh index 3447dee0..5f843c21 100755 --- a/files/grest/cron/jobs/stake-distribution-update.sh +++ b/files/grest/cron/jobs/stake-distribution-update.sh @@ -8,5 +8,5 @@ if [[ $(( $(date +%s) - tip )) -gt 300 ]]; then fi echo "$(date +%F_%H:%M:%S) Running stake distribution update..." -psql ${DB_NAME} -qbt -c "SELECT GREST.STAKE_DISTRIBUTION_CACHE_UPDATE_CHECK();" 1>/dev/null 2>&1 +psql ${DB_NAME} -qbt -c "SELECT GREST.STAKE_DISTRIBUTION_CACHE_UPDATE_CHECK();" 1>/dev/null echo "$(date +%F_%H:%M:%S) Job done!" diff --git a/files/grest/cron/jobs/stake-snapshot-cache.sh b/files/grest/cron/jobs/stake-snapshot-cache.sh deleted file mode 100755 index 44549802..00000000 --- a/files/grest/cron/jobs/stake-snapshot-cache.sh +++ /dev/null @@ -1,12 +0,0 @@ -#!/bin/bash -DB_NAME=cexplorer - -tip=$(psql ${DB_NAME} -qbt -c "select extract(epoch from time)::integer from block order by id desc limit 1;" | xargs) - -if [[ $(( $(date +%s) - tip )) -gt 300 ]]; then - echo "$(date +%F_%H:%M:%S) Skipping as database has not received a new block in past 300 seconds!" && exit 1 -fi - -echo "$(date +%F_%H:%M:%S) Capturing last epochs' snapshot..." -psql ${DB_NAME} -qbt -c "CALL GREST.CAPTURE_LAST_EPOCH_SNAPSHOT();" 1>/dev/null 2>&1 -echo "$(date +%F_%H:%M:%S) Job done!" diff --git a/files/grest/rpc/00_blockchain/reserve_withdrawals.sql b/files/grest/rpc/00_blockchain/reserve_withdrawals.sql index 7ff66c8b..cc5b3d5a 100644 --- a/files/grest/rpc/00_blockchain/reserve_withdrawals.sql +++ b/files/grest/rpc/00_blockchain/reserve_withdrawals.sql @@ -6,7 +6,9 @@ RETURNS TABLE ( block_hash text, block_height word31type, amount text, - stake_address text + stake_address text, + earned_epoch bigint, + spendable_epoch bigint ) LANGUAGE sql STABLE AS $$ @@ -17,11 +19,16 @@ AS $$ ENCODE(b.hash,'hex'), b.block_no, r.amount::text, - sa.view + sa.view, + earned_epoch, + spendable_epoch FROM reserve AS r LEFT JOIN tx ON r.tx_id = tx.id INNER JOIN block AS b ON tx.block_id = b.id - LEFT JOIN stake_address AS sa ON sa.id = r.addr_id; + LEFT JOIN stake_address AS sa ON sa.id = r.addr_id + LEFT JOIN instant_reward AS ir ON ir.addr_id = r.addr_id AND ir.earned_epoch = b.epoch_no AND ir.type = 'reserves' + ORDER BY b.block_no DESC + ; $$; COMMENT ON FUNCTION grest.reserve_withdrawals IS 'A list of withdrawals made from reserves (MIRs)'; --noqa: LT01 diff --git a/files/grest/rpc/00_blockchain/tip.sql b/files/grest/rpc/00_blockchain/tip.sql index 1cc95463..092b34e2 100644 --- a/files/grest/rpc/00_blockchain/tip.sql +++ b/files/grest/rpc/00_blockchain/tip.sql @@ -16,7 +16,7 @@ AS $$ b.epoch_slot_no AS epoch_slot, b.block_no, EXTRACT(EPOCH FROM b.time)::integer - FROM block b + FROM block AS b ORDER BY b.id DESC LIMIT 1; $$; diff --git a/files/grest/rpc/00_blockchain/treasury_withdrawals.sql b/files/grest/rpc/00_blockchain/treasury_withdrawals.sql index 5a109c7f..0f5f91e8 100644 --- a/files/grest/rpc/00_blockchain/treasury_withdrawals.sql +++ b/files/grest/rpc/00_blockchain/treasury_withdrawals.sql @@ -6,7 +6,9 @@ RETURNS TABLE ( block_hash text, block_height word31type, amount text, - stake_address text + stake_address text, + earned_epoch bigint, + spendable_epoch bigint ) LANGUAGE sql STABLE AS $$ @@ -17,11 +19,16 @@ AS $$ ENCODE(b.hash,'hex'), b.block_no, t.amount::text, - sa.view + sa.view, + earned_epoch, + spendable_epoch FROM treasury AS t LEFT JOIN tx ON t.tx_id = tx.id INNER JOIN block AS b ON tx.block_id = b.id - LEFT JOIN stake_address AS sa ON sa.id = t.addr_id; + LEFT JOIN stake_address AS sa ON sa.id = t.addr_id + LEFT JOIN instant_reward AS ir ON ir.addr_id = t.addr_id AND ir.earned_epoch = b.epoch_no AND ir.type = 'treasury' + ORDER BY b.block_no DESC + ; $$; COMMENT ON FUNCTION grest.treasury_withdrawals IS 'A list of withdrawals made from treasury'; --noqa: LT01 diff --git a/files/grest/rpc/01_cached_tables/active_stake_cache.sql b/files/grest/rpc/01_cached_tables/active_stake_cache.sql index 4672c859..e9f0a780 100644 --- a/files/grest/rpc/01_cached_tables/active_stake_cache.sql +++ b/files/grest/rpc/01_cached_tables/active_stake_cache.sql @@ -11,14 +11,6 @@ CREATE TABLE IF NOT EXISTS grest.epoch_active_stake_cache ( PRIMARY KEY (epoch_no) ); -CREATE TABLE IF NOT EXISTS grest.account_active_stake_cache ( - stake_address varchar NOT NULL, - pool_id varchar NOT NULL, - epoch_no bigint NOT NULL, - amount lovelace NOT NULL, - PRIMARY KEY (stake_address, pool_id, epoch_no) -); - CREATE OR REPLACE FUNCTION grest.active_stake_cache_update_check() RETURNS boolean LANGUAGE plpgsql @@ -34,11 +26,18 @@ BEGIN -- Get Current Epoch SELECT MAX(no) INTO _current_epoch_no FROM epoch; - RAISE NOTICE 'Current epoch: %', _current_epoch_no; - RAISE NOTICE 'Last active stake validated epoch: %', _last_active_stake_validated_epoch; + RAISE NOTICE 'Next epoch: %', _current_epoch_no+1; + RAISE NOTICE 'Latest epoch in active stake cache: %', _last_active_stake_validated_epoch; IF _current_epoch_no > COALESCE(_last_active_stake_validated_epoch::integer, 0) THEN RETURN TRUE; + ELSE + -- If last active stake cache is same as current epoch_no, check if we're beyond 60% within epoch to populate next epoch stake, only valid as of dbsync 13.2.0.0 + IF _current_epoch_no = _last_active_stake_validated_epoch::integer + AND (SELECT MAX(epoch_no) FROM epoch_stake_progress WHERE completed='t')::integer > _last_active_stake_validated_epoch::integer THEN + RETURN TRUE; + END IF; END IF; + RAISE NOTICE 'Active Stake cache is up to date with DB!'; RETURN FALSE; END; $$; @@ -51,7 +50,6 @@ LANGUAGE plpgsql AS $$ DECLARE _last_active_stake_validated_epoch integer; - _last_account_active_stake_cache_epoch_no integer; BEGIN -- CHECK PREVIOUS QUERY FINISHED RUNNING IF ( @@ -100,33 +98,7 @@ BEGIN ON CONFLICT (epoch_no) DO UPDATE SET amount = excluded.amount WHERE epoch_active_stake_cache.amount IS DISTINCT FROM excluded.amount; - -- ACCOUNT ACTIVE STAKE CACHE - SELECT COALESCE(MAX(epoch_no), (_epoch_no - 4)) INTO _last_account_active_stake_cache_epoch_no - FROM grest.account_active_stake_cache; - INSERT INTO grest.account_active_stake_cache - SELECT - stake_address.view AS stake_address, - pool_hash.view AS pool_id, - epoch_stake.epoch_no AS epoch_no, - SUM(epoch_stake.amount) AS amount - FROM public.epoch_stake - INNER JOIN public.pool_hash ON pool_hash.id = epoch_stake.pool_id - INNER JOIN public.stake_address ON stake_address.id = epoch_stake.addr_id - WHERE epoch_stake.epoch_no > _last_account_active_stake_cache_epoch_no - AND epoch_stake.epoch_no <= _epoch_no - GROUP BY - stake_address.id, - pool_hash.id, - epoch_stake.epoch_no - ON CONFLICT ( - stake_address, - pool_id, - epoch_no - ) DO UPDATE - SET amount = excluded.amount; - DELETE FROM grest.account_active_stake_cache - WHERE epoch_no <= (_epoch_no - 4); -- CONTROL TABLE ENTRY PERFORM grest.update_control_table( 'last_active_stake_validated_epoch', diff --git a/files/grest/rpc/01_cached_tables/asset_cache_control.sql b/files/grest/rpc/01_cached_tables/asset_cache_control.sql index 72ff2729..f01e00f9 100644 --- a/files/grest/rpc/01_cached_tables/asset_cache_control.sql +++ b/files/grest/rpc/01_cached_tables/asset_cache_control.sql @@ -16,24 +16,24 @@ CREATE INDEX IF NOT EXISTS idx_atoc_txoid ON grest.asset_tx_out_cache USING btre CREATE INDEX IF NOT EXISTS idx_atoc_maid ON grest.asset_tx_out_cache USING btree (ma_id) INCLUDE (txo_id, quantity); DELETE FROM grest.asset_cache_control; -INSERT INTO grest.asset_cache_control VALUES (DECODE('a0028f350aaabe0545fdcb56b039bfb08e4bb4d8c4d7c3c7d481c235', 'hex')); -- HOSKY -INSERT INTO grest.asset_cache_control VALUES (DECODE('af2e27f580f7f08e93190a81f72462f153026d06450924726645891b', 'hex')); -- DRIP -INSERT INTO grest.asset_cache_control VALUES (DECODE('29d222ce763455e3d7a09a665ce554f00ac89d2e99a1a83d267170c6', 'hex')); -- MIN -INSERT INTO grest.asset_cache_control VALUES (DECODE('9a9693a9a37912a5097918f97918d15240c92ab729a0b7c4aa144d77', 'hex')); -- SUNDAE -INSERT INTO grest.asset_cache_control VALUES (DECODE('13aa2accf2e1561723aa26871e071fdf32c867cff7e7d50ad470d62f', 'hex')); -- MINSWAP -INSERT INTO grest.asset_cache_control VALUES (DECODE('c0ee29a85b13209423b10447d3c2e6a50641a15c57770e27cb9d5073', 'hex')); -- WINGRIDERS -INSERT INTO grest.asset_cache_control VALUES (DECODE('1d7f33bd23d85e1a25d87d86fac4f199c3197a2f7afeb662a0f34e1e', 'hex')); -- worldmobiletoken -INSERT INTO grest.asset_cache_control VALUES (DECODE('682fe60c9918842b3323c43b5144bc3d52a23bd2fb81345560d73f63', 'hex')); -- NEWM -INSERT INTO grest.asset_cache_control VALUES (DECODE('6ac8ef33b510ec004fe11585f7c5a9f0c07f0c23428ab4f29c1d7d10', 'hex')); -- MELD -INSERT INTO grest.asset_cache_control VALUES (DECODE('884892bcdc360bcef87d6b3f806e7f9cd5ac30d999d49970e7a903ae', 'hex')); -- PAVIA -INSERT INTO grest.asset_cache_control VALUES (DECODE('279c909f348e533da5808898f87f9a14bb2c3dfbbacccd631d927a3f', 'hex')); -- SNEK -INSERT INTO grest.asset_cache_control VALUES (DECODE('f43a62fdc3965df486de8a0d32fe800963589c41b38946602a0dc535', 'hex')); -- AGIX -INSERT INTO grest.asset_cache_control VALUES (DECODE('92292852e3820cfbe99874b284fdf2befbddb38e070cf3512009a60a', 'hex')); -- *Pearl -INSERT INTO grest.asset_cache_control VALUES (DECODE('de9b756719341e79785aa13c164e7fe68c189ed04d61c9876b2fe53f', 'hex')); -- MuesliSwap_AMM -INSERT INTO grest.asset_cache_control VALUES (DECODE('10a49b996e2402269af553a8a96fb8eb90d79e9eca79e2b4223057b6', 'hex')); -- GERO -INSERT INTO grest.asset_cache_control VALUES (DECODE('750900e4999ebe0d58f19b634768ba25e525aaf12403bfe8fe130501', 'hex')); -- BOOK -INSERT INTO grest.asset_cache_control VALUES (DECODE('e38748c08c510a4a5d712922a0f91269b8446ac565068f653c517475', 'hex')); -- preprod KUt1 -INSERT INTO grest.asset_cache_control VALUES (DECODE('602866d30452bf3ea0af2d6b4007389eed5542d2572808cba3eb991f', 'hex')); -- preprod tokenA -INSERT INTO grest.asset_cache_control VALUES (DECODE('af6c50cb85c8df17f539437c01b405ab9b62b03140d872e787d7a279', 'hex')); -- preprod tokenB -INSERT INTO grest.asset_cache_control VALUES (DECODE('c462512684cf5a5ee0b176326c724d5879a37a4977d3bf1e4edc39f6', 'hex')); -- preview mTOSI BLUE/GREEN/PURPLE/RAINBOW/RED/YELLOW +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('a0028f350aaabe0545fdcb56b039bfb08e4bb4d8c4d7c3c7d481c235', 'hex')); -- HOSKY +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('af2e27f580f7f08e93190a81f72462f153026d06450924726645891b', 'hex')); -- DRIP +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('29d222ce763455e3d7a09a665ce554f00ac89d2e99a1a83d267170c6', 'hex')); -- MIN +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('9a9693a9a37912a5097918f97918d15240c92ab729a0b7c4aa144d77', 'hex')); -- SUNDAE +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('13aa2accf2e1561723aa26871e071fdf32c867cff7e7d50ad470d62f', 'hex')); -- MINSWAP +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('c0ee29a85b13209423b10447d3c2e6a50641a15c57770e27cb9d5073', 'hex')); -- WINGRIDERS +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('1d7f33bd23d85e1a25d87d86fac4f199c3197a2f7afeb662a0f34e1e', 'hex')); -- worldmobiletoken +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('682fe60c9918842b3323c43b5144bc3d52a23bd2fb81345560d73f63', 'hex')); -- NEWM +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('6ac8ef33b510ec004fe11585f7c5a9f0c07f0c23428ab4f29c1d7d10', 'hex')); -- MELD +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('884892bcdc360bcef87d6b3f806e7f9cd5ac30d999d49970e7a903ae', 'hex')); -- PAVIA +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('279c909f348e533da5808898f87f9a14bb2c3dfbbacccd631d927a3f', 'hex')); -- SNEK +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('f43a62fdc3965df486de8a0d32fe800963589c41b38946602a0dc535', 'hex')); -- AGIX +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('92292852e3820cfbe99874b284fdf2befbddb38e070cf3512009a60a', 'hex')); -- *Pearl +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('de9b756719341e79785aa13c164e7fe68c189ed04d61c9876b2fe53f', 'hex')); -- MuesliSwap_AMM +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('10a49b996e2402269af553a8a96fb8eb90d79e9eca79e2b4223057b6', 'hex')); -- GERO +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('750900e4999ebe0d58f19b634768ba25e525aaf12403bfe8fe130501', 'hex')); -- BOOK +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('e38748c08c510a4a5d712922a0f91269b8446ac565068f653c517475', 'hex')); -- preprod KUt1 +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('602866d30452bf3ea0af2d6b4007389eed5542d2572808cba3eb991f', 'hex')); -- preprod tokenA +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('af6c50cb85c8df17f539437c01b405ab9b62b03140d872e787d7a279', 'hex')); -- preprod tokenB +-- INSERT INTO grest.asset_cache_control VALUES (DECODE('c462512684cf5a5ee0b176326c724d5879a37a4977d3bf1e4edc39f6', 'hex')); -- preview mTOSI BLUE/GREEN/PURPLE/RAINBOW/RED/YELLOW -- INSERT INTO grest.asset_cache_control VALUES (DECODE('', 'hex')); -- 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 3b49d354..acd480f2 100644 --- a/files/grest/rpc/01_cached_tables/asset_info_cache.sql +++ b/files/grest/rpc/01_cached_tables/asset_info_cache.sql @@ -13,6 +13,7 @@ CREATE TABLE IF NOT EXISTS grest.asset_info_cache ( CREATE INDEX IF NOT EXISTS idx_first_mint_tx_id ON grest.asset_info_cache (first_mint_tx_id); CREATE INDEX IF NOT EXISTS idx_last_mint_tx_id ON grest.asset_info_cache (last_mint_tx_id); +CREATE INDEX IF NOT EXISTS idx_creation_time ON grest.asset_info_cache (creation_time DESC); CREATE OR REPLACE FUNCTION grest.asset_info_cache_update() RETURNS void @@ -37,7 +38,8 @@ BEGIN SELECT MAX(id) INTO _lastest_tx_id FROM public.tx; - SELECT COALESCE(last_value::bigint,1000) - 1000 INTO _asset_info_cache_last_tx_id + -- assumption rollback to cater for - 15 blocks (16 tx each) , accordingly - rounding off to 250 + SELECT COALESCE(last_value::bigint,250) - 250 INTO _asset_info_cache_last_tx_id FROM grest.control_table WHERE key = 'asset_info_cache_last_tx_id'; diff --git a/files/grest/rpc/01_cached_tables/asset_txo_cache.sql b/files/grest/rpc/01_cached_tables/asset_txo_cache.sql index 442f9d7a..7a4084c3 100644 --- a/files/grest/rpc/01_cached_tables/asset_txo_cache.sql +++ b/files/grest/rpc/01_cached_tables/asset_txo_cache.sql @@ -32,14 +32,14 @@ BEGIN mf.quantity FROM ma_filtered AS mf LEFT JOIN tx_out AS txo ON mf.tx_out_id = txo.id - WHERE txo.consumed_by_tx_in_id IS NULL AND txo.id < (SELECT MAX(id) from tx_out) + WHERE txo.consumed_by_tx_id IS NULL AND txo.id < (SELECT MAX(id) from tx_out) ; DELETE FROM grest.asset_tx_out_cache WHERE txo_id IN (SELECT atoc.txo_id FROM grest.asset_tx_out_cache AS atoc LEFT JOIN tx_out AS txo ON atoc.txo_id = txo.id - WHERE txo.consumed_by_tx_in_id IS NOT NULL + WHERE txo.consumed_by_tx_id IS NOT NULL OR txo.id IS NULL); END; 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 e4a0951b..db3267bf 100644 --- a/files/grest/rpc/01_cached_tables/pool_history_cache.sql +++ b/files/grest/rpc/01_cached_tables/pool_history_cache.sql @@ -44,16 +44,16 @@ BEGIN RAISE EXCEPTION 'Active stake cache not yet populated! Exiting...'; END IF; + SELECT COALESCE(MAX(epoch_no), 0) INTO _latest_epoch_no_in_cache FROM grest.pool_history_cache; + -- Split into 100 epochs at a time to avoid hours spent on a single query (which can be risky if that query is killed) + SELECT LEAST( 500 , (MAX(no) - _latest_epoch_no_in_cache) ) + _latest_epoch_no_in_cache INTO _curr_epoch FROM epoch; + IF _epoch_no_to_insert_from IS NULL THEN - SELECT COALESCE(MAX(epoch_no), 0) INTO _latest_epoch_no_in_cache - FROM grest.pool_history_cache; IF _latest_epoch_no_in_cache = 0 THEN RAISE NOTICE 'Pool history cache table is empty, starting initial population...'; PERFORM grest.pool_history_cache_update (0); RETURN; END IF; - SELECT MAX(no) INTO _curr_epoch - FROM epoch; -- no-op IF we already have data up until second most recent epoch IF _latest_epoch_no_in_cache >= (_curr_epoch - 1) THEN INSERT INTO grest.control_table (key, last_value) @@ -68,6 +68,7 @@ BEGIN -- purge the data for the given epoch range, in theory should do nothing IF invoked only at start of new epoch DELETE FROM grest.pool_history_cache WHERE epoch_no >= _epoch_no_to_insert_from; + INSERT INTO grest.pool_history_cache ( WITH blockcounts AS ( @@ -75,8 +76,7 @@ BEGIN sl.pool_hash_id, b.epoch_no, COUNT(*) AS block_cnt - FROM - block AS b, + FROM block AS b, slot_leader AS sl WHERE b.slot_leader_id = sl.id AND b.epoch_no >= _epoch_no_to_insert_from @@ -123,8 +123,7 @@ BEGIN WHERE id = ( SELECT MAX(pup2.id) - FROM - pool_hash AS ph, + FROM pool_hash AS ph, pool_update AS pup2 WHERE pup2.hash_id = ph.id AND ph.view = act.pool_id @@ -133,12 +132,10 @@ BEGIN ) AS pool_fee_variable, ( SELECT fixed_cost - FROM - pool_update + FROM pool_update WHERE id = ( SELECT MAX(pup2.id) - FROM - pool_update AS pup2, + FROM pool_update AS pup2, pool_hash AS ph WHERE ph.view = act.pool_id AND pup2.hash_id = ph.id @@ -163,12 +160,7 @@ BEGIN ) AS saturation_pct FROM grest.pool_active_stake_cache AS act WHERE act.epoch_no >= _epoch_no_to_insert_from - -- TODO: revisit later: currently ignore latest epoch AS active stake might not be populated for it yet - AND act.epoch_no < ( - SELECT MAX(e."no") - FROM - epoch AS e - ) + AND act.epoch_no <= _curr_epoch ), delegators AS ( @@ -178,6 +170,7 @@ BEGIN COUNT(1) AS delegator_cnt FROM epoch_stake AS es WHERE es.epoch_no >= _epoch_no_to_insert_from + AND es.epoch_no <= _curr_epoch GROUP BY es.pool_id, es.epoch_no @@ -201,12 +194,11 @@ BEGIN ELSE -- special CASE for WHEN reward information is not available yet CASE COALESCE(l.leadertotal, 0) + COALESCE(m.memtotal, 0) - WHEN 0 THEN - NULL - ELSE + WHEN 0 THEN NULL + ELSE CASE - WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN COALESCE(l.leadertotal, 0) - ELSE ROUND(actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable)) + WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN COALESCE(l.leadertotal, 0) + ELSE ROUND(actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable)) END END END AS pool_fees, @@ -216,46 +208,39 @@ BEGIN ELSE -- special CASE for WHEN reward information is not available yet CASE COALESCE(l.leadertotal, 0) + COALESCE(m.memtotal, 0) - WHEN 0 THEN - NULL + WHEN 0 THEN NULL ELSE CASE - WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN COALESCE(m.memtotal, 0) - ELSE ROUND(COALESCE(m.memtotal, 0) + (COALESCE(l.leadertotal, 0) - (actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable)))) + WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN COALESCE(m.memtotal, 0) + ELSE ROUND(COALESCE(m.memtotal, 0) + (COALESCE(l.leadertotal, 0) - (actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable)))) END END END AS deleg_rewards, CASE COALESCE(b.block_cnt, 0) - WHEN 0 THEN - 0 + WHEN 0 THEN 0 ELSE CASE COALESCE(m.memtotal, 0) - WHEN 0 THEN - NULL - ELSE - COALESCE(m.memtotal, 0) + WHEN 0 THEN NULL + ELSE COALESCE(m.memtotal, 0) END END AS member_rewards, CASE COALESCE(b.block_cnt, 0) - WHEN 0 THEN - 0 + WHEN 0 THEN 0 ELSE -- special CASE for WHEN reward information is not available yet CASE COALESCE(l.leadertotal, 0) + COALESCE(m.memtotal, 0) - WHEN 0 THEN - NULL - ELSE - CASE - WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN - ROUND((((POW((LEAST(((COALESCE(m.memtotal, 0)) / (NULLIF(actf.active_stake, 0))), 1000) + 1), 73) - 1)) * 100)::numeric, 9) - -- using LEAST AS a way to prevent overflow, in CASE of dodgy database data (e.g. giant rewards / tiny active stake) - ELSE ROUND((((POW((LEAST((((COALESCE(m.memtotal, 0) + (COALESCE(l.leadertotal, 0) - (actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) - + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable))))) / (NULLIF(actf.active_stake, 0))), 1000) + 1), 73) - 1)) * 100)::numeric, 9) - END + WHEN 0 THEN NULL + ELSE + CASE + WHEN COALESCE(l.leadertotal, 0) < actf.pool_fee_fixed THEN ROUND((((POW((LEAST(((COALESCE(m.memtotal, 0)) / (NULLIF(actf.active_stake, 0))), 1000) + 1), 73) - 1)) * 100)::numeric, 9) + -- using LEAST AS a way to prevent overflow, in CASE of dodgy database data (e.g. giant rewards / tiny active stake) + ELSE ROUND((((POW((LEAST((((COALESCE(m.memtotal, 0) + (COALESCE(l.leadertotal, 0) - (actf.pool_fee_fixed + (((COALESCE(m.memtotal, 0) + + COALESCE(l.leadertotal, 0)) - actf.pool_fee_fixed) * actf.pool_fee_variable))))) / (NULLIF(actf.active_stake, 0))), 1000) + 1), 73) - 1)) * 100)::numeric, 9) + END END END AS epoch_ros FROM pool_hash AS ph - INNER JOIN activeandfees AS actf ON actf.pool_id = ph."view" + INNER JOIN activeandfees AS actf ON actf.pool_id = ph.view LEFT JOIN blockcounts AS b ON ph.id = b.pool_hash_id AND actf.epoch_no = b.epoch_no LEFT JOIN leadertotals AS l ON ph.id = l.pool_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 aa56c0c8..ce9f77b4 100644 --- a/files/grest/rpc/01_cached_tables/stake_distribution_cache.sql +++ b/files/grest/rpc/01_cached_tables/stake_distribution_cache.sql @@ -15,19 +15,16 @@ DECLARE -- Last block height to control future re-runs of the query _last_accounted_block_height bigint; _last_account_tx_id bigint; _active_stake_epoch bigint; - _last_active_stake_blockid bigint; _latest_epoch bigint; + _row_count bigint; BEGIN SELECT MAX(block_no) FROM public.block WHERE block_no IS NOT NULL INTO _last_accounted_block_height; SELECT (last_value::integer - 2)::integer INTO _active_stake_epoch FROM grest.control_table WHERE key = 'last_active_stake_validated_epoch'; - SELECT MAX(tx.id) INTO _last_account_tx_id - FROM public.tx - INNER JOIN block AS b ON b.id = tx.block_id - WHERE b.epoch_no <= _active_stake_epoch - AND b.block_no IS NOT NULL - AND b.tx_count != 0; + SELECT MAX(eic.i_last_tx_id) INTO _last_account_tx_id + FROM grest.epoch_info_cache AS eic + WHERE eic.epoch_no <= _active_stake_epoch; SELECT MAX(no) INTO _latest_epoch FROM public.epoch WHERE no IS NOT NULL; WITH @@ -50,6 +47,8 @@ BEGIN WHERE stake_deregistration.addr_id = delegation.addr_id AND stake_deregistration.tx_id > delegation.tx_id ) + -- skip delegations that were followed by at least one stake pool retirement + AND NOT grest.is_dangling_delegation(delegation.id) -- Account must be present in epoch_stake table for the last validated epoch AND EXISTS ( SELECT TRUE @@ -74,22 +73,19 @@ BEGIN account_active_stake AS ( SELECT awdp.stake_address_id, - acsc.amount - FROM grest.account_active_stake_cache AS acsc - INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address = acsc.stake_address + es.amount + FROM epoch_stake AS es + INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = es.addr_id WHERE epoch_no = (_active_stake_epoch + 2) ), account_delta_tx_ins AS ( SELECT awdp.stake_address_id, - tx_in.tx_out_id AS txoid, - tx_in.tx_out_index AS txoidx - FROM tx_in - LEFT JOIN tx_out ON tx_in.tx_out_id = tx_out.tx_id - AND tx_in.tx_out_index::smallint = tx_out.index::smallint + tx_out.id AS txoid + FROM tx_out INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = tx_out.stake_address_id - WHERE tx_in.tx_in_id > _last_account_tx_id + WHERE tx_out.consumed_by_tx_id > _last_account_tx_id ), account_delta_input AS ( @@ -97,9 +93,7 @@ BEGIN tx_out.stake_address_id, COALESCE(SUM(tx_out.value), 0) AS amount FROM account_delta_tx_ins - LEFT JOIN tx_out - ON account_delta_tx_ins.txoid=tx_out.tx_id - AND account_delta_tx_ins.txoidx = tx_out.index + LEFT JOIN tx_out ON account_delta_tx_ins.txoid=tx_out.id INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = tx_out.stake_address_id GROUP BY tx_out.stake_address_id ), @@ -126,6 +120,17 @@ BEGIN GROUP BY awdp.stake_address_id ), + account_delta_instant_rewards AS ( + SELECT + awdp.stake_address_id, + COALESCE(SUM(ir.amount), 0) AS amount + FROM instant_reward AS ir + INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = ir.addr_id + WHERE ir.spendable_epoch >= (_active_stake_epoch + 2) + AND ir.spendable_epoch <= _latest_epoch + GROUP BY awdp.stake_address_id + ), + account_delta_withdrawals AS ( SELECT accounts_with_delegated_pools.stake_address_id, @@ -160,18 +165,13 @@ BEGIN SELECT awdp.stake_address, pi.pool_id, - COALESCE(aas.amount, 0) + COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) - COALESCE(adw.withdrawals, 0) AS total_balance, - CASE - WHEN ( COALESCE(atrew.rewards, 0) - COALESCE(atw.withdrawals, 0) ) <= 0 THEN - COALESCE(aas.amount, 0) + COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) - COALESCE(adw.withdrawals, 0) - ELSE - COALESCE(aas.amount, 0) + COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) - COALESCE(adw.withdrawals, 0) - (COALESCE(atrew.rewards, 0) - COALESCE(atw.withdrawals, 0)) - END AS utxo, + COALESCE(aas.amount, 0) + COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) + COALESCE(adir.amount, 0) - COALESCE(adw.withdrawals, 0) AS total_balance, + COALESCE(aas.amount, 0) + COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) + COALESCE(adir.amount, 0) - COALESCE(adw.withdrawals, 0) AS utxo, COALESCE(atrew.rewards, 0) AS rewards, COALESCE(atw.withdrawals, 0) AS withdrawals, CASE - WHEN ( COALESCE(atrew.rewards, 0) - COALESCE(atw.withdrawals, 0) ) <= 0 THEN 0 - ELSE COALESCE(atrew.rewards, 0) - COALESCE(atw.withdrawals, 0) + WHEN ( COALESCE(atrew.rewards, 0) + COALESCE(adir.amount, 0) - COALESCE(atw.withdrawals, 0) ) <= 0 THEN 0 + ELSE COALESCE(atrew.rewards, 0) + COALESCE(adir.amount, 0) - COALESCE(atw.withdrawals, 0) END AS rewards_available FROM accounts_with_delegated_pools AS awdp INNER JOIN pool_ids AS pi ON pi.stake_address_id = awdp.stake_address_id @@ -181,6 +181,7 @@ BEGIN LEFT JOIN account_delta_input AS adi ON adi.stake_address_id = awdp.stake_address_id LEFT JOIN account_delta_output AS ado ON ado.stake_address_id = awdp.stake_address_id LEFT JOIN account_delta_rewards AS adr ON adr.stake_address_id = awdp.stake_address_id + LEFT JOIN account_delta_instant_rewards AS adir ON adir.stake_address_id = awdp.stake_address_id LEFT JOIN account_delta_withdrawals AS adw ON adw.stake_address_id = awdp.stake_address_id ON CONFLICT (stake_address) DO UPDATE @@ -199,6 +200,43 @@ BEGIN ) ON CONFLICT (key) DO UPDATE SET last_value = _last_accounted_block_height; + + + -- Clean up de-registered accounts + DELETE FROM grest.stake_distribution_cache + WHERE stake_address IN ( + SELECT DISTINCT ON (sa.id) + sa.view + FROM stake_address AS sa + INNER JOIN stake_deregistration AS sd ON sa.id = sd.addr_id + WHERE NOT EXISTS ( + SELECT TRUE + FROM stake_registration AS sr + WHERE sr.addr_id = sd.addr_id + AND sr.tx_id >= sd.tx_id + ) + ); + + -- Clean up accounts registered to retired-at-least-once-since pools + RAISE NOTICE 'DANGLING delegation cleanup from SDC commencing'; + DELETE FROM grest.stake_distribution_cache + WHERE stake_address in ( + SELECT z.stake_address + FROM ( + SELECT + ( + SELECT max(d.id) + FROM delegation d + INNER JOIN stake_address sd ON sd.view = sdc.stake_address AND sd.id = d.addr_id) AS last_deleg, + sdc.stake_address + FROM grest.stake_distribution_cache AS sdc + ) AS z + WHERE grest.is_dangling_delegation(z.last_deleg) + ); + + GET DIAGNOSTICS _row_count = ROW_COUNT; + RAISE NOTICE 'DANGLING delegations - deleted % rows', _row_count; + END; $$; @@ -247,6 +285,11 @@ BEGIN WHERE key = 'last_active_stake_validated_epoch' ) THEN RAISE EXCEPTION 'Active Stake cache too far, skipping...'; + ELSIF ( + SELECT + ((SELECT MAX(no) FROM epoch) - (SELECT MAX(epoch_no)::integer FROM grest.epoch_info_cache))::integer > 1 + ) THEN + RAISE EXCEPTION 'Epoch Info cache wasnt run yet, skipping...'; END IF; -- QUERY START -- diff --git a/files/grest/rpc/01_cached_tables/stake_distribution_new_accounts.sql b/files/grest/rpc/01_cached_tables/stake_distribution_new_accounts.sql index 90325710..6c44bc61 100644 --- a/files/grest/rpc/01_cached_tables/stake_distribution_new_accounts.sql +++ b/files/grest/rpc/01_cached_tables/stake_distribution_new_accounts.sql @@ -51,10 +51,16 @@ BEGIN AND NOT EXISTS ( SELECT TRUE FROM epoch_stake - WHERE epoch_stake.epoch_no = ( - SELECT last_value::integer FROM grest.control_table - WHERE key = 'last_active_stake_validated_epoch' - ) + WHERE epoch_stake.epoch_no <= COALESCE( + ( + SELECT last_value::integer + FROM grest.control_table + WHERE key = 'stake_distribution_new_epoch' + ), ( + SELECT last_value::integer + FROM grest.control_table + WHERE key = 'last_active_stake_validated_epoch' + )) AND epoch_stake.addr_id = stake_address.id ) ) @@ -80,19 +86,15 @@ BEGIN withdrawals = EXCLUDED.withdrawals, rewards_available = EXCLUDED.rewards_available; - -- Clean up de-registered accounts - DELETE FROM grest.stake_distribution_cache - WHERE stake_address IN ( - SELECT DISTINCT ON (sa.id) - sa.view - FROM stake_address AS sa - INNER JOIN stake_deregistration AS sd ON sa.id = sd.addr_id - WHERE NOT EXISTS ( - SELECT TRUE - FROM stake_registration AS sr - WHERE sr.addr_id = sd.addr_id - AND sr.tx_id >= sd.tx_id - ) - ); + INSERT INTO grest.control_table (key, last_value) + VALUES ( + 'stake_distribution_new_epoch', + (SELECT last_value::integer FROM grest.control_table + WHERE key = 'last_active_stake_validated_epoch') + ) ON CONFLICT (key) DO + UPDATE + SET last_value = (SELECT last_value::integer FROM grest.control_table + WHERE key = 'last_active_stake_validated_epoch'); + END; $$; diff --git a/files/grest/rpc/01_cached_tables/stake_snapshot_cache.sql b/files/grest/rpc/01_cached_tables/stake_snapshot_cache.sql deleted file mode 100644 index b8335074..00000000 --- a/files/grest/rpc/01_cached_tables/stake_snapshot_cache.sql +++ /dev/null @@ -1,428 +0,0 @@ -/* Keeps track of stake snapshots taken at the end of epochs n - 1 and n - 2 */ -CREATE TABLE IF NOT EXISTS grest.stake_snapshot_cache ( - addr_id integer, - pool_id integer, - amount numeric, - epoch_no bigint, - PRIMARY KEY (addr_id, epoch_no) -); - -CREATE INDEX IF NOT EXISTS _idx_pool_id ON grest.stake_snapshot_cache (pool_id); -CREATE INDEX IF NOT EXISTS _idx_addr_id ON grest.stake_snapshot_cache (addr_id); - -CREATE OR REPLACE PROCEDURE grest.capture_last_epoch_snapshot() -LANGUAGE plpgsql -AS $$ -DECLARE - _previous_epoch_no bigint; - _lower_bound_account_tx_id bigint; - _upper_bound_account_tx_id bigint; - _newly_registered_account_ids bigint[]; -BEGIN - IF ( - -- If checking query with the same name there will be 2 results - SELECT COUNT(pid) > 1 - FROM pg_stat_activity - WHERE state = 'active' - AND query ILIKE '%grest.capture_last_epoch_snapshot(%' - AND datname = ( - SELECT current_database() - ) - ) THEN - RAISE EXCEPTION 'Previous query still running but should have completed! Exiting...'; - END IF; - - SELECT MAX(no) - 1 INTO _previous_epoch_no FROM public.epoch; - - IF NOT EXISTS ( - SELECT i_last_tx_id FROM grest.epoch_info_cache - WHERE epoch_no = _previous_epoch_no - AND i_last_tx_id IS NOT NULL - ) THEN - RAISE NOTICE 'Epoch % info cache not ready, exiting.', _previous_epoch_no; - RETURN; - END IF; - - IF EXISTS ( - SELECT FROM grest.stake_snapshot_cache - WHERE epoch_no = _previous_epoch_no - ) THEN - RETURN; - END IF; - - -- Set-up interval limits for previous epoch - SELECT MAX(tx.id) INTO _lower_bound_account_tx_id - FROM public.tx - INNER JOIN BLOCK AS b ON b.id = tx.block_id - WHERE b.epoch_no <= _previous_epoch_no - 2 - AND b.block_no IS NOT NULL - AND b.tx_count != 0; - - SELECT MAX(tx.id) INTO _upper_bound_account_tx_id - FROM public.tx - INNER JOIN BLOCK AS b ON b.id = tx.block_id - WHERE b.epoch_no <= _previous_epoch_no - AND b.block_no IS NOT NULL - AND b.tx_count != 0; - - /* Temporary table to figure out valid delegations ending up in active stake in case of pool retires */ - DROP TABLE IF EXISTS minimum_pool_delegation_tx_ids; - CREATE TEMP TABLE minimum_pool_delegation_tx_ids ( - pool_hash_id integer PRIMARY KEY, - latest_registered_tx_id integer, - latest_registered_tx_cert_index integer - ); - - DROP TABLE IF EXISTS latest_accounts_delegation_txs; - CREATE TEMP TABLE latest_accounts_delegation_txs ( - addr_id integer PRIMARY KEY, - tx_id integer, - cert_index integer, - pool_hash_id integer - ); - - DROP TABLE IF EXISTS rewards_subset; - CREATE TEMP TABLE rewards_subset ( - stake_address_id bigint, - type rewardtype, - spendable_epoch bigint, - amount lovelace - ); - - INSERT INTO rewards_subset - SELECT addr_id, type, spendable_epoch, amount - FROM reward - WHERE spendable_epoch BETWEEN _previous_epoch_no - 1 AND _previous_epoch_no + 1; - -/* Registered and delegated accounts to be captured (have epoch_stake entries for baseline) */ - WITH - latest_non_cancelled_pool_retire AS ( - SELECT DISTINCT ON (pr.hash_id) - pr.hash_id, - pr.retiring_epoch - FROM pool_retire AS pr - WHERE - pr.announced_tx_id <= _upper_bound_account_tx_id - AND pr.retiring_epoch <= _previous_epoch_no - AND NOT EXISTS ( - SELECT TRUE - FROM pool_update AS pu - WHERE pu.hash_id = pr.hash_id - AND ( - pu.registered_tx_id > pr.announced_tx_id - OR ( - pu.registered_tx_id = pr.announced_tx_id - AND pu.cert_index > pr.cert_index - ) - ) - AND pu.registered_tx_id <= _upper_bound_account_tx_id - AND pu.registered_tx_id <= ( - SELECT i_last_tx_id - FROM grest.epoch_info_cache AS eic - WHERE eic.epoch_no = pr.retiring_epoch - 1 - ) - ) - AND NOT EXISTS ( - SELECT TRUE - FROM pool_retire AS sub_pr - WHERE pr.hash_id = sub_pr.hash_id - AND ( - sub_pr.announced_tx_id > pr.announced_tx_id - OR ( - sub_pr.announced_tx_id = pr.announced_tx_id - AND sub_pr.cert_index > pr.cert_index - ) - ) - AND sub_pr.announced_tx_id <= _upper_bound_account_tx_id - AND sub_pr.announced_tx_id <= ( - SELECT i_last_tx_id - FROM grest.epoch_info_cache AS eic - WHERE eic.epoch_no = pr.retiring_epoch - 1 - ) - ) - ORDER BY - pr.hash_id, pr.retiring_epoch DESC - ) - - INSERT INTO minimum_pool_delegation_tx_ids - SELECT DISTINCT ON (pu.hash_id) - pu.hash_id, - pu.registered_tx_id AS min_tx_id, - pu.cert_index - FROM pool_update AS pu - LEFT JOIN latest_non_cancelled_pool_retire AS lncpr ON lncpr.hash_id = pu.hash_id - WHERE pu.registered_tx_id <= _upper_bound_account_tx_id - AND - CASE WHEN lncpr.retiring_epoch IS NOT NULL - THEN - pu.registered_tx_id > ( - SELECT i_last_tx_id - FROM grest.epoch_info_cache AS eic - WHERE eic.epoch_no = lncpr.retiring_epoch - 1 - ) - ELSE TRUE - END - ORDER BY - pu.hash_id, pu.registered_tx_id ASC; - - INSERT INTO latest_accounts_delegation_txs - SELECT distinct ON (d.addr_id) - d.addr_id, - d.tx_id, - d.cert_index, - d.pool_hash_id - FROM delegation AS d - WHERE - d.tx_id <= _upper_bound_account_tx_id - AND NOT EXISTS ( - SELECT TRUE FROM stake_deregistration - WHERE stake_deregistration.addr_id = d.addr_id - AND ( - stake_deregistration.tx_id > d.tx_id - OR ( - stake_deregistration.tx_id = d.tx_id - AND stake_deregistration.cert_index > d.cert_index - ) - ) - AND stake_deregistration.tx_id <= _upper_bound_account_tx_id - ) - ORDER BY - d.addr_id, d.tx_id DESC; - CREATE INDEX _idx_pool_hash_id ON latest_accounts_delegation_txs (pool_hash_id); - /* Registered and delegated accounts to be captured (have epoch_stake entries for baseline) */ - WITH - accounts_with_delegated_pools AS ( - SELECT DISTINCT ON (ladt.addr_id) - ladt.addr_id AS stake_address_id, - ladt.pool_hash_id - FROM latest_accounts_delegation_txs AS ladt - INNER JOIN minimum_pool_delegation_tx_ids AS mpdtx ON mpdtx.pool_hash_id = ladt.pool_hash_id - WHERE - ( - ladt.tx_id > mpdtx.latest_registered_tx_id - OR ( - ladt.tx_id = mpdtx.latest_registered_tx_id - AND ladt.cert_index > mpdtx.latest_registered_tx_cert_index - ) - ) - -- Account must be present in epoch_stake table for the previous epoch - AND EXISTS ( - SELECT TRUE FROM epoch_stake AS es - WHERE es.epoch_no = _previous_epoch_no - AND es.addr_id = ladt.addr_id - ) - ), - account_active_stake AS ( - SELECT - awdp.stake_address_id, - es.amount - FROM public.epoch_stake AS es - INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = es.addr_id - WHERE epoch_no = _previous_epoch_no - ), - account_delta_tx_ins AS ( - SELECT - awdp.stake_address_id, - tx_in.tx_out_id AS txoid, - tx_in.tx_out_index AS txoidx - FROM tx_in - LEFT JOIN tx_out ON tx_in.tx_out_id = tx_out.tx_id - AND tx_in.tx_out_index::smallint = tx_out.index::smallint - INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = tx_out.stake_address_id - WHERE tx_in.tx_in_id > _lower_bound_account_tx_id - AND tx_in.tx_in_id <= _upper_bound_account_tx_id - ), - account_delta_input AS ( - SELECT - tx_out.stake_address_id, - COALESCE(SUM(tx_out.value), 0) AS amount - FROM account_delta_tx_ins - LEFT JOIN tx_out ON account_delta_tx_ins.txoid=tx_out.tx_id AND account_delta_tx_ins.txoidx = tx_out.index - INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = tx_out.stake_address_id - GROUP BY tx_out.stake_address_id - ), - account_delta_output AS ( - SELECT - awdp.stake_address_id, - COALESCE(SUM(tx_out.value), 0) AS amount - FROM tx_out - INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = tx_out.stake_address_id - WHERE tx_out.tx_id > _lower_bound_account_tx_id - AND tx_out.tx_id <= _upper_bound_account_tx_id - GROUP BY awdp.stake_address_id - ), - account_delta_rewards AS ( - SELECT - awdp.stake_address_id, - COALESCE(SUM(rs.amount), 0) AS rewards - FROM rewards_subset AS rs - INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = rs.stake_address_id - WHERE - CASE WHEN rs.type = 'refund' - THEN rs.spendable_epoch IN (_previous_epoch_no - 1, _previous_epoch_no) - ELSE rs.spendable_epoch IN (_previous_epoch_no, _previous_epoch_no + 1) - END - GROUP BY awdp.stake_address_id - ), - account_delta_withdrawals AS ( - SELECT - accounts_with_delegated_pools.stake_address_id, - COALESCE(SUM(withdrawal.amount), 0) AS withdrawals - FROM withdrawal - INNER JOIN accounts_with_delegated_pools ON accounts_with_delegated_pools.stake_address_id = withdrawal.addr_id - WHERE withdrawal.tx_id > _lower_bound_account_tx_id - AND withdrawal.tx_id <= _upper_bound_account_tx_id - GROUP BY accounts_with_delegated_pools.stake_address_id - ) - - INSERT INTO grest.stake_snapshot_cache - SELECT - awdp.stake_address_id AS addr_id, - awdp.pool_hash_id, - COALESCE(aas.amount, 0) + COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) - COALESCE(adw.withdrawals, 0) AS amount, - _previous_epoch_no AS epoch_no - FROM accounts_with_delegated_pools AS awdp - LEFT JOIN account_active_stake AS aas ON aas.stake_address_id = awdp.stake_address_id - LEFT JOIN account_delta_input AS adi ON adi.stake_address_id = awdp.stake_address_id - LEFT JOIN account_delta_output AS ado ON ado.stake_address_id = awdp.stake_address_id - LEFT JOIN account_delta_rewards AS adr ON adr.stake_address_id = awdp.stake_address_id - LEFT JOIN account_delta_withdrawals AS adw ON adw.stake_address_id = awdp.stake_address_id - ON CONFLICT (addr_id, epoch_no) DO - UPDATE - SET - pool_id = excluded.pool_id, - amount = excluded.amount; - - /* Newly registered accounts to be captured (they don't have epoch_stake entries for baseline) */ - SELECT INTO _newly_registered_account_ids ARRAY_AGG(addr_id) - FROM ( - SELECT DISTINCT ladt.addr_id - FROM latest_accounts_delegation_txs AS ladt - INNER JOIN minimum_pool_delegation_tx_ids AS mpdtx ON mpdtx.pool_hash_id = ladt.pool_hash_id - WHERE - ( - ladt.tx_id > mpdtx.latest_registered_tx_id - OR ( - ladt.tx_id = mpdtx.latest_registered_tx_id - AND ladt.cert_index > mpdtx.latest_registered_tx_cert_index - ) - ) - -- Account must NOT be present in epoch_stake table for the previous epoch - AND NOT EXISTS ( - SELECT TRUE FROM epoch_stake AS es - WHERE es.epoch_no = _previous_epoch_no - AND es.addr_id = ladt.addr_id - ) - ) AS tmp; - - WITH - account_delta_tx_ins AS ( - SELECT - tx_out.stake_address_id, - tx_in.tx_out_id AS txoid, - tx_in.tx_out_index AS txoidx - FROM tx_in - LEFT JOIN tx_out ON tx_in.tx_out_id = tx_out.tx_id AND tx_in.tx_out_index::smallint = tx_out.index::smallint - WHERE tx_in.tx_in_id <= _upper_bound_account_tx_id - AND tx_out.stake_address_id = ANY(_newly_registered_account_ids) - ), - - account_delta_input AS ( - SELECT - tx_out.stake_address_id, - COALESCE(SUM(tx_out.value), 0) AS amount - FROM account_delta_tx_ins - LEFT JOIN tx_out ON account_delta_tx_ins.txoid=tx_out.tx_id AND account_delta_tx_ins.txoidx = tx_out.index - WHERE tx_out.stake_address_id = ANY(_newly_registered_account_ids) - GROUP BY tx_out.stake_address_id - ), - - account_delta_output AS ( - SELECT - tx_out.stake_address_id, - COALESCE(SUM(tx_out.value), 0) AS amount - FROM tx_out - WHERE tx_out.tx_id <= _upper_bound_account_tx_id - AND tx_out.stake_address_id = ANY(_newly_registered_account_ids) - GROUP BY tx_out.stake_address_id - ), - - account_delta_rewards AS ( - SELECT - r.addr_id AS stake_address_id, - COALESCE(SUM(r.amount), 0) AS rewards - FROM REWARD AS r - WHERE r.addr_id = ANY(_newly_registered_account_ids) - AND - CASE WHEN r.type = 'refund' - THEN r.spendable_epoch <= _previous_epoch_no - ELSE r.spendable_epoch <= _previous_epoch_no + 1 - END - GROUP BY r.addr_id - ), - - account_delta_withdrawals AS ( - SELECT - withdrawal.addr_id AS stake_address_id, - COALESCE(SUM(withdrawal.amount), 0) AS withdrawals - FROM withdrawal - WHERE withdrawal.tx_id <= _upper_bound_account_tx_id - AND withdrawal.addr_id = ANY(_newly_registered_account_ids) - GROUP BY withdrawal.addr_id - ) - - INSERT INTO grest.stake_snapshot_cache - SELECT - ladt.addr_id, - ladt.pool_hash_id, - COALESCE(ado.amount, 0) - COALESCE(adi.amount, 0) + COALESCE(adr.rewards, 0) - COALESCE(adw.withdrawals, 0) AS amount, - _previous_epoch_no AS epoch_no - FROM latest_accounts_delegation_txs AS ladt - LEFT JOIN account_delta_input AS adi ON adi.stake_address_id = ladt.addr_id - LEFT JOIN account_delta_output AS ado ON ado.stake_address_id = ladt.addr_id - LEFT JOIN account_delta_rewards AS adr ON adr.stake_address_id = ladt.addr_id - LEFT JOIN account_delta_withdrawals AS adw ON adw.stake_address_id = ladt.addr_id - WHERE - ladt.addr_id = ANY(_newly_registered_account_ids) - ON CONFLICT (addr_id, epoch_no) DO - UPDATE - SET - pool_id = excluded.pool_id, - amount = excluded.amount; - - INSERT INTO grest.control_table (key, last_value) - VALUES ( - 'last_stake_snapshot_epoch', - _previous_epoch_no - ) ON CONFLICT (key) - DO UPDATE - SET last_value = _previous_epoch_no; - - INSERT INTO grest.epoch_active_stake_cache - SELECT - _previous_epoch_no + 2, - SUM(amount) - FROM grest.stake_snapshot_cache - WHERE epoch_no = _previous_epoch_no - ON CONFLICT (epoch_no) DO UPDATE - SET amount = excluded.amount - WHERE epoch_active_stake_cache.amount IS DISTINCT FROM excluded.amount; - - INSERT INTO grest.pool_active_stake_cache - SELECT - ph.view, - _previous_epoch_no + 2, - SUM(ssc.amount) - FROM grest.stake_snapshot_cache AS ssc - INNER JOIN pool_hash AS ph ON ph.id = ssc.pool_id - WHERE epoch_no = _previous_epoch_no - GROUP BY - ssc.pool_id, ph.view - ON CONFLICT (pool_id, epoch_no) DO UPDATE - SET amount = excluded.amount - WHERE pool_active_stake_cache.amount IS DISTINCT FROM excluded.amount; - - DELETE FROM grest.stake_snapshot_cache - WHERE epoch_no <= _previous_epoch_no - 2; -END; -$$; diff --git a/files/grest/rpc/02_indexes/13_1_00.sql b/files/grest/rpc/02_indexes/13_1_00.sql index a5f3f543..b5042190 100644 --- a/files/grest/rpc/02_indexes/13_1_00.sql +++ b/files/grest/rpc/02_indexes/13_1_00.sql @@ -19,7 +19,6 @@ CREATE UNIQUE INDEX IF NOT EXISTS unique_stake_deregistration ON public.stake_de CREATE UNIQUE INDEX IF NOT EXISTS unique_stake_registration ON public.stake_registration USING btree (tx_id, cert_index); CREATE UNIQUE INDEX IF NOT EXISTS unique_treasury ON public.treasury USING btree (addr_id, tx_id, cert_index); CREATE UNIQUE INDEX IF NOT EXISTS unique_tx_metadata ON public.tx_metadata USING btree (key, tx_id); -CREATE UNIQUE INDEX IF NOT EXISTS unique_txin ON tx_in USING btree (tx_out_id, tx_out_index); CREATE UNIQUE INDEX IF NOT EXISTS unique_withdrawal ON public.withdrawal USING btree (addr_id, tx_id); CREATE INDEX IF NOT EXISTS idx_ma_tx_out_ident ON ma_tx_out (ident) INCLUDE (tx_out_id, quantity); CREATE INDEX IF NOT EXISTS idx_collateral_tx_in_tx_in_id ON collateral_tx_in (tx_in_id); diff --git a/files/grest/rpc/03_utilities/cip67.sql b/files/grest/rpc/03_utilities/cip67.sql index 9a30b37e..adc39500 100644 --- a/files/grest/rpc/03_utilities/cip67.sql +++ b/files/grest/rpc/03_utilities/cip67.sql @@ -27,18 +27,17 @@ END; $$; CREATE OR REPLACE FUNCTION grest.cip67_strip_label(_asset_name text) -RETURNS text +RETURNS bytea LANGUAGE plpgsql STABLE AS $$ BEGIN IF (grest.cip67_label(_asset_name) != 0) THEN - RETURN SUBSTRING(_asset_name FROM 9); + RETURN DECODE(SUBSTRING(_asset_name FROM 9),'hex'); ELSE - RETURN _asset_name; + RETURN DECODE(_asset_name,'hex'); END IF; END; $$; COMMENT ON FUNCTION grest.cip67_label IS 'Returns CIP-67 label for asset name or 0 if not a valid CIP-68 token'; -- noqa: LT01 COMMENT ON FUNCTION grest.cip67_strip_label IS 'Strips prefix from asset name matching CIP-67 standard'; -- noqa: LT01 - diff --git a/files/grest/rpc/03_utilities/cli_protocol_params.sql b/files/grest/rpc/03_utilities/cli_protocol_params.sql new file mode 100644 index 00000000..6fbc2994 --- /dev/null +++ b/files/grest/rpc/03_utilities/cli_protocol_params.sql @@ -0,0 +1,8 @@ +CREATE OR REPLACE FUNCTION grest.cli_protocol_params() +RETURNS JSON +LANGUAGE sql STABLE +AS $$ + SELECT ct.artifacts::json + FROM grest.control_table AS ct + WHERE ct.key = 'cli_protocol_params'; +$$; diff --git a/files/grest/rpc/03_utilities/is_dangling_delegation.sql b/files/grest/rpc/03_utilities/is_dangling_delegation.sql new file mode 100644 index 00000000..5280c430 --- /dev/null +++ b/files/grest/rpc/03_utilities/is_dangling_delegation.sql @@ -0,0 +1,41 @@ +CREATE OR REPLACE FUNCTION grest.is_dangling_delegation(delegation_id bigint) +RETURNS boolean +LANGUAGE plpgsql +AS $$ +DECLARE + curr_epoch bigint; + num_retirements bigint; + +BEGIN + + SELECT INTO curr_epoch MAX(no) FROM epoch; + -- revised logic: + -- check for any pool retirement record exists for the pool corresponding to given delegation + -- pool retiring epoch is current or in the past (future scheduled retirements don't count) + -- pool retiring epoch is after delegation cert submission epoch + -- and there does not exist a pool_update transaction for this pool that came after currently analyzed pool retirement tx + -- and before last transaction of the epoch preceeding the pool retirement epoch.. pool update submitted after that point in + -- time is too late and pool should have been fully retired + SELECT INTO num_retirements COUNT(*) + FROM delegation AS d + INNER JOIN pool_retire AS pr ON d.id = delegation_id + AND pr.hash_id = d.pool_hash_id + AND pr.retiring_epoch <= curr_epoch + AND pr.retiring_epoch > (SELECT b.epoch_no FROM block AS b INNER JOIN tx AS t on t.id = d.tx_id and t.block_id = b.id) + AND NOT EXISTS + ( SELECT 1 + FROM pool_update AS pu + WHERE pu.hash_id = d.pool_hash_id + AND pu.registered_tx_id >= pr.announced_tx_id + AND pu.registered_tx_id <= ( + SELECT i_last_tx_id + FROM grest.epoch_info_cache AS eic + WHERE eic.epoch_no = pr.retiring_epoch - 1 + ) + ); + + RETURN num_retirements > 0; +END; +$$; + +COMMENT ON FUNCTION grest.is_dangling_delegation IS 'Returns a boolean to indicate whether a given delegation id corresponds to a delegation that has been made dangling by retirement of a stake pool associated with it'; --noqa: LT01 diff --git a/files/grest/rpc/account/account_addresses.sql b/files/grest/rpc/account/account_addresses.sql index b3039088..2bf217cf 100644 --- a/files/grest/rpc/account/account_addresses.sql +++ b/files/grest/rpc/account/account_addresses.sql @@ -29,7 +29,7 @@ BEGIN txo.id FROM tx_out AS txo WHERE txo.stake_address_id = ANY(sa_id_list) - AND txo.consumed_by_tx_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL ) AS x ) diff --git a/files/grest/rpc/account/account_assets.sql b/files/grest/rpc/account/account_assets.sql index 94bdd455..5a64210b 100644 --- a/files/grest/rpc/account/account_assets.sql +++ b/files/grest/rpc/account/account_assets.sql @@ -26,7 +26,7 @@ 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 WHERE sa.view = ANY(_stake_addresses) - AND txo.consumed_by_tx_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL GROUP BY sa.view, ma.policy, ma.name, ma.fingerprint, aic.decimals ) diff --git a/files/grest/rpc/account/account_info.sql b/files/grest/rpc/account/account_info.sql index 213e3aaa..72c02a8f 100644 --- a/files/grest/rpc/account/account_info.sql +++ b/files/grest/rpc/account/account_info.sql @@ -66,12 +66,12 @@ BEGIN FROM ( SELECT - sas.id, - sas.view, + sa.id, + sa.view, EXISTS ( SELECT TRUE FROM stake_registration WHERE - stake_registration.addr_id = sas.id + stake_registration.addr_id = sa.id AND NOT EXISTS ( SELECT TRUE FROM stake_deregistration @@ -80,30 +80,29 @@ BEGIN AND stake_deregistration.tx_id > stake_registration.tx_id ) ) AS registered - FROM public.stake_address sas - WHERE sas.id = ANY(sa_id_list) + FROM public.stake_address sa + WHERE sa.id = ANY(sa_id_list) ) AS status_t LEFT JOIN ( SELECT delegation.addr_id, pool_hash.view AS delegated_pool - FROM - delegation + FROM delegation INNER JOIN pool_hash ON pool_hash.id = delegation.pool_hash_id WHERE delegation.addr_id = ANY(sa_id_list) AND NOT EXISTS ( SELECT TRUE FROM delegation AS d - WHERE - d.addr_id = delegation.addr_id + WHERE d.addr_id = delegation.addr_id AND d.id > delegation.id) AND NOT EXISTS ( SELECT TRUE FROM stake_deregistration - WHERE - stake_deregistration.addr_id = delegation.addr_id + WHERE stake_deregistration.addr_id = delegation.addr_id AND stake_deregistration.tx_id > delegation.tx_id) + -- skip delegations that were followed by at least one pool retirement + AND NOT grest.is_dangling_delegation(delegation.id) ) AS pool_t ON pool_t.addr_id = status_t.id LEFT JOIN ( SELECT @@ -111,18 +110,16 @@ BEGIN COALESCE(SUM(VALUE), 0) AS utxo FROM tx_out WHERE tx_out.stake_address_id = ANY(sa_id_list) - AND tx_out.consumed_by_tx_in_id IS NULL + AND tx_out.consumed_by_tx_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 reward.addr_id, COALESCE(SUM(reward.amount), 0) AS rewards - FROM - reward - WHERE - reward.addr_id = ANY(sa_id_list) - AND reward.SPENDABLE_EPOCH <= ( + FROM reward + WHERE reward.addr_id = ANY(sa_id_list) + AND reward.spendable_epoch <= ( SELECT MAX(no) FROM epoch ) @@ -133,10 +130,8 @@ BEGIN SELECT withdrawal.addr_id, COALESCE(SUM(withdrawal.amount), 0) AS withdrawals - FROM - withdrawal - WHERE - withdrawal.addr_id = ANY(sa_id_list) + FROM withdrawal + WHERE withdrawal.addr_id = ANY(sa_id_list) GROUP BY withdrawal.addr_id ) AS withdrawals_t ON withdrawals_t.addr_id = status_t.id @@ -144,13 +139,11 @@ BEGIN SELECT reserve.addr_id, COALESCE(SUM(reserve.amount), 0) AS reserves - FROM - reserve + FROM reserve INNER JOIN tx ON tx.id = reserve.tx_id INNER JOIN block ON block.id = tx.block_id INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = reserve.addr_id - WHERE - reserve.addr_id = ANY(sa_id_list) + WHERE reserve.addr_id = ANY(sa_id_list) AND block.epoch_no >= lwe.epoch_no GROUP BY reserve.addr_id @@ -159,13 +152,11 @@ BEGIN SELECT treasury.addr_id, COALESCE(SUM(treasury.amount), 0) AS treasury - FROM - treasury + FROM treasury INNER JOIN tx ON tx.id = treasury.tx_id INNER JOIN block ON block.id = tx.block_id INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = treasury.addr_id - WHERE - treasury.addr_id = ANY(sa_id_list) + WHERE treasury.addr_id = ANY(sa_id_list) AND block.epoch_no >= lwe.epoch_no GROUP BY treasury.addr_id diff --git a/files/grest/rpc/account/account_info_cached.sql b/files/grest/rpc/account/account_info_cached.sql index 3a4855ab..a088d932 100644 --- a/files/grest/rpc/account/account_info_cached.sql +++ b/files/grest/rpc/account/account_info_cached.sql @@ -56,8 +56,7 @@ BEGIN sdc.rewards_available::text, COALESCE(reserves_t.reserves, 0)::text AS reserves, COALESCE(treasury_t.treasury, 0)::text AS treasury - FROM - grest.stake_distribution_cache AS sdc + FROM grest.stake_distribution_cache AS sdc LEFT JOIN ( SELECT sas.id, @@ -69,8 +68,7 @@ BEGIN AND NOT EXISTS ( SELECT TRUE FROM stake_deregistration - WHERE - stake_deregistration.addr_id = stake_registration.addr_id + WHERE stake_deregistration.addr_id = stake_registration.addr_id AND stake_deregistration.tx_id > stake_registration.tx_id ) ) AS registered @@ -81,33 +79,79 @@ BEGIN SELECT reserve.addr_id, COALESCE(SUM(reserve.amount), 0) AS reserves - FROM - reserve + FROM reserve INNER JOIN tx ON tx.id = reserve.tx_id INNER JOIN block ON block.id = tx.block_id INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = reserve.addr_id - WHERE - reserve.addr_id = ANY(sa_id_list) + WHERE reserve.addr_id = ANY(sa_id_list) AND block.epoch_no >= lwe.epoch_no - GROUP BY - reserve.addr_id - ) AS reserves_t ON reserves_t.addr_id = status_t.id + GROUP BY reserve.addr_id + ) AS reserves_t ON reserves_t.addr_id = status_t.id LEFT JOIN ( SELECT treasury.addr_id, COALESCE(SUM(treasury.amount), 0) AS treasury - FROM - treasury + FROM treasury INNER JOIN tx ON tx.id = treasury.tx_id INNER JOIN block ON block.id = tx.block_id INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = treasury.addr_id - WHERE - treasury.addr_id = ANY(sa_id_list) + WHERE treasury.addr_id = ANY(sa_id_list) AND block.epoch_no >= lwe.epoch_no GROUP BY treasury.addr_id - ) AS treasury_t ON treasury_t.addr_id = status_t.id - WHERE sdc.stake_address = ANY(_stake_addresses); + ) AS treasury_t ON treasury_t.addr_id = status_t.id + WHERE sdc.stake_address = ANY(_stake_addresses) + + UNION ALL + + SELECT + z.stake_address, + ai.status, + ai.delegated_pool AS pool_id, + ai.total_balance::text, + ai.utxo::text, + ai.rewards::text, + ai.withdrawals::text, + ai.rewards_available::text, + COALESCE(reserves_t.reserves, 0)::text AS reserves, + COALESCE(treasury_t.treasury, 0)::text AS treasury + FROM + ( + SELECT + sa.view AS stake_address, + sa.id AS addr_id + FROM stake_address AS sa + WHERE view = ANY(_stake_addresses) + AND NOT EXISTS (SELECT null FROM grest.stake_distribution_cache AS sdc WHERE sdc.stake_address = sa.view) + ) AS z + LEFT JOIN ( + SELECT + reserve.addr_id, + COALESCE(SUM(reserve.amount), 0) AS reserves + FROM reserve + INNER JOIN tx ON tx.id = reserve.tx_id + INNER JOIN block ON block.id = tx.block_id + INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = reserve.addr_id + WHERE reserve.addr_id = ANY(sa_id_list) + AND block.epoch_no >= lwe.epoch_no + GROUP BY reserve.addr_id + ) AS reserves_t ON reserves_t.addr_id = z.addr_id + LEFT JOIN ( + SELECT + treasury.addr_id, + COALESCE(SUM(treasury.amount), 0) AS treasury + FROM treasury + INNER JOIN tx ON tx.id = treasury.tx_id + INNER JOIN block ON block.id = tx.block_id + INNER JOIN latest_withdrawal_epochs AS lwe ON lwe.addr_id = treasury.addr_id + WHERE treasury.addr_id = ANY(sa_id_list) + AND block.epoch_no >= lwe.epoch_no + GROUP BY + treasury.addr_id + ) AS treasury_t ON treasury_t.addr_id = z.addr_id + , LATERAL grest.account_info(array[z.stake_address]) AS ai + ; + END; $$; diff --git a/files/grest/rpc/account/account_list.sql b/files/grest/rpc/account/account_list.sql index 3138cd90..7e81e260 100644 --- a/files/grest/rpc/account/account_list.sql +++ b/files/grest/rpc/account/account_list.sql @@ -14,4 +14,4 @@ AS $$ ORDER BY sa.id; $$; -COMMENT ON FUNCTION grest.account_list IS 'Get a list of all accounts'; +COMMENT ON FUNCTION grest.account_list IS 'Get a list of all accounts'; -- noqa: LT01 diff --git a/files/grest/rpc/account/account_txs.sql b/files/grest/rpc/account/account_txs.sql index 8a1f9d44..d1cc4992 100644 --- a/files/grest/rpc/account/account_txs.sql +++ b/files/grest/rpc/account/account_txs.sql @@ -26,12 +26,12 @@ BEGIN -- UNION -- - SELECT consumed_by_tx_in_id AS tx_id + SELECT consumed_by_tx_id AS tx_id FROM tx_out WHERE - tx_out.consumed_by_tx_in_id IS NULL + tx_out.consumed_by_tx_id IS NOT NULL AND tx_out.stake_address_id = ANY(SELECT id FROM stake_address WHERE view = _stake_address) - AND tx_out.consumed_by_tx_in_id >= _tx_id_min + AND tx_out.consumed_by_tx_id >= _tx_id_min ) AS tmp; RETURN QUERY diff --git a/files/grest/rpc/account/account_utxos.sql b/files/grest/rpc/account/account_utxos.sql index 70e27f9f..679af2f3 100644 --- a/files/grest/rpc/account/account_utxos.sql +++ b/files/grest/rpc/account/account_utxos.sql @@ -39,7 +39,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 WHERE txo.stake_address_id IN (SELECT sa.id FROM stake_address AS sa WHERE sa.view = ANY(_stake_addresses)) - AND txo.consumed_by_tx_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL GROUP BY txo.id ) SELECT @@ -75,7 +75,7 @@ BEGIN ELSE COALESCE(assets, JSONB_BUILD_ARRAY()) END AS asset_list, (CASE - WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false + WHEN tx_out.consumed_by_tx_id IS NULL THEN false ELSE true END) AS is_spent FROM tx_out @@ -86,7 +86,7 @@ BEGIN LEFT JOIN script ON script.id = tx_out.reference_script_id LEFT JOIN _assets ON tx_out.id = _assets.id WHERE tx_out.stake_address_id IN (SELECT sa.id FROM stake_address AS sa WHERE sa.view = ANY(_stake_addresses)) - AND tx_out.consumed_by_tx_in_id IS NULL + AND tx_out.consumed_by_tx_id IS NULL ; END; $$; diff --git a/files/grest/rpc/address/address_assets.sql b/files/grest/rpc/address/address_assets.sql index ea1bea11..fe990662 100644 --- a/files/grest/rpc/address/address_assets.sql +++ b/files/grest/rpc/address/address_assets.sql @@ -25,7 +25,7 @@ BEGIN 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 txo.consumed_by_tx_in_id IS NULL + AND txo.consumed_by_tx_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 7ab30396..e2a494cf 100644 --- a/files/grest/rpc/address/address_info.sql +++ b/files/grest/rpc/address/address_info.sql @@ -35,7 +35,7 @@ BEGIN tx_out.reference_script_id FROM tx_out INNER JOIN tx ON tx.id = tx_out.tx_id - WHERE tx_out.consumed_by_tx_in_id IS NULL + WHERE tx_out.consumed_by_tx_id IS NULL AND tx_out.address = ANY(_addresses) ) diff --git a/files/grest/rpc/address/address_txs.sql b/files/grest/rpc/address/address_txs.sql index 67b4a696..93bd563b 100644 --- a/files/grest/rpc/address/address_txs.sql +++ b/files/grest/rpc/address/address_txs.sql @@ -11,28 +11,19 @@ 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 address = ANY(_addresses) - AND tx_id >= _tx_id_min + WHERE address = ANY (_addresses) -- UNION -- - SELECT consumed_by_tx_in_id AS tx_id + SELECT consumed_by_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_out.consumed_by_tx_in_id IS NOT NULL - AND tx_out.address = ANY(_addresses) - AND tx_out.consumed_by_tx_in_id >= _tx_id_min + WHERE tx_out.address = ANY(_addresses) + AND tx_out.consumed_by_tx_id IS NOT NULL ) AS tmp; RETURN QUERY @@ -44,7 +35,7 @@ BEGIN FROM public.tx INNER JOIN public.block AS b ON b.id = tx.block_id WHERE tx.id = ANY(_tx_id_list) - AND tx.block_id >= _tx_id_min + AND b.block_no >= _after_block_height ORDER BY b.block_no DESC; END; $$; diff --git a/files/grest/rpc/address/address_utxos.sql b/files/grest/rpc/address/address_utxos.sql index 87bcd5f5..b317e9e1 100644 --- a/files/grest/rpc/address/address_utxos.sql +++ b/files/grest/rpc/address/address_utxos.sql @@ -39,7 +39,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 WHERE txo.address = ANY(_addresses) - AND txo.consumed_by_tx_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL GROUP BY txo.id ) SELECT @@ -75,7 +75,7 @@ BEGIN ELSE COALESCE(assets, JSONB_BUILD_ARRAY()) END AS asset_list, (CASE - WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false + WHEN tx_out.consumed_by_tx_id IS NULL THEN false ELSE true END) AS is_spent FROM tx_out @@ -86,7 +86,7 @@ BEGIN 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) - AND tx_out.consumed_by_tx_in_id IS NULL + 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 21763479..5c6b048c 100644 --- a/files/grest/rpc/address/credential_txs.sql +++ b/files/grest/rpc/address/credential_txs.sql @@ -34,11 +34,11 @@ BEGIN -- UNION -- - SELECT consumed_by_tx_in_id AS tx_id + SELECT consumed_by_tx_id AS tx_id FROM tx_out - WHERE tx_out.consumed_by_tx_in_id IS NOT NULL + WHERE tx_out.consumed_by_tx_id IS NOT NULL AND tx_out.payment_cred = ANY(_payment_cred_bytea) - AND tx_out.consumed_by_tx_in_id >= _tx_id_min + AND tx_out.consumed_by_tx_id >= _tx_id_min ) AS tmp; RETURN QUERY diff --git a/files/grest/rpc/address/credential_utxos.sql b/files/grest/rpc/address/credential_utxos.sql index 2a970492..5c160941 100644 --- a/files/grest/rpc/address/credential_utxos.sql +++ b/files/grest/rpc/address/credential_utxos.sql @@ -45,7 +45,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 WHERE txo.payment_cred = ANY(_payment_cred_bytea) - AND txo.consumed_by_tx_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL GROUP BY txo.id ) SELECT @@ -81,7 +81,7 @@ BEGIN ELSE COALESCE(assets, JSONB_BUILD_ARRAY()) END AS asset_list, (CASE - WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false + WHEN tx_out.consumed_by_tx_id IS NULL THEN false ELSE true END) AS is_spent FROM tx_out @@ -92,7 +92,7 @@ BEGIN 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) - AND tx_out.consumed_by_tx_in_id IS NULL + 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 c0a61fb3..8a3dacb5 100644 --- a/files/grest/rpc/assets/asset_addresses.sql +++ b/files/grest/rpc/assets/asset_addresses.sql @@ -1,16 +1,3 @@ -CREATE OR REPLACE FUNCTION grest.asset_address_list(_asset_policy text, _asset_name text DEFAULT '') -RETURNS TABLE ( - payment_address varchar, - quantity text -) -LANGUAGE plpgsql -AS $$ -BEGIN - RETURN QUERY - SELECT payment_address, quantity FROM grest.asset_addresses(_asset_policy, _asset_name); -END; -$$; - CREATE OR REPLACE FUNCTION grest.asset_addresses(_asset_policy text, _asset_name text DEFAULT '') RETURNS TABLE ( payment_address varchar, @@ -53,7 +40,7 @@ BEGIN LEFT JOIN tx_out AS txo ON atoc.txo_id = txo.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_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL ) AS x GROUP BY x.address, x.stake_address; ELSE @@ -72,12 +59,11 @@ BEGIN LEFT JOIN tx_out AS txo ON txo.id = mto.tx_out_id LEFT JOIN stake_address AS sa ON txo.stake_address_id = sa.id WHERE mto.ident = _asset_id - AND txo.consumed_by_tx_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL ) AS x - GROUP BY x.address; + GROUP BY x.address, x.stake_address; END IF; END; $$; -COMMENT ON FUNCTION grest.asset_address_list IS 'DEPRECATED!! Use asset_addresses instead.'; -- noqa: LT01 COMMENT ON FUNCTION grest.asset_addresses IS 'Returns a list of addresses with quantity holding the specified asset'; -- noqa: LT01 diff --git a/files/grest/rpc/assets/asset_list.sql b/files/grest/rpc/assets/asset_list.sql index 351c1e64..81ad1064 100644 --- a/files/grest/rpc/assets/asset_list.sql +++ b/files/grest/rpc/assets/asset_list.sql @@ -16,4 +16,4 @@ AS $$ ORDER BY ma.policy, ma.name; $$; -COMMENT ON FUNCTION grest.asset_list IS 'Get a raw listing of all native assets on chain, without any CIP overlays'; +COMMENT ON FUNCTION grest.asset_list IS 'Get a raw listing of all native assets on chain, without any CIP overlays'; --noqa: LT01 diff --git a/files/grest/rpc/assets/asset_nft_address.sql b/files/grest/rpc/assets/asset_nft_address.sql index 7d9cfe9a..bd66c90e 100644 --- a/files/grest/rpc/assets/asset_nft_address.sql +++ b/files/grest/rpc/assets/asset_nft_address.sql @@ -45,7 +45,7 @@ BEGIN 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 - AND txo.consumed_by_tx_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL ORDER BY txo.id DESC LIMIT 1; END IF; diff --git a/files/grest/rpc/assets/asset_summary.sql b/files/grest/rpc/assets/asset_summary.sql index b7d02d4b..213284d6 100644 --- a/files/grest/rpc/assets/asset_summary.sql +++ b/files/grest/rpc/assets/asset_summary.sql @@ -37,7 +37,7 @@ BEGIN 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 txo.consumed_by_tx_in_id IS NULL) + AND txo.consumed_by_tx_id IS NULL) SELECT _asset_policy, diff --git a/files/grest/rpc/assets/asset_token_registry.sql b/files/grest/rpc/assets/asset_token_registry.sql index 4c4c0ad5..5892ca15 100644 --- a/files/grest/rpc/assets/asset_token_registry.sql +++ b/files/grest/rpc/assets/asset_token_registry.sql @@ -20,7 +20,8 @@ AS $$ url, decimals, logo - FROM grest.asset_registry_cache; + FROM grest.asset_registry_cache + ORDER BY asset_policy,asset_name; $$; -COMMENT ON FUNCTION grest.asset_token_registry IS 'An array of token registry information (registered via github) for each asset'; +COMMENT ON FUNCTION grest.asset_token_registry IS 'An array of token registry information (registered via github) for each asset'; -- noqa: LT01 diff --git a/files/grest/rpc/assets/asset_txs.sql b/files/grest/rpc/assets/asset_txs.sql index aaa7f6b7..72ec700d 100644 --- a/files/grest/rpc/assets/asset_txs.sql +++ b/files/grest/rpc/assets/asset_txs.sql @@ -36,21 +36,22 @@ BEGIN tx_hashes.block_no, EXTRACT(EPOCH FROM tx_hashes.time)::integer FROM ( - SELECT DISTINCT ON (tx.hash,txo.index::smallint) + SELECT DISTINCT ON (tx.hash) tx.hash, block.epoch_no, block.block_no, block.time FROM ma_tx_out AS mto + LEFT JOIN ma_tx_mint AS mtm ON mto.ident = mtm.ident INNER JOIN tx_out AS txo ON txo.id = mto.tx_out_id - INNER JOIN tx ON tx.id = txo.tx_id + INNER JOIN tx ON tx.id = txo.tx_id OR tx.id = mtm.tx_id INNER JOIN block ON block.id = tx.block_id WHERE mto.ident = _asset_id AND block.block_no >= _after_block_height - AND (_history = TRUE OR txo.consumed_by_tx_in_id IS NULL) + AND (_history = TRUE OR txo.consumed_by_tx_id IS NULL) GROUP BY - ident, + mto.ident, tx.hash, txo.index::smallint, block.epoch_no, diff --git a/files/grest/rpc/assets/asset_utxos.sql b/files/grest/rpc/assets/asset_utxos.sql index b33a0324..17392559 100644 --- a/files/grest/rpc/assets/asset_utxos.sql +++ b/files/grest/rpc/assets/asset_utxos.sql @@ -41,7 +41,7 @@ BEGIN FROM tx_out AS txo INNER JOIN ma_tx_out AS mto ON mto.tx_out_id = txo.id WHERE mto.ident = ANY(_asset_id_list) - AND txo.consumed_by_tx_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL ), _assets AS ( SELECT @@ -94,7 +94,7 @@ BEGIN ELSE COALESCE(assets, JSONB_BUILD_ARRAY()) END AS asset_list, (CASE - WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false + WHEN tx_out.consumed_by_tx_id IS NULL THEN false ELSE true END) AS is_spent FROM tx_out @@ -104,7 +104,7 @@ BEGIN 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 - WHERE tx_out.consumed_by_tx_in_id IS NULL + WHERE tx_out.consumed_by_tx_id IS NULL ; END; $$; diff --git a/files/grest/rpc/assets/policy_asset_addresses.sql b/files/grest/rpc/assets/policy_asset_addresses.sql index e360ade0..32974095 100644 --- a/files/grest/rpc/assets/policy_asset_addresses.sql +++ b/files/grest/rpc/assets/policy_asset_addresses.sql @@ -35,12 +35,13 @@ BEGIN LEFT JOIN tx_out AS txo ON txo.id = atoc.txo_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_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL ) x LEFT JOIN multi_asset AS ma ON ma.id = x.ma_id GROUP BY ma.name, - x.address; + x.address, + x.stake_address; ELSE RETURN QUERY SELECT @@ -53,10 +54,11 @@ BEGIN LEFT JOIN tx_out AS txo ON txo.id = mto.tx_out_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_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL GROUP BY ma.name, - txo.address; + txo.address, + sa.view; END IF; END; $$; diff --git a/files/grest/rpc/assets/policy_asset_info.sql b/files/grest/rpc/assets/policy_asset_info.sql index 26a79c1c..66750b6f 100644 --- a/files/grest/rpc/assets/policy_asset_info.sql +++ b/files/grest/rpc/assets/policy_asset_info.sql @@ -1,24 +1,3 @@ -CREATE OR REPLACE FUNCTION grest.asset_policy_info(_asset_policy text) -RETURNS TABLE ( - asset_name text, - asset_name_ascii text, - fingerprint varchar, - minting_tx_hash text, - total_supply text, - mint_cnt bigint, - burn_cnt bigint, - creation_time integer, - minting_tx_metadata jsonb, - token_registry_metadata jsonb -) -LANGUAGE plpgsql -AS $$ -BEGIN - RETURN QUERY - SELECT * FROM grest.policy_asset_info(_asset_policy); -END; -$$; - CREATE OR REPLACE FUNCTION grest.policy_asset_info(_asset_policy text) RETURNS TABLE ( asset_name text, @@ -73,4 +52,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.asset_policy_info IS 'Get the asset information of all assets under a policy'; -- noqa: LT01 +COMMENT ON FUNCTION grest.policy_asset_info IS 'Get the asset information of all assets under a policy'; -- noqa: LT01 diff --git a/files/grest/rpc/assets/policy_asset_mints.sql b/files/grest/rpc/assets/policy_asset_mints.sql new file mode 100644 index 00000000..26c6a12d --- /dev/null +++ b/files/grest/rpc/assets/policy_asset_mints.sql @@ -0,0 +1,32 @@ +CREATE OR REPLACE FUNCTION grest.policy_asset_mints(_asset_policy text) +RETURNS TABLE ( + asset_name text, + asset_name_ascii text, + fingerprint text, + minting_tx_hash text, + total_supply text, + mint_cnt bigint, + burn_cnt bigint, + creation_time integer, + decimals integer +) +LANGUAGE sql STABLE +AS $$ + SELECT + ENCODE(ma.name, 'hex')::text AS asset_name, + ENCODE(ma.name, 'escape')::text AS asset_name_ascii, + ma.fingerprint::text, + ENCODE(tx.hash, 'hex') AS minting_tx_hash, + aic.total_supply::text, + aic.mint_cnt, + aic.burn_cnt, + EXTRACT(EPOCH FROM aic.creation_time)::integer, + aic.decimals + FROM public.multi_asset AS ma + INNER JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id + LEFT JOIN tx ON tx.id = aic.first_mint_tx_id + WHERE ma.policy = DECODE(_asset_policy, 'hex') + ORDER BY tx.id; +$$; + +COMMENT ON FUNCTION grest.policy_asset_mints IS 'Get a list of mint/burn count details for all assets minted under a policy'; -- noqa: LT01 diff --git a/files/grest/rpc/blocks/block_tx_info.sql b/files/grest/rpc/blocks/block_tx_info.sql index 1160de82..f03ebcbd 100644 --- a/files/grest/rpc/blocks/block_tx_info.sql +++ b/files/grest/rpc/blocks/block_tx_info.sql @@ -1,11 +1,11 @@ CREATE OR REPLACE FUNCTION grest.block_tx_info( - _block_hashes text[], - _inputs boolean DEFAULT false, - _metadata boolean DEFAULT false, - _assets boolean DEFAULT false, - _withdrawals boolean DEFAULT false, - _certs boolean DEFAULT false, - _scripts boolean DEFAULT false + _block_hashes text [], + _inputs boolean DEFAULT false, + _metadata boolean DEFAULT false, + _assets boolean DEFAULT false, + _withdrawals boolean DEFAULT false, + _certs boolean DEFAULT false, + _scripts boolean DEFAULT false ) RETURNS TABLE ( tx_hash text, @@ -200,14 +200,14 @@ BEGIN _all_inputs AS ( SELECT - 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, - sa.view AS stake_addr, - ENCODE(tx.hash, 'hex') AS tx_hash, - tx_out.index AS tx_index, - tx_out.value::text AS value, - ENCODE(tx_out.data_hash, 'hex') AS datum_hash, + 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, + sa.view AS stake_addr, + ENCODE(tx.hash, 'hex') AS tx_hash, + tx_out.index AS tx_index, + tx_out.value::text AS value, + ENCODE(tx_out.data_hash, 'hex') AS datum_hash, (CASE WHEN ma.policy IS NULL THEN NULL ELSE JSONB_BUILD_OBJECT( @@ -238,10 +238,7 @@ BEGIN ) END ) AS reference_script - FROM - tx_in - INNER JOIN tx_out ON tx_out.tx_id = tx_in.tx_out_id - AND tx_out.index = tx_in.tx_out_index + 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 ma_tx_out AS mto ON _assets IS TRUE AND mto.tx_out_id = tx_out.id @@ -250,7 +247,7 @@ 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 tx_in.tx_in_id = ANY(_tx_id_list) + AND tx_out.consumed_by_tx_id = ANY(_tx_id_list) ), _all_collateral_outputs AS ( @@ -664,8 +661,8 @@ BEGIN ind.hash AS ind_hash, ind.value AS ind_value FROM redeemer - INNER JOIN tx_in ON tx_in.redeemer_id = redeemer.id - INNER JOIN tx_out AS inutxo ON inutxo.tx_id = tx_in.tx_out_id AND inutxo.index = tx_in.tx_out_index + INNER JOIN tx_out AS inutxo ON inutxo.consumed_by_tx_id = redeemer.tx_id + INNER JOIN script ON redeemer.script_hash = inutxo.payment_cred INNER JOIN datum AS ind ON ind.hash = inutxo.data_hash WHERE _scripts IS TRUE AND redeemer.tx_id = ANY(_tx_id_list) diff --git a/files/grest/rpc/blocks/blocks.sql b/files/grest/rpc/blocks/blocks.sql index cf009412..77141539 100644 --- a/files/grest/rpc/blocks/blocks.sql +++ b/files/grest/rpc/blocks/blocks.sql @@ -42,4 +42,4 @@ AS $$ ORDER BY b.id DESC; $$; -COMMENT ON FUNCTION grest.blocks IS 'Get detailed information about all blocks (paginated - latest first)'; +COMMENT ON FUNCTION grest.blocks IS 'Get detailed information about all blocks (paginated - latest first)'; -- noqa: LT01 diff --git a/files/grest/rpc/pool/pool_delegators.sql b/files/grest/rpc/pool/pool_delegators.sql index e9145a0c..f6489484 100644 --- a/files/grest/rpc/pool/pool_delegators.sql +++ b/files/grest/rpc/pool/pool_delegators.sql @@ -25,8 +25,30 @@ BEGIN ) AS total_balance FROM grest.stake_distribution_cache AS sdc INNER JOIN public.stake_address AS sa ON sa.view = sdc.stake_address - WHERE - sdc.pool_id = _pool_bech32 + WHERE sdc.pool_id = _pool_bech32 + + UNION ALL + + -- combine with registered delegations not in stake-dist-cache yet + SELECT + z.stake_address_id, z.stake_address, SUM(acc_info.value::numeric) AS total_balance + FROM + ( + SELECT + sa.id AS stake_address_id, + sa.view AS stake_address + FROM delegation AS d + INNER JOIN pool_hash AS ph ON d.pool_hash_id = ph.id AND ph.view = _pool_bech32 + INNER JOIN stake_address AS sa ON d.addr_id = sa.id + AND NOT EXISTS (SELECT null FROM delegation AS d2 WHERE d2.addr_id = d.addr_id AND d2.id > d.id) + AND NOT EXISTS (SELECT null FROM stake_deregistration AS sd WHERE sd.addr_id = d.addr_id AND sd.tx_id > d.tx_id) + AND NOT grest.is_dangling_delegation(d.id) + AND NOT EXISTS (SELECT null FROM grest.stake_distribution_cache AS sdc WHERE sdc.stake_address = sa.view) + ) z, + LATERAL grest.account_utxos(array[z.stake_address], false) AS acc_info + GROUP BY + z.stake_address_id, + z.stake_address ) SELECT DISTINCT ON (ad.stake_address) @@ -38,7 +60,8 @@ BEGIN INNER JOIN public.delegation AS d ON d.addr_id = ad.stake_address_id INNER JOIN public.tx ON tx.id = d.tx_id ORDER BY - ad.stake_address, d.tx_id DESC; + ad.stake_address, + d.tx_id DESC; END; $$; diff --git a/files/grest/rpc/pool/pool_info.sql b/files/grest/rpc/pool/pool_info.sql index b295c4b0..4bcf0cc6 100644 --- a/files/grest/rpc/pool/pool_info.sql +++ b/files/grest/rpc/pool/pool_info.sql @@ -77,11 +77,11 @@ 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 - ORDER BY pod.pmr_id DESC + SELECT ocpd.json + FROM public.off_chain_pool_data AS ocpd + WHERE ocpd.pool_id = api.pool_hash_id + AND ocpd.pmr_id = api.meta_id + ORDER BY ocpd.pmr_id DESC LIMIT 1 ) AS offline_data ON TRUE LEFT JOIN LATERAL ( @@ -115,8 +115,8 @@ BEGIN THEN NULL ELSE SUM( - CASE WHEN total_balance >= 0 - THEN total_balance + CASE WHEN amount::numeric >= 0 + THEN amount::numeric ELSE 0 END )::lovelace @@ -125,10 +125,9 @@ BEGIN CASE WHEN api.pool_status = 'retired' THEN NULL ELSE - SUM(CASE WHEN sdc.stake_address = ANY(api.owners) THEN total_balance ELSE 0 END)::lovelace + SUM(CASE WHEN pool_delegs.stake_address = ANY(api.owners) THEN amount::numeric ELSE 0 END)::lovelace END AS pledge - FROM grest.stake_distribution_cache AS sdc - WHERE sdc.pool_id = api.pool_id_bech32 + FROM grest.pool_delegators(api.pool_id_bech32) AS pool_delegs ) AS live ON TRUE; END; $$; diff --git a/files/grest/rpc/pool/pool_list.sql b/files/grest/rpc/pool/pool_list.sql index 3d8ce843..9c0dbfb5 100644 --- a/files/grest/rpc/pool/pool_list.sql +++ b/files/grest/rpc/pool/pool_list.sql @@ -39,13 +39,13 @@ BEGIN pic.reward_addr, pic.owners, pic.relays, - pod.ticker_name, + ocpd.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 + LEFT JOIN public.off_chain_pool_data AS ocpd ON ocpd.pmr_id = pic.meta_id ORDER BY pic.pool_id_bech32, pic.tx_id DESC diff --git a/files/grest/rpc/pool/pool_metadata.sql b/files/grest/rpc/pool/pool_metadata.sql index c919791c..100268ec 100644 --- a/files/grest/rpc/pool/pool_metadata.sql +++ b/files/grest/rpc/pool/pool_metadata.sql @@ -15,11 +15,11 @@ BEGIN ph.view AS pool_id_bech32, pic.meta_url, pic.meta_hash, - pod.json, + ocpd.json, pic.pool_status FROM public.pool_hash AS ph LEFT JOIN grest.pool_info_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 + LEFT JOIN public.off_chain_pool_data AS ocpd ON ocpd.pmr_id = pic.meta_id WHERE CASE WHEN _pool_bech32_ids IS NULL THEN TRUE diff --git a/files/grest/rpc/pool/pool_updates.sql b/files/grest/rpc/pool/pool_updates.sql index 61fd2e22..490f4878 100644 --- a/files/grest/rpc/pool/pool_updates.sql +++ b/files/grest/rpc/pool/pool_updates.sql @@ -42,12 +42,12 @@ BEGIN pic.relays, pic.meta_url, pic.meta_hash, - pod.json, + ocpd.json, 'registration' AS update_type, NULL::word31type AS retiring_epoch FROM grest.pool_info_cache AS pic - LEFT JOIN public.pool_offline_data AS pod ON pod.pmr_id = pic.meta_id + LEFT JOIN public.off_chain_pool_data AS ocpd ON ocpd.pmr_id = pic.meta_id LEFT JOIN public.pool_retire AS pr ON pic.pool_hash_id = pr.hash_id WHERE _pool_bech32 IS NULL OR pic.pool_id_bech32 = _pool_bech32), diff --git a/files/grest/rpc/script/script_utxos.sql b/files/grest/rpc/script/script_utxos.sql index ae65c981..68419423 100644 --- a/files/grest/rpc/script/script_utxos.sql +++ b/files/grest/rpc/script/script_utxos.sql @@ -21,6 +21,28 @@ DECLARE known_addresses varchar[]; BEGIN RETURN QUERY + WITH + _assets AS ( + SELECT + txo.id, + JSONB_AGG(CASE WHEN 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 assets + FROM tx_out AS txo + INNER JOIN script ON script.tx_id = txo.tx_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 script.hash = DECODE(_script_hash,'hex') + 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, @@ -49,32 +71,23 @@ BEGIN 'size', script.serialised_size ) END) AS reference_script, + CASE + WHEN _extended = false THEN NULL + ELSE COALESCE(assets, JSONB_BUILD_ARRAY()) + END AS asset_list, (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 + WHEN tx_out.consumed_by_tx_id IS NULL THEN false ELSE true END) AS is_spent FROM tx_out INNER JOIN tx ON tx_out.tx_id = tx.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 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 block AS b ON b.id = tx.block_id + LEFT JOIN _assets ON tx_out.id = _assets.id WHERE script.hash = DECODE(_script_hash,'hex') - AND tx_out.consumed_by_tx_in_id IS NULL + AND tx_out.consumed_by_tx_id IS NULL ; END; $$; diff --git a/files/grest/rpc/transactions/tx_info.sql b/files/grest/rpc/transactions/tx_info.sql index 44b3c78c..9dfb82e4 100644 --- a/files/grest/rpc/transactions/tx_info.sql +++ b/files/grest/rpc/transactions/tx_info.sql @@ -184,14 +184,14 @@ BEGIN _all_inputs AS ( SELECT - tx_in.tx_in_id AS tx_id, + 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, sa.view AS stake_addr, ENCODE(tx.hash, 'hex') AS tx_hash, tx_out.index AS tx_index, tx_out.value::text AS value, - ENCODE(tx_out.data_hash, 'hex') AS datum_hash, + tx_out.data_hash AS datum_hash, (CASE WHEN ma.policy IS NULL THEN NULL ELSE JSONB_BUILD_OBJECT( @@ -222,10 +222,7 @@ BEGIN ) END ) AS reference_script - FROM - tx_in - INNER JOIN tx_out ON tx_out.tx_id = tx_in.tx_out_id - AND tx_out.index = tx_in.tx_out_index + 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 ma_tx_out AS mto ON mto.tx_out_id = tx_out.id @@ -233,8 +230,7 @@ BEGIN 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_in.tx_in_id = ANY(_tx_id_list) + WHERE tx_out.consumed_by_tx_id = ANY(_tx_id_list) ), _all_collateral_outputs AS ( @@ -656,17 +652,37 @@ BEGIN WHERE redeemer.tx_id = ANY(_tx_id_list) ), + _all_inputs_sorted AS ( + SELECT + ROW_NUMBER () OVER ( + PARTITION BY ai.tx_id + ORDER BY ai.tx_hash, ai.tx_index + ) - 1 AS sorted_index, + ai.* + FROM ( + SELECT DISTINCT ON (_ai.tx_hash, _ai.tx_index) + _ai.tx_id, + _ai.tx_hash, + _ai.tx_index, + _ai.payment_addr_bech32 as address, + _ai.datum_hash + from _all_inputs as _ai + ) as ai + ), + spend_redeemers AS ( SELECT DISTINCT ON (redeemer.id) redeemer.id, - inutxo.address, + ais.address, + ais.tx_hash, + ais.tx_index, ind.hash AS ind_hash, ind.value AS ind_value FROM redeemer - INNER JOIN tx_in ON tx_in.redeemer_id = redeemer.id - INNER JOIN tx_out AS inutxo ON inutxo.tx_id = tx_in.tx_out_id AND inutxo.index = tx_in.tx_out_index - INNER JOIN datum AS ind ON ind.hash = inutxo.data_hash + INNER JOIN _all_inputs_sorted AS ais ON ais.tx_id = redeemer.tx_id AND ais.sorted_index = redeemer.index + INNER JOIN datum AS ind ON ind.hash = ais.datum_hash WHERE redeemer.tx_id = ANY(_tx_id_list) + AND redeemer.purpose = 'spend' ) SELECT @@ -677,6 +693,18 @@ BEGIN WHEN ar.purpose = 'spend' THEN (SELECT address FROM spend_redeemers AS sr WHERE sr.id = ar.id) END, + 'spends_input', + CASE + WHEN ar.purpose = 'spend' THEN + ( + SELECT JSONB_BUILD_OBJECT( + 'tx_hash', sr.tx_hash, + 'tx_index', sr.tx_index + ) + FROM spend_redeemers AS sr + WHERE sr.id = ar.id + ) + END, 'script_hash', ENCODE(ar.script_hash, 'hex'), 'bytecode', ENCODE(ar.script_bytes, 'hex'), 'size', ar.script_serialised_size, @@ -703,8 +731,7 @@ BEGIN ) END ) ) AS data - FROM - all_redeemers AS ar + FROM all_redeemers AS ar ) AS tmp GROUP BY tx_id @@ -805,7 +832,7 @@ BEGIN 'tx_hash', ai.tx_hash, 'tx_index', tx_index, 'value', value, - 'datum_hash', datum_hash, + 'datum_hash', ENCODE(datum_hash, 'hex'), 'inline_datum', inline_datum, 'reference_script', reference_script, 'asset_list', COALESCE(JSONB_AGG(asset_list) FILTER (WHERE asset_list IS NOT NULL), JSONB_BUILD_ARRAY()) diff --git a/files/grest/rpc/transactions/tx_utxos.sql b/files/grest/rpc/transactions/tx_utxos.sql index bda74b2e..221b3169 100644 --- a/files/grest/rpc/transactions/tx_utxos.sql +++ b/files/grest/rpc/transactions/tx_utxos.sql @@ -32,14 +32,13 @@ BEGIN SELECT tx.id AS tx_id, tx.hash AS tx_hash - FROM - tx + FROM tx WHERE tx.id = ANY(_tx_id_list) ), _all_inputs AS ( SELECT - tx_in.tx_in_id AS tx_id, + 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, sa.view AS stake_addr, @@ -57,17 +56,13 @@ BEGIN ) END ) AS asset_list - FROM - tx_in - INNER JOIN tx_out ON tx_out.tx_id = tx_in.tx_out_id - AND tx_out.index = tx_in.tx_out_index + 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 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 - tx_in.tx_in_id = ANY(_tx_id_list) + WHERE tx_out.consumed_by_tx_id = ANY(_tx_id_list) ), _all_outputs AS ( @@ -90,15 +85,13 @@ BEGIN ) END ) AS asset_list - FROM - tx_out + 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 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 - tx_out.tx_id = ANY(_tx_id_list) + WHERE tx_out.tx_id = ANY(_tx_id_list) ) SELECT diff --git a/files/grest/rpc/transactions/utxo_info.sql b/files/grest/rpc/transactions/utxo_info.sql index 6e91f0f0..53b65301 100644 --- a/files/grest/rpc/transactions/utxo_info.sql +++ b/files/grest/rpc/transactions/utxo_info.sql @@ -94,7 +94,7 @@ BEGIN ELSE COALESCE(assets, JSONB_BUILD_ARRAY()) END AS asset_list, (CASE - WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false + WHEN tx_out.consumed_by_tx_id IS NULL THEN false ELSE true END) AS is_spent FROM tx_out diff --git a/files/grest/rpc/v0/account.sql b/files/grest/rpc/v0/account.sql index 26783259..fce8ec08 100644 --- a/files/grest/rpc/v0/account.sql +++ b/files/grest/rpc/v0/account.sql @@ -45,7 +45,7 @@ BEGIN 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 WHERE sa.id = ANY(sa_id_list) - AND txo.consumed_by_tx_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL GROUP BY sa.view, ma.policy, ma.name, ma.fingerprint, aic.decimals ) @@ -178,7 +178,7 @@ BEGIN tx_out INNER JOIN tx ON tx.id = tx_out.tx_id LEFT JOIN block AS b ON b.id = tx.block_id - WHERE tx_out.consumed_by_tx_in_id IS NULL + WHERE tx_out.consumed_by_tx_id IS NULL AND tx_out.stake_address_id = (SELECT id FROM stake_address WHERE view = _stake_address); END; $$; diff --git a/files/grest/rpc/v0/address.sql b/files/grest/rpc/v0/address.sql index b50f4293..f8f750d5 100644 --- a/files/grest/rpc/v0/address.sql +++ b/files/grest/rpc/v0/address.sql @@ -25,7 +25,7 @@ BEGIN INNER JOIN tx_out AS txo ON txo.id = mtx.tx_out_id WHERE txo.address = ANY(_addresses) - AND txo.consumed_by_tx_in_id IS NULL + AND txo.consumed_by_tx_id IS NULL GROUP BY txo.address, ma.policy, ma.name, ma.fingerprint, aic.decimals ) @@ -127,6 +127,6 @@ BEGIN FROM tx_out INNER JOIN tx ON tx_out.tx_id = tx.id WHERE payment_cred = ANY(_payment_cred_bytea) - AND tx_out.consumed_by_tx_in_id IS NULL; + AND tx_out.consumed_by_tx_id IS NULL; END; $$; diff --git a/files/grest/rpc/v0/pool.sql b/files/grest/rpc/v0/pool.sql index 31213a01..bdbd0242 100644 --- a/files/grest/rpc/v0/pool.sql +++ b/files/grest/rpc/v0/pool.sql @@ -130,11 +130,11 @@ BEGIN _pool_meta AS ( SELECT DISTINCT ON (pic.pool_id_bech32) pool_id_bech32, - pod.ticker_name + ocpd.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 + LEFT JOIN public.off_chain_pool_data AS ocpd ON ocpd.pmr_id = pic.meta_id + WHERE ocpd.ticker_name IS NOT NULL ORDER BY pic.pool_id_bech32, pic.tx_id DESC @@ -239,12 +239,12 @@ BEGIN relays, meta_url, meta_hash, - pod.json, + ocpd.json, pool_status, retiring_epoch FROM grest.pool_info_cache AS pic - LEFT JOIN public.pool_offline_data AS pod ON pod.pmr_id = pic.meta_id + LEFT JOIN public.off_chain_pool_data AS ocpd ON ocpd.pmr_id = pic.meta_id WHERE _pool_bech32 IS NULL OR diff --git a/files/grest/rpc/v0/views.sql b/files/grest/rpc/v0/views.sql index 38fdb35f..177e99e2 100644 --- a/files/grest/rpc/v0/views.sql +++ b/files/grest/rpc/v0/views.sql @@ -38,7 +38,7 @@ DROP VIEW IF EXISTS grestv0.blocks; CREATE VIEW grestv0.blocks AS SELECT ENCODE(b.hash::bytea, 'hex') AS hash, - b.epoch_no AS epoch_no, + b.epoch_no, b.slot_no AS abs_slot, b.epoch_slot_no AS epoch_slot, b.block_no AS block_height, diff --git a/specs/results/koiosapi-guild.yaml b/specs/results/koiosapi-guild.yaml index 4bfaa922..e2ee5b93 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.1.1-dev + version: v1.1.1rc 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. @@ -23,24 +23,24 @@ info: ``` bash curl "https://api.koios.rest/api/v1/tip" - # [{"hash":"4d44c8a453e677f933c3df42ebcf2fe45987c41268b9cfc9b42ae305e8c3d99a","epoch":317,"abs_slot":51700871,"epoch_slot":120071,"block_height":6806994,"block_time":1643267162}] + # [{"hash":"4d44c8a453e677f933c3df42ebcf2fe45987c41268b9cfc9b42ae305e8c3d99a","epoch_no":317,"abs_slot":51700871,"epoch_slot":120071,"block_height":6806994,"block_time":1643267162}] - curl "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_height" + curl "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_height" - # [{"epoch":317,"epoch_slot":120071,"block_height":6806994}] + # [{"epoch_no":317,"epoch_slot":120071,"block_height":6806994}] ``` ## Horizontal Filtering You can filter the returned output based on specific conditions using operators against a column within returned result. Consider an example where you would want to query blocks minted in first 3 minutes of epoch 250 (i.e. epoch_slot was less than 180). To do so your query would look like below:

``` bash - curl "https://api.koios.rest/api/v1/blocks?epoch=eq.250&epoch_slot=lt.180" + curl "https://api.koios.rest/api/v1/blocks?epoch_no=eq.250&epoch_slot=lt.180" - # [{"hash":"8fad2808ac6b37064a0fa69f6fe065807703d5235a57442647bbcdba1c02faf8","epoch":250,"abs_slot":22636942,"epoch_slot":142,"block_height":5385757,"block_time":1614203233,"tx_count":65,"vrf_key":"vrf_vk14y9pjprzlsjvjt66mv5u7w7292sxp3kn4ewhss45ayjga5vurgaqhqknuu","pool":null,"op_cert_counter":2}, - # {"hash":"9d33b02badaedc0dedd0d59f3e0411e5fb4ac94217fb5ee86719e8463c570e16","epoch":250,"abs_slot":22636800,"epoch_slot":0,"block_height":5385756,"block_time":1614203091,"tx_count":10,"vrf_key":"vrf_vk1dkfsejw3h2k7tnguwrauqfwnxa7wj3nkp3yw2yw3400c4nlkluwqzwvka6","pool":null,"op_cert_counter":2}] + # [{"hash":"8fad2808ac6b37064a0fa69f6fe065807703d5235a57442647bbcdba1c02faf8","epoch_no":250,"abs_slot":22636942,"epoch_slot":142,"block_height":5385757,"block_time":1614203233,"tx_count":65,"vrf_key":"vrf_vk14y9pjprzlsjvjt66mv5u7w7292sxp3kn4ewhss45ayjga5vurgaqhqknuu","pool":null,"op_cert_counter":2}, + # {"hash":"9d33b02badaedc0dedd0d59f3e0411e5fb4ac94217fb5ee86719e8463c570e16","epoch_no":250,"abs_slot":22636800,"epoch_slot":0,"block_height":5385756,"block_time":1614203091,"tx_count":10,"vrf_key":"vrf_vk1dkfsejw3h2k7tnguwrauqfwnxa7wj3nkp3yw2yw3400c4nlkluwqzwvka6","pool":null,"op_cert_counter":2}] ``` - Here, we made use of `eq.` operator to denote a filter of "value equal to" against `epoch` column. Similarly, we added a filter using `lt.` operator to denote a filter of "values lower than" against `epoch_slot` column. You can find a complete list of operators supported in PostgREST documentation (commonly used ones extracted below): + Here, we made use of `eq.` operator to denote a filter of "value equal to" against `epoch_no` column. Similarly, we added a filter using `lt.` operator to denote a filter of "values lower than" against `epoch_slot` column. You can find a complete list of operators supported in PostgREST documentation (commonly used ones extracted below): |Abbreviation|In PostgreSQL|Meaning | |------------|-------------|-------------------------------------------| @@ -84,30 +84,22 @@ info: ``` - For GET endpoints, there is also another method to achieve the above, instead of adding parameters to the URL itself, you can specify a `Range` header as below to achieve something similar:

- - ``` bash - curl -s "https://api.koios.rest/api/v1/blocks?select=block_height" -H "Range: 1000-1499" -I | grep -i content-range - - # content-range: 1000-1499/* - - ``` - - The above methods for pagination are very useful to keep your queries light as well as process the output in smaller pages, making better use of your resources and respecting server timeouts for response times. + The above methods for pagination are very useful to keep some of the queries light as well as process the output in smaller pages, making better use of your resources and respecting server timeouts for response times. + However, note that due to the complex nature of some queries that require pre-processing before being subjected to paginations, these may not always be helpful to avoid server timeouts. ## Ordering You can set a sorting order for returned queries against specific column(s). - Consider example where you want to check `epoch` and `epoch_slot` for the first 5 blocks created by a particular pool, i.e. you can set order to ascending based on block_height column and add horizontal filter for that pool ID as below:

+ Consider example where you want to check `epoch_no` and `epoch_slot` for the first 5 blocks created by a particular pool, i.e. you can set order to ascending based on block_height column and add horizontal filter for that pool ID as below:

``` bash curl -s "https://api.koios.rest/api/v1/blocks?pool=eq.pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc&order=block_height.asc&limit=5" - # [{"hash":"610b4c7bbebeeb212bd002885048cc33154ba29f39919d62a3d96de05d315706","epoch":236,"abs_slot":16594295,"epoch_slot":5495,"block_height":5086774,"block_time":1608160586,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"d93d1db5275329ab695d30c06a35124038d8d9af64fc2b0aa082b8aa43da4164","epoch":236,"abs_slot":16597729,"epoch_slot":8929,"block_height":5086944,"block_time":1608164020,"tx_count":7,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"dc9496eae64294b46f07eb20499ae6dae4d81fdc67c63c354397db91bda1ee55","epoch":236,"abs_slot":16598058,"epoch_slot":9258,"block_height":5086962,"block_time":1608164349,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"6ebc7b734c513bc19290d96ca573a09cac9503c5a349dd9892b9ab43f917f9bd","epoch":236,"abs_slot":16601491,"epoch_slot":12691,"block_height":5087097,"block_time":1608167782,"tx_count":0,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"2eac97548829fc312858bc56a40f7ce3bf9b0ca27ee8530283ccebb3963de1c0","epoch":236,"abs_slot":16602308,"epoch_slot":13508,"block_height":5087136,"block_time":1608168599,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}] + # [{"hash":"610b4c7bbebeeb212bd002885048cc33154ba29f39919d62a3d96de05d315706","epoch_no":236,"abs_slot":16594295,"epoch_slot":5495,"block_height":5086774,"block_time":1608160586,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"d93d1db5275329ab695d30c06a35124038d8d9af64fc2b0aa082b8aa43da4164","epoch_no":236,"abs_slot":16597729,"epoch_slot":8929,"block_height":5086944,"block_time":1608164020,"tx_count":7,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"dc9496eae64294b46f07eb20499ae6dae4d81fdc67c63c354397db91bda1ee55","epoch_no":236,"abs_slot":16598058,"epoch_slot":9258,"block_height":5086962,"block_time":1608164349,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"6ebc7b734c513bc19290d96ca573a09cac9503c5a349dd9892b9ab43f917f9bd","epoch_no":236,"abs_slot":16601491,"epoch_slot":12691,"block_height":5087097,"block_time":1608167782,"tx_count":0,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"2eac97548829fc312858bc56a40f7ce3bf9b0ca27ee8530283ccebb3963de1c0","epoch_no":236,"abs_slot":16602308,"epoch_slot":13508,"block_height":5087136,"block_time":1608168599,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}] ``` ## Response Formats @@ -116,15 +108,15 @@ info: Below is an example of JSON/CSV output making use of above to print first in JSON (default), and then override response format to CSV.

``` bash - curl -s "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_time&limit=3" + curl -s "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_time&limit=3" - # [{"epoch":318,"epoch_slot":27867,"block_time":1643606958}, - # {"epoch":318,"epoch_slot":27841,"block_time":1643606932}, - # {"epoch":318,"epoch_slot":27839,"block_time":1643606930}] + # [{"epoch_no":318,"epoch_slot":27867,"block_time":1643606958}, + # {"epoch_no":318,"epoch_slot":27841,"block_time":1643606932}, + # {"epoch_no":318,"epoch_slot":27839,"block_time":1643606930}] - curl -s "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_time&limit=3" -H "Accept: text/csv" + curl -s "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_time&limit=3" -H "Accept: text/csv" - # epoch,epoch_slot,block_time + # epoch_no,epoch_slot,block_time # 318,28491,1643607582 # 318,28479,1643607570 # 318,28406,1643607497 @@ -243,6 +235,31 @@ paths: summary: Param Update Proposals description: Get all parameter update proposals submitted to the chain starting Shelley era operationId: param_updates + /cli_protocol_params: #RPC + get: + tags: + - Network + responses: + "200": + description: Success!! + content: + application/json: + schema: + $ref: "#/components/schemas/cli_protocol_params" + "400": + $ref: "#/components/responses/BadRequest" + "401": + $ref: "#/components/responses/Unauthorized" + "404": + $ref: "#/components/responses/NotFound" + summary: CLI Protocol Parameters + description: >- + Get Current Protocol Parameters as published by cardano-cli. Note that + the output schema of this command is unfortunately fluid on cardano-node + and may vary between CLI versions/era. Accordingly, the returned output for + this endpoint is left as raw JSON (single row) and any filtering to output should + be done on client-side + operationId: cli_protocol_params /reserve_withdrawals: #RPC get: tags: @@ -1186,102 +1203,76 @@ paths: summary: Policy Asset Information description: Get the information for all assets under the same policy operationId: policy_asset_info - /asset_summary: #RPC + /policy_asset_mints: #RPC get: tags: - Asset parameters: - $ref: "#/components/parameters/_asset_policy" - - $ref: "#/components/parameters/_asset_name" responses: "200": - description: Array of asset summary information + description: Get a list of mint or burn count details for all assets minted under a policy content: application/json: schema: - $ref: "#/components/schemas/asset_summary" + $ref: "#/components/schemas/policy_asset_mints" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Summary - description: Get the summary of an asset (total transactions exclude minting/total wallets include only wallets with asset balance) - operationId: asset_summary - /asset_txs: #RPC + summary: Policy Asset Mints + description: Get a list of mint or burn count details for all assets minted under a policy + operationId: policy_asset_mints + /asset_summary: #RPC get: tags: - Asset parameters: - $ref: "#/components/parameters/_asset_policy" - $ref: "#/components/parameters/_asset_name" - - $ref: "#/components/parameters/_after_block_height" - - $ref: "#/components/parameters/_history" responses: "200": - description: An array of Tx hashes that included the given asset (latest first) + description: Array of asset summary information content: application/json: schema: - $ref: "#/components/schemas/address_txs" + $ref: "#/components/schemas/asset_summary" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Transactions - description: Get the list of current or all asset transaction hashes (newest first) - operationId: asset_txs - /asset_address_list: #RPC + summary: Asset Summary + description: Get the summary of an asset (total transactions exclude minting/total wallets include only wallets with asset balance) + operationId: asset_summary + /asset_txs: #RPC get: tags: - Asset - deprecated: true parameters: - $ref: "#/components/parameters/_asset_policy" - $ref: "#/components/parameters/_asset_name" + - $ref: "#/components/parameters/_after_block_height" + - $ref: "#/components/parameters/_history" responses: "200": - description: Array of payment addresses holding the given token (including balances) [DEPRECATED - replaced by asset_addresses] - content: - application/json: - schema: - $ref: "#/components/schemas/asset_addresses" - "400": - $ref: "#/components/responses/BadRequest" - "401": - $ref: "#/components/responses/Unauthorized" - "404": - $ref: "#/components/responses/NotFound" - summary: Asset Address List - description: Get the list of all addresses holding a given asset [DEPRECATED - replaced by asset_addresses] - operationId: asset_address_list - /asset_policy_info: #RPC - get: - deprecated: true - tags: - - Asset - parameters: - - $ref: "#/components/parameters/_asset_policy" - responses: - "200": - description: Array of detailed information of assets under the same policy [DEPRECATED - replaced by policy_asset_info] + description: An array of Tx hashes that included the given asset (latest first) content: application/json: schema: - $ref: "#/components/schemas/policy_asset_info" + $ref: "#/components/schemas/address_txs" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Policy Information - description: Get the information for all assets under the same policy (DEPRECATED - replaced by policy_asset_info) - operationId: asset_policy_info - + summary: Asset Transactions + description: Get the list of current or all asset transaction hashes (newest first) + operationId: asset_txs /pool_list: #RPC get: tags: @@ -1468,7 +1459,7 @@ paths: tags: - Pool parameters: - - $ref: "#/components/parameters/_epoch_no" + - $ref: "#/components/parameters/_pool_epoch_no" responses: "200": description: Success!! @@ -1826,6 +1817,16 @@ components: in: query required: false allowEmptyValue: true + _pool_epoch_no: + deprecated: false + name: _epoch_no + description: Epoch Number to fetch details for + schema: + type: string + example: "18852" + in: query + required: false + allowEmptyValue: true _script_hash: deprecated: false name: _script_hash @@ -2474,6 +2475,35 @@ components: type: string description: JSON encoded data with details about the parameter update example: {"decentralisation": 0.9} + cli_protocol_params: + description: Get Current Protocol Parameters from node as published by cardano-cli in JSON format + type: object + example: + { + "collateralPercentage": 150, + "maxBlockBodySize": 90112, + "maxBlockHeaderSize": 1100, + "maxCollateralInputs": 3, + "maxTxSize": 16384, + "maxValueSize": 5000, + "minPoolCost": 170000000, + "minUTxOValue": null, + "monetaryExpansion": 3.0e-3, + "poolPledgeInfluence": 0.3, + "poolRetireMaxEpoch": 18, + "protocolVersion": { + "major": 8, + "minor": 0 + }, + "...": "...", + "stakeAddressDeposit": 2000000, + "stakePoolDeposit": 500000000, + "stakePoolTargetNum": 500, + "treasuryCut": 0.2, + "txFeeFixed": 155381, + "txFeePerByte": 44, + "utxoCostPerByte": 4310 + } reserve_withdrawals: description: Array of withdrawals from reserves/treasury against stake accounts type: array @@ -2493,6 +2523,14 @@ components: $ref: "#/components/schemas/pool_delegators/items/properties/amount" stake_address: $ref: "#/components/schemas/account_history/items/properties/stake_address" + earned_epoch: + description: Epoch where amount is earned + allOf: + - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + spendable_epoch: + description: Epoch where the earned amount can be spent + allOf: + - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" pool_list: description: Array of pool IDs and tickers type: array @@ -3632,9 +3670,9 @@ components: type: object properties: earned_epoch: - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + $ref: "#/components/schemas/reserve_withdrawals/items/properties/earned_epoch" spendable_epoch: - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + $ref: "#/components/schemas/reserve_withdrawals/items/properties/spendable_epoch" amount: type: string description: Amount of rewards earned (in lovelace) @@ -3983,6 +4021,16 @@ components: - 'null' description: Plutus script address example: addr1w999n67e86jn6xal07pzxtrmqynspgx0fwmcmpua4wc6yzsxpljz3 + spends_input: + type: + - object + - 'null' + properties: + tx_hash: + $ref: "#/components/schemas/utxo_infos/items/properties/tx_hash" + tx_index: + $ref: "#/components/schemas/utxo_infos/items/properties/tx_index" + description: Input utxo this contract spends script_hash: $ref: "#/components/schemas/script_info/items/properties/script_hash" bytecode: @@ -4153,7 +4201,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" quantity: type: string description: Asset balance on the payment address @@ -4166,7 +4214,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" asset_summary: description: Array of asset summary information type: array @@ -4316,7 +4364,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" quantity: $ref: "#/components/schemas/asset_addresses/items/properties/quantity" policy_asset_info: @@ -4344,6 +4392,31 @@ components: $ref: "#/components/schemas/asset_info/items/properties/minting_tx_metadata" token_registry_metadata: $ref: "#/components/schemas/asset_info/items/properties/token_registry_metadata" + policy_asset_mints: + description: Array of mint information for assets under requested policies + type: array + items: + properties: + asset_name: + $ref: "#/components/schemas/asset_info/items/properties/asset_name" + asset_name_ascii: + $ref: "#/components/schemas/asset_info/items/properties/asset_name_ascii" + fingerprint: + $ref: "#/components/schemas/asset_info/items/properties/fingerprint" + minting_tx_hash: + $ref: "#/components/schemas/asset_info/items/properties/minting_tx_hash" + total_supply: + $ref: "#/components/schemas/asset_info/items/properties/total_supply" + mint_cnt: + $ref: "#/components/schemas/asset_info/items/properties/mint_cnt" + burn_cnt: + $ref: "#/components/schemas/asset_info/items/properties/burn_cnt" + creation_time: + $ref: "#/components/schemas/asset_info/items/properties/creation_time" + minting_tx_metadata: + $ref: "#/components/schemas/asset_info/items/properties/minting_tx_metadata" + decimals: + $ref: "#/components/schemas/asset_info/items/properties/token_registry_metadata/properties/decimals" policy_asset_list: description: Array of brief information of assets under the same policy type: array diff --git a/specs/results/koiosapi-mainnet.yaml b/specs/results/koiosapi-mainnet.yaml index c3678356..c24134c3 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.1.1-dev + version: v1.1.1rc 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. @@ -23,24 +23,24 @@ info: ``` bash curl "https://api.koios.rest/api/v1/tip" - # [{"hash":"4d44c8a453e677f933c3df42ebcf2fe45987c41268b9cfc9b42ae305e8c3d99a","epoch":317,"abs_slot":51700871,"epoch_slot":120071,"block_height":6806994,"block_time":1643267162}] + # [{"hash":"4d44c8a453e677f933c3df42ebcf2fe45987c41268b9cfc9b42ae305e8c3d99a","epoch_no":317,"abs_slot":51700871,"epoch_slot":120071,"block_height":6806994,"block_time":1643267162}] - curl "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_height" + curl "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_height" - # [{"epoch":317,"epoch_slot":120071,"block_height":6806994}] + # [{"epoch_no":317,"epoch_slot":120071,"block_height":6806994}] ``` ## Horizontal Filtering You can filter the returned output based on specific conditions using operators against a column within returned result. Consider an example where you would want to query blocks minted in first 3 minutes of epoch 250 (i.e. epoch_slot was less than 180). To do so your query would look like below:

``` bash - curl "https://api.koios.rest/api/v1/blocks?epoch=eq.250&epoch_slot=lt.180" + curl "https://api.koios.rest/api/v1/blocks?epoch_no=eq.250&epoch_slot=lt.180" - # [{"hash":"8fad2808ac6b37064a0fa69f6fe065807703d5235a57442647bbcdba1c02faf8","epoch":250,"abs_slot":22636942,"epoch_slot":142,"block_height":5385757,"block_time":1614203233,"tx_count":65,"vrf_key":"vrf_vk14y9pjprzlsjvjt66mv5u7w7292sxp3kn4ewhss45ayjga5vurgaqhqknuu","pool":null,"op_cert_counter":2}, - # {"hash":"9d33b02badaedc0dedd0d59f3e0411e5fb4ac94217fb5ee86719e8463c570e16","epoch":250,"abs_slot":22636800,"epoch_slot":0,"block_height":5385756,"block_time":1614203091,"tx_count":10,"vrf_key":"vrf_vk1dkfsejw3h2k7tnguwrauqfwnxa7wj3nkp3yw2yw3400c4nlkluwqzwvka6","pool":null,"op_cert_counter":2}] + # [{"hash":"8fad2808ac6b37064a0fa69f6fe065807703d5235a57442647bbcdba1c02faf8","epoch_no":250,"abs_slot":22636942,"epoch_slot":142,"block_height":5385757,"block_time":1614203233,"tx_count":65,"vrf_key":"vrf_vk14y9pjprzlsjvjt66mv5u7w7292sxp3kn4ewhss45ayjga5vurgaqhqknuu","pool":null,"op_cert_counter":2}, + # {"hash":"9d33b02badaedc0dedd0d59f3e0411e5fb4ac94217fb5ee86719e8463c570e16","epoch_no":250,"abs_slot":22636800,"epoch_slot":0,"block_height":5385756,"block_time":1614203091,"tx_count":10,"vrf_key":"vrf_vk1dkfsejw3h2k7tnguwrauqfwnxa7wj3nkp3yw2yw3400c4nlkluwqzwvka6","pool":null,"op_cert_counter":2}] ``` - Here, we made use of `eq.` operator to denote a filter of "value equal to" against `epoch` column. Similarly, we added a filter using `lt.` operator to denote a filter of "values lower than" against `epoch_slot` column. You can find a complete list of operators supported in PostgREST documentation (commonly used ones extracted below): + Here, we made use of `eq.` operator to denote a filter of "value equal to" against `epoch_no` column. Similarly, we added a filter using `lt.` operator to denote a filter of "values lower than" against `epoch_slot` column. You can find a complete list of operators supported in PostgREST documentation (commonly used ones extracted below): |Abbreviation|In PostgreSQL|Meaning | |------------|-------------|-------------------------------------------| @@ -84,30 +84,22 @@ info: ``` - For GET endpoints, there is also another method to achieve the above, instead of adding parameters to the URL itself, you can specify a `Range` header as below to achieve something similar:

- - ``` bash - curl -s "https://api.koios.rest/api/v1/blocks?select=block_height" -H "Range: 1000-1499" -I | grep -i content-range - - # content-range: 1000-1499/* - - ``` - - The above methods for pagination are very useful to keep your queries light as well as process the output in smaller pages, making better use of your resources and respecting server timeouts for response times. + The above methods for pagination are very useful to keep some of the queries light as well as process the output in smaller pages, making better use of your resources and respecting server timeouts for response times. + However, note that due to the complex nature of some queries that require pre-processing before being subjected to paginations, these may not always be helpful to avoid server timeouts. ## Ordering You can set a sorting order for returned queries against specific column(s). - Consider example where you want to check `epoch` and `epoch_slot` for the first 5 blocks created by a particular pool, i.e. you can set order to ascending based on block_height column and add horizontal filter for that pool ID as below:

+ Consider example where you want to check `epoch_no` and `epoch_slot` for the first 5 blocks created by a particular pool, i.e. you can set order to ascending based on block_height column and add horizontal filter for that pool ID as below:

``` bash curl -s "https://api.koios.rest/api/v1/blocks?pool=eq.pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc&order=block_height.asc&limit=5" - # [{"hash":"610b4c7bbebeeb212bd002885048cc33154ba29f39919d62a3d96de05d315706","epoch":236,"abs_slot":16594295,"epoch_slot":5495,"block_height":5086774,"block_time":1608160586,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"d93d1db5275329ab695d30c06a35124038d8d9af64fc2b0aa082b8aa43da4164","epoch":236,"abs_slot":16597729,"epoch_slot":8929,"block_height":5086944,"block_time":1608164020,"tx_count":7,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"dc9496eae64294b46f07eb20499ae6dae4d81fdc67c63c354397db91bda1ee55","epoch":236,"abs_slot":16598058,"epoch_slot":9258,"block_height":5086962,"block_time":1608164349,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"6ebc7b734c513bc19290d96ca573a09cac9503c5a349dd9892b9ab43f917f9bd","epoch":236,"abs_slot":16601491,"epoch_slot":12691,"block_height":5087097,"block_time":1608167782,"tx_count":0,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"2eac97548829fc312858bc56a40f7ce3bf9b0ca27ee8530283ccebb3963de1c0","epoch":236,"abs_slot":16602308,"epoch_slot":13508,"block_height":5087136,"block_time":1608168599,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}] + # [{"hash":"610b4c7bbebeeb212bd002885048cc33154ba29f39919d62a3d96de05d315706","epoch_no":236,"abs_slot":16594295,"epoch_slot":5495,"block_height":5086774,"block_time":1608160586,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"d93d1db5275329ab695d30c06a35124038d8d9af64fc2b0aa082b8aa43da4164","epoch_no":236,"abs_slot":16597729,"epoch_slot":8929,"block_height":5086944,"block_time":1608164020,"tx_count":7,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"dc9496eae64294b46f07eb20499ae6dae4d81fdc67c63c354397db91bda1ee55","epoch_no":236,"abs_slot":16598058,"epoch_slot":9258,"block_height":5086962,"block_time":1608164349,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"6ebc7b734c513bc19290d96ca573a09cac9503c5a349dd9892b9ab43f917f9bd","epoch_no":236,"abs_slot":16601491,"epoch_slot":12691,"block_height":5087097,"block_time":1608167782,"tx_count":0,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"2eac97548829fc312858bc56a40f7ce3bf9b0ca27ee8530283ccebb3963de1c0","epoch_no":236,"abs_slot":16602308,"epoch_slot":13508,"block_height":5087136,"block_time":1608168599,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}] ``` ## Response Formats @@ -116,15 +108,15 @@ info: Below is an example of JSON/CSV output making use of above to print first in JSON (default), and then override response format to CSV.

``` bash - curl -s "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_time&limit=3" + curl -s "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_time&limit=3" - # [{"epoch":318,"epoch_slot":27867,"block_time":1643606958}, - # {"epoch":318,"epoch_slot":27841,"block_time":1643606932}, - # {"epoch":318,"epoch_slot":27839,"block_time":1643606930}] + # [{"epoch_no":318,"epoch_slot":27867,"block_time":1643606958}, + # {"epoch_no":318,"epoch_slot":27841,"block_time":1643606932}, + # {"epoch_no":318,"epoch_slot":27839,"block_time":1643606930}] - curl -s "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_time&limit=3" -H "Accept: text/csv" + curl -s "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_time&limit=3" -H "Accept: text/csv" - # epoch,epoch_slot,block_time + # epoch_no,epoch_slot,block_time # 318,28491,1643607582 # 318,28479,1643607570 # 318,28406,1643607497 @@ -243,6 +235,31 @@ paths: summary: Param Update Proposals description: Get all parameter update proposals submitted to the chain starting Shelley era operationId: param_updates + /cli_protocol_params: #RPC + get: + tags: + - Network + responses: + "200": + description: Success!! + content: + application/json: + schema: + $ref: "#/components/schemas/cli_protocol_params" + "400": + $ref: "#/components/responses/BadRequest" + "401": + $ref: "#/components/responses/Unauthorized" + "404": + $ref: "#/components/responses/NotFound" + summary: CLI Protocol Parameters + description: >- + Get Current Protocol Parameters as published by cardano-cli. Note that + the output schema of this command is unfortunately fluid on cardano-node + and may vary between CLI versions/era. Accordingly, the returned output for + this endpoint is left as raw JSON (single row) and any filtering to output should + be done on client-side + operationId: cli_protocol_params /reserve_withdrawals: #RPC get: tags: @@ -1186,102 +1203,76 @@ paths: summary: Policy Asset Information description: Get the information for all assets under the same policy operationId: policy_asset_info - /asset_summary: #RPC + /policy_asset_mints: #RPC get: tags: - Asset parameters: - $ref: "#/components/parameters/_asset_policy" - - $ref: "#/components/parameters/_asset_name" responses: "200": - description: Array of asset summary information + description: Get a list of mint or burn count details for all assets minted under a policy content: application/json: schema: - $ref: "#/components/schemas/asset_summary" + $ref: "#/components/schemas/policy_asset_mints" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Summary - description: Get the summary of an asset (total transactions exclude minting/total wallets include only wallets with asset balance) - operationId: asset_summary - /asset_txs: #RPC + summary: Policy Asset Mints + description: Get a list of mint or burn count details for all assets minted under a policy + operationId: policy_asset_mints + /asset_summary: #RPC get: tags: - Asset parameters: - $ref: "#/components/parameters/_asset_policy" - $ref: "#/components/parameters/_asset_name" - - $ref: "#/components/parameters/_after_block_height" - - $ref: "#/components/parameters/_history" responses: "200": - description: An array of Tx hashes that included the given asset (latest first) + description: Array of asset summary information content: application/json: schema: - $ref: "#/components/schemas/address_txs" + $ref: "#/components/schemas/asset_summary" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Transactions - description: Get the list of current or all asset transaction hashes (newest first) - operationId: asset_txs - /asset_address_list: #RPC + summary: Asset Summary + description: Get the summary of an asset (total transactions exclude minting/total wallets include only wallets with asset balance) + operationId: asset_summary + /asset_txs: #RPC get: tags: - Asset - deprecated: true parameters: - $ref: "#/components/parameters/_asset_policy" - $ref: "#/components/parameters/_asset_name" + - $ref: "#/components/parameters/_after_block_height" + - $ref: "#/components/parameters/_history" responses: "200": - description: Array of payment addresses holding the given token (including balances) [DEPRECATED - replaced by asset_addresses] - content: - application/json: - schema: - $ref: "#/components/schemas/asset_addresses" - "400": - $ref: "#/components/responses/BadRequest" - "401": - $ref: "#/components/responses/Unauthorized" - "404": - $ref: "#/components/responses/NotFound" - summary: Asset Address List - description: Get the list of all addresses holding a given asset [DEPRECATED - replaced by asset_addresses] - operationId: asset_address_list - /asset_policy_info: #RPC - get: - deprecated: true - tags: - - Asset - parameters: - - $ref: "#/components/parameters/_asset_policy" - responses: - "200": - description: Array of detailed information of assets under the same policy [DEPRECATED - replaced by policy_asset_info] + description: An array of Tx hashes that included the given asset (latest first) content: application/json: schema: - $ref: "#/components/schemas/policy_asset_info" + $ref: "#/components/schemas/address_txs" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Policy Information - description: Get the information for all assets under the same policy (DEPRECATED - replaced by policy_asset_info) - operationId: asset_policy_info - + summary: Asset Transactions + description: Get the list of current or all asset transaction hashes (newest first) + operationId: asset_txs /pool_list: #RPC get: tags: @@ -1468,7 +1459,7 @@ paths: tags: - Pool parameters: - - $ref: "#/components/parameters/_epoch_no" + - $ref: "#/components/parameters/_pool_epoch_no" responses: "200": description: Success!! @@ -1826,6 +1817,16 @@ components: in: query required: false allowEmptyValue: true + _pool_epoch_no: + deprecated: false + name: _epoch_no + description: Epoch Number to fetch details for + schema: + type: string + example: "320" + in: query + required: false + allowEmptyValue: true _script_hash: deprecated: false name: _script_hash @@ -2474,6 +2475,35 @@ components: type: string description: JSON encoded data with details about the parameter update example: {"decentralisation": 0.9} + cli_protocol_params: + description: Get Current Protocol Parameters from node as published by cardano-cli in JSON format + type: object + example: + { + "collateralPercentage": 150, + "maxBlockBodySize": 90112, + "maxBlockHeaderSize": 1100, + "maxCollateralInputs": 3, + "maxTxSize": 16384, + "maxValueSize": 5000, + "minPoolCost": 170000000, + "minUTxOValue": null, + "monetaryExpansion": 3.0e-3, + "poolPledgeInfluence": 0.3, + "poolRetireMaxEpoch": 18, + "protocolVersion": { + "major": 8, + "minor": 0 + }, + "...": "...", + "stakeAddressDeposit": 2000000, + "stakePoolDeposit": 500000000, + "stakePoolTargetNum": 500, + "treasuryCut": 0.2, + "txFeeFixed": 155381, + "txFeePerByte": 44, + "utxoCostPerByte": 4310 + } reserve_withdrawals: description: Array of withdrawals from reserves/treasury against stake accounts type: array @@ -2493,6 +2523,14 @@ components: $ref: "#/components/schemas/pool_delegators/items/properties/amount" stake_address: $ref: "#/components/schemas/account_history/items/properties/stake_address" + earned_epoch: + description: Epoch where amount is earned + allOf: + - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + spendable_epoch: + description: Epoch where the earned amount can be spent + allOf: + - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" pool_list: description: Array of pool IDs and tickers type: array @@ -3632,9 +3670,9 @@ components: type: object properties: earned_epoch: - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + $ref: "#/components/schemas/reserve_withdrawals/items/properties/earned_epoch" spendable_epoch: - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + $ref: "#/components/schemas/reserve_withdrawals/items/properties/spendable_epoch" amount: type: string description: Amount of rewards earned (in lovelace) @@ -3983,6 +4021,16 @@ components: - 'null' description: Plutus script address example: addr1w999n67e86jn6xal07pzxtrmqynspgx0fwmcmpua4wc6yzsxpljz3 + spends_input: + type: + - object + - 'null' + properties: + tx_hash: + $ref: "#/components/schemas/utxo_infos/items/properties/tx_hash" + tx_index: + $ref: "#/components/schemas/utxo_infos/items/properties/tx_index" + description: Input utxo this contract spends script_hash: $ref: "#/components/schemas/script_info/items/properties/script_hash" bytecode: @@ -4153,7 +4201,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" quantity: type: string description: Asset balance on the payment address @@ -4166,7 +4214,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" asset_summary: description: Array of asset summary information type: array @@ -4316,7 +4364,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" quantity: $ref: "#/components/schemas/asset_addresses/items/properties/quantity" policy_asset_info: @@ -4344,6 +4392,31 @@ components: $ref: "#/components/schemas/asset_info/items/properties/minting_tx_metadata" token_registry_metadata: $ref: "#/components/schemas/asset_info/items/properties/token_registry_metadata" + policy_asset_mints: + description: Array of mint information for assets under requested policies + type: array + items: + properties: + asset_name: + $ref: "#/components/schemas/asset_info/items/properties/asset_name" + asset_name_ascii: + $ref: "#/components/schemas/asset_info/items/properties/asset_name_ascii" + fingerprint: + $ref: "#/components/schemas/asset_info/items/properties/fingerprint" + minting_tx_hash: + $ref: "#/components/schemas/asset_info/items/properties/minting_tx_hash" + total_supply: + $ref: "#/components/schemas/asset_info/items/properties/total_supply" + mint_cnt: + $ref: "#/components/schemas/asset_info/items/properties/mint_cnt" + burn_cnt: + $ref: "#/components/schemas/asset_info/items/properties/burn_cnt" + creation_time: + $ref: "#/components/schemas/asset_info/items/properties/creation_time" + minting_tx_metadata: + $ref: "#/components/schemas/asset_info/items/properties/minting_tx_metadata" + decimals: + $ref: "#/components/schemas/asset_info/items/properties/token_registry_metadata/properties/decimals" policy_asset_list: description: Array of brief information of assets under the same policy type: array diff --git a/specs/results/koiosapi-preprod.yaml b/specs/results/koiosapi-preprod.yaml index e6f2fd59..0b2b13c7 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.1.1-dev + version: v1.1.1rc 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. @@ -23,24 +23,24 @@ info: ``` bash curl "https://api.koios.rest/api/v1/tip" - # [{"hash":"4d44c8a453e677f933c3df42ebcf2fe45987c41268b9cfc9b42ae305e8c3d99a","epoch":317,"abs_slot":51700871,"epoch_slot":120071,"block_height":6806994,"block_time":1643267162}] + # [{"hash":"4d44c8a453e677f933c3df42ebcf2fe45987c41268b9cfc9b42ae305e8c3d99a","epoch_no":317,"abs_slot":51700871,"epoch_slot":120071,"block_height":6806994,"block_time":1643267162}] - curl "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_height" + curl "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_height" - # [{"epoch":317,"epoch_slot":120071,"block_height":6806994}] + # [{"epoch_no":317,"epoch_slot":120071,"block_height":6806994}] ``` ## Horizontal Filtering You can filter the returned output based on specific conditions using operators against a column within returned result. Consider an example where you would want to query blocks minted in first 3 minutes of epoch 250 (i.e. epoch_slot was less than 180). To do so your query would look like below:

``` bash - curl "https://api.koios.rest/api/v1/blocks?epoch=eq.250&epoch_slot=lt.180" + curl "https://api.koios.rest/api/v1/blocks?epoch_no=eq.250&epoch_slot=lt.180" - # [{"hash":"8fad2808ac6b37064a0fa69f6fe065807703d5235a57442647bbcdba1c02faf8","epoch":250,"abs_slot":22636942,"epoch_slot":142,"block_height":5385757,"block_time":1614203233,"tx_count":65,"vrf_key":"vrf_vk14y9pjprzlsjvjt66mv5u7w7292sxp3kn4ewhss45ayjga5vurgaqhqknuu","pool":null,"op_cert_counter":2}, - # {"hash":"9d33b02badaedc0dedd0d59f3e0411e5fb4ac94217fb5ee86719e8463c570e16","epoch":250,"abs_slot":22636800,"epoch_slot":0,"block_height":5385756,"block_time":1614203091,"tx_count":10,"vrf_key":"vrf_vk1dkfsejw3h2k7tnguwrauqfwnxa7wj3nkp3yw2yw3400c4nlkluwqzwvka6","pool":null,"op_cert_counter":2}] + # [{"hash":"8fad2808ac6b37064a0fa69f6fe065807703d5235a57442647bbcdba1c02faf8","epoch_no":250,"abs_slot":22636942,"epoch_slot":142,"block_height":5385757,"block_time":1614203233,"tx_count":65,"vrf_key":"vrf_vk14y9pjprzlsjvjt66mv5u7w7292sxp3kn4ewhss45ayjga5vurgaqhqknuu","pool":null,"op_cert_counter":2}, + # {"hash":"9d33b02badaedc0dedd0d59f3e0411e5fb4ac94217fb5ee86719e8463c570e16","epoch_no":250,"abs_slot":22636800,"epoch_slot":0,"block_height":5385756,"block_time":1614203091,"tx_count":10,"vrf_key":"vrf_vk1dkfsejw3h2k7tnguwrauqfwnxa7wj3nkp3yw2yw3400c4nlkluwqzwvka6","pool":null,"op_cert_counter":2}] ``` - Here, we made use of `eq.` operator to denote a filter of "value equal to" against `epoch` column. Similarly, we added a filter using `lt.` operator to denote a filter of "values lower than" against `epoch_slot` column. You can find a complete list of operators supported in PostgREST documentation (commonly used ones extracted below): + Here, we made use of `eq.` operator to denote a filter of "value equal to" against `epoch_no` column. Similarly, we added a filter using `lt.` operator to denote a filter of "values lower than" against `epoch_slot` column. You can find a complete list of operators supported in PostgREST documentation (commonly used ones extracted below): |Abbreviation|In PostgreSQL|Meaning | |------------|-------------|-------------------------------------------| @@ -84,30 +84,22 @@ info: ``` - For GET endpoints, there is also another method to achieve the above, instead of adding parameters to the URL itself, you can specify a `Range` header as below to achieve something similar:

- - ``` bash - curl -s "https://api.koios.rest/api/v1/blocks?select=block_height" -H "Range: 1000-1499" -I | grep -i content-range - - # content-range: 1000-1499/* - - ``` - - The above methods for pagination are very useful to keep your queries light as well as process the output in smaller pages, making better use of your resources and respecting server timeouts for response times. + The above methods for pagination are very useful to keep some of the queries light as well as process the output in smaller pages, making better use of your resources and respecting server timeouts for response times. + However, note that due to the complex nature of some queries that require pre-processing before being subjected to paginations, these may not always be helpful to avoid server timeouts. ## Ordering You can set a sorting order for returned queries against specific column(s). - Consider example where you want to check `epoch` and `epoch_slot` for the first 5 blocks created by a particular pool, i.e. you can set order to ascending based on block_height column and add horizontal filter for that pool ID as below:

+ Consider example where you want to check `epoch_no` and `epoch_slot` for the first 5 blocks created by a particular pool, i.e. you can set order to ascending based on block_height column and add horizontal filter for that pool ID as below:

``` bash curl -s "https://api.koios.rest/api/v1/blocks?pool=eq.pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc&order=block_height.asc&limit=5" - # [{"hash":"610b4c7bbebeeb212bd002885048cc33154ba29f39919d62a3d96de05d315706","epoch":236,"abs_slot":16594295,"epoch_slot":5495,"block_height":5086774,"block_time":1608160586,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"d93d1db5275329ab695d30c06a35124038d8d9af64fc2b0aa082b8aa43da4164","epoch":236,"abs_slot":16597729,"epoch_slot":8929,"block_height":5086944,"block_time":1608164020,"tx_count":7,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"dc9496eae64294b46f07eb20499ae6dae4d81fdc67c63c354397db91bda1ee55","epoch":236,"abs_slot":16598058,"epoch_slot":9258,"block_height":5086962,"block_time":1608164349,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"6ebc7b734c513bc19290d96ca573a09cac9503c5a349dd9892b9ab43f917f9bd","epoch":236,"abs_slot":16601491,"epoch_slot":12691,"block_height":5087097,"block_time":1608167782,"tx_count":0,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"2eac97548829fc312858bc56a40f7ce3bf9b0ca27ee8530283ccebb3963de1c0","epoch":236,"abs_slot":16602308,"epoch_slot":13508,"block_height":5087136,"block_time":1608168599,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}] + # [{"hash":"610b4c7bbebeeb212bd002885048cc33154ba29f39919d62a3d96de05d315706","epoch_no":236,"abs_slot":16594295,"epoch_slot":5495,"block_height":5086774,"block_time":1608160586,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"d93d1db5275329ab695d30c06a35124038d8d9af64fc2b0aa082b8aa43da4164","epoch_no":236,"abs_slot":16597729,"epoch_slot":8929,"block_height":5086944,"block_time":1608164020,"tx_count":7,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"dc9496eae64294b46f07eb20499ae6dae4d81fdc67c63c354397db91bda1ee55","epoch_no":236,"abs_slot":16598058,"epoch_slot":9258,"block_height":5086962,"block_time":1608164349,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"6ebc7b734c513bc19290d96ca573a09cac9503c5a349dd9892b9ab43f917f9bd","epoch_no":236,"abs_slot":16601491,"epoch_slot":12691,"block_height":5087097,"block_time":1608167782,"tx_count":0,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"2eac97548829fc312858bc56a40f7ce3bf9b0ca27ee8530283ccebb3963de1c0","epoch_no":236,"abs_slot":16602308,"epoch_slot":13508,"block_height":5087136,"block_time":1608168599,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}] ``` ## Response Formats @@ -116,15 +108,15 @@ info: Below is an example of JSON/CSV output making use of above to print first in JSON (default), and then override response format to CSV.

``` bash - curl -s "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_time&limit=3" + curl -s "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_time&limit=3" - # [{"epoch":318,"epoch_slot":27867,"block_time":1643606958}, - # {"epoch":318,"epoch_slot":27841,"block_time":1643606932}, - # {"epoch":318,"epoch_slot":27839,"block_time":1643606930}] + # [{"epoch_no":318,"epoch_slot":27867,"block_time":1643606958}, + # {"epoch_no":318,"epoch_slot":27841,"block_time":1643606932}, + # {"epoch_no":318,"epoch_slot":27839,"block_time":1643606930}] - curl -s "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_time&limit=3" -H "Accept: text/csv" + curl -s "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_time&limit=3" -H "Accept: text/csv" - # epoch,epoch_slot,block_time + # epoch_no,epoch_slot,block_time # 318,28491,1643607582 # 318,28479,1643607570 # 318,28406,1643607497 @@ -243,6 +235,31 @@ paths: summary: Param Update Proposals description: Get all parameter update proposals submitted to the chain starting Shelley era operationId: param_updates + /cli_protocol_params: #RPC + get: + tags: + - Network + responses: + "200": + description: Success!! + content: + application/json: + schema: + $ref: "#/components/schemas/cli_protocol_params" + "400": + $ref: "#/components/responses/BadRequest" + "401": + $ref: "#/components/responses/Unauthorized" + "404": + $ref: "#/components/responses/NotFound" + summary: CLI Protocol Parameters + description: >- + Get Current Protocol Parameters as published by cardano-cli. Note that + the output schema of this command is unfortunately fluid on cardano-node + and may vary between CLI versions/era. Accordingly, the returned output for + this endpoint is left as raw JSON (single row) and any filtering to output should + be done on client-side + operationId: cli_protocol_params /reserve_withdrawals: #RPC get: tags: @@ -1186,102 +1203,76 @@ paths: summary: Policy Asset Information description: Get the information for all assets under the same policy operationId: policy_asset_info - /asset_summary: #RPC + /policy_asset_mints: #RPC get: tags: - Asset parameters: - $ref: "#/components/parameters/_asset_policy" - - $ref: "#/components/parameters/_asset_name" responses: "200": - description: Array of asset summary information + description: Get a list of mint or burn count details for all assets minted under a policy content: application/json: schema: - $ref: "#/components/schemas/asset_summary" + $ref: "#/components/schemas/policy_asset_mints" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Summary - description: Get the summary of an asset (total transactions exclude minting/total wallets include only wallets with asset balance) - operationId: asset_summary - /asset_txs: #RPC + summary: Policy Asset Mints + description: Get a list of mint or burn count details for all assets minted under a policy + operationId: policy_asset_mints + /asset_summary: #RPC get: tags: - Asset parameters: - $ref: "#/components/parameters/_asset_policy" - $ref: "#/components/parameters/_asset_name" - - $ref: "#/components/parameters/_after_block_height" - - $ref: "#/components/parameters/_history" responses: "200": - description: An array of Tx hashes that included the given asset (latest first) + description: Array of asset summary information content: application/json: schema: - $ref: "#/components/schemas/address_txs" + $ref: "#/components/schemas/asset_summary" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Transactions - description: Get the list of current or all asset transaction hashes (newest first) - operationId: asset_txs - /asset_address_list: #RPC + summary: Asset Summary + description: Get the summary of an asset (total transactions exclude minting/total wallets include only wallets with asset balance) + operationId: asset_summary + /asset_txs: #RPC get: tags: - Asset - deprecated: true parameters: - $ref: "#/components/parameters/_asset_policy" - $ref: "#/components/parameters/_asset_name" + - $ref: "#/components/parameters/_after_block_height" + - $ref: "#/components/parameters/_history" responses: "200": - description: Array of payment addresses holding the given token (including balances) [DEPRECATED - replaced by asset_addresses] - content: - application/json: - schema: - $ref: "#/components/schemas/asset_addresses" - "400": - $ref: "#/components/responses/BadRequest" - "401": - $ref: "#/components/responses/Unauthorized" - "404": - $ref: "#/components/responses/NotFound" - summary: Asset Address List - description: Get the list of all addresses holding a given asset [DEPRECATED - replaced by asset_addresses] - operationId: asset_address_list - /asset_policy_info: #RPC - get: - deprecated: true - tags: - - Asset - parameters: - - $ref: "#/components/parameters/_asset_policy" - responses: - "200": - description: Array of detailed information of assets under the same policy [DEPRECATED - replaced by policy_asset_info] + description: An array of Tx hashes that included the given asset (latest first) content: application/json: schema: - $ref: "#/components/schemas/policy_asset_info" + $ref: "#/components/schemas/address_txs" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Policy Information - description: Get the information for all assets under the same policy (DEPRECATED - replaced by policy_asset_info) - operationId: asset_policy_info - + summary: Asset Transactions + description: Get the list of current or all asset transaction hashes (newest first) + operationId: asset_txs /pool_list: #RPC get: tags: @@ -1468,7 +1459,7 @@ paths: tags: - Pool parameters: - - $ref: "#/components/parameters/_epoch_no" + - $ref: "#/components/parameters/_pool_epoch_no" responses: "200": description: Success!! @@ -1826,13 +1817,23 @@ components: in: query required: false allowEmptyValue: true + _pool_epoch_no: + deprecated: false + name: _epoch_no + description: Epoch Number to fetch details for + schema: + type: string + example: "31" + in: query + required: false + allowEmptyValue: true _script_hash: deprecated: false name: _script_hash description: Script hash in hexadecimal format (hex) schema: type: string - example: "590555d7b5760e98ae2bdd29b356247776251dfab0a207bfce98a485" + example: "14abafb323de75b7266fd0eab29b6ef562305e8a0dfbb64b07ef32c7" in: query required: true allowEmptyValue: false @@ -2474,6 +2475,35 @@ components: type: string description: JSON encoded data with details about the parameter update example: {"decentralisation": 0.9} + cli_protocol_params: + description: Get Current Protocol Parameters from node as published by cardano-cli in JSON format + type: object + example: + { + "collateralPercentage": 150, + "maxBlockBodySize": 90112, + "maxBlockHeaderSize": 1100, + "maxCollateralInputs": 3, + "maxTxSize": 16384, + "maxValueSize": 5000, + "minPoolCost": 170000000, + "minUTxOValue": null, + "monetaryExpansion": 3.0e-3, + "poolPledgeInfluence": 0.3, + "poolRetireMaxEpoch": 18, + "protocolVersion": { + "major": 8, + "minor": 0 + }, + "...": "...", + "stakeAddressDeposit": 2000000, + "stakePoolDeposit": 500000000, + "stakePoolTargetNum": 500, + "treasuryCut": 0.2, + "txFeeFixed": 155381, + "txFeePerByte": 44, + "utxoCostPerByte": 4310 + } reserve_withdrawals: description: Array of withdrawals from reserves/treasury against stake accounts type: array @@ -2493,6 +2523,14 @@ components: $ref: "#/components/schemas/pool_delegators/items/properties/amount" stake_address: $ref: "#/components/schemas/account_history/items/properties/stake_address" + earned_epoch: + description: Epoch where amount is earned + allOf: + - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + spendable_epoch: + description: Epoch where the earned amount can be spent + allOf: + - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" pool_list: description: Array of pool IDs and tickers type: array @@ -3632,9 +3670,9 @@ components: type: object properties: earned_epoch: - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + $ref: "#/components/schemas/reserve_withdrawals/items/properties/earned_epoch" spendable_epoch: - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + $ref: "#/components/schemas/reserve_withdrawals/items/properties/spendable_epoch" amount: type: string description: Amount of rewards earned (in lovelace) @@ -3983,6 +4021,16 @@ components: - 'null' description: Plutus script address example: addr1w999n67e86jn6xal07pzxtrmqynspgx0fwmcmpua4wc6yzsxpljz3 + spends_input: + type: + - object + - 'null' + properties: + tx_hash: + $ref: "#/components/schemas/utxo_infos/items/properties/tx_hash" + tx_index: + $ref: "#/components/schemas/utxo_infos/items/properties/tx_index" + description: Input utxo this contract spends script_hash: $ref: "#/components/schemas/script_info/items/properties/script_hash" bytecode: @@ -4153,7 +4201,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" quantity: type: string description: Asset balance on the payment address @@ -4166,7 +4214,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" asset_summary: description: Array of asset summary information type: array @@ -4316,7 +4364,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" quantity: $ref: "#/components/schemas/asset_addresses/items/properties/quantity" policy_asset_info: @@ -4344,6 +4392,31 @@ components: $ref: "#/components/schemas/asset_info/items/properties/minting_tx_metadata" token_registry_metadata: $ref: "#/components/schemas/asset_info/items/properties/token_registry_metadata" + policy_asset_mints: + description: Array of mint information for assets under requested policies + type: array + items: + properties: + asset_name: + $ref: "#/components/schemas/asset_info/items/properties/asset_name" + asset_name_ascii: + $ref: "#/components/schemas/asset_info/items/properties/asset_name_ascii" + fingerprint: + $ref: "#/components/schemas/asset_info/items/properties/fingerprint" + minting_tx_hash: + $ref: "#/components/schemas/asset_info/items/properties/minting_tx_hash" + total_supply: + $ref: "#/components/schemas/asset_info/items/properties/total_supply" + mint_cnt: + $ref: "#/components/schemas/asset_info/items/properties/mint_cnt" + burn_cnt: + $ref: "#/components/schemas/asset_info/items/properties/burn_cnt" + creation_time: + $ref: "#/components/schemas/asset_info/items/properties/creation_time" + minting_tx_metadata: + $ref: "#/components/schemas/asset_info/items/properties/minting_tx_metadata" + decimals: + $ref: "#/components/schemas/asset_info/items/properties/token_registry_metadata/properties/decimals" policy_asset_list: description: Array of brief information of assets under the same policy type: array diff --git a/specs/results/koiosapi-preview.yaml b/specs/results/koiosapi-preview.yaml index 7d0aa0b3..1235e025 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.1.1-dev + version: v1.1.1rc 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. @@ -23,24 +23,24 @@ info: ``` bash curl "https://api.koios.rest/api/v1/tip" - # [{"hash":"4d44c8a453e677f933c3df42ebcf2fe45987c41268b9cfc9b42ae305e8c3d99a","epoch":317,"abs_slot":51700871,"epoch_slot":120071,"block_height":6806994,"block_time":1643267162}] + # [{"hash":"4d44c8a453e677f933c3df42ebcf2fe45987c41268b9cfc9b42ae305e8c3d99a","epoch_no":317,"abs_slot":51700871,"epoch_slot":120071,"block_height":6806994,"block_time":1643267162}] - curl "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_height" + curl "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_height" - # [{"epoch":317,"epoch_slot":120071,"block_height":6806994}] + # [{"epoch_no":317,"epoch_slot":120071,"block_height":6806994}] ``` ## Horizontal Filtering You can filter the returned output based on specific conditions using operators against a column within returned result. Consider an example where you would want to query blocks minted in first 3 minutes of epoch 250 (i.e. epoch_slot was less than 180). To do so your query would look like below:

``` bash - curl "https://api.koios.rest/api/v1/blocks?epoch=eq.250&epoch_slot=lt.180" + curl "https://api.koios.rest/api/v1/blocks?epoch_no=eq.250&epoch_slot=lt.180" - # [{"hash":"8fad2808ac6b37064a0fa69f6fe065807703d5235a57442647bbcdba1c02faf8","epoch":250,"abs_slot":22636942,"epoch_slot":142,"block_height":5385757,"block_time":1614203233,"tx_count":65,"vrf_key":"vrf_vk14y9pjprzlsjvjt66mv5u7w7292sxp3kn4ewhss45ayjga5vurgaqhqknuu","pool":null,"op_cert_counter":2}, - # {"hash":"9d33b02badaedc0dedd0d59f3e0411e5fb4ac94217fb5ee86719e8463c570e16","epoch":250,"abs_slot":22636800,"epoch_slot":0,"block_height":5385756,"block_time":1614203091,"tx_count":10,"vrf_key":"vrf_vk1dkfsejw3h2k7tnguwrauqfwnxa7wj3nkp3yw2yw3400c4nlkluwqzwvka6","pool":null,"op_cert_counter":2}] + # [{"hash":"8fad2808ac6b37064a0fa69f6fe065807703d5235a57442647bbcdba1c02faf8","epoch_no":250,"abs_slot":22636942,"epoch_slot":142,"block_height":5385757,"block_time":1614203233,"tx_count":65,"vrf_key":"vrf_vk14y9pjprzlsjvjt66mv5u7w7292sxp3kn4ewhss45ayjga5vurgaqhqknuu","pool":null,"op_cert_counter":2}, + # {"hash":"9d33b02badaedc0dedd0d59f3e0411e5fb4ac94217fb5ee86719e8463c570e16","epoch_no":250,"abs_slot":22636800,"epoch_slot":0,"block_height":5385756,"block_time":1614203091,"tx_count":10,"vrf_key":"vrf_vk1dkfsejw3h2k7tnguwrauqfwnxa7wj3nkp3yw2yw3400c4nlkluwqzwvka6","pool":null,"op_cert_counter":2}] ``` - Here, we made use of `eq.` operator to denote a filter of "value equal to" against `epoch` column. Similarly, we added a filter using `lt.` operator to denote a filter of "values lower than" against `epoch_slot` column. You can find a complete list of operators supported in PostgREST documentation (commonly used ones extracted below): + Here, we made use of `eq.` operator to denote a filter of "value equal to" against `epoch_no` column. Similarly, we added a filter using `lt.` operator to denote a filter of "values lower than" against `epoch_slot` column. You can find a complete list of operators supported in PostgREST documentation (commonly used ones extracted below): |Abbreviation|In PostgreSQL|Meaning | |------------|-------------|-------------------------------------------| @@ -84,30 +84,22 @@ info: ``` - For GET endpoints, there is also another method to achieve the above, instead of adding parameters to the URL itself, you can specify a `Range` header as below to achieve something similar:

- - ``` bash - curl -s "https://api.koios.rest/api/v1/blocks?select=block_height" -H "Range: 1000-1499" -I | grep -i content-range - - # content-range: 1000-1499/* - - ``` - - The above methods for pagination are very useful to keep your queries light as well as process the output in smaller pages, making better use of your resources and respecting server timeouts for response times. + The above methods for pagination are very useful to keep some of the queries light as well as process the output in smaller pages, making better use of your resources and respecting server timeouts for response times. + However, note that due to the complex nature of some queries that require pre-processing before being subjected to paginations, these may not always be helpful to avoid server timeouts. ## Ordering You can set a sorting order for returned queries against specific column(s). - Consider example where you want to check `epoch` and `epoch_slot` for the first 5 blocks created by a particular pool, i.e. you can set order to ascending based on block_height column and add horizontal filter for that pool ID as below:

+ Consider example where you want to check `epoch_no` and `epoch_slot` for the first 5 blocks created by a particular pool, i.e. you can set order to ascending based on block_height column and add horizontal filter for that pool ID as below:

``` bash curl -s "https://api.koios.rest/api/v1/blocks?pool=eq.pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc&order=block_height.asc&limit=5" - # [{"hash":"610b4c7bbebeeb212bd002885048cc33154ba29f39919d62a3d96de05d315706","epoch":236,"abs_slot":16594295,"epoch_slot":5495,"block_height":5086774,"block_time":1608160586,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"d93d1db5275329ab695d30c06a35124038d8d9af64fc2b0aa082b8aa43da4164","epoch":236,"abs_slot":16597729,"epoch_slot":8929,"block_height":5086944,"block_time":1608164020,"tx_count":7,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"dc9496eae64294b46f07eb20499ae6dae4d81fdc67c63c354397db91bda1ee55","epoch":236,"abs_slot":16598058,"epoch_slot":9258,"block_height":5086962,"block_time":1608164349,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"6ebc7b734c513bc19290d96ca573a09cac9503c5a349dd9892b9ab43f917f9bd","epoch":236,"abs_slot":16601491,"epoch_slot":12691,"block_height":5087097,"block_time":1608167782,"tx_count":0,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"2eac97548829fc312858bc56a40f7ce3bf9b0ca27ee8530283ccebb3963de1c0","epoch":236,"abs_slot":16602308,"epoch_slot":13508,"block_height":5087136,"block_time":1608168599,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}] + # [{"hash":"610b4c7bbebeeb212bd002885048cc33154ba29f39919d62a3d96de05d315706","epoch_no":236,"abs_slot":16594295,"epoch_slot":5495,"block_height":5086774,"block_time":1608160586,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"d93d1db5275329ab695d30c06a35124038d8d9af64fc2b0aa082b8aa43da4164","epoch_no":236,"abs_slot":16597729,"epoch_slot":8929,"block_height":5086944,"block_time":1608164020,"tx_count":7,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"dc9496eae64294b46f07eb20499ae6dae4d81fdc67c63c354397db91bda1ee55","epoch_no":236,"abs_slot":16598058,"epoch_slot":9258,"block_height":5086962,"block_time":1608164349,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"6ebc7b734c513bc19290d96ca573a09cac9503c5a349dd9892b9ab43f917f9bd","epoch_no":236,"abs_slot":16601491,"epoch_slot":12691,"block_height":5087097,"block_time":1608167782,"tx_count":0,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"2eac97548829fc312858bc56a40f7ce3bf9b0ca27ee8530283ccebb3963de1c0","epoch_no":236,"abs_slot":16602308,"epoch_slot":13508,"block_height":5087136,"block_time":1608168599,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}] ``` ## Response Formats @@ -116,15 +108,15 @@ info: Below is an example of JSON/CSV output making use of above to print first in JSON (default), and then override response format to CSV.

``` bash - curl -s "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_time&limit=3" + curl -s "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_time&limit=3" - # [{"epoch":318,"epoch_slot":27867,"block_time":1643606958}, - # {"epoch":318,"epoch_slot":27841,"block_time":1643606932}, - # {"epoch":318,"epoch_slot":27839,"block_time":1643606930}] + # [{"epoch_no":318,"epoch_slot":27867,"block_time":1643606958}, + # {"epoch_no":318,"epoch_slot":27841,"block_time":1643606932}, + # {"epoch_no":318,"epoch_slot":27839,"block_time":1643606930}] - curl -s "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_time&limit=3" -H "Accept: text/csv" + curl -s "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_time&limit=3" -H "Accept: text/csv" - # epoch,epoch_slot,block_time + # epoch_no,epoch_slot,block_time # 318,28491,1643607582 # 318,28479,1643607570 # 318,28406,1643607497 @@ -243,6 +235,31 @@ paths: summary: Param Update Proposals description: Get all parameter update proposals submitted to the chain starting Shelley era operationId: param_updates + /cli_protocol_params: #RPC + get: + tags: + - Network + responses: + "200": + description: Success!! + content: + application/json: + schema: + $ref: "#/components/schemas/cli_protocol_params" + "400": + $ref: "#/components/responses/BadRequest" + "401": + $ref: "#/components/responses/Unauthorized" + "404": + $ref: "#/components/responses/NotFound" + summary: CLI Protocol Parameters + description: >- + Get Current Protocol Parameters as published by cardano-cli. Note that + the output schema of this command is unfortunately fluid on cardano-node + and may vary between CLI versions/era. Accordingly, the returned output for + this endpoint is left as raw JSON (single row) and any filtering to output should + be done on client-side + operationId: cli_protocol_params /reserve_withdrawals: #RPC get: tags: @@ -1186,102 +1203,76 @@ paths: summary: Policy Asset Information description: Get the information for all assets under the same policy operationId: policy_asset_info - /asset_summary: #RPC + /policy_asset_mints: #RPC get: tags: - Asset parameters: - $ref: "#/components/parameters/_asset_policy" - - $ref: "#/components/parameters/_asset_name" responses: "200": - description: Array of asset summary information + description: Get a list of mint or burn count details for all assets minted under a policy content: application/json: schema: - $ref: "#/components/schemas/asset_summary" + $ref: "#/components/schemas/policy_asset_mints" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Summary - description: Get the summary of an asset (total transactions exclude minting/total wallets include only wallets with asset balance) - operationId: asset_summary - /asset_txs: #RPC + summary: Policy Asset Mints + description: Get a list of mint or burn count details for all assets minted under a policy + operationId: policy_asset_mints + /asset_summary: #RPC get: tags: - Asset parameters: - $ref: "#/components/parameters/_asset_policy" - $ref: "#/components/parameters/_asset_name" - - $ref: "#/components/parameters/_after_block_height" - - $ref: "#/components/parameters/_history" responses: "200": - description: An array of Tx hashes that included the given asset (latest first) + description: Array of asset summary information content: application/json: schema: - $ref: "#/components/schemas/address_txs" + $ref: "#/components/schemas/asset_summary" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Transactions - description: Get the list of current or all asset transaction hashes (newest first) - operationId: asset_txs - /asset_address_list: #RPC + summary: Asset Summary + description: Get the summary of an asset (total transactions exclude minting/total wallets include only wallets with asset balance) + operationId: asset_summary + /asset_txs: #RPC get: tags: - Asset - deprecated: true parameters: - $ref: "#/components/parameters/_asset_policy" - $ref: "#/components/parameters/_asset_name" + - $ref: "#/components/parameters/_after_block_height" + - $ref: "#/components/parameters/_history" responses: "200": - description: Array of payment addresses holding the given token (including balances) [DEPRECATED - replaced by asset_addresses] - content: - application/json: - schema: - $ref: "#/components/schemas/asset_addresses" - "400": - $ref: "#/components/responses/BadRequest" - "401": - $ref: "#/components/responses/Unauthorized" - "404": - $ref: "#/components/responses/NotFound" - summary: Asset Address List - description: Get the list of all addresses holding a given asset [DEPRECATED - replaced by asset_addresses] - operationId: asset_address_list - /asset_policy_info: #RPC - get: - deprecated: true - tags: - - Asset - parameters: - - $ref: "#/components/parameters/_asset_policy" - responses: - "200": - description: Array of detailed information of assets under the same policy [DEPRECATED - replaced by policy_asset_info] + description: An array of Tx hashes that included the given asset (latest first) content: application/json: schema: - $ref: "#/components/schemas/policy_asset_info" + $ref: "#/components/schemas/address_txs" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Policy Information - description: Get the information for all assets under the same policy (DEPRECATED - replaced by policy_asset_info) - operationId: asset_policy_info - + summary: Asset Transactions + description: Get the list of current or all asset transaction hashes (newest first) + operationId: asset_txs /pool_list: #RPC get: tags: @@ -1468,7 +1459,7 @@ paths: tags: - Pool parameters: - - $ref: "#/components/parameters/_epoch_no" + - $ref: "#/components/parameters/_pool_epoch_no" responses: "200": description: Success!! @@ -1826,6 +1817,16 @@ components: in: query required: false allowEmptyValue: true + _pool_epoch_no: + deprecated: false + name: _epoch_no + description: Epoch Number to fetch details for + schema: + type: string + example: "12" + in: query + required: false + allowEmptyValue: true _script_hash: deprecated: false name: _script_hash @@ -2474,6 +2475,35 @@ components: type: string description: JSON encoded data with details about the parameter update example: {"decentralisation": 0.9} + cli_protocol_params: + description: Get Current Protocol Parameters from node as published by cardano-cli in JSON format + type: object + example: + { + "collateralPercentage": 150, + "maxBlockBodySize": 90112, + "maxBlockHeaderSize": 1100, + "maxCollateralInputs": 3, + "maxTxSize": 16384, + "maxValueSize": 5000, + "minPoolCost": 170000000, + "minUTxOValue": null, + "monetaryExpansion": 3.0e-3, + "poolPledgeInfluence": 0.3, + "poolRetireMaxEpoch": 18, + "protocolVersion": { + "major": 8, + "minor": 0 + }, + "...": "...", + "stakeAddressDeposit": 2000000, + "stakePoolDeposit": 500000000, + "stakePoolTargetNum": 500, + "treasuryCut": 0.2, + "txFeeFixed": 155381, + "txFeePerByte": 44, + "utxoCostPerByte": 4310 + } reserve_withdrawals: description: Array of withdrawals from reserves/treasury against stake accounts type: array @@ -2493,6 +2523,14 @@ components: $ref: "#/components/schemas/pool_delegators/items/properties/amount" stake_address: $ref: "#/components/schemas/account_history/items/properties/stake_address" + earned_epoch: + description: Epoch where amount is earned + allOf: + - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + spendable_epoch: + description: Epoch where the earned amount can be spent + allOf: + - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" pool_list: description: Array of pool IDs and tickers type: array @@ -3632,9 +3670,9 @@ components: type: object properties: earned_epoch: - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + $ref: "#/components/schemas/reserve_withdrawals/items/properties/earned_epoch" spendable_epoch: - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + $ref: "#/components/schemas/reserve_withdrawals/items/properties/spendable_epoch" amount: type: string description: Amount of rewards earned (in lovelace) @@ -3983,6 +4021,16 @@ components: - 'null' description: Plutus script address example: addr1w999n67e86jn6xal07pzxtrmqynspgx0fwmcmpua4wc6yzsxpljz3 + spends_input: + type: + - object + - 'null' + properties: + tx_hash: + $ref: "#/components/schemas/utxo_infos/items/properties/tx_hash" + tx_index: + $ref: "#/components/schemas/utxo_infos/items/properties/tx_index" + description: Input utxo this contract spends script_hash: $ref: "#/components/schemas/script_info/items/properties/script_hash" bytecode: @@ -4153,7 +4201,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" quantity: type: string description: Asset balance on the payment address @@ -4166,7 +4214,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" asset_summary: description: Array of asset summary information type: array @@ -4316,7 +4364,7 @@ components: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" quantity: $ref: "#/components/schemas/asset_addresses/items/properties/quantity" policy_asset_info: @@ -4344,6 +4392,31 @@ components: $ref: "#/components/schemas/asset_info/items/properties/minting_tx_metadata" token_registry_metadata: $ref: "#/components/schemas/asset_info/items/properties/token_registry_metadata" + policy_asset_mints: + description: Array of mint information for assets under requested policies + type: array + items: + properties: + asset_name: + $ref: "#/components/schemas/asset_info/items/properties/asset_name" + asset_name_ascii: + $ref: "#/components/schemas/asset_info/items/properties/asset_name_ascii" + fingerprint: + $ref: "#/components/schemas/asset_info/items/properties/fingerprint" + minting_tx_hash: + $ref: "#/components/schemas/asset_info/items/properties/minting_tx_hash" + total_supply: + $ref: "#/components/schemas/asset_info/items/properties/total_supply" + mint_cnt: + $ref: "#/components/schemas/asset_info/items/properties/mint_cnt" + burn_cnt: + $ref: "#/components/schemas/asset_info/items/properties/burn_cnt" + creation_time: + $ref: "#/components/schemas/asset_info/items/properties/creation_time" + minting_tx_metadata: + $ref: "#/components/schemas/asset_info/items/properties/minting_tx_metadata" + decimals: + $ref: "#/components/schemas/asset_info/items/properties/token_registry_metadata/properties/decimals" policy_asset_list: description: Array of brief information of assets under the same policy type: array diff --git a/specs/templates/1-api-info.yaml b/specs/templates/1-api-info.yaml index cee64f07..82c6ff09 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.1.1-dev + version: v1.1.1rc 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. @@ -22,24 +22,24 @@ info: ``` bash curl "https://api.koios.rest/api/v1/tip" - # [{"hash":"4d44c8a453e677f933c3df42ebcf2fe45987c41268b9cfc9b42ae305e8c3d99a","epoch":317,"abs_slot":51700871,"epoch_slot":120071,"block_height":6806994,"block_time":1643267162}] + # [{"hash":"4d44c8a453e677f933c3df42ebcf2fe45987c41268b9cfc9b42ae305e8c3d99a","epoch_no":317,"abs_slot":51700871,"epoch_slot":120071,"block_height":6806994,"block_time":1643267162}] - curl "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_height" + curl "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_height" - # [{"epoch":317,"epoch_slot":120071,"block_height":6806994}] + # [{"epoch_no":317,"epoch_slot":120071,"block_height":6806994}] ``` ## Horizontal Filtering You can filter the returned output based on specific conditions using operators against a column within returned result. Consider an example where you would want to query blocks minted in first 3 minutes of epoch 250 (i.e. epoch_slot was less than 180). To do so your query would look like below:

``` bash - curl "https://api.koios.rest/api/v1/blocks?epoch=eq.250&epoch_slot=lt.180" + curl "https://api.koios.rest/api/v1/blocks?epoch_no=eq.250&epoch_slot=lt.180" - # [{"hash":"8fad2808ac6b37064a0fa69f6fe065807703d5235a57442647bbcdba1c02faf8","epoch":250,"abs_slot":22636942,"epoch_slot":142,"block_height":5385757,"block_time":1614203233,"tx_count":65,"vrf_key":"vrf_vk14y9pjprzlsjvjt66mv5u7w7292sxp3kn4ewhss45ayjga5vurgaqhqknuu","pool":null,"op_cert_counter":2}, - # {"hash":"9d33b02badaedc0dedd0d59f3e0411e5fb4ac94217fb5ee86719e8463c570e16","epoch":250,"abs_slot":22636800,"epoch_slot":0,"block_height":5385756,"block_time":1614203091,"tx_count":10,"vrf_key":"vrf_vk1dkfsejw3h2k7tnguwrauqfwnxa7wj3nkp3yw2yw3400c4nlkluwqzwvka6","pool":null,"op_cert_counter":2}] + # [{"hash":"8fad2808ac6b37064a0fa69f6fe065807703d5235a57442647bbcdba1c02faf8","epoch_no":250,"abs_slot":22636942,"epoch_slot":142,"block_height":5385757,"block_time":1614203233,"tx_count":65,"vrf_key":"vrf_vk14y9pjprzlsjvjt66mv5u7w7292sxp3kn4ewhss45ayjga5vurgaqhqknuu","pool":null,"op_cert_counter":2}, + # {"hash":"9d33b02badaedc0dedd0d59f3e0411e5fb4ac94217fb5ee86719e8463c570e16","epoch_no":250,"abs_slot":22636800,"epoch_slot":0,"block_height":5385756,"block_time":1614203091,"tx_count":10,"vrf_key":"vrf_vk1dkfsejw3h2k7tnguwrauqfwnxa7wj3nkp3yw2yw3400c4nlkluwqzwvka6","pool":null,"op_cert_counter":2}] ``` - Here, we made use of `eq.` operator to denote a filter of "value equal to" against `epoch` column. Similarly, we added a filter using `lt.` operator to denote a filter of "values lower than" against `epoch_slot` column. You can find a complete list of operators supported in PostgREST documentation (commonly used ones extracted below): + Here, we made use of `eq.` operator to denote a filter of "value equal to" against `epoch_no` column. Similarly, we added a filter using `lt.` operator to denote a filter of "values lower than" against `epoch_slot` column. You can find a complete list of operators supported in PostgREST documentation (commonly used ones extracted below): |Abbreviation|In PostgreSQL|Meaning | |------------|-------------|-------------------------------------------| @@ -83,30 +83,22 @@ info: ``` - For GET endpoints, there is also another method to achieve the above, instead of adding parameters to the URL itself, you can specify a `Range` header as below to achieve something similar:

- - ``` bash - curl -s "https://api.koios.rest/api/v1/blocks?select=block_height" -H "Range: 1000-1499" -I | grep -i content-range - - # content-range: 1000-1499/* - - ``` - - The above methods for pagination are very useful to keep your queries light as well as process the output in smaller pages, making better use of your resources and respecting server timeouts for response times. + The above methods for pagination are very useful to keep some of the queries light as well as process the output in smaller pages, making better use of your resources and respecting server timeouts for response times. + However, note that due to the complex nature of some queries that require pre-processing before being subjected to paginations, these may not always be helpful to avoid server timeouts. ## Ordering You can set a sorting order for returned queries against specific column(s). - Consider example where you want to check `epoch` and `epoch_slot` for the first 5 blocks created by a particular pool, i.e. you can set order to ascending based on block_height column and add horizontal filter for that pool ID as below:

+ Consider example where you want to check `epoch_no` and `epoch_slot` for the first 5 blocks created by a particular pool, i.e. you can set order to ascending based on block_height column and add horizontal filter for that pool ID as below:

``` bash curl -s "https://api.koios.rest/api/v1/blocks?pool=eq.pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc&order=block_height.asc&limit=5" - # [{"hash":"610b4c7bbebeeb212bd002885048cc33154ba29f39919d62a3d96de05d315706","epoch":236,"abs_slot":16594295,"epoch_slot":5495,"block_height":5086774,"block_time":1608160586,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"d93d1db5275329ab695d30c06a35124038d8d9af64fc2b0aa082b8aa43da4164","epoch":236,"abs_slot":16597729,"epoch_slot":8929,"block_height":5086944,"block_time":1608164020,"tx_count":7,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"dc9496eae64294b46f07eb20499ae6dae4d81fdc67c63c354397db91bda1ee55","epoch":236,"abs_slot":16598058,"epoch_slot":9258,"block_height":5086962,"block_time":1608164349,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"6ebc7b734c513bc19290d96ca573a09cac9503c5a349dd9892b9ab43f917f9bd","epoch":236,"abs_slot":16601491,"epoch_slot":12691,"block_height":5087097,"block_time":1608167782,"tx_count":0,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, - # {"hash":"2eac97548829fc312858bc56a40f7ce3bf9b0ca27ee8530283ccebb3963de1c0","epoch":236,"abs_slot":16602308,"epoch_slot":13508,"block_height":5087136,"block_time":1608168599,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}] + # [{"hash":"610b4c7bbebeeb212bd002885048cc33154ba29f39919d62a3d96de05d315706","epoch_no":236,"abs_slot":16594295,"epoch_slot":5495,"block_height":5086774,"block_time":1608160586,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"d93d1db5275329ab695d30c06a35124038d8d9af64fc2b0aa082b8aa43da4164","epoch_no":236,"abs_slot":16597729,"epoch_slot":8929,"block_height":5086944,"block_time":1608164020,"tx_count":7,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"dc9496eae64294b46f07eb20499ae6dae4d81fdc67c63c354397db91bda1ee55","epoch_no":236,"abs_slot":16598058,"epoch_slot":9258,"block_height":5086962,"block_time":1608164349,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"6ebc7b734c513bc19290d96ca573a09cac9503c5a349dd9892b9ab43f917f9bd","epoch_no":236,"abs_slot":16601491,"epoch_slot":12691,"block_height":5087097,"block_time":1608167782,"tx_count":0,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}, + # {"hash":"2eac97548829fc312858bc56a40f7ce3bf9b0ca27ee8530283ccebb3963de1c0","epoch_no":236,"abs_slot":16602308,"epoch_slot":13508,"block_height":5087136,"block_time":1608168599,"tx_count":1,"vrf_key":"vrf_vk18x0e7dx8j37gdxftnn8ru6jcxs7n6acdazc4ykeda2ygjwg9a7ls7ns699","pool":"pool155efqn9xpcf73pphkk88cmlkdwx4ulkg606tne970qswczg3asc","op_cert_counter":1}] ``` ## Response Formats @@ -115,15 +107,15 @@ info: Below is an example of JSON/CSV output making use of above to print first in JSON (default), and then override response format to CSV.

``` bash - curl -s "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_time&limit=3" + curl -s "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_time&limit=3" - # [{"epoch":318,"epoch_slot":27867,"block_time":1643606958}, - # {"epoch":318,"epoch_slot":27841,"block_time":1643606932}, - # {"epoch":318,"epoch_slot":27839,"block_time":1643606930}] + # [{"epoch_no":318,"epoch_slot":27867,"block_time":1643606958}, + # {"epoch_no":318,"epoch_slot":27841,"block_time":1643606932}, + # {"epoch_no":318,"epoch_slot":27839,"block_time":1643606930}] - curl -s "https://api.koios.rest/api/v1/blocks?select=epoch,epoch_slot,block_time&limit=3" -H "Accept: text/csv" + curl -s "https://api.koios.rest/api/v1/blocks?select=epoch_no,epoch_slot,block_time&limit=3" -H "Accept: text/csv" - # epoch,epoch_slot,block_time + # epoch_no,epoch_slot,block_time # 318,28491,1643607582 # 318,28479,1643607570 # 318,28406,1643607497 diff --git a/specs/templates/2-api-params.yaml b/specs/templates/2-api-params.yaml index f34ba37a..7fb1ec23 100644 --- a/specs/templates/2-api-params.yaml +++ b/specs/templates/2-api-params.yaml @@ -119,6 +119,16 @@ parameters: in: query required: false allowEmptyValue: true + _pool_epoch_no: + deprecated: false + name: _epoch_no + description: Epoch Number to fetch details for + schema: + type: string + example: "##_pool_epoch_no_param##" + in: query + required: false + allowEmptyValue: true _script_hash: deprecated: false name: _script_hash diff --git a/specs/templates/4-api-schemas.yaml b/specs/templates/4-api-schemas.yaml index b4f6e6c0..5efd7665 100644 --- a/specs/templates/4-api-schemas.yaml +++ b/specs/templates/4-api-schemas.yaml @@ -115,6 +115,35 @@ schemas: type: string description: JSON encoded data with details about the parameter update example: {"decentralisation": 0.9} + cli_protocol_params: + description: Get Current Protocol Parameters from node as published by cardano-cli in JSON format + type: object + example: + { + "collateralPercentage": 150, + "maxBlockBodySize": 90112, + "maxBlockHeaderSize": 1100, + "maxCollateralInputs": 3, + "maxTxSize": 16384, + "maxValueSize": 5000, + "minPoolCost": 170000000, + "minUTxOValue": null, + "monetaryExpansion": 3.0e-3, + "poolPledgeInfluence": 0.3, + "poolRetireMaxEpoch": 18, + "protocolVersion": { + "major": 8, + "minor": 0 + }, + "...": "...", + "stakeAddressDeposit": 2000000, + "stakePoolDeposit": 500000000, + "stakePoolTargetNum": 500, + "treasuryCut": 0.2, + "txFeeFixed": 155381, + "txFeePerByte": 44, + "utxoCostPerByte": 4310 + } reserve_withdrawals: description: Array of withdrawals from reserves/treasury against stake accounts type: array @@ -134,6 +163,14 @@ schemas: $ref: "#/components/schemas/pool_delegators/items/properties/amount" stake_address: $ref: "#/components/schemas/account_history/items/properties/stake_address" + earned_epoch: + description: Epoch where amount is earned + allOf: + - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + spendable_epoch: + description: Epoch where the earned amount can be spent + allOf: + - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" pool_list: description: Array of pool IDs and tickers type: array @@ -1273,9 +1310,9 @@ schemas: type: object properties: earned_epoch: - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + $ref: "#/components/schemas/reserve_withdrawals/items/properties/earned_epoch" spendable_epoch: - $ref: "#/components/schemas/epoch_info/items/properties/epoch_no" + $ref: "#/components/schemas/reserve_withdrawals/items/properties/spendable_epoch" amount: type: string description: Amount of rewards earned (in lovelace) @@ -1624,6 +1661,16 @@ schemas: - 'null' description: Plutus script address example: addr1w999n67e86jn6xal07pzxtrmqynspgx0fwmcmpua4wc6yzsxpljz3 + spends_input: + type: + - object + - 'null' + properties: + tx_hash: + $ref: "#/components/schemas/utxo_infos/items/properties/tx_hash" + tx_index: + $ref: "#/components/schemas/utxo_infos/items/properties/tx_index" + description: Input utxo this contract spends script_hash: $ref: "#/components/schemas/script_info/items/properties/script_hash" bytecode: @@ -1794,7 +1841,7 @@ schemas: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" quantity: type: string description: Asset balance on the payment address @@ -1807,7 +1854,7 @@ schemas: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" asset_summary: description: Array of asset summary information type: array @@ -1957,7 +2004,7 @@ schemas: payment_address: $ref: "#/components/schemas/utxo_infos/items/properties/address" stake_address: - $ref: "#/components/schemas/account_history/items/properties/stake_address" + $ref: "#/components/schemas/address_info/items/properties/stake_address" quantity: $ref: "#/components/schemas/asset_addresses/items/properties/quantity" policy_asset_info: @@ -1985,6 +2032,31 @@ schemas: $ref: "#/components/schemas/asset_info/items/properties/minting_tx_metadata" token_registry_metadata: $ref: "#/components/schemas/asset_info/items/properties/token_registry_metadata" + policy_asset_mints: + description: Array of mint information for assets under requested policies + type: array + items: + properties: + asset_name: + $ref: "#/components/schemas/asset_info/items/properties/asset_name" + asset_name_ascii: + $ref: "#/components/schemas/asset_info/items/properties/asset_name_ascii" + fingerprint: + $ref: "#/components/schemas/asset_info/items/properties/fingerprint" + minting_tx_hash: + $ref: "#/components/schemas/asset_info/items/properties/minting_tx_hash" + total_supply: + $ref: "#/components/schemas/asset_info/items/properties/total_supply" + mint_cnt: + $ref: "#/components/schemas/asset_info/items/properties/mint_cnt" + burn_cnt: + $ref: "#/components/schemas/asset_info/items/properties/burn_cnt" + creation_time: + $ref: "#/components/schemas/asset_info/items/properties/creation_time" + minting_tx_metadata: + $ref: "#/components/schemas/asset_info/items/properties/minting_tx_metadata" + decimals: + $ref: "#/components/schemas/asset_info/items/properties/token_registry_metadata/properties/decimals" policy_asset_list: description: Array of brief information of assets under the same policy type: array diff --git a/specs/templates/api-main.yaml b/specs/templates/api-main.yaml index a99c95cd..59101003 100644 --- a/specs/templates/api-main.yaml +++ b/specs/templates/api-main.yaml @@ -91,6 +91,31 @@ paths: summary: Param Update Proposals description: Get all parameter update proposals submitted to the chain starting Shelley era operationId: param_updates + /cli_protocol_params: #RPC + get: + tags: + - Network + responses: + "200": + description: Success!! + content: + application/json: + schema: + $ref: "#/components/schemas/cli_protocol_params" + "400": + $ref: "#/components/responses/BadRequest" + "401": + $ref: "#/components/responses/Unauthorized" + "404": + $ref: "#/components/responses/NotFound" + summary: CLI Protocol Parameters + description: >- + Get Current Protocol Parameters as published by cardano-cli. Note that + the output schema of this command is unfortunately fluid on cardano-node + and may vary between CLI versions/era. Accordingly, the returned output for + this endpoint is left as raw JSON (single row) and any filtering to output should + be done on client-side + operationId: cli_protocol_params /reserve_withdrawals: #RPC get: tags: @@ -1034,102 +1059,76 @@ paths: summary: Policy Asset Information description: Get the information for all assets under the same policy operationId: policy_asset_info - /asset_summary: #RPC + /policy_asset_mints: #RPC get: tags: - Asset parameters: - $ref: "#/components/parameters/_asset_policy" - - $ref: "#/components/parameters/_asset_name" responses: "200": - description: Array of asset summary information + description: Get a list of mint or burn count details for all assets minted under a policy content: application/json: schema: - $ref: "#/components/schemas/asset_summary" + $ref: "#/components/schemas/policy_asset_mints" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Summary - description: Get the summary of an asset (total transactions exclude minting/total wallets include only wallets with asset balance) - operationId: asset_summary - /asset_txs: #RPC + summary: Policy Asset Mints + description: Get a list of mint or burn count details for all assets minted under a policy + operationId: policy_asset_mints + /asset_summary: #RPC get: tags: - Asset parameters: - $ref: "#/components/parameters/_asset_policy" - $ref: "#/components/parameters/_asset_name" - - $ref: "#/components/parameters/_after_block_height" - - $ref: "#/components/parameters/_history" responses: "200": - description: An array of Tx hashes that included the given asset (latest first) + description: Array of asset summary information content: application/json: schema: - $ref: "#/components/schemas/address_txs" + $ref: "#/components/schemas/asset_summary" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Transactions - description: Get the list of current or all asset transaction hashes (newest first) - operationId: asset_txs - /asset_address_list: #RPC + summary: Asset Summary + description: Get the summary of an asset (total transactions exclude minting/total wallets include only wallets with asset balance) + operationId: asset_summary + /asset_txs: #RPC get: tags: - Asset - deprecated: true parameters: - $ref: "#/components/parameters/_asset_policy" - $ref: "#/components/parameters/_asset_name" + - $ref: "#/components/parameters/_after_block_height" + - $ref: "#/components/parameters/_history" responses: "200": - description: Array of payment addresses holding the given token (including balances) [DEPRECATED - replaced by asset_addresses] - content: - application/json: - schema: - $ref: "#/components/schemas/asset_addresses" - "400": - $ref: "#/components/responses/BadRequest" - "401": - $ref: "#/components/responses/Unauthorized" - "404": - $ref: "#/components/responses/NotFound" - summary: Asset Address List - description: Get the list of all addresses holding a given asset [DEPRECATED - replaced by asset_addresses] - operationId: asset_address_list - /asset_policy_info: #RPC - get: - deprecated: true - tags: - - Asset - parameters: - - $ref: "#/components/parameters/_asset_policy" - responses: - "200": - description: Array of detailed information of assets under the same policy [DEPRECATED - replaced by policy_asset_info] + description: An array of Tx hashes that included the given asset (latest first) content: application/json: schema: - $ref: "#/components/schemas/policy_asset_info" + $ref: "#/components/schemas/address_txs" "400": $ref: "#/components/responses/BadRequest" "401": $ref: "#/components/responses/Unauthorized" "404": $ref: "#/components/responses/NotFound" - summary: Asset Policy Information - description: Get the information for all assets under the same policy (DEPRECATED - replaced by policy_asset_info) - operationId: asset_policy_info - + summary: Asset Transactions + description: Get the list of current or all asset transaction hashes (newest first) + operationId: asset_txs /pool_list: #RPC get: tags: @@ -1316,7 +1315,7 @@ paths: tags: - Pool parameters: - - $ref: "#/components/parameters/_epoch_no" + - $ref: "#/components/parameters/_pool_epoch_no" responses: "200": description: Success!! diff --git a/specs/templates/example-map.json b/specs/templates/example-map.json index 1d63245c..64a2e904 100644 --- a/specs/templates/example-map.json +++ b/specs/templates/example-map.json @@ -78,11 +78,17 @@ "pv": "pool1leml52hm4fcp3hhe4zye08qz27llhj7d339p3gs0tl85cstx59q", "pp": "pool1x4p3cwemsm356vpxnjwuud7w76jz64hyss729zp7xa6wuey6yr9" }, + "_pool_epoch_no": { + "m": "320", + "g": "18852", + "pv": "12", + "pp": "31" + }, "_script_hash": { "m": "d8480dc869b94b80e81ec91b0abe307279311fe0e7001a9488f61ff8", "g": "1392eec7d575292ae1523da65ff1b4b021886e917c8c43de54aa7cbd", "pv": "f758cf422ca0cbed7d9d6fad1eb5a3c70537d62e661ad450dd2a3810", - "pp": "590555d7b5760e98ae2bdd29b356247776251dfab0a207bfce98a485" + "pp": "14abafb323de75b7266fd0eab29b6ef562305e8a0dfbb64b07ef32c7" } }, "requestBodies": { diff --git a/specs/wiretap/wiretap-report.json b/specs/wiretap/wiretap-report.json new file mode 100644 index 00000000..0637a088 --- /dev/null +++ b/specs/wiretap/wiretap-report.json @@ -0,0 +1 @@ +[] \ No newline at end of file