diff --git a/files/grest/rpc/00_blockchain/param_updates.sql b/files/grest/rpc/00_blockchain/param_updates.sql new file mode 100644 index 00000000..cf6f5595 --- /dev/null +++ b/files/grest/rpc/00_blockchain/param_updates.sql @@ -0,0 +1,59 @@ +CREATE OR REPLACE FUNCTION grest.param_updates () + RETURNS TABLE ( + tx_hash text, + block_height word31type, + block_time integer, + epoch_no word31type, + data jsonb + ) + LANGUAGE PLPGSQL + AS $$ + +BEGIN + RETURN QUERY + SELECT DISTINCT ON (pp.registered_tx_id) + ENCODE(t.hash,'hex') as tx_hash, + b.block_no AS block_height, + EXTRACT(epoch from b.time)::integer as block_time, + b.epoch_no, + JSONB_STRIP_NULLS(JSONB_BUILD_OBJECT( + 'min_fee_a', pp.min_fee_a, + 'min_fee_b', pp.min_fee_b, + 'max_block_size', pp.max_block_size, + 'max_tx_size', pp.max_tx_size, + 'max_bh_size', pp.max_bh_size, + 'key_deposit', pp.key_deposit, + 'pool_deposit', pp.pool_deposit, + 'max_epoch', pp.max_epoch, + 'optimal_pool_count', pp.optimal_pool_count, + 'influence', pp.influence, + 'monetary_expand_rate', pp.monetary_expand_rate, + 'treasury_growth_rate', pp.treasury_growth_rate, + 'decentralisation', pp.decentralisation, + 'entropy', pp.entropy, + 'protocol_major', pp.protocol_major, + 'protocol_minor', pp.protocol_minor, + 'min_utxo_value', pp.min_utxo_value, + 'min_pool_cost', pp.min_pool_cost, + 'cost_model', CM.costs, + 'price_mem', pp.price_mem, + 'price_step', pp.price_step, + 'max_tx_ex_mem', pp.max_tx_ex_mem, + 'max_tx_ex_steps', pp.max_tx_ex_steps, + 'max_block_ex_mem', pp.max_block_ex_mem, + 'max_block_ex_steps', pp.max_block_ex_steps, + 'max_val_size', pp.max_val_size, + 'collateral_percent', pp.collateral_percent, + 'max_collateral_inputs', pp.max_collateral_inputs, + 'coins_per_utxo_size', pp.coins_per_utxo_size + )) AS data + FROM + public.param_proposal pp + INNER JOIN tx t ON t.id = pp.registered_tx_id + INNER JOIN block b ON t.block_id = b.id + LEFT JOIN cost_model CM ON CM.id = pp.cost_model_id + ; +END; +$$; + +COMMENT ON FUNCTION grest.param_updates IS 'Parameter updates applied to the network'; diff --git a/files/grest/rpc/01_cached_tables/asset_registry_cache.sql b/files/grest/rpc/01_cached_tables/asset_registry_cache.sql index e54d23d4..407563f2 100644 --- a/files/grest/rpc/01_cached_tables/asset_registry_cache.sql +++ b/files/grest/rpc/01_cached_tables/asset_registry_cache.sql @@ -1,4 +1,4 @@ -DROP TABLE IF EXISTS grest.asset_registry_cache; +DROP TABLE IF EXISTS grest.asset_registry_cache CASCADE; CREATE TABLE grest.asset_registry_cache ( asset_policy text NOT NULL, @@ -56,4 +56,4 @@ BEGIN logo = _logo, decimals = _decimals; END; -$$; \ No newline at end of file +$$; diff --git a/files/grest/rpc/02_indexes/13_1_00.sql b/files/grest/rpc/02_indexes/13_1_00.sql new file mode 100644 index 00000000..4c18b47b --- /dev/null +++ b/files/grest/rpc/02_indexes/13_1_00.sql @@ -0,0 +1,26 @@ +/* Unique Indexes that got dropped at 13.1.0.0 */ +CREATE UNIQUE INDEX IF NOT EXISTS unique_ada_pots ON public.ada_pots USING btree (block_id); +CREATE UNIQUE INDEX IF NOT EXISTS unique_col_txin ON public.collateral_tx_in USING btree (tx_in_id, tx_out_id, tx_out_index); +CREATE UNIQUE INDEX IF NOT EXISTS unique_col_txout ON public.collateral_tx_out USING btree (tx_id, index); +CREATE UNIQUE INDEX IF NOT EXISTS unique_delegation ON public.delegation USING btree (tx_id, cert_index); +CREATE UNIQUE INDEX IF NOT EXISTS unique_epoch_param ON public.epoch_param USING btree (epoch_no, block_id); +CREATE UNIQUE INDEX IF NOT EXISTS unique_ma_tx_mint ON public.ma_tx_mint USING btree (ident, tx_id); +CREATE UNIQUE INDEX IF NOT EXISTS unique_ma_tx_out ON public.ma_tx_out USING btree (ident, tx_out_id); +CREATE UNIQUE INDEX IF NOT EXISTS unique_param_proposal ON public.param_proposal USING btree (key, registered_tx_id); +CREATE UNIQUE INDEX IF NOT EXISTS unique_pool_owner ON public.pool_owner USING btree (addr_id, pool_update_id); +CREATE UNIQUE INDEX IF NOT EXISTS unique_pool_relay ON public.pool_relay USING btree (update_id, ipv4, ipv6, dns_name); +CREATE UNIQUE INDEX IF NOT EXISTS unique_pool_retiring ON public.pool_retire USING btree (announced_tx_id, cert_index); +CREATE UNIQUE INDEX IF NOT EXISTS unique_pool_update ON public.pool_update USING btree (registered_tx_id, cert_index); +CREATE UNIQUE INDEX IF NOT EXISTS unique_pot_transfer ON public.pot_transfer USING btree (tx_id, cert_index); +CREATE UNIQUE INDEX IF NOT EXISTS unique_redeemer ON public.redeemer USING btree (tx_id, purpose, index); +CREATE UNIQUE INDEX IF NOT EXISTS unique_ref_tx_in ON reference_tx_in USING btree (tx_in_id, tx_out_id, tx_out_index); +CREATE UNIQUE INDEX IF NOT EXISTS unique_reserves ON public.reserve USING btree (addr_id, tx_id, cert_index); +CREATE UNIQUE INDEX IF NOT EXISTS unique_stake_deregistration ON public.stake_deregistration USING btree (tx_id, cert_index); +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); + +/* Help multi asset queries */ +CREATE INDEX IF NOT EXISTS idx_ma_tx_out_ident ON ma_tx_out (ident) ; diff --git a/files/grest/rpc/account/account_addresses.sql b/files/grest/rpc/account/account_addresses.sql index b46e04ce..7170fd54 100644 --- a/files/grest/rpc/account/account_addresses.sql +++ b/files/grest/rpc/account/account_addresses.sql @@ -33,7 +33,7 @@ BEGIN AND txo.index::smallint = tx_in.tx_out_index::smallint WHERE txo.stake_address_id = ANY(sa_id_list) - AND tx_in.id IS NULL + AND TX_IN.TX_OUT_ID IS NULL ) x ) SELECT diff --git a/files/grest/rpc/account/account_assets.sql b/files/grest/rpc/account/account_assets.sql index 743468bd..e3098c91 100644 --- a/files/grest/rpc/account/account_assets.sql +++ b/files/grest/rpc/account/account_assets.sql @@ -1,4 +1,4 @@ -CREATE FUNCTION grest.account_assets (_stake_addresses text[]) +CREATE OR REPLACE FUNCTION grest.account_assets (_stake_addresses text[]) RETURNS TABLE ( stake_address varchar, asset_list json @@ -34,9 +34,9 @@ BEGIN AND TXO.INDEX::smallint = TX_IN.TX_OUT_INDEX::smallint WHERE sa.id = ANY(sa_id_list) - AND TX_IN.ID IS NULL + AND TX_IN.TX_OUT_ID IS NULL GROUP BY - sa.view, MA.policy, MA.name, MA.fingerprint + sa.view, MA.policy, MA.name, MA.fingerprint, aic.decimals ) SELECT diff --git a/files/grest/rpc/account/account_info.sql b/files/grest/rpc/account/account_info.sql index b74512bf..cde440cf 100644 --- a/files/grest/rpc/account/account_info.sql +++ b/files/grest/rpc/account/account_info.sql @@ -119,7 +119,7 @@ BEGIN AND TX_OUT.INDEX::smallint = TX_IN.TX_OUT_INDEX::smallint WHERE TX_OUT.STAKE_ADDRESS_ID = ANY(sa_id_list) - AND TX_IN.ID IS NULL + AND TX_IN.TX_OUT_ID IS NULL GROUP BY tx_out.stake_address_id ) UTXO_T ON UTXO_T.stake_address_id = status_t.id diff --git a/files/grest/rpc/account/account_utxos.sql b/files/grest/rpc/account/account_utxos.sql new file mode 100644 index 00000000..5c0a0027 --- /dev/null +++ b/files/grest/rpc/account/account_utxos.sql @@ -0,0 +1,36 @@ +CREATE OR REPLACE FUNCTION grest.account_utxos (_stake_address text) + RETURNS TABLE ( + tx_hash text, + tx_index smallint, + address varchar, + value text, + block_height word31type, + block_time integer + ) + LANGUAGE PLPGSQL + AS $$ + +BEGIN + RETURN QUERY + SELECT + ENCODE(tx.hash,'hex') as tx_hash, + tx_out.index::smallint as tx_index, + tx_out.address, + tx_out.value::text as value, + b.block_no as block_height, + EXTRACT(epoch from b.time)::integer as block_time + FROM + tx_out + LEFT JOIN tx_in ON tx_in.tx_out_id = tx_out.tx_id + AND tx_in.tx_out_index = tx_out.index + INNER JOIN tx ON tx.id = tx_out.tx_id + LEFT JOIN block b ON b.id = tx.block_id + WHERE + tx_in.tx_out_id IS NULL + AND + tx_out.stake_address_id = (select id from stake_address where view = _stake_address); + +END; +$$; + +COMMENT ON FUNCTION grest.account_utxos IS 'Get non-empty UTxOs associated with a given stake address'; diff --git a/files/grest/rpc/address/address_assets.sql b/files/grest/rpc/address/address_assets.sql index 9504d5bb..2e27c9e7 100644 --- a/files/grest/rpc/address/address_assets.sql +++ b/files/grest/rpc/address/address_assets.sql @@ -25,9 +25,9 @@ BEGIN AND TXO.INDEX::smallint = TX_IN.TX_OUT_INDEX::smallint WHERE TXO.address = ANY(_addresses) - AND TX_IN.id IS NULL + AND TX_IN.tx_out_id IS NULL GROUP BY - TXO.address, MA.policy, MA.name, ma.fingerprint + TXO.address, MA.policy, MA.name, ma.fingerprint, aic.decimals ) SELECT diff --git a/files/grest/rpc/address/address_info.sql b/files/grest/rpc/address/address_info.sql index 3f0e43c4..b883d61e 100644 --- a/files/grest/rpc/address/address_info.sql +++ b/files/grest/rpc/address/address_info.sql @@ -43,7 +43,7 @@ BEGIN AND tx_in.tx_out_index = tx_out.index INNER JOIN tx ON tx.id = tx_out.tx_id WHERE - tx_in.id IS NULL + tx_in.tx_out_id IS NULL AND tx_out.address = ANY(_addresses) ) diff --git a/files/grest/rpc/address/credential_utxos.sql b/files/grest/rpc/address/credential_utxos.sql index 16548ac9..c4f13cb9 100644 --- a/files/grest/rpc/address/credential_utxos.sql +++ b/files/grest/rpc/address/credential_utxos.sql @@ -30,6 +30,6 @@ BEGIN WHERE payment_cred = any(_payment_cred_bytea) AND - tx_in.id IS NULL; + tx_in.tx_out_id IS NULL; END; $$; diff --git a/files/grest/rpc/assets/asset_addresses.sql b/files/grest/rpc/assets/asset_addresses.sql index 74af6fe6..f303abc1 100644 --- a/files/grest/rpc/assets/asset_addresses.sql +++ b/files/grest/rpc/assets/asset_addresses.sql @@ -48,7 +48,7 @@ BEGIN AND txo.index::smallint = tx_in.tx_out_index::smallint WHERE mto.ident = _asset_id - AND tx_in.id IS NULL + AND tx_in.tx_out_id IS NULL ) x GROUP BY x.address; diff --git a/files/grest/rpc/assets/asset_info.sql b/files/grest/rpc/assets/asset_info.sql index b3636ef2..37189072 100644 --- a/files/grest/rpc/assets/asset_info.sql +++ b/files/grest/rpc/assets/asset_info.sql @@ -14,13 +14,63 @@ CREATE OR REPLACE FUNCTION grest.asset_info (_asset_policy text, _asset_name tex ) LANGUAGE PLPGSQL AS $$ +DECLARE + _asset_id_list bigint[]; BEGIN - + + -- find all asset id's based on nested array input + SELECT INTO _asset_id_list ARRAY_AGG(id) + FROM ( + SELECT DISTINCT mu.id + FROM + multi_asset mu + WHERE + mu.policy = DECODE(_asset_policy, 'hex') AND mu.name = DECODE(_asset_name, 'hex') + ) AS tmp; + RETURN QUERY - SELECT grest.asset_info_bulk(array[array[_asset_policy, _asset_name]]); - + + SELECT + ENCODE(ma.policy, 'hex'), + ENCODE(ma.name, 'hex'), + ENCODE(ma.name, 'escape'), + ma.fingerprint, + ENCODE(tx.hash, 'hex'), + aic.total_supply::text, + aic.mint_cnt, + aic.burn_cnt, + EXTRACT(epoch from aic.creation_time)::integer, + metadata.minting_tx_metadata, + CASE WHEN arc.name IS NULL THEN NULL + ELSE + JSON_BUILD_OBJECT( + 'name', arc.name, + 'description', arc.description, + 'ticker', arc.ticker, + 'url', arc.url, + 'logo', arc.logo, + 'decimals', arc.decimals + ) + END + FROM + multi_asset ma + INNER JOIN grest.asset_info_cache aic ON aic.asset_id = ma.id + INNER JOIN tx ON tx.id = aic.last_mint_tx_id + LEFT JOIN grest.asset_registry_cache arc ON arc.asset_policy = ENCODE(ma.policy,'hex') AND arc.asset_name = ENCODE(ma.name,'hex') + LEFT JOIN LATERAL ( + SELECT + JSONB_OBJECT_AGG( + key::text, + json + ) AS minting_tx_metadata + FROM + tx_metadata tm + WHERE + tm.tx_id = tx.id + ) metadata ON TRUE + WHERE + ma.id = any (_asset_id_list); + END; $$; -COMMENT ON FUNCTION grest.asset_info IS 'Get the information of an asset incl first minting & token registry metadata'; - diff --git a/files/grest/rpc/assets/asset_info_bulk.sql b/files/grest/rpc/assets/asset_info_bulk.sql index 1f6d7424..843386ee 100644 --- a/files/grest/rpc/assets/asset_info_bulk.sql +++ b/files/grest/rpc/assets/asset_info_bulk.sql @@ -60,7 +60,7 @@ BEGIN multi_asset ma INNER JOIN grest.asset_info_cache aic ON aic.asset_id = ma.id INNER JOIN tx ON tx.id = aic.last_mint_tx_id - LEFT JOIN grest.asset_registry_cache arc ON DECODE(arc.asset_policy, 'hex') = ma.policy AND DECODE(arc.asset_name, 'hex') = ma.name + LEFT JOIN grest.asset_registry_cache arc ON arc.asset_policy = ENCODE(ma.policy,'hex') AND arc.asset_name = ENCODE(ma.name,'hex') LEFT JOIN LATERAL ( SELECT JSONB_OBJECT_AGG( diff --git a/files/grest/rpc/assets/policy_asset_addresses.sql b/files/grest/rpc/assets/policy_asset_addresses.sql index d0740cab..a0914493 100644 --- a/files/grest/rpc/assets/policy_asset_addresses.sql +++ b/files/grest/rpc/assets/policy_asset_addresses.sql @@ -38,7 +38,7 @@ BEGIN LEFT JOIN tx_in ON txo.tx_id = tx_in.tx_out_id AND txo.index::smallint = tx_in.tx_out_index::smallint WHERE - tx_in.id IS NULL + tx_in.tx_out_id IS NULL ) x GROUP BY x.asset_name, x.address; diff --git a/files/grest/rpc/assets/policy_asset_info.sql b/files/grest/rpc/assets/policy_asset_info.sql index 8c4e6f2c..d479576c 100644 --- a/files/grest/rpc/assets/policy_asset_info.sql +++ b/files/grest/rpc/assets/policy_asset_info.sql @@ -66,7 +66,7 @@ BEGIN multi_asset ma INNER JOIN grest.asset_info_cache aic ON aic.asset_id = ma.id INNER JOIN tx ON tx.id = aic.last_mint_tx_id - LEFT JOIN grest.asset_registry_cache arc ON DECODE(arc.asset_policy, 'hex') = ma.policy AND DECODE(arc.asset_name, 'hex') = ma.name + LEFT JOIN grest.asset_registry_cache arc ON arc.asset_policy = ENCODE(ma.policy,'hex') AND arc.asset_name = ENCODE(ma.name, 'hex') LEFT JOIN LATERAL ( SELECT JSONB_OBJECT_AGG( diff --git a/files/grest/rpc/transactions/tx_info.sql b/files/grest/rpc/transactions/tx_info.sql index 4a42e0b1..8328b7f4 100644 --- a/files/grest/rpc/transactions/tx_info.sql +++ b/files/grest/rpc/transactions/tx_info.sql @@ -644,52 +644,75 @@ BEGIN tx_id, JSONB_AGG(data) AS list FROM ( + WITH + all_redeemers AS ( + SELECT + redeemer.id, + redeemer.tx_id, + redeemer.purpose, + redeemer.fee, + redeemer.unit_steps, + redeemer.unit_mem, + rd.hash as rd_hash, + rd.value as rd_value, + script.hash as script_hash, + script.bytes as script_bytes, + script.serialised_size as script_serialised_size, + tx.valid_contract + FROM redeemer + INNER JOIN tx ON redeemer.tx_id = tx.id + INNER JOIN redeemer_data RD ON RD.id = redeemer.redeemer_data_id + INNER JOIN script ON redeemer.script_hash = script.hash + WHERE redeemer.tx_id = ANY (_tx_id_list) + ), + spend_redeemers AS ( + SELECT + DISTINCT ON(redeemer.id) redeemer.id, + INUTXO.address, + 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 INUTXO ON INUTXO.tx_id = tx_in.tx_out_id AND INUTXO.index = tx_in.tx_out_index + INNER JOIN datum IND ON IND.hash = INUTXO.data_hash + WHERE redeemer.tx_id = ANY (_tx_id_list) + ) SELECT - redeemer.tx_id, + ar.tx_id, JSONB_BUILD_OBJECT( - 'address', INUTXO.address, - 'script_hash', ENCODE(script.hash, 'hex'), - 'bytecode', ENCODE(script.bytes, 'hex'), - 'size', script.serialised_size, - 'valid_contract', tx.valid_contract, + 'address', + CASE + WHEN ar.purpose = 'spend' THEN + (SELECT address FROM spend_redeemers sr WHERE sr.id = ar.id) + ELSE NULL + END, + 'script_hash', ENCODE(ar.script_hash, 'hex'), + 'bytecode', ENCODE(ar.script_bytes, 'hex'), + 'size', ar.script_serialised_size, + 'valid_contract', ar.valid_contract, 'input', JSONB_BUILD_OBJECT( 'redeemer', JSONB_BUILD_OBJECT( - 'purpose', redeemer.purpose, - 'fee', redeemer.fee::text, + 'purpose', ar.purpose, + 'fee', ar.fee::text, 'unit', JSONB_BUILD_OBJECT( - 'steps', redeemer.unit_steps::text, - 'mem', redeemer.unit_mem::text + 'steps', ar.unit_steps::text, + 'mem', ar.unit_mem::text ), 'datum', JSONB_BUILD_OBJECT( - 'hash', ENCODE(rd.hash, 'hex'), - 'value', rd.value + 'hash', ENCODE(ar.rd_hash, 'hex'), + 'value', ar.rd_value ) ), - 'datum', JSONB_BUILD_OBJECT( - 'hash', ENCODE(ind.hash, 'hex'), - 'value', ind.value - ) - ), - 'output', CASE WHEN outd.hash IS NULL THEN NULL - ELSE - JSONB_BUILD_OBJECT( - 'hash', ENCODE(outd.hash, 'hex'), - 'value', outd.value - ) - END + 'datum', CASE WHEN ar.purpose = 'spend' THEN ( + SELECT JSONB_BUILD_OBJECT( + 'hash', ENCODE(sr.ind_hash, 'hex'), + 'value', sr.ind_value + ) FROM spend_redeemers sr WHERE sr.id = ar.id + ) ELSE NULL END + ) ) AS data FROM - redeemer - INNER JOIN tx ON redeemer.tx_id = tx.id - INNER JOIN redeemer_data RD ON RD.id = redeemer.redeemer_data_id - INNER JOIN script ON redeemer.script_hash = script.hash - INNER JOIN tx_in ON tx_in.redeemer_id = redeemer.id - INNER JOIN tx_out INUTXO ON INUTXO.tx_id = tx_in.tx_out_id AND INUTXO.index = tx_in.tx_out_index - INNER JOIN datum IND ON IND.hash = INUTXO.data_hash - LEFT JOIN tx_out OUTUTXO ON OUTUTXO.tx_id = redeemer.tx_id AND OUTUTXO.address = INUTXO.address - LEFT JOIN datum OUTD ON OUTD.hash = OUTUTXO.data_hash - WHERE - redeemer.tx_id = ANY (_tx_id_list) + all_redeemers ar ) AS tmp GROUP BY tx_id diff --git a/files/grest/rpc/views/asset_token_registry.sql b/files/grest/rpc/views/asset_token_registry.sql index 70b01d89..c376deed 100644 --- a/files/grest/rpc/views/asset_token_registry.sql +++ b/files/grest/rpc/views/asset_token_registry.sql @@ -1,3 +1,5 @@ +DROP VIEW IF EXISTS grest.asset_token_registry; + CREATE VIEW grest.asset_token_registry AS SELECT asset_policy AS policy_id, diff --git a/html/index.html b/html/index.html index 5aa2898c..fcdb96f3 100644 --- a/html/index.html +++ b/html/index.html @@ -5,7 +5,7 @@