diff --git a/files/grest/.sqlfluff b/files/grest/.sqlfluff index 22fde660..55ed4bb6 100644 --- a/files/grest/.sqlfluff +++ b/files/grest/.sqlfluff @@ -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 diff --git a/files/grest/rpc/00_blockchain/genesis.sql b/files/grest/rpc/00_blockchain/genesis.sql index 164f6894..90d23269 100644 --- a/files/grest/rpc/00_blockchain/genesis.sql +++ b/files/grest/rpc/00_blockchain/genesis.sql @@ -13,10 +13,8 @@ RETURNS TABLE ( securityparam varchar, alonzogenesis varchar ) -LANGUAGE plpgsql +LANGUAGE sql STABLE AS $$ -BEGIN - RETURN QUERY SELECT g.networkmagic, g.networkid, @@ -30,7 +28,5 @@ BEGIN g.maxkesrevolutions, g.securityparam, g.alonzogenesis - FROM - grest.genesis AS g; -END; + FROM grest.genesis AS g; $$; diff --git a/files/grest/rpc/00_blockchain/param_updates.sql b/files/grest/rpc/00_blockchain/param_updates.sql index 67ae8782..80df2aa1 100644 --- a/files/grest/rpc/00_blockchain/param_updates.sql +++ b/files/grest/rpc/00_blockchain/param_updates.sql @@ -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 diff --git a/files/grest/rpc/00_blockchain/reserve_withdrawals.sql b/files/grest/rpc/00_blockchain/reserve_withdrawals.sql index 4c0f3c18..7ff66c8b 100644 --- a/files/grest/rpc/00_blockchain/reserve_withdrawals.sql +++ b/files/grest/rpc/00_blockchain/reserve_withdrawals.sql @@ -8,7 +8,7 @@ RETURNS TABLE ( amount text, stake_address text ) -LANGUAGE SQL STABLE +LANGUAGE sql STABLE AS $$ SELECT b.epoch_no, @@ -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 \ No newline at end of file +COMMENT ON FUNCTION grest.reserve_withdrawals IS 'A list of withdrawals made from reserves (MIRs)'; --noqa: LT01 diff --git a/files/grest/rpc/00_blockchain/tip.sql b/files/grest/rpc/00_blockchain/tip.sql index 0fccd977..1cc95463 100644 --- a/files/grest/rpc/00_blockchain/tip.sql +++ b/files/grest/rpc/00_blockchain/tip.sql @@ -7,10 +7,8 @@ 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, @@ -18,12 +16,9 @@ BEGIN 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 diff --git a/files/grest/rpc/00_blockchain/totals.sql b/files/grest/rpc/00_blockchain/totals.sql index 63ccc030..9a3f00e1 100644 --- a/files/grest/rpc/00_blockchain/totals.sql +++ b/files/grest/rpc/00_blockchain/totals.sql @@ -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 diff --git a/files/grest/rpc/00_blockchain/treasury_withdrawals.sql b/files/grest/rpc/00_blockchain/treasury_withdrawals.sql index b9919831..5a109c7f 100644 --- a/files/grest/rpc/00_blockchain/treasury_withdrawals.sql +++ b/files/grest/rpc/00_blockchain/treasury_withdrawals.sql @@ -8,7 +8,7 @@ RETURNS TABLE ( amount text, stake_address text ) -LANGUAGE SQL STABLE +LANGUAGE sql STABLE AS $$ SELECT b.epoch_no, @@ -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 \ No newline at end of file +COMMENT ON FUNCTION grest.treasury_withdrawals IS 'A list of withdrawals made from treasury'; --noqa: LT01 diff --git a/files/grest/rpc/01_cached_tables/asset_txo_cache.sql b/files/grest/rpc/01_cached_tables/asset_txo_cache.sql index e334f352..0c889531 100644 --- a/files/grest/rpc/01_cached_tables/asset_txo_cache.sql +++ b/files/grest/rpc/01_cached_tables/asset_txo_cache.sql @@ -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 ( @@ -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 ( @@ -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) ) @@ -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; $$; diff --git a/files/grest/rpc/02_indexes/13_1_00.sql b/files/grest/rpc/02_indexes/13_1_00.sql index 39d471ca..a5f3f543 100644 --- a/files/grest/rpc/02_indexes/13_1_00.sql +++ b/files/grest/rpc/02_indexes/13_1_00.sql @@ -1,4 +1,4 @@ -/* Unique Indexes that got dropped at 13.1.0.0 */ +/* Indexes additional to vanila dbsync instance */ CREATE UNIQUE INDEX IF NOT EXISTS unique_ada_pots ON public.ada_pots USING btree (block_id); CREATE UNIQUE INDEX IF NOT EXISTS unique_col_txin ON public.collateral_tx_in USING btree (tx_in_id, tx_out_id, tx_out_index); CREATE UNIQUE INDEX IF NOT EXISTS unique_col_txout ON public.collateral_tx_out USING btree (tx_id, index); @@ -21,6 +21,6 @@ CREATE UNIQUE INDEX IF NOT EXISTS unique_treasury ON public.treasury USING btree CREATE UNIQUE INDEX IF NOT EXISTS unique_tx_metadata ON public.tx_metadata USING btree (key, tx_id); CREATE UNIQUE INDEX IF NOT EXISTS unique_txin ON tx_in USING btree (tx_out_id, tx_out_index); CREATE UNIQUE INDEX IF NOT EXISTS unique_withdrawal ON public.withdrawal USING btree (addr_id, tx_id); - -/* Help multi asset queries */ -CREATE INDEX IF NOT EXISTS idx_ma_tx_out_ident ON ma_tx_out (ident); +CREATE INDEX IF NOT EXISTS idx_ma_tx_out_ident ON ma_tx_out (ident) INCLUDE (tx_out_id, quantity); +CREATE INDEX IF NOT EXISTS idx_collateral_tx_in_tx_in_id ON collateral_tx_in (tx_in_id); +CREATE INDEX IF NOT EXISTS idx_reference_tx_in_tx_in_id ON reference_tx_in (tx_in_id); diff --git a/files/grest/rpc/account/account_assets.sql b/files/grest/rpc/account/account_assets.sql index 0ead9fc8..94bdd455 100644 --- a/files/grest/rpc/account/account_assets.sql +++ b/files/grest/rpc/account/account_assets.sql @@ -43,4 +43,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.account_assets IS 'Get the native asset balance of given accounts'; -- noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.account_assets IS 'Get the native asset balance of given accounts'; -- noqa: LT01 diff --git a/files/grest/rpc/account/account_utxos.sql b/files/grest/rpc/account/account_utxos.sql index acdcb63f..70e27f9f 100644 --- a/files/grest/rpc/account/account_utxos.sql +++ b/files/grest/rpc/account/account_utxos.sql @@ -91,4 +91,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.account_utxos IS 'Get UTxO details for requested stake account'; -- noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.account_utxos IS 'Get UTxO details for requested stake account'; -- noqa: LT01 diff --git a/files/grest/rpc/address/address_info.sql b/files/grest/rpc/address/address_info.sql index 3c4ee367..7ab30396 100644 --- a/files/grest/rpc/address/address_info.sql +++ b/files/grest/rpc/address/address_info.sql @@ -116,4 +116,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.address_info IS 'Get bulk address info - balance, associated stake address (if any) and UTXO set'; -- noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.address_info IS 'Get bulk address info - balance, associated stake address (if any) and UTXO set'; -- noqa: LT01 diff --git a/files/grest/rpc/address/address_utxos.sql b/files/grest/rpc/address/address_utxos.sql index 30f45519..87bcd5f5 100644 --- a/files/grest/rpc/address/address_utxos.sql +++ b/files/grest/rpc/address/address_utxos.sql @@ -91,4 +91,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.address_utxos IS 'Get UTxO details for requested addresses'; -- noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.address_utxos IS 'Get UTxO details for requested addresses'; -- noqa: LT01 diff --git a/files/grest/rpc/address/credential_utxos.sql b/files/grest/rpc/address/credential_utxos.sql index f505103c..2a970492 100644 --- a/files/grest/rpc/address/credential_utxos.sql +++ b/files/grest/rpc/address/credential_utxos.sql @@ -97,4 +97,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.credential_utxos IS 'Get UTxO details for requested payment credentials'; -- noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.credential_utxos IS 'Get UTxO details for requested payment credentials'; -- noqa: LT01 diff --git a/files/grest/rpc/assets/asset_utxos.sql b/files/grest/rpc/assets/asset_utxos.sql index 975ed92d..b33a0324 100644 --- a/files/grest/rpc/assets/asset_utxos.sql +++ b/files/grest/rpc/assets/asset_utxos.sql @@ -109,4 +109,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.asset_utxos IS 'Get UTxO details for requested assets'; -- noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.asset_utxos IS 'Get UTxO details for requested assets'; -- noqa: LT01 diff --git a/files/grest/rpc/assets/policy_asset_addresses.sql b/files/grest/rpc/assets/policy_asset_addresses.sql index 0c07b8c2..ca9ebed6 100644 --- a/files/grest/rpc/assets/policy_asset_addresses.sql +++ b/files/grest/rpc/assets/policy_asset_addresses.sql @@ -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; $$; diff --git a/files/grest/rpc/db-scripts/asset_cache_control.sql b/files/grest/rpc/db-scripts/asset_cache_control.sql index aeaaddb4..e2a3ea20 100644 --- a/files/grest/rpc/db-scripts/asset_cache_control.sql +++ b/files/grest/rpc/db-scripts/asset_cache_control.sql @@ -1,19 +1,34 @@ 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 ); 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 + 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')); \ No newline at end of file +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')); -- diff --git a/files/grest/rpc/db-scripts/basics.sql b/files/grest/rpc/db-scripts/basics.sql index 641b05d4..a002738e 100644 --- a/files/grest/rpc/db-scripts/basics.sql +++ b/files/grest/rpc/db-scripts/basics.sql @@ -10,6 +10,7 @@ -------------------------------------------------------------------------------- -- GREST SCHEMA -- CREATE SCHEMA IF NOT EXISTS grest; +CREATE SCHEMA IF NOT EXISTS grestv0; -- WEB_ANON USER -- DO $$ @@ -31,26 +32,29 @@ EXCEPTION END; $$; -GRANT USAGE ON SCHEMA public TO authenticator,web_anon; -GRANT USAGE ON SCHEMA grest 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 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; ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT -SELECT - ON TABLES TO web_anon,authenticator; +SELECT ON TABLES TO authenticator, web_anon; ALTER DEFAULT PRIVILEGES IN SCHEMA grest GRANT -SELECT - ON TABLES TO web_anon,authenticator; +SELECT ON TABLES TO authenticator, web_anon; + +ALTER DEFAULT PRIVILEGES IN SCHEMA grestv0 GRANT +SELECT ON TABLES TO authenticator, web_anon; ALTER ROLE web_anon SET search_path TO grest, public; ALTER ROLE authenticator SET search_path TO grest, public; -- CONTROL TABLE -- -CREATE TABLE IF NOT EXISTS GREST.CONTROL_TABLE ( +CREATE TABLE IF NOT EXISTS grest.control_table ( key text PRIMARY KEY, last_value text NOT NULL, artifacts text @@ -61,20 +65,21 @@ DROP TABLE IF EXISTS grest.genesis; -- Data Types are intentionally kept varchar for single ID row to avoid future edge cases CREATE TABLE grest.genesis ( - NETWORKMAGIC varchar, - NETWORKID varchar, - ACTIVESLOTCOEFF varchar, - UPDATEQUORUM varchar, - MAXLOVELACESUPPLY varchar, - EPOCHLENGTH varchar, - SYSTEMSTART varchar, - SLOTSPERKESPERIOD varchar, - SLOTLENGTH varchar, - MAXKESREVOLUTIONS varchar, - SECURITYPARAM varchar, - ALONZOGENESIS varchar + networkmagic varchar, + networkid varchar, + activeslotcoeff varchar, + updatequorum varchar, + maxlovelacesupply varchar, + epochlength varchar, + systemstart varchar, + slotsperkesperiod varchar, + slotlength varchar, + maxkesrevolutions varchar, + securityparam varchar, + alonzogenesis varchar ); + -- DROP EXISTING FUNCTIONS DO $do$ @@ -111,11 +116,12 @@ END $do$; -- HELPER FUNCTIONS -- -CREATE FUNCTION grest.get_query_pids_partial_match (_query text) - RETURNS TABLE ( - pid integer) - LANGUAGE plpgsql - AS $$ +CREATE FUNCTION grest.get_query_pids_partial_match(_query text) +RETURNS TABLE ( + pid integer +) +LANGUAGE plpgsql +AS $$ BEGIN RETURN QUERY SELECT @@ -130,7 +136,7 @@ BEGIN END; $$; -CREATE PROCEDURE grest.kill_queries_partial_match (_query text) +CREATE PROCEDURE grest.kill_queries_partial_match(_query text) LANGUAGE plpgsql AS $$ DECLARE @@ -148,10 +154,10 @@ BEGIN END; $$; -CREATE FUNCTION grest.update_control_table (_key text, _last_value text, _artifacts text default null) - RETURNS void - LANGUAGE plpgsql - AS +CREATE FUNCTION grest.update_control_table(_key text, _last_value text, _artifacts text DEFAULT NULL) +RETURNS void +LANGUAGE plpgsql +AS $$ BEGIN INSERT INTO @@ -168,6 +174,6 @@ $$ $$; -- Refresh asset token registry cache from github, to avoid stale deletes -DELETE FROM grest.control_table WHERE key='asset_registry_commit'; +DELETE FROM grest.control_table WHERE key = 'asset_registry_commit'; -- DATABASE INDEXES -- -- Empty diff --git a/files/grest/rpc/db-scripts/genesis_table.sql b/files/grest/rpc/db-scripts/genesis_table.sql deleted file mode 100644 index 43b0d9b3..00000000 --- a/files/grest/rpc/db-scripts/genesis_table.sql +++ /dev/null @@ -1,17 +0,0 @@ -DROP TABLE IF EXISTS grest.genesis; - --- Data Types are intentionally kept varchar for single ID row to avoid future edge cases -CREATE TABLE grest.genesis ( - NETWORKMAGIC varchar, - NETWORKID varchar, - ACTIVESLOTCOEFF varchar, - UPDATEQUORUM varchar, - MAXLOVELACESUPPLY varchar, - EPOCHLENGTH varchar, - SYSTEMSTART varchar, - SLOTSPERKESPERIOD varchar, - SLOTLENGTH varchar, - MAXKESREVOLUTIONS varchar, - SECURITYPARAM varchar, - ALONZOGENESIS varchar -); diff --git a/files/grest/rpc/db-scripts/reset_grest.sql b/files/grest/rpc/db-scripts/reset_grest.sql index a022ef6e..48a26cb2 100644 --- a/files/grest/rpc/db-scripts/reset_grest.sql +++ b/files/grest/rpc/db-scripts/reset_grest.sql @@ -1,21 +1,16 @@ -- Drop triggers first that depend on grest.functions() -SELECT - 'DROP TRIGGER ' || trigger_name || ' ON ' || event_object_table || ';' -FROM - information_schema.triggers -WHERE - trigger_schema = 'public'; +SELECT 'DROP TRIGGER ' || trigger_name || ' ON ' || event_object_table || ';' +FROM information_schema.triggers +WHERE trigger_schema = 'public'; -- Recreate grest schema DROP SCHEMA IF EXISTS grest CASCADE; CREATE SCHEMA grest; -GRANT USAGE ON SCHEMA grest TO authenticator,web_anon; +GRANT USAGE ON SCHEMA grest TO authenticator, web_anon; -GRANT SELECT ON ALL TABLES IN SCHEMA grest TO authenticator,web_anon; +GRANT SELECT ON ALL TABLES IN SCHEMA grest TO authenticator, web_anon; ALTER DEFAULT PRIVILEGES IN SCHEMA grest GRANT -SELECT - ON TABLES TO authenticator,web_anon; - +SELECT ON TABLES TO authenticator, web_anon; diff --git a/files/grest/rpc/epoch/epoch_summary_corrections_update.sql b/files/grest/rpc/epoch/epoch_summary_corrections_update.sql index 48b5559c..0346ad83 100644 --- a/files/grest/rpc/epoch/epoch_summary_corrections_update.sql +++ b/files/grest/rpc/epoch/epoch_summary_corrections_update.sql @@ -1,4 +1,4 @@ -CREATE OR REPLACE function grest.epoch_summary_corrections_update() +CREATE OR REPLACE FUNCTION grest.epoch_summary_corrections_update() RETURNS void LANGUAGE plpgsql AS $$ diff --git a/files/grest/rpc/pool/pool_blocks.sql b/files/grest/rpc/pool/pool_blocks.sql index 372dac8e..80ac6cee 100644 --- a/files/grest/rpc/pool/pool_blocks.sql +++ b/files/grest/rpc/pool/pool_blocks.sql @@ -7,30 +7,19 @@ RETURNS TABLE ( block_hash text, block_time integer ) -LANGUAGE plpgsql +LANGUAGE sql STABLE AS $$ -BEGIN - RETURN query SELECT b.epoch_no, b.epoch_slot_no AS epoch_slot, b.slot_no AS abs_slot, b.block_no AS block_height, - encode(b.hash::bytea, 'hex'), + ENCODE(b.hash::bytea, 'hex'), EXTRACT(EPOCH FROM b.time)::integer - FROM - public.block AS b - INNER JOIN - public.slot_leader AS sl ON b.slot_leader_id = sl.id - WHERE - sl.pool_hash_id = (SELECT pool_hash_id FROM grest.pool_info_cache WHERE pool_id_bech32 = _pool_bech32 ORDER BY tx_id DESC LIMIT 1) - AND - ( - _epoch_no IS NULL - OR - b.epoch_no = _epoch_no - ); -END; + FROM public.block AS b + INNER JOIN public.slot_leader AS sl ON b.slot_leader_id = sl.id + WHERE sl.pool_hash_id = (SELECT pool_hash_id FROM grest.pool_info_cache WHERE pool_id_bech32 = _pool_bech32 ORDER BY tx_id DESC LIMIT 1) + AND (_epoch_no IS NULL OR b.epoch_no = _epoch_no); $$; COMMENT ON FUNCTION grest.pool_blocks IS 'Return information about blocks minted by a given pool in current epoch (or epoch nbr if provided)'; -- noqa: LT01 diff --git a/files/grest/rpc/pool/pool_registrations.sql b/files/grest/rpc/pool/pool_registrations.sql index 04f99f07..dcff9f99 100644 --- a/files/grest/rpc/pool/pool_registrations.sql +++ b/files/grest/rpc/pool/pool_registrations.sql @@ -8,7 +8,7 @@ RETURNS TABLE ( epoch_slot word31type, active_epoch_no bigint ) -LANGUAGE SQL STABLE +LANGUAGE sql STABLE AS $$ SELECT ph.view, @@ -25,4 +25,4 @@ AS $$ WHERE b.epoch_no = _epoch_no; $$; -COMMENT ON FUNCTION grest.pool_registrations IS 'A list of all pool registrations initiated in the requested epoch'; --noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.pool_registrations IS 'A list of all pool registrations initiated in the requested epoch'; --noqa: LT01 diff --git a/files/grest/rpc/pool/pool_relays.sql b/files/grest/rpc/pool/pool_relays.sql index 84b70ab9..2b3e2c09 100644 --- a/files/grest/rpc/pool/pool_relays.sql +++ b/files/grest/rpc/pool/pool_relays.sql @@ -20,4 +20,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.pool_relays IS 'A list of registered relays for all pools'; --noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.pool_relays IS 'A list of registered relays for all pools'; --noqa: LT01 diff --git a/files/grest/rpc/pool/pool_retirements.sql b/files/grest/rpc/pool/pool_retirements.sql index 09772a75..ea9a9b5a 100644 --- a/files/grest/rpc/pool/pool_retirements.sql +++ b/files/grest/rpc/pool/pool_retirements.sql @@ -8,7 +8,7 @@ RETURNS TABLE ( epoch_slot word31type, active_epoch_no word31type ) -LANGUAGE SQL STABLE +LANGUAGE sql STABLE AS $$ SELECT ph.view, diff --git a/files/grest/rpc/pool/pool_updates.sql b/files/grest/rpc/pool/pool_updates.sql index 4cd4c48d..61fd2e22 100644 --- a/files/grest/rpc/pool/pool_updates.sql +++ b/files/grest/rpc/pool/pool_updates.sql @@ -87,5 +87,3 @@ END; $$; COMMENT ON FUNCTION grest.pool_updates IS 'Return all pool_updates for all pools or only updates for specific pool if specified'; -- noqa: LT01 - -SELECT grest.pool_updates(); \ No newline at end of file diff --git a/files/grest/rpc/script/datum_info.sql b/files/grest/rpc/script/datum_info.sql index c09c7d81..9f974322 100644 --- a/files/grest/rpc/script/datum_info.sql +++ b/files/grest/rpc/script/datum_info.sql @@ -5,23 +5,16 @@ RETURNS TABLE ( value jsonb, bytes text ) -LANGUAGE plpgsql +LANGUAGE sql STABLE AS $$ -DECLARE - _datum_hashes_decoded bytea[]; -BEGIN - SELECT INTO _datum_hashes_decoded ARRAY_AGG(DECODE(d_hash, 'hex')) - FROM UNNEST(_datum_hashes) AS d_hash; - RETURN QUERY - SELECT - ENCODE(d.hash,'hex'), - ENCODE(tx.hash,'hex') AS creation_tx_hash, - d.value, - ENCODE(d.bytes,'hex') - FROM datum AS d - INNER JOIN tx ON tx.id = d.tx_id - WHERE d.hash = ANY(_datum_hashes_decoded); -END; + SELECT + ENCODE(d.hash,'hex'), + ENCODE(tx.hash,'hex') AS creation_tx_hash, + d.value, + ENCODE(d.bytes,'hex') + FROM datum AS d + INNER JOIN tx ON tx.id = d.tx_id + WHERE d.hash IN (SELECT DECODE(d_hash, 'hex') FROM UNNEST(_datum_hashes) AS d_hash); $$; -COMMENT ON FUNCTION grest.datum_info IS 'Get information about a given datum FROM hashes.'; -- noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.datum_info IS 'Get information about a given datum FROM hashes.'; -- noqa: LT01 diff --git a/files/grest/rpc/script/native_script_list.sql b/files/grest/rpc/script/native_script_list.sql index 7f0482e1..920e1f5e 100644 --- a/files/grest/rpc/script/native_script_list.sql +++ b/files/grest/rpc/script/native_script_list.sql @@ -5,10 +5,8 @@ RETURNS TABLE ( type text, size word31type ) -LANGUAGE plpgsql +LANGUAGE sql STABLE AS $$ -BEGIN - RETURN QUERY SELECT ENCODE(s.hash, 'hex')::text AS script_hash, ENCODE(tx.hash, 'hex')::text AS creation_tx_hash, @@ -17,7 +15,6 @@ BEGIN FROM script AS s INNER JOIN tx ON tx.id = s.tx_id WHERE s.type IN ('timelock', 'multisig'); -END; $$; -COMMENT ON FUNCTION grest.native_script_list IS 'Get a list of all native(multisig/timelock) script hashes with creation tx hash, type and script size.'; --noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.native_script_list IS 'Get a list of all native(multisig/timelock) script hashes with creation tx hash, type and script size.'; --noqa: LT01 diff --git a/files/grest/rpc/script/plutus_script_list.sql b/files/grest/rpc/script/plutus_script_list.sql index b7f66b56..c921a171 100644 --- a/files/grest/rpc/script/plutus_script_list.sql +++ b/files/grest/rpc/script/plutus_script_list.sql @@ -5,10 +5,8 @@ RETURNS TABLE ( type text, size word31type ) -LANGUAGE plpgsql +LANGUAGE sql STABLE AS $$ -BEGIN - RETURN QUERY SELECT ENCODE(s.hash,'hex')::text AS script_hash, ENCODE(tx.hash,'hex')::text AS creation_tx_hash, @@ -17,7 +15,6 @@ BEGIN FROM script AS s INNER JOIN tx ON tx.id = s.tx_id WHERE s.type IN ('plutusV1', 'plutusV2'); -END; $$; -COMMENT ON FUNCTION grest.plutus_script_list IS 'Get a list of all plutus script hashes with creation tx hash.'; --noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.plutus_script_list IS 'Get a list of all plutus script hashes with creation tx hash.'; --noqa: LT01 diff --git a/files/grest/rpc/script/script_info.sql b/files/grest/rpc/script/script_info.sql index c7322d4b..825bfc8d 100644 --- a/files/grest/rpc/script/script_info.sql +++ b/files/grest/rpc/script/script_info.sql @@ -7,14 +7,8 @@ RETURNS TABLE ( bytes text, size word31type ) -LANGUAGE plpgsql +LANGUAGE sql STABLE AS $$ -DECLARE - _script_hashes_decoded bytea[]; -BEGIN - SELECT INTO _script_hashes_decoded ARRAY_AGG(DECODE(s_hash, 'hex')) - FROM UNNEST(_script_hashes) AS s_hash; - RETURN QUERY SELECT ENCODE(s.hash,'hex') AS script_hash, ENCODE(tx.hash,'hex') AS creation_tx_hash, @@ -24,9 +18,8 @@ BEGIN s.serialised_size AS size FROM script AS s INNER JOIN tx ON tx.id = s.tx_id - WHERE s.hash = ANY(_script_hashes_decoded) + WHERE s.hash IN (SELECT DECODE(s_hash, 'hex') FROM UNNEST(_script_hashes) AS s_hash) ; -END; $$; -COMMENT ON FUNCTION grest.script_info IS 'Get information about a given script FROM hashes.'; -- noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.script_info IS 'Get information about a given script FROM hashes.'; -- noqa: LT01 diff --git a/files/grest/rpc/script/script_redeemers.sql b/files/grest/rpc/script/script_redeemers.sql index 19321e45..42bd169a 100644 --- a/files/grest/rpc/script/script_redeemers.sql +++ b/files/grest/rpc/script/script_redeemers.sql @@ -3,12 +3,8 @@ RETURNS TABLE ( script_hash text, redeemers jsonb ) -LANGUAGE plpgsql +LANGUAGE sql STABLE AS $$ -DECLARE _script_hash_bytea bytea; -BEGIN - SELECT INTO _script_hash_bytea DECODE(_script_hash, 'hex'); - RETURN QUERY SELECT _script_hash, JSONB_AGG( @@ -27,9 +23,8 @@ BEGIN FROM redeemer INNER JOIN TX ON tx.id = redeemer.tx_id INNER JOIN REDEEMER_DATA rd ON rd.id = redeemer.redeemer_data_id - WHERE redeemer.script_hash = _script_hash_bytea + WHERE redeemer.script_hash = DECODE(_script_hash, 'hex') GROUP BY redeemer.script_hash; -END; $$; COMMENT ON FUNCTION grest.script_redeemers IS 'Get all redeemers for a given script hash.'; --noqa: LT01 diff --git a/files/grest/rpc/script/script_utxos.sql b/files/grest/rpc/script/script_utxos.sql index 65ba9890..d6af76e0 100644 --- a/files/grest/rpc/script/script_utxos.sql +++ b/files/grest/rpc/script/script_utxos.sql @@ -78,4 +78,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.script_utxos IS 'Get UTxO details for requested scripts'; -- noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.script_utxos IS 'Get UTxO details for requested scripts'; -- noqa: LT01 diff --git a/files/grest/rpc/transactions/tx_metalabels.sql b/files/grest/rpc/transactions/tx_metalabels.sql index c64f5f31..f6a7edde 100644 --- a/files/grest/rpc/transactions/tx_metalabels.sql +++ b/files/grest/rpc/transactions/tx_metalabels.sql @@ -1,4 +1,3 @@ -DROP FUNCTION IF EXISTS grest.tx_metalabels; CREATE OR REPLACE FUNCTION grest.tx_metalabels() RETURNS TABLE (key text) LANGUAGE plpgsql diff --git a/files/grest/rpc/transactions/utxo_info.sql b/files/grest/rpc/transactions/utxo_info.sql index 50fe3277..6e91f0f0 100644 --- a/files/grest/rpc/transactions/utxo_info.sql +++ b/files/grest/rpc/transactions/utxo_info.sql @@ -110,4 +110,4 @@ BEGIN END; $$; -COMMENT ON FUNCTION grest.utxo_info IS 'Get details for requested UTxO arrays (UTxOs accepted in # format).'; -- noqa: LT01 \ No newline at end of file +COMMENT ON FUNCTION grest.utxo_info IS 'Get details for requested UTxO arrays (UTxOs accepted in # format).'; -- noqa: LT01 diff --git a/files/grest/rpc/v0/00_blockchain.sql b/files/grest/rpc/v0/00_blockchain.sql new file mode 100644 index 00000000..aa141bb8 --- /dev/null +++ b/files/grest/rpc/v0/00_blockchain.sql @@ -0,0 +1,76 @@ +-- NETWORK + +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; +$$; + +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; +$$; + +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; +$$; + +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; +$$; diff --git a/files/grest/rpc/v0/account.sql b/files/grest/rpc/v0/account.sql new file mode 100644 index 00000000..26783259 --- /dev/null +++ b/files/grest/rpc/v0/account.sql @@ -0,0 +1,184 @@ +-- ACCOUNT + +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; +$$; + +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; +$$; + +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; +$$; + +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; +$$; + +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; +$$; + +CREATE OR REPLACE FUNCTION grestv0.account_rewards(_stake_addresses text [], _epoch_no numeric DEFAULT NULL) +RETURNS TABLE ( + stake_address varchar, + rewards jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.account_rewards(_stake_addresses, _epoch_no); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.account_updates(_stake_addresses text []) +RETURNS TABLE ( + stake_address varchar, + updates jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.account_updates(_stake_addresses); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.account_utxos(_stake_address text) +RETURNS TABLE ( + tx_hash text, + tx_index smallint, + address varchar, + value text, + block_height word31type, + block_time integer +) +LANGUAGE plpgsql +AS $$ +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 + INNER JOIN tx ON tx.id = tx_out.tx_id + LEFT JOIN block AS b ON b.id = tx.block_id + WHERE tx_out.consumed_by_tx_in_id IS NULL + AND tx_out.stake_address_id = (SELECT id FROM stake_address WHERE view = _stake_address); +END; +$$; diff --git a/files/grest/rpc/v0/address.sql b/files/grest/rpc/v0/address.sql new file mode 100644 index 00000000..b50f4293 --- /dev/null +++ b/files/grest/rpc/v0/address.sql @@ -0,0 +1,132 @@ +-- ADDRESS + +CREATE OR REPLACE FUNCTION grestv0.address_assets(_addresses text []) +RETURNS TABLE ( + address varchar, + asset_list jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + + WITH _all_assets AS ( + SELECT + txo.address, + 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 + LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id + INNER JOIN tx_out AS txo ON txo.id = mtx.tx_out_id + WHERE + txo.address = ANY(_addresses) + AND txo.consumed_by_tx_in_id IS NULL + GROUP BY + txo.address, ma.policy, ma.name, ma.fingerprint, aic.decimals + ) + + SELECT + assets_grouped.address, + assets_grouped.asset_list + FROM ( + SELECT + aa.address, + JSONB_AGG( + JSONB_BUILD_OBJECT( + 'policy_id', ENCODE(aa.policy, 'hex'), + 'asset_name', ENCODE(aa.name, 'hex'), + 'fingerprint', aa.fingerprint, + 'decimals', aa.decimals, + 'quantity', aa.quantity::text + ) + ) AS asset_list + FROM + _all_assets AS aa + GROUP BY + aa.address + ) assets_grouped; +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.address_info(_addresses text []) +RETURNS TABLE ( + address varchar, + balance text, + stake_address character varying, + script_address boolean, + utxo_set jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.address_info(_addresses); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.address_txs(_addresses text [], _after_block_height integer DEFAULT 0) +RETURNS TABLE ( + tx_hash text, + epoch_no word31type, + block_height word31type, + block_time integer +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.address_txs(_addresses, _after_block_height); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.credential_txs(_payment_credentials text [], _after_block_height integer DEFAULT 0) +RETURNS TABLE ( + tx_hash text, + epoch_no word31type, + block_height word31type, + block_time integer +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.credential_txs(_payment_credentials,_after_block_height); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.credential_utxos(_payment_credentials text []) +RETURNS TABLE ( + tx_hash text, + tx_index smallint, + value text +) +LANGUAGE plpgsql +AS $$ +DECLARE + _payment_cred_bytea bytea[]; + +BEGIN + SELECT INTO _payment_cred_bytea ARRAY_AGG(cred_bytea) + FROM ( + SELECT + DECODE(cred_hex, 'hex') AS cred_bytea + FROM + UNNEST(_payment_credentials) AS cred_hex + ) AS tmp; + + RETURN QUERY + SELECT + ENCODE(tx.hash, 'hex')::text AS tx_hash, + tx_out.index::smallint, + tx_out.value::text AS balance + FROM tx_out + INNER JOIN tx ON tx_out.tx_id = tx.id + WHERE payment_cred = ANY(_payment_cred_bytea) + AND tx_out.consumed_by_tx_in_id IS NULL; +END; +$$; diff --git a/files/grest/rpc/v0/assets.sql b/files/grest/rpc/v0/assets.sql new file mode 100644 index 00000000..7a49d776 --- /dev/null +++ b/files/grest/rpc/v0/assets.sql @@ -0,0 +1,211 @@ +-- ASSETS + +CREATE OR REPLACE FUNCTION grestv0.asset_address_list(_asset_policy text, _asset_name text DEFAULT '') +RETURNS TABLE ( + payment_address varchar, + quantity text +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.asset_addresses(_asset_policy, _asset_name); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.asset_addresses(_asset_policy text, _asset_name text DEFAULT '') +RETURNS TABLE ( + payment_address varchar, + quantity text +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.asset_addresses(_asset_policy, _asset_name); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.asset_history(_asset_policy text, _asset_name text DEFAULT '') +RETURNS TABLE ( + policy_id text, + asset_name text, + fingerprint character varying, + minting_txs jsonb [] +) +LANGUAGE plpgsql +AS $$ +DECLARE + _asset_policy_decoded bytea; + _asset_name_decoded bytea; +BEGIN + RETURN QUERY + SELECT * FROM grest.asset_history(_asset_policy, _asset_name); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.asset_info(_asset_policy text, _asset_name text DEFAULT '') +RETURNS TABLE ( + policy_id text, + asset_name text, + asset_name_ascii text, + fingerprint character varying, + minting_tx_hash text, + total_supply text, + mint_cnt bigint, + burn_cnt bigint, + creation_time integer, + minting_tx_metadata jsonb, + token_registry_metadata jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.asset_info(_asset_policy,_asset_name); + +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.asset_info(_asset_list text [] []) +RETURNS TABLE ( + policy_id text, + asset_name text, + asset_name_ascii text, + fingerprint character varying, + minting_tx_hash text, + total_supply text, + mint_cnt bigint, + burn_cnt bigint, + creation_time integer, + minting_tx_metadata jsonb, + token_registry_metadata jsonb, + cip68_metadata jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + -- find all asset id's based ON nested array input + RETURN QUERY + SELECT * FROM grest.asset_info(_asset_list); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.asset_nft_address(_asset_policy text, _asset_name text DEFAULT '') +RETURNS TABLE ( + payment_address varchar +) LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.asset_nft_address(_asset_policy, _asset_name); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.asset_summary(_asset_policy text, _asset_name text DEFAULT '') +RETURNS TABLE ( + policy_id text, + asset_name text, + fingerprint character varying, + total_transactions bigint, + staked_wallets bigint, + unstaked_addresses bigint +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.asset_summary(_asset_policy, _asset_name); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.asset_txs( + _asset_policy text, + _asset_name text DEFAULT '', + _after_block_height integer DEFAULT 0, + _history boolean DEFAULT FALSE +) +RETURNS TABLE ( + tx_hash text, + epoch_no word31type, + block_height word31type, + block_time integer +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.asset_txs(_asset_policy, _asset_name, _after_block_height, _history); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.policy_asset_addresses(_asset_policy text) +RETURNS TABLE ( + asset_name text, + payment_address varchar, + quantity text +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.policy_asset_addresses(_asset_policy); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.asset_policy_info(_asset_policy text) +RETURNS TABLE ( + asset_name text, + asset_name_ascii text, + fingerprint varchar, + minting_tx_hash text, + total_supply text, + mint_cnt bigint, + burn_cnt bigint, + creation_time integer, + minting_tx_metadata jsonb, + token_registry_metadata jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.policy_asset_info(_asset_policy); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.policy_asset_info(_asset_policy text) +RETURNS TABLE ( + asset_name text, + asset_name_ascii text, + fingerprint varchar, + minting_tx_hash text, + total_supply text, + mint_cnt bigint, + burn_cnt bigint, + creation_time integer, + minting_tx_metadata jsonb, + token_registry_metadata jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.policy_asset_info(_asset_policy); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.policy_asset_list(_asset_policy text) +RETURNS TABLE ( + asset_name text, + fingerprint varchar, + total_supply text, + decimals integer +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.policy_asset_list(_asset_policy); +END; +$$; diff --git a/files/grest/rpc/v0/blocks.sql b/files/grest/rpc/v0/blocks.sql new file mode 100644 index 00000000..4f346afe --- /dev/null +++ b/files/grest/rpc/v0/blocks.sql @@ -0,0 +1,64 @@ +-- BLOCKS + +CREATE OR REPLACE FUNCTION grestv0.block_info(_block_hashes text []) +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 varchar, + op_cert text, + op_cert_counter word63type, + pool varchar, + proto_major word31type, + proto_minor word31type, + total_output text, + total_fees text, + num_confirmations integer, + parent_hash text, + child_hash text +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.block_info(_block_hashes); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.block_txs(_block_hashes text []) +RETURNS TABLE ( + block_hash text, + tx_hashes text [] +) +LANGUAGE plpgsql +AS $$ +DECLARE + _block_hashes_bytea bytea[]; + _block_ids integer[]; +BEGIN + SELECT INTO _block_hashes_bytea ARRAY_AGG(block_hashes_bytea) + FROM ( + SELECT DECODE(hex, 'hex') AS block_hashes_bytea + FROM UNNEST(_block_hashes) AS hex + ) AS tmp; + + SELECT INTO _block_ids ARRAY_AGG(b.id) + FROM public.block AS b + WHERE b.hash = ANY(_block_hashes_bytea); + + RETURN QUERY + SELECT + encode(b.hash, 'hex'), + ARRAY_AGG(ENCODE(tx.hash::bytea, 'hex')) + FROM + public.block AS b + INNER JOIN public.tx ON tx.block_id = b.id + WHERE b.id = ANY(_block_ids) + GROUP BY b.hash; +END; +$$; diff --git a/files/grest/rpc/v0/epoch.sql b/files/grest/rpc/v0/epoch.sql new file mode 100644 index 00000000..e999b4b2 --- /dev/null +++ b/files/grest/rpc/v0/epoch.sql @@ -0,0 +1,81 @@ +-- EPOCH + +CREATE OR REPLACE FUNCTION grestv0.epoch_block_protocols(_epoch_no numeric DEFAULT NULL) +RETURNS TABLE ( + proto_major word31type, + proto_minor word31type, + blocks bigint +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.epoch_block_protocols(_epoch_no); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.epoch_info(_epoch_no numeric DEFAULT NULL, _include_next_epoch boolean DEFAULT FALSE) +RETURNS TABLE ( + epoch_no word31type, + out_sum text, + fees text, + tx_count word31type, + blk_count word31type, + start_time integer, + end_time integer, + first_block_time integer, + last_block_time integer, + active_stake text, + total_rewards text, + avg_blk_reward text +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.epoch_info(_epoch_no, _include_next_epoch); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.epoch_params(_epoch_no numeric DEFAULT NULL) +RETURNS TABLE ( + epoch_no word31type, + min_fee_a word31type, + min_fee_b word31type, + max_block_size word31type, + max_tx_size word31type, + max_bh_size word31type, + key_deposit text, + pool_deposit text, + max_epoch word31type, + optimal_pool_count word31type, + influence double precision, + monetary_expand_rate double precision, + treasury_growth_rate double precision, + decentralisation double precision, + extra_entropy text, + protocol_major word31type, + protocol_minor word31type, + min_utxo_value text, + min_pool_cost text, + nonce text, + block_hash text, + cost_models jsonb, + price_mem double precision, + price_step double precision, + max_tx_ex_mem word64type, + max_tx_ex_steps word64type, + max_block_ex_mem word64type, + max_block_ex_steps word64type, + max_val_size word64type, + collateral_percent word31type, + max_collateral_inputs word31type, + coins_per_utxo_size text +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.epoch_params(_epoch_no); +END; +$$; diff --git a/files/grest/rpc/v0/pool.sql b/files/grest/rpc/v0/pool.sql new file mode 100644 index 00000000..31213a01 --- /dev/null +++ b/files/grest/rpc/v0/pool.sql @@ -0,0 +1,255 @@ +-- POOL + +CREATE OR REPLACE FUNCTION grestv0.pool_blocks(_pool_bech32 text, _epoch_no word31type DEFAULT NULL) +RETURNS TABLE ( + epoch_no word31type, + epoch_slot word31type, + abs_slot word63type, + block_height word31type, + block_hash text, + block_time integer +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN query + SELECT * FROM grest.pool_blocks(_pool_bech32, _epoch_no); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.pool_delegators(_pool_bech32 text) +RETURNS TABLE ( + stake_address character varying, + amount text, + active_epoch_no bigint, + latest_delegation_tx_hash text +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.pool_delegators(_pool_bech32); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.pool_delegators_history(_pool_bech32 text, _epoch_no word31type DEFAULT NULL) +RETURNS TABLE ( + stake_address character varying, + amount text, + epoch_no word31type +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.pool_delegators_history(_pool_bech32, _epoch_no); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.pool_history(_pool_bech32 text, _epoch_no word31type DEFAULT NULL) +RETURNS TABLE ( + epoch_no bigint, + active_stake text, + active_stake_pct numeric, + saturation_pct numeric, + block_cnt bigint, + delegator_cnt bigint, + margin double precision, + fixed_cost text, + pool_fees text, + deleg_rewards text, + member_rewards text, + epoch_ros numeric +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.pool_history(_pool_bech32, _epoch_no); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.pool_info(_pool_bech32_ids text []) +RETURNS TABLE ( + pool_id_bech32 character varying, + pool_id_hex text, + active_epoch_no bigint, + vrf_key_hash text, + margin double precision, + fixed_cost text, + pledge text, + reward_addr character varying, + owners character varying [], + relays jsonb [], + meta_url character varying, + meta_hash text, + meta_json jsonb, + pool_status text, + retiring_epoch word31type, + op_cert text, + op_cert_counter word63type, + active_stake text, + sigma numeric, + block_count numeric, + live_pledge text, + live_stake text, + live_delegators bigint, + live_saturation numeric +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.pool_info(_pool_bech32_ids); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.pool_list() +RETURNS TABLE ( + pool_id_bech32 character varying, + ticker character varying +) +LANGUAGE plpgsql +AS $$ +# variable_conflict use_column +BEGIN + RETURN QUERY ( + WITH + -- Get last pool update for each pool + _pool_list AS ( + SELECT + DISTINCT ON (pic.pool_id_bech32) pool_id_bech32, + pool_status + FROM + grest.pool_info_cache AS pic + ORDER BY + pic.pool_id_bech32, + pic.tx_id DESC + ), + + _pool_meta AS ( + SELECT + DISTINCT ON (pic.pool_id_bech32) pool_id_bech32, + pod.ticker_name + FROM + grest.pool_info_cache AS pic + LEFT JOIN public.pool_offline_data AS pod ON pod.pmr_id = pic.meta_id + WHERE pod.ticker_name IS NOT NULL + ORDER BY + pic.pool_id_bech32, + pic.tx_id DESC + ) + + SELECT + pl.pool_id_bech32, + pm.ticker_name + FROM + _pool_list AS pl + LEFT JOIN _pool_meta AS pm ON pl.pool_id_bech32 = pm.pool_id_bech32 + WHERE + pool_status != 'retired' + ); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.pool_metadata(_pool_bech32_ids text [] DEFAULT NULL) +RETURNS TABLE ( + pool_id_bech32 character varying, + meta_url character varying, + meta_hash text, + meta_json jsonb, + pool_status text +) +LANGUAGE plpgsql +AS $$ +#variable_conflict use_column +BEGIN + RETURN QUERY + SELECT * FROM grest.pool_metadata(_pool_bech32_ids); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.pool_relays() +RETURNS TABLE ( + pool_id_bech32 character varying, + relays jsonb [], + pool_status text +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.pool_relays(); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.pool_stake_snapshot(_pool_bech32 text) +RETURNS TABLE ( + snapshot text, + epoch_no bigint, + nonce text, + pool_stake text, + active_stake text +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.pool_stake_snapshot(_pool_bech32); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.pool_updates(_pool_bech32 text DEFAULT NULL) +RETURNS TABLE ( + tx_hash text, + block_time integer, + pool_id_bech32 character varying, + pool_id_hex text, + active_epoch_no bigint, + vrf_key_hash text, + margin double precision, + fixed_cost text, + pledge text, + reward_addr character varying, + owners character varying [], + relays jsonb [], + meta_url character varying, + meta_hash text, + meta_json jsonb, + pool_status text, + retiring_epoch word31type +) +LANGUAGE plpgsql +AS $$ +#variable_conflict use_column +BEGIN + RETURN QUERY + SELECT + tx_hash, + block_time::integer, + pool_id_bech32, + pool_id_hex, + active_epoch_no, + vrf_key_hash, + margin, + fixed_cost::text, + pledge::text, + reward_addr, + owners, + relays, + meta_url, + meta_hash, + pod.json, + pool_status, + retiring_epoch + FROM + grest.pool_info_cache AS pic + LEFT JOIN public.pool_offline_data AS pod ON pod.pmr_id = pic.meta_id + WHERE + _pool_bech32 IS NULL + OR + pool_id_bech32 = _pool_bech32 + ORDER BY + tx_id DESC; +END; +$$; diff --git a/files/grest/rpc/v0/script.sql b/files/grest/rpc/v0/script.sql new file mode 100644 index 00000000..3702a433 --- /dev/null +++ b/files/grest/rpc/v0/script.sql @@ -0,0 +1,79 @@ +-- SCRIPT + +CREATE OR REPLACE FUNCTION grestv0.datum_info(_datum_hashes text []) +RETURNS TABLE ( + hash text, + value jsonb, + bytes text +) +LANGUAGE plpgsql +AS $$ +DECLARE + _datum_hashes_decoded bytea[]; +BEGIN + SELECT INTO _datum_hashes_decoded ARRAY_AGG(DECODE(d_hash, 'hex')) + FROM UNNEST(_datum_hashes) AS d_hash; + RETURN QUERY + SELECT + ENCODE(d.hash, 'hex'), + d.value, + ENCODE(d.bytes, 'hex') + FROM + datum AS d + WHERE + d.hash = ANY(_datum_hashes_decoded); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.native_script_list() +RETURNS TABLE ( + script_hash text, + creation_tx_hash text, + type scripttype, + script jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT + ENCODE(script.hash, 'hex'), + ENCODE(tx.hash, 'hex'), + script.type, + script.json + FROM script + INNER JOIN tx ON tx.id = script.tx_id + WHERE script.type IN ('timelock', 'multisig'); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.plutus_script_list() +RETURNS TABLE ( + script_hash text, + creation_tx_hash text +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT + ENCODE(script.hash, 'hex') AS script_hash, + ENCODE(tx.hash, 'hex') AS creation_tx_hash + FROM script + INNER JOIN tx ON tx.id = script.tx_id + WHERE script.type IN ('plutusV1', 'plutusV2'); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.script_redeemers(_script_hash text) +RETURNS TABLE ( + script_hash text, + redeemers jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.script_redeemers(_script_hash); +END; +$$; diff --git a/files/grest/rpc/v0/transactions.sql b/files/grest/rpc/v0/transactions.sql new file mode 100644 index 00000000..6e12da14 --- /dev/null +++ b/files/grest/rpc/v0/transactions.sql @@ -0,0 +1,87 @@ +-- TX + +CREATE OR REPLACE FUNCTION grestv0.tx_info(_tx_hashes text []) +RETURNS TABLE ( + tx_hash text, + block_hash text, + block_height word31type, + epoch_no word31type, + epoch_slot word31type, + absolute_slot word63type, + tx_timestamp integer, + tx_block_index word31type, + tx_size word31type, + total_output text, + fee text, + deposit text, + invalid_before text, + invalid_after text, + collateral_inputs jsonb, + collateral_output jsonb, + reference_inputs jsonb, + inputs jsonb, + outputs jsonb, + withdrawals jsonb, + assets_minted jsonb, + metadata jsonb, + certificates jsonb, + native_scripts jsonb, + plutus_contracts jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM tx_info(_tx_hashes); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.tx_metadata(_tx_hashes text []) +RETURNS TABLE ( + tx_hash text, + metadata jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.tx_metadata(_tx_hashes); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.tx_metalabels() +RETURNS TABLE (key text) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.tx_metalabels(); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.tx_status(_tx_hashes text []) +RETURNS TABLE ( + tx_hash text, + num_confirmations integer +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.tx_status(_tx_hashes); +END; +$$; + +CREATE OR REPLACE FUNCTION grestv0.tx_utxos(_tx_hashes text []) +RETURNS TABLE ( + tx_hash text, + inputs jsonb, + outputs jsonb +) +LANGUAGE plpgsql +AS $$ +BEGIN + RETURN QUERY + SELECT * FROM grest.tx_utxos(_tx_hashes); +END; +$$; diff --git a/files/grest/rpc/v0/views.sql b/files/grest/rpc/v0/views.sql new file mode 100644 index 00000000..38fdb35f --- /dev/null +++ b/files/grest/rpc/v0/views.sql @@ -0,0 +1,56 @@ +-- VIEWS + +DROP VIEW IF EXISTS grestv0.account_list; + +CREATE VIEW grestv0.account_list AS +SELECT stake_address.view AS id +FROM + stake_address; + +DROP VIEW IF EXISTS grestv0.asset_list; + +CREATE VIEW grestv0.asset_list AS +SELECT + ENCODE(ma.policy, 'hex') AS policy_id, + ENCODE(ma.name, 'hex') AS asset_name, + ma.fingerprint +FROM + public.multi_asset AS ma +ORDER BY ma.policy, ma.name; + +DROP VIEW IF EXISTS grestv0.asset_token_registry; + +CREATE VIEW grestv0.asset_token_registry AS +SELECT + asset_policy AS policy_id, + asset_name, + name AS asset_name_ascii, + ticker, + description, + url, + decimals, + logo +FROM + grest.asset_registry_cache; + +DROP VIEW IF EXISTS grestv0.blocks; + +CREATE VIEW grestv0.blocks 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 +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; diff --git a/files/grest/rpc/views/account_list.sql b/files/grest/rpc/views/account_list.sql index 2d26218b..deee0b83 100644 --- a/files/grest/rpc/views/account_list.sql +++ b/files/grest/rpc/views/account_list.sql @@ -2,7 +2,6 @@ DROP VIEW IF EXISTS grest.account_list; CREATE VIEW grest.account_list AS SELECT stake_address.view AS id -FROM - stake_address; +FROM stake_address; COMMENT ON VIEW grest.account_list IS 'Get a list of all accounts'; diff --git a/files/grest/rpc/views/asset_list.sql b/files/grest/rpc/views/asset_list.sql index 7fc71ded..edc860f2 100644 --- a/files/grest/rpc/views/asset_list.sql +++ b/files/grest/rpc/views/asset_list.sql @@ -5,8 +5,7 @@ SELECT ENCODE(ma.policy, 'hex') AS policy_id, ENCODE(ma.name, 'hex') AS asset_name, ma.fingerprint -FROM - public.multi_asset AS ma +FROM public.multi_asset AS ma ORDER BY ma.policy, ma.name; COMMENT ON VIEW grest.asset_list IS 'Get the list of all native assets'; diff --git a/files/grest/rpc/views/asset_token_registry.sql b/files/grest/rpc/views/asset_token_registry.sql index ca5c7561..edf7bf4a 100644 --- a/files/grest/rpc/views/asset_token_registry.sql +++ b/files/grest/rpc/views/asset_token_registry.sql @@ -10,7 +10,6 @@ SELECT url, decimals, logo -FROM - grest.asset_registry_cache; +FROM grest.asset_registry_cache; COMMENT ON VIEW grest.asset_token_registry IS 'Get a list of assets registered via token registry on github'; diff --git a/files/grest/rpc/views/blocks.sql b/files/grest/rpc/views/blocks.sql index dc50da9f..2ab9c0ec 100644 --- a/files/grest/rpc/views/blocks.sql +++ b/files/grest/rpc/views/blocks.sql @@ -15,11 +15,9 @@ SELECT b.proto_major, b.proto_minor, b.op_cert_counter -FROM - block AS b -LEFT JOIN slot_leader AS sl ON sl.id = b.slot_leader_id -LEFT JOIN pool_hash AS ph ON ph.id = sl.pool_hash_id -ORDER BY - b.id DESC; +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 VIEW grest.blocks IS 'Get detailed information about all blocks (paginated - latest first)'; diff --git a/specs/results/koiosapi-guild.yaml b/specs/results/koiosapi-guild.yaml index 62b4317a..acb33e2f 100644 --- a/specs/results/koiosapi-guild.yaml +++ b/specs/results/koiosapi-guild.yaml @@ -8,7 +8,7 @@ info: license: name: Creative Commons Attribution 4.0 International url: https://github.com/cardano-community/koios-artifacts/blob/main/LICENSE - version: v1.1.0rc + version: v1.1.0 description: | Koios is best described as a Decentralized and Elastic RESTful query layer for exploring data on Cardano blockchain to consume within applications/wallets/explorers/etc. This page not only provides an OpenAPI Spec for live implementation, but also ability to execute live demo from client browser against each endpoint with pre-filled examples. diff --git a/specs/results/koiosapi-mainnet.yaml b/specs/results/koiosapi-mainnet.yaml index 7953f725..228c8f37 100644 --- a/specs/results/koiosapi-mainnet.yaml +++ b/specs/results/koiosapi-mainnet.yaml @@ -8,7 +8,7 @@ info: license: name: Creative Commons Attribution 4.0 International url: https://github.com/cardano-community/koios-artifacts/blob/main/LICENSE - version: v1.1.0rc + version: v1.1.0 description: | Koios is best described as a Decentralized and Elastic RESTful query layer for exploring data on Cardano blockchain to consume within applications/wallets/explorers/etc. This page not only provides an OpenAPI Spec for live implementation, but also ability to execute live demo from client browser against each endpoint with pre-filled examples. diff --git a/specs/results/koiosapi-preprod.yaml b/specs/results/koiosapi-preprod.yaml index 5de9ab1f..96884c0f 100644 --- a/specs/results/koiosapi-preprod.yaml +++ b/specs/results/koiosapi-preprod.yaml @@ -8,7 +8,7 @@ info: license: name: Creative Commons Attribution 4.0 International url: https://github.com/cardano-community/koios-artifacts/blob/main/LICENSE - version: v1.1.0rc + version: v1.1.0 description: | Koios is best described as a Decentralized and Elastic RESTful query layer for exploring data on Cardano blockchain to consume within applications/wallets/explorers/etc. This page not only provides an OpenAPI Spec for live implementation, but also ability to execute live demo from client browser against each endpoint with pre-filled examples. diff --git a/specs/results/koiosapi-preview.yaml b/specs/results/koiosapi-preview.yaml index 17cf6ca3..a8b32f80 100644 --- a/specs/results/koiosapi-preview.yaml +++ b/specs/results/koiosapi-preview.yaml @@ -8,7 +8,7 @@ info: license: name: Creative Commons Attribution 4.0 International url: https://github.com/cardano-community/koios-artifacts/blob/main/LICENSE - version: v1.1.0rc + version: v1.1.0 description: | Koios is best described as a Decentralized and Elastic RESTful query layer for exploring data on Cardano blockchain to consume within applications/wallets/explorers/etc. This page not only provides an OpenAPI Spec for live implementation, but also ability to execute live demo from client browser against each endpoint with pre-filled examples. diff --git a/specs/templates/1-api-info.yaml b/specs/templates/1-api-info.yaml index 53edfae3..5086faec 100644 --- a/specs/templates/1-api-info.yaml +++ b/specs/templates/1-api-info.yaml @@ -7,7 +7,7 @@ info: license: name: Creative Commons Attribution 4.0 International url: https://github.com/cardano-community/koios-artifacts/blob/main/LICENSE - version: v1.1.0rc + version: v1.1.0 description: | Koios is best described as a Decentralized and Elastic RESTful query layer for exploring data on Cardano blockchain to consume within applications/wallets/explorers/etc. This page not only provides an OpenAPI Spec for live implementation, but also ability to execute live demo from client browser against each endpoint with pre-filled examples.