Skip to content

Commit

Permalink
- [x] Add addresses to asset_summary, closes #263
Browse files Browse the repository at this point in the history
- [x] Convert block view to rpc and add parent_hash to output
- [x] Convert account_list view to rpc and add stake_address_hex, script_hash to output
- [x] Convert asset_list view to rpc and add asset_name_ascii to output
- [x] Convert asset_token_registry from view to rpc
  • Loading branch information
rdlrt committed Jan 12, 2024
1 parent 28453f2 commit 8529bd3
Show file tree
Hide file tree
Showing 20 changed files with 302 additions and 151 deletions.
5 changes: 2 additions & 3 deletions files/grest/rpc/01_cached_tables/stake_distribution_cache.sql
Original file line number Diff line number Diff line change
Expand Up @@ -86,9 +86,8 @@ BEGIN
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
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 > _last_account_tx_id
),
Expand Down
5 changes: 3 additions & 2 deletions files/grest/rpc/01_cached_tables/stake_snapshot_cache.sql
Original file line number Diff line number Diff line change
Expand Up @@ -226,10 +226,11 @@ BEGIN
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
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
AND tx_in.tx_in_id <= _upper_bound_account_tx_id
),
account_delta_input AS (
SELECT
Expand Down
17 changes: 17 additions & 0 deletions files/grest/rpc/account/account_list.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
CREATE OR REPLACE FUNCTION grest.account_list()
RETURNS TABLE (
stake_address text,
stake_address_hex text,
script_hash text
)
LANGUAGE sql STABLE
AS $$
SELECT
sa.view::text,
ENCODE(sa.hash_raw,'hex'),
ENCODE(sa.script_hash,'hex')
FROM stake_address AS sa
ORDER BY sa.id;
$$;

COMMENT ON FUNCTION grest.account_list IS 'Get a list of all accounts';
2 changes: 1 addition & 1 deletion files/grest/rpc/address/address_txs.sql
Original file line number Diff line number Diff line change
Expand Up @@ -44,7 +44,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 b.block_no >= _after_block_height
AND tx.block_id >= _tx_id_min
ORDER BY b.block_no DESC;
END;
$$;
Expand Down
19 changes: 19 additions & 0 deletions files/grest/rpc/assets/asset_list.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
CREATE OR REPLACE FUNCTION grest.asset_list()
RETURNS TABLE (
policy_id text,
asset_name text,
asset_name_ascii text,
fingerprint text
)
LANGUAGE sql STABLE
AS $$
SELECT
ENCODE(ma.policy, 'hex')::text AS policy_id,
ENCODE(ma.name, 'hex')::text AS asset_name,
ENCODE(ma.name, 'escape')::text as asset_name_ascii,
ma.fingerprint::text
FROM public.multi_asset AS ma
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';
10 changes: 5 additions & 5 deletions files/grest/rpc/assets/asset_nft_address.sql
Original file line number Diff line number Diff line change
Expand Up @@ -30,7 +30,7 @@ BEGIN
txo.address,
sa.view AS stake_address
FROM tx_out AS txo
LEFT JOIN stake_address ON txo.stake_address_id = sa.view
LEFT JOIN stake_address AS sa ON txo.stake_address_id = sa.id
WHERE id = (
SELECT MAX(tx_out_id)
FROM ma_tx_out
Expand All @@ -42,11 +42,11 @@ BEGIN
txo.address,
sa.view AS stake_address
FROM tx_out AS txo
INNER JOIN ma_tx_out mto ON mto.tx_out_id = tx_out.id
LEFT JOIN stake_address ON txo.stake_address_id = sa.view
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 tx_out.consumed_by_tx_in_id IS NULL
ORDER BY tx_out.id DESC
AND txo.consumed_by_tx_in_id IS NULL
ORDER BY txo.id DESC
LIMIT 1;
END IF;
END;
Expand Down
12 changes: 8 additions & 4 deletions files/grest/rpc/assets/asset_summary.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,7 +5,8 @@ RETURNS TABLE (
fingerprint character varying,
total_transactions bigint,
staked_wallets bigint,
unstaked_addresses bigint
unstaked_addresses bigint,
addresses bigint
)
LANGUAGE plpgsql
AS $$
Expand Down Expand Up @@ -35,9 +36,8 @@ BEGIN
txo.stake_address_id AS sa_id
FROM ma_tx_out AS mto
INNER JOIN tx_out AS txo ON txo.id = mto.tx_out_id
LEFT JOIN tx_in AS txi ON txi.tx_out_id = txo.tx_id
WHERE mto.ident = _asset_id
AND txi.tx_out_id IS NULL)
AND txo.consumed_by_tx_in_id IS NULL)

SELECT
_asset_policy,
Expand All @@ -58,7 +58,11 @@ BEGIN
SELECT COUNT(DISTINCT(_asset_utxos.address))
FROM _asset_utxos
WHERE _asset_utxos.sa_id IS NULL
) AS unstaked_addresses
) AS unstaked_addresses,
(
SELECT COUNT(DISTINCT(_asset_utxos.address))
FROM _asset_utxos
) AS addresses
FROM multi_asset AS ma
WHERE ma.id = _asset_id;
END;
Expand Down
26 changes: 26 additions & 0 deletions files/grest/rpc/assets/asset_token_registry.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
CREATE OR REPLACE FUNCTION grest.asset_token_registry()
RETURNS TABLE (
policy_id text,
asset_name text,
asset_name_ascii text,
ticker text,
description text,
url text,
decimals integer,
logo text
)
LANGUAGE sql STABLE
AS $$
SELECT
asset_policy AS policy_id,
asset_name,
name AS asset_name_ascii,
ticker,
description,
url,
decimals,
logo
FROM grest.asset_registry_cache;
$$;

COMMENT ON FUNCTION grest.asset_token_registry IS 'An array of token registry information (registered via github) for each asset';
45 changes: 45 additions & 0 deletions files/grest/rpc/blocks/blocks.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,45 @@
CREATE OR REPLACE FUNCTION grest.blocks()
RETURNS TABLE (
hash text,
epoch_no word31type,
abs_slot word63type,
epoch_slot word31type,
block_height word31type,
block_size word31type,
block_time integer,
tx_count bigint,
vrf_key character varying,
pool character varying,
proto_major word31type,
proto_minor word31type,
op_cert_counter word63type,
parent_hash text
)
LANGUAGE sql STABLE
AS $$
SELECT
ENCODE(b.hash::bytea, 'hex') AS hash,
b.epoch_no AS epoch_no,
b.slot_no AS abs_slot,
b.epoch_slot_no AS epoch_slot,
b.block_no AS block_height,
b.size AS block_size,
EXTRACT(EPOCH FROM b.time)::integer AS block_time,
b.tx_count,
b.vrf_key,
ph.view AS pool,
b.proto_major,
b.proto_minor,
b.op_cert_counter,
(
SELECT ENCODE(tb.hash::bytea, 'hex')
FROM block tb
WHERE id = b.previous_id
) AS parent_hash
FROM block AS b
LEFT JOIN slot_leader AS sl ON b.slot_leader_id = sl.id
LEFT JOIN pool_hash AS ph ON sl.pool_hash_id = ph.id
ORDER BY b.id DESC;
$$;

COMMENT ON FUNCTION grest.blocks IS 'Get detailed information about all blocks (paginated - latest first)';
1 change: 1 addition & 0 deletions files/grest/rpc/script/script_utxos.sql
Original file line number Diff line number Diff line change
Expand Up @@ -74,6 +74,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
WHERE script.hash = DECODE(_script_hash,'hex')
AND tx_out.consumed_by_tx_in_id IS NULL
;
END;
$$;
Expand Down
7 changes: 0 additions & 7 deletions files/grest/rpc/views/account_list.sql

This file was deleted.

11 changes: 0 additions & 11 deletions files/grest/rpc/views/asset_list.sql

This file was deleted.

15 changes: 0 additions & 15 deletions files/grest/rpc/views/asset_token_registry.sql

This file was deleted.

23 changes: 0 additions & 23 deletions files/grest/rpc/views/blocks.sql

This file was deleted.

Loading

0 comments on commit 8529bd3

Please sign in to comment.