Skip to content

Commit 8529bd3

Browse files
committed
- [x] Add addresses to asset_summary, closes #263
- [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
1 parent 28453f2 commit 8529bd3

20 files changed

+302
-151
lines changed

files/grest/rpc/01_cached_tables/stake_distribution_cache.sql

Lines changed: 2 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -86,9 +86,8 @@ BEGIN
8686
tx_in.tx_out_id AS txoid,
8787
tx_in.tx_out_index AS txoidx
8888
FROM tx_in
89-
LEFT JOIN tx_out
90-
ON tx_in.tx_out_id = tx_out.tx_id
91-
AND tx_in.tx_out_index::smallint = tx_out.index::smallint
89+
LEFT JOIN tx_out ON tx_in.tx_out_id = tx_out.tx_id
90+
AND tx_in.tx_out_index::smallint = tx_out.index::smallint
9291
INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = tx_out.stake_address_id
9392
WHERE tx_in.tx_in_id > _last_account_tx_id
9493
),

files/grest/rpc/01_cached_tables/stake_snapshot_cache.sql

Lines changed: 3 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -226,10 +226,11 @@ BEGIN
226226
tx_in.tx_out_id AS txoid,
227227
tx_in.tx_out_index AS txoidx
228228
FROM tx_in
229-
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
229+
LEFT JOIN tx_out ON tx_in.tx_out_id = tx_out.tx_id
230+
AND tx_in.tx_out_index::smallint = tx_out.index::smallint
230231
INNER JOIN accounts_with_delegated_pools AS awdp ON awdp.stake_address_id = tx_out.stake_address_id
231232
WHERE tx_in.tx_in_id > _lower_bound_account_tx_id
232-
AND tx_in.tx_in_id <= _upper_bound_account_tx_id
233+
AND tx_in.tx_in_id <= _upper_bound_account_tx_id
233234
),
234235
account_delta_input AS (
235236
SELECT
Lines changed: 17 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,17 @@
1+
CREATE OR REPLACE FUNCTION grest.account_list()
2+
RETURNS TABLE (
3+
stake_address text,
4+
stake_address_hex text,
5+
script_hash text
6+
)
7+
LANGUAGE sql STABLE
8+
AS $$
9+
SELECT
10+
sa.view::text,
11+
ENCODE(sa.hash_raw,'hex'),
12+
ENCODE(sa.script_hash,'hex')
13+
FROM stake_address AS sa
14+
ORDER BY sa.id;
15+
$$;
16+
17+
COMMENT ON FUNCTION grest.account_list IS 'Get a list of all accounts';

files/grest/rpc/address/address_txs.sql

Lines changed: 1 addition & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -44,7 +44,7 @@ BEGIN
4444
FROM public.tx
4545
INNER JOIN public.block AS b ON b.id = tx.block_id
4646
WHERE tx.id = ANY(_tx_id_list)
47-
AND b.block_no >= _after_block_height
47+
AND tx.block_id >= _tx_id_min
4848
ORDER BY b.block_no DESC;
4949
END;
5050
$$;
Lines changed: 19 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,19 @@
1+
CREATE OR REPLACE FUNCTION grest.asset_list()
2+
RETURNS TABLE (
3+
policy_id text,
4+
asset_name text,
5+
asset_name_ascii text,
6+
fingerprint text
7+
)
8+
LANGUAGE sql STABLE
9+
AS $$
10+
SELECT
11+
ENCODE(ma.policy, 'hex')::text AS policy_id,
12+
ENCODE(ma.name, 'hex')::text AS asset_name,
13+
ENCODE(ma.name, 'escape')::text as asset_name_ascii,
14+
ma.fingerprint::text
15+
FROM public.multi_asset AS ma
16+
ORDER BY ma.policy, ma.name;
17+
$$;
18+
19+
COMMENT ON FUNCTION grest.asset_list IS 'Get a raw listing of all native assets on chain, without any CIP overlays';

files/grest/rpc/assets/asset_nft_address.sql

Lines changed: 5 additions & 5 deletions
Original file line numberDiff line numberDiff line change
@@ -30,7 +30,7 @@ BEGIN
3030
txo.address,
3131
sa.view AS stake_address
3232
FROM tx_out AS txo
33-
LEFT JOIN stake_address ON txo.stake_address_id = sa.view
33+
LEFT JOIN stake_address AS sa ON txo.stake_address_id = sa.id
3434
WHERE id = (
3535
SELECT MAX(tx_out_id)
3636
FROM ma_tx_out
@@ -42,11 +42,11 @@ BEGIN
4242
txo.address,
4343
sa.view AS stake_address
4444
FROM tx_out AS txo
45-
INNER JOIN ma_tx_out mto ON mto.tx_out_id = tx_out.id
46-
LEFT JOIN stake_address ON txo.stake_address_id = sa.view
45+
INNER JOIN ma_tx_out mto ON mto.tx_out_id = txo.id
46+
LEFT JOIN stake_address AS sa ON txo.stake_address_id = sa.id
4747
WHERE mto.ident = _asset_id
48-
AND tx_out.consumed_by_tx_in_id IS NULL
49-
ORDER BY tx_out.id DESC
48+
AND txo.consumed_by_tx_in_id IS NULL
49+
ORDER BY txo.id DESC
5050
LIMIT 1;
5151
END IF;
5252
END;

files/grest/rpc/assets/asset_summary.sql

Lines changed: 8 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -5,7 +5,8 @@ RETURNS TABLE (
55
fingerprint character varying,
66
total_transactions bigint,
77
staked_wallets bigint,
8-
unstaked_addresses bigint
8+
unstaked_addresses bigint,
9+
addresses bigint
910
)
1011
LANGUAGE plpgsql
1112
AS $$
@@ -35,9 +36,8 @@ BEGIN
3536
txo.stake_address_id AS sa_id
3637
FROM ma_tx_out AS mto
3738
INNER JOIN tx_out AS txo ON txo.id = mto.tx_out_id
38-
LEFT JOIN tx_in AS txi ON txi.tx_out_id = txo.tx_id
3939
WHERE mto.ident = _asset_id
40-
AND txi.tx_out_id IS NULL)
40+
AND txo.consumed_by_tx_in_id IS NULL)
4141

4242
SELECT
4343
_asset_policy,
@@ -58,7 +58,11 @@ BEGIN
5858
SELECT COUNT(DISTINCT(_asset_utxos.address))
5959
FROM _asset_utxos
6060
WHERE _asset_utxos.sa_id IS NULL
61-
) AS unstaked_addresses
61+
) AS unstaked_addresses,
62+
(
63+
SELECT COUNT(DISTINCT(_asset_utxos.address))
64+
FROM _asset_utxos
65+
) AS addresses
6266
FROM multi_asset AS ma
6367
WHERE ma.id = _asset_id;
6468
END;
Lines changed: 26 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,26 @@
1+
CREATE OR REPLACE FUNCTION grest.asset_token_registry()
2+
RETURNS TABLE (
3+
policy_id text,
4+
asset_name text,
5+
asset_name_ascii text,
6+
ticker text,
7+
description text,
8+
url text,
9+
decimals integer,
10+
logo text
11+
)
12+
LANGUAGE sql STABLE
13+
AS $$
14+
SELECT
15+
asset_policy AS policy_id,
16+
asset_name,
17+
name AS asset_name_ascii,
18+
ticker,
19+
description,
20+
url,
21+
decimals,
22+
logo
23+
FROM grest.asset_registry_cache;
24+
$$;
25+
26+
COMMENT ON FUNCTION grest.asset_token_registry IS 'An array of token registry information (registered via github) for each asset';

files/grest/rpc/blocks/blocks.sql

Lines changed: 45 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,45 @@
1+
CREATE OR REPLACE FUNCTION grest.blocks()
2+
RETURNS TABLE (
3+
hash text,
4+
epoch_no word31type,
5+
abs_slot word63type,
6+
epoch_slot word31type,
7+
block_height word31type,
8+
block_size word31type,
9+
block_time integer,
10+
tx_count bigint,
11+
vrf_key character varying,
12+
pool character varying,
13+
proto_major word31type,
14+
proto_minor word31type,
15+
op_cert_counter word63type,
16+
parent_hash text
17+
)
18+
LANGUAGE sql STABLE
19+
AS $$
20+
SELECT
21+
ENCODE(b.hash::bytea, 'hex') AS hash,
22+
b.epoch_no AS epoch_no,
23+
b.slot_no AS abs_slot,
24+
b.epoch_slot_no AS epoch_slot,
25+
b.block_no AS block_height,
26+
b.size AS block_size,
27+
EXTRACT(EPOCH FROM b.time)::integer AS block_time,
28+
b.tx_count,
29+
b.vrf_key,
30+
ph.view AS pool,
31+
b.proto_major,
32+
b.proto_minor,
33+
b.op_cert_counter,
34+
(
35+
SELECT ENCODE(tb.hash::bytea, 'hex')
36+
FROM block tb
37+
WHERE id = b.previous_id
38+
) AS parent_hash
39+
FROM block AS b
40+
LEFT JOIN slot_leader AS sl ON b.slot_leader_id = sl.id
41+
LEFT JOIN pool_hash AS ph ON sl.pool_hash_id = ph.id
42+
ORDER BY b.id DESC;
43+
$$;
44+
45+
COMMENT ON FUNCTION grest.blocks IS 'Get detailed information about all blocks (paginated - latest first)';

files/grest/rpc/script/script_utxos.sql

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -74,6 +74,7 @@ BEGIN
7474
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id
7575
LEFT JOIN datum ON datum.id = tx_out.inline_datum_id
7676
WHERE script.hash = DECODE(_script_hash,'hex')
77+
AND tx_out.consumed_by_tx_in_id IS NULL
7778
;
7879
END;
7980
$$;

0 commit comments

Comments
 (0)