Skip to content

Commit

Permalink
Performance improvement rejiggling of the second CTE
Browse files Browse the repository at this point in the history
  • Loading branch information
hodlonaut authored and rdlrt committed Dec 6, 2024
1 parent 5fab725 commit 6e9b00f
Show file tree
Hide file tree
Showing 4 changed files with 91 additions and 118 deletions.
56 changes: 24 additions & 32 deletions files/grest/rpc/account/account_utxos.sql
Original file line number Diff line number Diff line change
Expand Up @@ -30,33 +30,12 @@ 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 ma_tx_out AS mto ON mto.tx_out_id = txo.id
LEFT JOIN multi_asset AS ma ON ma.id = mto.ident
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id
WHERE txo.stake_address_id = ANY(sa_id_list)
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,
a.address::text,
tx_out.value::text,
grest.cip5_hex_to_stake_addr(sa.hash_raw) as stake_address,
sa.view::text AS stake_address,
ENCODE(a.payment_cred, 'hex') AS payment_cred,
b.epoch_no,
b.block_no,
Expand All @@ -79,26 +58,39 @@ 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 tx_out.consumed_by_tx_id IS NULL THEN false
ELSE true
END) AS is_spent
WHEN _extended = false THEN NULL
ELSE COALESCE(
(
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 = tx_out.id AND ma.id = mto.ident
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id
GROUP BY tx_out.id
), JSONB_BUILD_ARRAY())
END) AS asset_list,
false AS is_spent
FROM tx_out
INNER JOIN tx ON tx_out.tx_id = tx.id
INNER JOIN address AS a ON a.id = tx_out.address_id
INNER JOIN tx ON tx_out.tx_id = tx.id
LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id
LEFT JOIN block AS b ON b.id = tx.block_id
LEFT JOIN datum ON datum.id = tx_out.inline_datum_id
LEFT JOIN script ON script.id = tx_out.reference_script_id
LEFT JOIN _assets ON tx_out.id = _assets.id
WHERE tx_out.stake_address_id = ANY(sa_id_list)
AND tx_out.consumed_by_tx_id IS NULL
;
END;
$$;

COMMENT ON FUNCTION grest.account_utxos IS 'Get UTxO details for requested stake account'; -- noqa: LT01
COMMENT ON FUNCTION grest.account_utxos IS 'Get UTxO details for requested stake account'; -- noqa: LT01
55 changes: 23 additions & 32 deletions files/grest/rpc/address/address_utxos.sql
Original file line number Diff line number Diff line change
Expand Up @@ -21,34 +21,12 @@ 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 address AS a ON a.id = txo.address_id
INNER JOIN ma_tx_out AS mto ON mto.tx_out_id = txo.id
LEFT JOIN multi_asset AS ma ON ma.id = mto.ident
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id
WHERE a.address = ANY(_addresses)
AND txo.consumed_by_tx_id IS NULL
GROUP BY txo.id
)
SELECT
ENCODE(tx.hash, 'hex')::text AS tx_hash,
tx_out.index::smallint,
a.address::text,
tx_out.value::text,
grest.cip5_hex_to_stake_addr(sa.hash_raw)::text as stake_address,
sa.view::text AS stake_address,
ENCODE(a.payment_cred, 'hex') AS payment_cred,
b.epoch_no,
b.block_no,
Expand All @@ -71,26 +49,39 @@ 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 tx_out.consumed_by_tx_id IS NULL THEN false
ELSE true
END) AS is_spent
WHEN _extended = false THEN NULL
ELSE COALESCE(
(
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 = tx_out.id and ma.id = mto.ident
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id
GROUP BY tx_out.id
), JSONB_BUILD_ARRAY())
END) AS asset_list,
false AS is_spent
FROM tx_out
INNER JOIN address AS a ON a.id = tx_out.address_id
INNER JOIN tx ON tx_out.tx_id = tx.id
LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id
LEFT JOIN block AS b ON b.id = tx.block_id
LEFT JOIN datum ON datum.id = tx_out.inline_datum_id
LEFT JOIN script ON script.id = tx_out.reference_script_id
LEFT JOIN _assets ON tx_out.id = _assets.id
WHERE a.address = ANY(_addresses)
AND tx_out.consumed_by_tx_id IS NULL
;
END;
$$;

COMMENT ON FUNCTION grest.address_utxos IS 'Get UTxO details for requested addresses'; -- noqa: LT01
COMMENT ON FUNCTION grest.address_utxos IS 'Get UTxO details for requested addresses'; -- noqa: LT01
55 changes: 23 additions & 32 deletions files/grest/rpc/address/credential_utxos.sql
Original file line number Diff line number Diff line change
Expand Up @@ -27,34 +27,12 @@ BEGIN
) AS tmp;

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 address AS a ON a.id = txo.address_id
INNER JOIN ma_tx_out AS mto ON mto.tx_out_id = txo.id
LEFT JOIN multi_asset AS ma ON ma.id = mto.ident
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id
WHERE a.payment_cred = ANY(_payment_cred_bytea)
AND txo.consumed_by_tx_id IS NULL
GROUP BY txo.id
)
SELECT
ENCODE(tx.hash, 'hex')::text AS tx_hash,
tx_out.index::smallint,
a.address::text,
tx_out.value::text,
grest.cip5_hex_to_stake_addr(sa.hash_raw)::text as stake_address,
sa.view::text AS stake_address,
ENCODE(a.payment_cred, 'hex') AS payment_cred,
b.epoch_no,
b.block_no,
Expand All @@ -77,26 +55,39 @@ 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 tx_out.consumed_by_tx_id IS NULL THEN false
ELSE true
END) AS is_spent
WHEN _extended = false THEN NULL
ELSE COALESCE(
(
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 = tx_out.id and ma.id = mto.ident
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id
GROUP BY tx_out.id
), JSONB_BUILD_ARRAY())
END) AS asset_list,
false AS is_spent
FROM tx_out
INNER JOIN address AS a ON a.id = tx_out.address_id
INNER JOIN tx ON tx_out.tx_id = tx.id
LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id
LEFT JOIN block AS b ON b.id = tx.block_id
LEFT JOIN datum ON datum.id = tx_out.inline_datum_id
LEFT JOIN script ON script.id = tx_out.reference_script_id
LEFT JOIN _assets ON tx_out.id = _assets.id
WHERE a.payment_cred = ANY(_payment_cred_bytea)
AND tx_out.consumed_by_tx_id IS NULL
;
END;
$$;

COMMENT ON FUNCTION grest.credential_utxos IS 'Get UTxO details for requested payment credentials'; -- noqa: LT01
COMMENT ON FUNCTION grest.credential_utxos IS 'Get UTxO details for requested credentials'; -- noqa: LT01
43 changes: 21 additions & 22 deletions files/grest/rpc/assets/asset_utxos.sql
Original file line number Diff line number Diff line change
Expand Up @@ -37,29 +37,11 @@ BEGIN
WITH
_txo_list AS (
SELECT
txo.id
DISTINCT txo.id
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,
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 _txo_list AS txol
INNER JOIN ma_tx_out AS mto ON mto.tx_out_id = txol.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
GROUP BY txol.id
)
SELECT
ENCODE(tx.hash, 'hex')::text AS tx_hash,
Expand Down Expand Up @@ -91,16 +73,33 @@ BEGIN
END) AS reference_script,
CASE
WHEN _extended = false THEN NULL
ELSE COALESCE(assets, JSONB_BUILD_ARRAY())
ELSE COALESCE(
(
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
Expand Down

0 comments on commit 6e9b00f

Please sign in to comment.