-
Notifications
You must be signed in to change notification settings - Fork 25
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Align *_txs to return consistent data
- Loading branch information
Showing
9 changed files
with
329 additions
and
104 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,53 @@ | ||
CREATE OR REPLACE FUNCTION grest.account_txs(_stake_address text, _after_block_height integer DEFAULT 0) | ||
RETURNS TABLE ( | ||
tx_hash text, | ||
epoch_no word31type, | ||
block_height word31type, | ||
block_time integer | ||
) | ||
LANGUAGE plpgsql | ||
AS $$ | ||
DECLARE | ||
_tx_id_min bigint; | ||
_tx_id_list bigint[]; | ||
BEGIN | ||
SELECT INTO _tx_id_min id | ||
FROM tx | ||
WHERE block_id >= (SELECT id FROM block WHERE block_no >= _after_block_height ORDER BY id limit 1) | ||
ORDER BY id limit 1; | ||
|
||
-- all tx_out & tx_in tx ids | ||
SELECT INTO _tx_id_list ARRAY_AGG(tx_id) | ||
FROM ( | ||
SELECT tx_id | ||
FROM tx_out | ||
WHERE stake_address_id = ANY(SELECT id FROM stake_address WHERE view = _stake_address) | ||
AND tx_id >= _tx_id_min | ||
-- | ||
UNION | ||
-- | ||
SELECT tx_in_id AS tx_id | ||
FROM tx_out | ||
LEFT JOIN tx_in ON tx_out.tx_id = tx_in.tx_out_id | ||
AND tx_out.index = tx_in.tx_out_index | ||
WHERE | ||
tx_in.tx_in_id IS NOT NULL | ||
AND tx_out.stake_address_id = ANY(SELECT id FROM stake_address WHERE view = _stake_address) | ||
AND tx_in.tx_in_id >= _tx_id_min | ||
) AS tmp; | ||
|
||
RETURN QUERY | ||
SELECT | ||
DISTINCT(ENCODE(tx.hash, 'hex')) AS tx_hash, | ||
b.epoch_no, | ||
b.block_no AS block_height, | ||
EXTRACT(EPOCH FROM b.time)::integer AS block_time | ||
FROM public.tx | ||
INNER JOIN public.block AS b ON b.id = tx.block_id | ||
WHERE tx.id = ANY(_tx_id_list) | ||
AND block.block_no >= _after_block_height | ||
ORDER BY block.block_no DESC; | ||
END; | ||
$$; | ||
|
||
COMMENT ON FUNCTION grest.account_txs IS 'Get transactions associated with a given stake address'; -- noqa: LT01 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -1,34 +1,82 @@ | ||
CREATE OR REPLACE FUNCTION grest.account_utxos(_stake_address text) | ||
CREATE OR REPLACE FUNCTION grest.account_utxos(_stake_addresses text [], _extended boolean DEFAULT false) | ||
RETURNS TABLE ( | ||
tx_hash text, | ||
tx_index smallint, | ||
address varchar, | ||
address text, | ||
value text, | ||
stake_address text, | ||
payment_cred text, | ||
epoch_no word31type, | ||
block_height word31type, | ||
block_time integer | ||
block_time integer, | ||
datum_hash text, | ||
inline_datum jsonb, | ||
reference_script jsonb, | ||
asset_list jsonb, | ||
is_spent boolean | ||
) | ||
LANGUAGE plpgsql | ||
AS $$ | ||
DECLARE | ||
known_addresses varchar[]; | ||
BEGIN | ||
RETURN QUERY | ||
SELECT | ||
ENCODE(tx.hash,'hex') AS tx_hash, | ||
tx_out.index::smallint AS tx_index, | ||
tx_out.address, | ||
tx_out.value::text AS value, | ||
b.block_no AS block_height, | ||
EXTRACT(EPOCH FROM b.time)::integer AS block_time | ||
FROM | ||
tx_out | ||
LEFT JOIN tx_in ON tx_in.tx_out_id = tx_out.tx_id | ||
AND tx_in.tx_out_index = tx_out.index | ||
INNER JOIN tx ON tx.id = tx_out.tx_id | ||
SELECT | ||
ENCODE(tx.hash, 'hex')::text AS tx_hash, | ||
tx_out.index::smallint, | ||
tx_out.address::text, | ||
tx_out.value::text, | ||
sa.view::text as stake_address, | ||
ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, | ||
b.epoch_no, | ||
b.block_no, | ||
EXTRACT(EPOCH FROM b.time)::integer AS block_time, | ||
ENCODE(tx_out.data_hash, 'hex') AS datum_hash, | ||
(CASE | ||
WHEN _extended = false OR tx_out.inline_datum_id IS NULL THEN NULL | ||
ELSE JSONB_BUILD_OBJECT( | ||
'bytes', ENCODE(datum.bytes, 'hex'), | ||
'value', datum.value | ||
) | ||
END) AS inline_datum, | ||
(CASE | ||
WHEN _extended = false OR tx_out.reference_script_id IS NULL THEN NULL | ||
ELSE JSONB_BUILD_OBJECT( | ||
'hash', ENCODE(script.hash, 'hex'), | ||
'bytes', ENCODE(script.bytes, 'hex'), | ||
'value', script.json, | ||
'type', script.type::text, | ||
'size', script.serialised_size | ||
) | ||
END) AS reference_script, | ||
(CASE | ||
WHEN _extended = false OR ma.policy IS NULL THEN NULL | ||
ELSE JSONB_BUILD_OBJECT( | ||
'policy_id', ENCODE(ma.policy, 'hex'), | ||
'asset_name', ENCODE(ma.name, 'hex'), | ||
'fingerprint', ma.fingerprint, | ||
'decimals', aic.decimals, | ||
'quantity', mto.quantity::text | ||
) | ||
END | ||
) AS asset_list, | ||
(CASE | ||
WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false | ||
ELSE true | ||
END) AS is_spent | ||
FROM tx_out | ||
INNER JOIN tx ON tx_out.tx_id = tx.id | ||
LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id | ||
LEFT JOIN block AS b ON b.id = tx.block_id | ||
WHERE | ||
tx_in.tx_out_id IS NULL | ||
AND | ||
tx_out.stake_address_id = (SELECT id FROM stake_address WHERE view = _stake_address); | ||
LEFT JOIN ma_tx_out AS mto ON mto.tx_out_id = tx_out.id | ||
LEFT JOIN multi_asset AS ma ON ma.id = mto.ident | ||
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id | ||
LEFT JOIN datum ON datum.id = tx_out.inline_datum_id | ||
LEFT JOIN script ON script.id = tx_out.reference_script_id | ||
WHERE | ||
tx_out.stake_address_id IN (SELECT sa.id FROM stake_address AS sa WHERE sa.view = ANY(_stake_addresses)) | ||
; | ||
END; | ||
$$; | ||
|
||
COMMENT ON FUNCTION grest.account_utxos IS 'Get non-empty UTxOs associated with a given stake address'; -- noqa: LT01 | ||
COMMENT ON FUNCTION grest.address_utxos IS 'Get UTxO details for requested addresses'; -- noqa: LT01 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,82 @@ | ||
CREATE OR REPLACE FUNCTION grest.address_utxos(_addresses text [], _extended boolean DEFAULT false) | ||
RETURNS TABLE ( | ||
tx_hash text, | ||
tx_index smallint, | ||
address text, | ||
value text, | ||
stake_address text, | ||
payment_cred text, | ||
epoch_no word31type, | ||
block_height word31type, | ||
block_time integer, | ||
datum_hash text, | ||
inline_datum jsonb, | ||
reference_script jsonb, | ||
asset_list jsonb, | ||
is_spent boolean | ||
) | ||
LANGUAGE plpgsql | ||
AS $$ | ||
DECLARE | ||
known_addresses varchar[]; | ||
BEGIN | ||
RETURN QUERY | ||
SELECT | ||
ENCODE(tx.hash, 'hex')::text AS tx_hash, | ||
tx_out.index::smallint, | ||
tx_out.address::text, | ||
tx_out.value::text, | ||
sa.view::text as stake_address, | ||
ENCODE(tx_out.payment_cred, 'hex') AS payment_cred, | ||
b.epoch_no, | ||
b.block_no, | ||
EXTRACT(EPOCH FROM b.time)::integer AS block_time, | ||
ENCODE(tx_out.data_hash, 'hex') AS datum_hash, | ||
(CASE | ||
WHEN _extended = false OR tx_out.inline_datum_id IS NULL THEN NULL | ||
ELSE JSONB_BUILD_OBJECT( | ||
'bytes', ENCODE(datum.bytes, 'hex'), | ||
'value', datum.value | ||
) | ||
END) AS inline_datum, | ||
(CASE | ||
WHEN _extended = false OR tx_out.reference_script_id IS NULL THEN NULL | ||
ELSE JSONB_BUILD_OBJECT( | ||
'hash', ENCODE(script.hash, 'hex'), | ||
'bytes', ENCODE(script.bytes, 'hex'), | ||
'value', script.json, | ||
'type', script.type::text, | ||
'size', script.serialised_size | ||
) | ||
END) AS reference_script, | ||
(CASE | ||
WHEN _extended = false OR ma.policy IS NULL THEN NULL | ||
ELSE JSONB_BUILD_OBJECT( | ||
'policy_id', ENCODE(ma.policy, 'hex'), | ||
'asset_name', ENCODE(ma.name, 'hex'), | ||
'fingerprint', ma.fingerprint, | ||
'decimals', aic.decimals, | ||
'quantity', mto.quantity::text | ||
) | ||
END | ||
) AS asset_list, | ||
(CASE | ||
WHEN tx_out.consumed_by_tx_in_id IS NULL THEN false | ||
ELSE true | ||
END) AS is_spent | ||
FROM tx_out | ||
INNER JOIN tx ON tx_out.tx_id = tx.id | ||
LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id | ||
LEFT JOIN block AS b ON b.id = tx.block_id | ||
LEFT JOIN ma_tx_out AS mto ON mto.tx_out_id = tx_out.id | ||
LEFT JOIN multi_asset AS ma ON ma.id = mto.ident | ||
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id | ||
LEFT JOIN datum ON datum.id = tx_out.inline_datum_id | ||
LEFT JOIN script ON script.id = tx_out.reference_script_id | ||
WHERE | ||
tx_out.address = ANY(_addresses) | ||
; | ||
END; | ||
$$; | ||
|
||
COMMENT ON FUNCTION grest.address_utxos IS 'Get UTxO details for requested addresses'; -- noqa: LT01 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.