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 28, 2023
1 parent 7f1ccd9 commit 21bebab
Show file tree
Hide file tree
Showing 41 changed files with 803 additions and 39 deletions.
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')); --
7 changes: 7 additions & 0 deletions files/grest/rpc/db-scripts/basics.sql
Original file line number Diff line number Diff line change
Expand Up @@ -10,6 +10,7 @@
--------------------------------------------------------------------------------
-- GREST SCHEMA --
CREATE SCHEMA IF NOT EXISTS grest;
CREATE SCHEMA IF NOT EXISTS grestv0;

-- WEB_ANON USER --
DO $$
Expand All @@ -33,8 +34,10 @@ $$;

GRANT USAGE ON SCHEMA public TO authenticator,web_anon;
GRANT USAGE ON SCHEMA grest TO authenticator,web_anon;
GRANT USAGE ON SCHEMA grestv0 TO authenticator,web_anon;
GRANT SELECT ON ALL TABLES IN SCHEMA public TO authenticator,web_anon;
GRANT SELECT ON ALL TABLES IN SCHEMA grest TO authenticator,web_anon;
GRANT SELECT ON ALL TABLES IN SCHEMA grestv0 TO authenticator,web_anon;
GRANT web_anon TO authenticator;
ALTER ROLE authenticator SET statement_timeout = 125000;

Expand All @@ -46,6 +49,10 @@ ALTER DEFAULT PRIVILEGES IN SCHEMA grest GRANT
SELECT
ON TABLES TO web_anon,authenticator;

ALTER DEFAULT PRIVILEGES IN SCHEMA grestv0 GRANT
SELECT
ON TABLES TO web_anon,authenticator;

ALTER ROLE web_anon SET search_path TO grest, public;
ALTER ROLE authenticator SET search_path TO grest, public;

Expand Down
22 changes: 22 additions & 0 deletions files/grest/rpc/v0/00_blockchain/genesis.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
CREATE OR REPLACE FUNCTION grestv0.genesis()
RETURNS TABLE (
networkmagic varchar,
networkid varchar,
activeslotcoeff varchar,
updatequorum varchar,
maxlovelacesupply varchar,
epochlength varchar,
systemstart integer,
slotsperkesperiod varchar,
slotlength varchar,
maxkesrevolutions varchar,
securityparam varchar,
alonzogenesis varchar
)
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY
SELECT * FROM grest.genesis();
END;
$$;
16 changes: 16 additions & 0 deletions files/grest/rpc/v0/00_blockchain/param_updates.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
CREATE OR REPLACE FUNCTION grestv0.param_updates()
RETURNS TABLE (
tx_hash text,
block_height word31type,
block_time integer,
epoch_no word31type,
data jsonb
)
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY
SELECT *
FROM grest.param_updates();
END;
$$;
17 changes: 17 additions & 0 deletions files/grest/rpc/v0/00_blockchain/tip.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
CREATE OR REPLACE FUNCTION grestv0.tip()
RETURNS TABLE (
hash text,
epoch_no word31type,
abs_slot word63type,
epoch_slot word31type,
block_no word31type,
block_time integer
)
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY
SELECT *
FROM grest.tip();
END;
$$;
16 changes: 16 additions & 0 deletions files/grest/rpc/v0/00_blockchain/totals.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
CREATE OR REPLACE FUNCTION grestv0.totals(_epoch_no numeric DEFAULT NULL)
RETURNS TABLE (
epoch_no word31type,
circulation text,
treasury text,
reward text,
supply text,
reserves text
)
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY
SELECT * FROM grest.totals(_epoch_no);
END;
$$;
12 changes: 12 additions & 0 deletions files/grest/rpc/v0/account/account_addresses.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
CREATE OR REPLACE FUNCTION grestv0.account_addresses(_stake_addresses text [], _first_only boolean DEFAULT FALSE, _empty boolean DEFAULT FALSE)
RETURNS TABLE (
stake_address varchar,
addresses jsonb
)
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY
SELECT * FROM grest.account_addresses(_stake_addresses,_first_only,_empty);
END;
$$;
59 changes: 59 additions & 0 deletions files/grest/rpc/v0/account/account_assets.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,59 @@
CREATE OR REPLACE FUNCTION grestv0.account_assets(_stake_addresses text [])
RETURNS TABLE (
stake_address varchar,
asset_list jsonb
)
LANGUAGE plpgsql
AS $$
DECLARE
sa_id_list integer[];
BEGIN
SELECT INTO sa_id_list
ARRAY_AGG(stake_address.id)
FROM
stake_address
WHERE
stake_address.view = ANY(_stake_addresses);
RETURN QUERY
WITH _all_assets AS (
SELECT
sa.view,
ma.policy,
ma.name,
ma.fingerprint,
COALESCE(aic.decimals, 0) AS decimals,
SUM(mtx.quantity) AS quantity
FROM
ma_tx_out AS mtx
INNER JOIN multi_asset AS ma ON ma.id = mtx.ident
INNER JOIN tx_out AS txo ON txo.id = mtx.tx_out_id
INNER JOIN stake_address AS sa ON sa.id = txo.stake_address_id
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id
WHERE sa.id = ANY(sa_id_list)
AND txo.consumed_by_tx_in_id IS NULL
GROUP BY
sa.view, ma.policy, ma.name, ma.fingerprint, aic.decimals
)

SELECT
assets_grouped.view AS stake_address,
assets_grouped.assets
FROM (
SELECT
aa.view,
JSONB_AGG(
JSONB_BUILD_OBJECT(
'policy_id', ENCODE(aa.policy, 'hex'),
'asset_name', ENCODE(aa.name, 'hex'),
'fingerprint', aa.fingerprint,
'decimals', COALESCE(aa.decimals, 0),
'quantity', aa.quantity::text
)
) AS assets
FROM
_all_assets AS aa
GROUP BY
aa.view
) AS assets_grouped;
END;
$$;
12 changes: 12 additions & 0 deletions files/grest/rpc/v0/account/account_history.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
CREATE OR REPLACE FUNCTION grestv0.account_history(_stake_addresses text [], _epoch_no integer DEFAULT NULL)
RETURNS TABLE (
stake_address varchar,
history jsonb
)
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY
SELECT * FROM grest.account_history(_stake_addresses, _epoch_no);
END;
$$;
20 changes: 20 additions & 0 deletions files/grest/rpc/v0/account/account_info.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
CREATE OR REPLACE FUNCTION grestv0.account_info(_stake_addresses text [])
RETURNS TABLE (
stake_address varchar,
status text,
delegated_pool varchar,
total_balance text,
utxo text,
rewards text,
withdrawals text,
rewards_available text,
reserves text,
treasury text
)
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY
SELECT * FROM grest.account_info(_stake_addresses);
END;
$$;
20 changes: 20 additions & 0 deletions files/grest/rpc/v0/account/account_info_cached.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
CREATE OR REPLACE FUNCTION grestv0.account_info_cached(_stake_addresses text [])
RETURNS TABLE (
stake_address varchar,
status text,
delegated_pool varchar,
total_balance text,
utxo text,
rewards text,
withdrawals text,
rewards_available text,
reserves text,
treasury text
)
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY
SELECT * FROM grest.account_info_cached(_stake_addresses);
END;
$$;
Loading

0 comments on commit 21bebab

Please sign in to comment.