From b5c226ab60f83e944be4c6c12c0ebcb5c2d656cb Mon Sep 17 00:00:00 2001 From: hodlonaut Date: Tue, 3 Dec 2024 10:36:21 +1100 Subject: [PATCH] Performance improvement rejiggling of the second CTE --- files/grest/rpc/assets/asset_utxos.sql | 32 ++++++++++++++++++++++---- 1 file changed, 27 insertions(+), 5 deletions(-) diff --git a/files/grest/rpc/assets/asset_utxos.sql b/files/grest/rpc/assets/asset_utxos.sql index 2090c80..33f8268 100644 --- a/files/grest/rpc/assets/asset_utxos.sql +++ b/files/grest/rpc/assets/asset_utxos.sql @@ -37,12 +37,13 @@ BEGIN WITH _txo_list AS ( SELECT - txo.id + DISTINCT txo.id -- added DISTINCT 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_id IS NULL - ), + ) + /*, _assets AS ( SELECT txol.id, @@ -61,6 +62,7 @@ BEGIN LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id GROUP BY txol.id ) + */ SELECT ENCODE(tx.hash, 'hex')::text AS tx_hash, tx_out.index::smallint, @@ -91,16 +93,36 @@ BEGIN END) AS reference_script, CASE WHEN _extended = false THEN NULL - ELSE COALESCE(assets, JSONB_BUILD_ARRAY()) + ELSE COALESCE( + + --assets, + ( + SELECT + 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 ma_tx_out AS mto + INNER JOIN multi_asset AS ma ON mto.tx_out_id = my_txo_list.id and ma.id = mto.ident + left JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id + GROUP BY my_txo_list.id + ), + + JSONB_BUILD_ARRAY()) END AS asset_list, (CASE WHEN tx_out.consumed_by_tx_id IS NULL THEN false ELSE true END) AS is_spent - FROM tx_out + FROM _txo_list AS my_txo_list + INNER JOIN tx_out on tx_out.id = my_txo_list.id INNER JOIN tx ON tx_out.tx_id = tx.id INNER JOIN address AS a ON a.id = tx_out.address_id - INNER JOIN _assets ON tx_out.id = _assets.id LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id LEFT JOIN block AS b ON b.id = tx.block_id LEFT JOIN datum ON datum.id = tx_out.inline_datum_id