Skip to content

Commit

Permalink
Add v0 and finalize v1.1.0 release
Browse files Browse the repository at this point in the history
  • Loading branch information
rdlrt committed Nov 29, 2023
1 parent 7f1ccd9 commit 1495bcd
Show file tree
Hide file tree
Showing 27 changed files with 1,382 additions and 135 deletions.
1 change: 0 additions & 1 deletion files/grest/.sqlfluff
Original file line number Diff line number Diff line change
Expand Up @@ -2,7 +2,6 @@
dialect = postgres
exclude_rules = structure.column_order, references.keywords
max_line_length=260
recurse = 0
capitalisation_policy = upper
extended_capitalisation_policy = upper
idented_joins = True
Expand Down
8 changes: 2 additions & 6 deletions files/grest/rpc/00_blockchain/genesis.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,10 +13,8 @@ RETURNS TABLE (
securityparam varchar,
alonzogenesis varchar
)
LANGUAGE plpgsql
LANGUAGE sql STABLE
AS $$
BEGIN
RETURN QUERY
SELECT
g.networkmagic,
g.networkid,
Expand All @@ -30,7 +28,5 @@ BEGIN
g.maxkesrevolutions,
g.securityparam,
g.alonzogenesis
FROM
grest.genesis AS g;
END;
FROM grest.genesis AS g;
$$;
86 changes: 41 additions & 45 deletions files/grest/rpc/00_blockchain/param_updates.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,52 +6,48 @@ RETURNS TABLE (
epoch_no word31type,
data jsonb
)
LANGUAGE plpgsql
LANGUAGE sql STABLE
AS $$
BEGIN
RETURN QUERY
SELECT DISTINCT ON (pp.registered_tx_id)
ENCODE(t.hash,'hex') AS tx_hash,
b.block_no AS block_height,
EXTRACT(EPOCH FROM b.time)::integer AS block_time,
b.epoch_no,
JSONB_STRIP_NULLS(JSONB_BUILD_OBJECT(
'min_fee_a', pp.min_fee_a,
'min_fee_b', pp.min_fee_b,
'max_block_size', pp.max_block_size,
'max_tx_size', pp.max_tx_size,
'max_bh_size', pp.max_bh_size,
'key_deposit', pp.key_deposit,
'pool_deposit', pp.pool_deposit,
'max_epoch', pp.max_epoch,
'optimal_pool_count', pp.optimal_pool_count,
'influence', pp.influence,
'monetary_expand_rate', pp.monetary_expand_rate,
'treasury_growth_rate', pp.treasury_growth_rate,
'decentralisation', pp.decentralisation,
'entropy', pp.entropy,
'protocol_major', pp.protocol_major,
'protocol_minor', pp.protocol_minor,
'min_utxo_value', pp.min_utxo_value,
'min_pool_cost', pp.min_pool_cost,
'cost_model', CM.costs,
'price_mem', pp.price_mem,
'price_step', pp.price_step,
'max_tx_ex_mem', pp.max_tx_ex_mem,
'max_tx_ex_steps', pp.max_tx_ex_steps,
'max_block_ex_mem', pp.max_block_ex_mem,
'max_block_ex_steps', pp.max_block_ex_steps,
'max_val_size', pp.max_val_size,
'collateral_percent', pp.collateral_percent,
'max_collateral_inputs', pp.max_collateral_inputs,
'coins_per_utxo_size', pp.coins_per_utxo_size
)) AS data
FROM
public.param_proposal pp
INNER JOIN tx t ON t.id = pp.registered_tx_id
INNER JOIN block b ON t.block_id = b.id
LEFT JOIN cost_model CM ON CM.id = pp.cost_model_id;
END;
SELECT DISTINCT ON (pp.registered_tx_id)
ENCODE(t.hash,'hex') AS tx_hash,
b.block_no AS block_height,
EXTRACT(EPOCH FROM b.time)::integer AS block_time,
b.epoch_no,
JSONB_STRIP_NULLS(JSONB_BUILD_OBJECT(
'min_fee_a', pp.min_fee_a,
'min_fee_b', pp.min_fee_b,
'max_block_size', pp.max_block_size,
'max_tx_size', pp.max_tx_size,
'max_bh_size', pp.max_bh_size,
'key_deposit', pp.key_deposit,
'pool_deposit', pp.pool_deposit,
'max_epoch', pp.max_epoch,
'optimal_pool_count', pp.optimal_pool_count,
'influence', pp.influence,
'monetary_expand_rate', pp.monetary_expand_rate,
'treasury_growth_rate', pp.treasury_growth_rate,
'decentralisation', pp.decentralisation,
'entropy', pp.entropy,
'protocol_major', pp.protocol_major,
'protocol_minor', pp.protocol_minor,
'min_utxo_value', pp.min_utxo_value,
'min_pool_cost', pp.min_pool_cost,
'cost_model', CM.costs,
'price_mem', pp.price_mem,
'price_step', pp.price_step,
'max_tx_ex_mem', pp.max_tx_ex_mem,
'max_tx_ex_steps', pp.max_tx_ex_steps,
'max_block_ex_mem', pp.max_block_ex_mem,
'max_block_ex_steps', pp.max_block_ex_steps,
'max_val_size', pp.max_val_size,
'collateral_percent', pp.collateral_percent,
'max_collateral_inputs', pp.max_collateral_inputs,
'coins_per_utxo_size', pp.coins_per_utxo_size
)) AS data
FROM public.param_proposal pp
INNER JOIN tx t ON t.id = pp.registered_tx_id
INNER JOIN block b ON t.block_id = b.id
LEFT JOIN cost_model CM ON CM.id = pp.cost_model_id;
$$;

COMMENT ON FUNCTION grest.param_updates IS 'Parameter updates applied to the network'; -- noqa: LT01
4 changes: 2 additions & 2 deletions files/grest/rpc/00_blockchain/reserve_withdrawals.sql
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,7 @@ RETURNS TABLE (
amount text,
stake_address text
)
LANGUAGE SQL STABLE
LANGUAGE sql STABLE
AS $$
SELECT
b.epoch_no,
Expand All @@ -24,4 +24,4 @@ AS $$
LEFT JOIN stake_address AS sa ON sa.id = r.addr_id;
$$;

COMMENT ON FUNCTION grest.reserve_withdrawals IS 'A list of withdrawals made from reserves (MIRs)'; --noqa: LT01
COMMENT ON FUNCTION grest.reserve_withdrawals IS 'A list of withdrawals made from reserves (MIRs)'; --noqa: LT01
11 changes: 3 additions & 8 deletions files/grest/rpc/00_blockchain/tip.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,23 +7,18 @@ RETURNS TABLE (
block_no word31type,
block_time integer
)
LANGUAGE plpgsql
LANGUAGE sql STABLE
AS $$
BEGIN
RETURN QUERY
SELECT
ENCODE(b.hash::bytea, 'hex') AS block_hash,
b.epoch_no AS epoch_no,
b.slot_no AS abs_slot,
b.epoch_slot_no AS epoch_slot,
b.block_no,
EXTRACT(EPOCH FROM b.time)::integer
FROM
block b
ORDER BY
b.id DESC
FROM block b
ORDER BY b.id DESC
LIMIT 1;
END;
$$;

COMMENT ON FUNCTION grest.tip IS 'Get the tip info about the latest block seen by chain'; -- noqa: LT01
43 changes: 12 additions & 31 deletions files/grest/rpc/00_blockchain/totals.sql
Original file line number Diff line number Diff line change
Expand Up @@ -7,38 +7,19 @@ RETURNS TABLE (
supply text,
reserves text
)
LANGUAGE plpgsql
LANGUAGE sql STABLE
AS $$
BEGIN
IF _epoch_no IS NULL THEN
RETURN QUERY (
SELECT
ap.epoch_no,
ap.utxo::text,
ap.treasury::text,
ap.rewards::text,
(ap.treasury + ap.rewards + ap.utxo + ap.deposits + ap.fees)::text AS supply,
ap.reserves::text
FROM
public.ada_pots AS ap
ORDER BY
ap.epoch_no DESC);
ELSE
RETURN QUERY (
SELECT
ap.epoch_no, ap.utxo::text,
ap.treasury::text,
ap.rewards::text,
(ap.treasury + ap.rewards + ap.utxo + ap.deposits + ap.fees)::text AS supply,
ap.reserves::text
FROM
public.ada_pots AS ap
WHERE
ap.epoch_no = _epoch_no
ORDER BY
ap.epoch_no DESC);
END IF;
END;
SELECT
ap.epoch_no,
ap.utxo::text,
ap.treasury::text,
ap.rewards::text,
(ap.treasury + ap.rewards + ap.utxo + ap.deposits + ap.fees)::text AS supply,
ap.reserves::text
FROM public.ada_pots AS ap
WHERE (_epoch_no IS NOT NULL AND ap.epoch_no = _epoch_no)
OR (_epoch_no IS NULL)
ORDER BY ap.epoch_no DESC;
$$;

COMMENT ON FUNCTION grest.totals IS 'Get the circulating utxo, treasury, rewards, supply and reserves in lovelace for specified epoch, all epochs if empty'; -- noqa: LT01
4 changes: 2 additions & 2 deletions files/grest/rpc/00_blockchain/treasury_withdrawals.sql
Original file line number Diff line number Diff line change
Expand Up @@ -8,7 +8,7 @@ RETURNS TABLE (
amount text,
stake_address text
)
LANGUAGE SQL STABLE
LANGUAGE sql STABLE
AS $$
SELECT
b.epoch_no,
Expand All @@ -24,4 +24,4 @@ AS $$
LEFT JOIN stake_address AS sa ON sa.id = t.addr_id;
$$;

COMMENT ON FUNCTION grest.treasury_withdrawals IS 'A list of withdrawals made from treasury'; --noqa: LT01
COMMENT ON FUNCTION grest.treasury_withdrawals IS 'A list of withdrawals made from treasury'; --noqa: LT01
22 changes: 13 additions & 9 deletions files/grest/rpc/01_cached_tables/asset_txo_cache.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,6 +13,14 @@ BEGIN
RAISE EXCEPTION 'Previous asset_txo_cache_update query still running but should have completed! Exiting...';
END IF;

CREATE TEMP TABLE tmp_ma AS (
SELECT ma1.id
FROM grest.asset_cache_control AS acc1
LEFT JOIN multi_asset AS ma1 ON ma1.policy = acc1.policy
LEFT JOIN grest.asset_tx_out_cache AS atoc1 ON ma1.id = atoc1.ma_id
WHERE atoc1.ma_id IS NULL
);

WITH
ma_filtered AS
(
Expand All @@ -21,16 +29,10 @@ BEGIN
mto.quantity,
mto.ident
FROM grest.asset_cache_control AS acc
LEFT JOIN multi_asset AS ma ON ma.policy = acc.policy AND ma.name = acc.name
LEFT JOIN multi_asset AS ma ON ma.policy = acc.policy
LEFT JOIN ma_tx_out AS mto ON mto.ident = ma.id
WHERE ma.id IN
(
SELECT ma.id
FROM grest.asset_cache_control AS acc
LEFT JOIN multi_asset AS ma ON ma.policy = acc.policy AND acc.name = ma.name
LEFT JOIN grest.asset_tx_out_cache AS atoc ON ma.id = atoc.ma_id
WHERE atoc.ma_id IS NULL
)
(SELECT id FROM tmp_ma)
)
UNION ALL
(
Expand All @@ -39,7 +41,7 @@ BEGIN
mto.quantity,
mto.ident
FROM grest.asset_cache_control AS acc
LEFT JOIN multi_asset AS ma ON ma.policy = acc.policy AND ma.name = acc.name
LEFT JOIN multi_asset AS ma ON ma.policy = acc.policy
LEFT JOIN ma_tx_out AS mto ON mto.ident = ma.id
WHERE mto.tx_out_id > (SELECT COALESCE(MAX(atoc.txo_id),0) FROM grest.asset_tx_out_cache AS atoc)
)
Expand All @@ -60,5 +62,7 @@ BEGIN
LEFT JOIN tx_out AS txo ON atoc.txo_id = txo.id
WHERE txo.consumed_by_tx_in_id IS NOT NULL
OR txo.id IS NULL);
DROP TABLE tmp_ma;

END;
$$;
58 changes: 45 additions & 13 deletions files/grest/rpc/assets/policy_asset_addresses.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,20 +6,52 @@ RETURNS TABLE (
)
LANGUAGE plpgsql
AS $$
DECLARE
_asset_policy_decoded bytea;
_asset_ids int[];
_isatoc int;
BEGIN
RETURN QUERY
SELECT
ENCODE(ma.name, 'hex') AS asset_name,
txo.address,
SUM(mto.quantity)::text
FROM multi_asset AS ma
LEFT JOIN ma_tx_out AS mto ON mto.ident = ma.id
LEFT JOIN tx_out AS txo ON txo.id = mto.tx_out_id
WHERE ma.policy = DECODE(_asset_policy, 'hex')
AND txo.consumed_by_tx_in_id IS NULL
GROUP BY
ma.name,
txo.address;
SELECT DECODE(_asset_policy, 'hex') INTO _asset_policy_decoded;
SELECT COUNT(ma_id) INTO _isatoc FROM grest.asset_tx_out_cache
WHERE ma_id IN (SELECT id FROM multi_asset WHERE policy = _asset_policy_decoded);

IF _isatoc > 0 THEN
RETURN QUERY
SELECT
ENCODE(ma.name, 'hex') AS asset_name,
x.address,
SUM(x.quantity)::text
FROM
(
SELECT
atoc.ma_id,
txo.address,
atoc.quantity
FROM grest.asset_tx_out_cache AS atoc
LEFT JOIN multi_asset AS ma ON ma.id = atoc.ma_id
LEFT JOIN tx_out AS txo ON txo.id = atoc.txo_id
WHERE ma.policy = DECODE(_asset_policy, 'hex')
AND txo.consumed_by_tx_in_id IS NULL
) x
LEFT JOIN multi_asset AS ma ON ma.id = x.ma_id
GROUP BY
ma.name,
x.address;
ELSE
RETURN QUERY
SELECT
ENCODE(ma.name, 'hex') AS asset_name,
txo.address,
SUM(mto.quantity)::text
FROM multi_asset AS ma
LEFT JOIN ma_tx_out AS mto ON mto.ident = ma.id
LEFT JOIN tx_out AS txo ON txo.id = mto.tx_out_id
WHERE ma.policy = DECODE(_asset_policy, 'hex')
AND txo.consumed_by_tx_in_id IS NULL
GROUP BY
ma.name,
txo.address;
END IF;
END;
$$;

Expand Down
35 changes: 23 additions & 12 deletions files/grest/rpc/db-scripts/asset_cache_control.sql
Original file line number Diff line number Diff line change
@@ -1,19 +1,30 @@
CREATE TABLE IF NOT EXISTS grest.asset_cache_control AS (
SELECT policy, name FROM multi_asset LIMIT 0
SELECT policy FROM multi_asset LIMIT 0
);

ALTER TABLE

CREATE TABLE IF NOT EXISTS grest.asset_tx_out_cache AS (
SELECT id AS ma_id, id AS txo_id, quantity FROM ma_tx_out LIMIT 0
);
CREATE INDEX IF NOT EXISTS idx_atoc_txoid ON grest.asset_tx_out_cache USING btree (txo_id);

INSERT INTO grest.asset_cache_control VALUES (DECODE('13aa2accf2e1561723aa26871e071fdf32c867cff7e7d50ad470d62f','hex'),DECODE('4d494e53574150','hex'));
INSERT INTO grest.asset_cache_control VALUES (DECODE('92292852e3820cfbe99874b284fdf2befbddb38e070cf3512009a60a','hex'),DECODE('436f6c6f72506561726c','hex'));
INSERT INTO grest.asset_cache_control VALUES (DECODE('29d222ce763455e3d7a09a665ce554f00ac89d2e99a1a83d267170c6','hex'),DECODE('4d494e','hex'));
INSERT INTO grest.asset_cache_control VALUES (DECODE('de9b756719341e79785aa13c164e7fe68c189ed04d61c9876b2fe53f','hex'),DECODE('4d7565736c69537761705f414d4d','hex'));
INSERT INTO grest.asset_cache_control VALUES (DECODE('f43a62fdc3965df486de8a0d32fe800963589c41b38946602a0dc535','hex'),DECODE('41474958','hex'));
INSERT INTO grest.asset_cache_control VALUES (DECODE('a0028f350aaabe0545fdcb56b039bfb08e4bb4d8c4d7c3c7d481c235','hex'),DECODE('484f534b59','hex'));
INSERT INTO grest.asset_cache_control VALUES (DECODE('682fe60c9918842b3323c43b5144bc3d52a23bd2fb81345560d73f63','hex'),DECODE('4e45574d','hex'));
INSERT INTO grest.asset_cache_control VALUES (DECODE('af2e27f580f7f08e93190a81f72462f153026d06450924726645891b','hex'),DECODE('44524950','hex'));
INSERT INTO grest.asset_cache_control VALUES (DECODE('10a49b996e2402269af553a8a96fb8eb90d79e9eca79e2b4223057b6','hex'),DECODE('4745524f','hex'));
INSERT INTO grest.asset_cache_control VALUES (DECODE('1d7f33bd23d85e1a25d87d86fac4f199c3197a2f7afeb662a0f34e1e','hex'),DECODE('776f726c646d6f62696c65746f6b656e','hex'));
CREATE INDEX IF NOT EXISTS idx_atoc_txoid ON grest.asset_tx_out_cache USING btree (txo_id) DESC;
CREATE INDEX IF NOT EXISTS idx_atoc_maid ON grest.asset_tx_out_cache USING btree (ma_id) INCLUDE (txo_id, quantity);

INSERT INTO grest.asset_cache_control VALUES (DECODE('a0028f350aaabe0545fdcb56b039bfb08e4bb4d8c4d7c3c7d481c235','hex')); -- HOSKY
INSERT INTO grest.asset_cache_control VALUES (DECODE('af2e27f580f7f08e93190a81f72462f153026d06450924726645891b','hex')); -- DRIP
INSERT INTO grest.asset_cache_control VALUES (DECODE('29d222ce763455e3d7a09a665ce554f00ac89d2e99a1a83d267170c6','hex')); -- MIN
INSERT INTO grest.asset_cache_control VALUES (DECODE('9a9693a9a37912a5097918f97918d15240c92ab729a0b7c4aa144d77','hex')); -- SUNDAE
INSERT INTO grest.asset_cache_control VALUES (DECODE('13aa2accf2e1561723aa26871e071fdf32c867cff7e7d50ad470d62f','hex')); -- MINSWAP
INSERT INTO grest.asset_cache_control VALUES (DECODE('c0ee29a85b13209423b10447d3c2e6a50641a15c57770e27cb9d5073','hex')); -- WINGRIDERS
INSERT INTO grest.asset_cache_control VALUES (DECODE('1d7f33bd23d85e1a25d87d86fac4f199c3197a2f7afeb662a0f34e1e','hex')); -- worldmobiletoken
INSERT INTO grest.asset_cache_control VALUES (DECODE('682fe60c9918842b3323c43b5144bc3d52a23bd2fb81345560d73f63','hex')); -- NEWM
INSERT INTO grest.asset_cache_control VALUES (DECODE('6ac8ef33b510ec004fe11585f7c5a9f0c07f0c23428ab4f29c1d7d10','hex')); -- MELD
INSERT INTO grest.asset_cache_control VALUES (DECODE('884892bcdc360bcef87d6b3f806e7f9cd5ac30d999d49970e7a903ae','hex')); -- PAVIA
INSERT INTO grest.asset_cache_control VALUES (DECODE('279c909f348e533da5808898f87f9a14bb2c3dfbbacccd631d927a3f','hex')); -- SNEK
INSERT INTO grest.asset_cache_control VALUES (DECODE('f43a62fdc3965df486de8a0d32fe800963589c41b38946602a0dc535','hex')); -- AGIX
INSERT INTO grest.asset_cache_control VALUES (DECODE('92292852e3820cfbe99874b284fdf2befbddb38e070cf3512009a60a','hex')); -- *Pearl
INSERT INTO grest.asset_cache_control VALUES (DECODE('de9b756719341e79785aa13c164e7fe68c189ed04d61c9876b2fe53f','hex')); -- MuesliSwap_AMM
INSERT INTO grest.asset_cache_control VALUES (DECODE('10a49b996e2402269af553a8a96fb8eb90d79e9eca79e2b4223057b6','hex')); -- GERO
INSERT INTO grest.asset_cache_control VALUES (DECODE('750900e4999ebe0d58f19b634768ba25e525aaf12403bfe8fe130501', 'hex')); -- BOOK
-- INSERT INTO grest.asset_cache_control VALUES (DECODE('','hex')); --
Loading

0 comments on commit 1495bcd

Please sign in to comment.