Skip to content

Commit

Permalink
Koios-1.0.10rc (#159)
Browse files Browse the repository at this point in the history
## Description (for this PR)
<!--- Describe your changes -->
- [x] Update version to Koios-1.0.10rc
- [x] Add account_utxos & specs update, closes #146
- [x] Fix pool_delegators endpoint specs doc, closes #157
- [x] Add param_updates, closes #158
- [x] Update changelog
- [x] Make input [hex] params case insensitive for asset endpoints
- [x] Uncertainty around adopting dbsync 13.1.0.0 (would require manually creating indexes for those missing)
  - [x] Investigate `tx_info` performance issue for 13.1.0.0 (some addresses only)
  - [x] Include missing indexes re-creation as part of setup-grest on guild-ops repo
- [x] Update docs for configuring statement_timeout in postgrest
- [x] Test & Resolve any issues reported via schemathesis
- [x] Prepare Draft Release notes
  - [x] Mention in notes asking to shutdown dbsync if up during upgrade to 13.1.0.0 - as it can cause locks
  • Loading branch information
rdlrt authored Feb 23, 2023
1 parent 50993af commit b3b91b5
Show file tree
Hide file tree
Showing 26 changed files with 787 additions and 221 deletions.
59 changes: 59 additions & 0 deletions files/grest/rpc/00_blockchain/param_updates.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,59 @@
CREATE OR REPLACE FUNCTION grest.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 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;
$$;

COMMENT ON FUNCTION grest.param_updates IS 'Parameter updates applied to the network';
4 changes: 2 additions & 2 deletions files/grest/rpc/01_cached_tables/asset_registry_cache.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
DROP TABLE IF EXISTS grest.asset_registry_cache;
DROP TABLE IF EXISTS grest.asset_registry_cache CASCADE;

CREATE TABLE grest.asset_registry_cache (
asset_policy text NOT NULL,
Expand Down Expand Up @@ -56,4 +56,4 @@ BEGIN
logo = _logo,
decimals = _decimals;
END;
$$;
$$;
26 changes: 26 additions & 0 deletions files/grest/rpc/02_indexes/13_1_00.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,26 @@
/* Unique Indexes that got dropped at 13.1.0.0 */
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);
CREATE UNIQUE INDEX IF NOT EXISTS unique_delegation ON public.delegation USING btree (tx_id, cert_index);
CREATE UNIQUE INDEX IF NOT EXISTS unique_epoch_param ON public.epoch_param USING btree (epoch_no, block_id);
CREATE UNIQUE INDEX IF NOT EXISTS unique_ma_tx_mint ON public.ma_tx_mint USING btree (ident, tx_id);
CREATE UNIQUE INDEX IF NOT EXISTS unique_ma_tx_out ON public.ma_tx_out USING btree (ident, tx_out_id);
CREATE UNIQUE INDEX IF NOT EXISTS unique_param_proposal ON public.param_proposal USING btree (key, registered_tx_id);
CREATE UNIQUE INDEX IF NOT EXISTS unique_pool_owner ON public.pool_owner USING btree (addr_id, pool_update_id);
CREATE UNIQUE INDEX IF NOT EXISTS unique_pool_relay ON public.pool_relay USING btree (update_id, ipv4, ipv6, dns_name);
CREATE UNIQUE INDEX IF NOT EXISTS unique_pool_retiring ON public.pool_retire USING btree (announced_tx_id, cert_index);
CREATE UNIQUE INDEX IF NOT EXISTS unique_pool_update ON public.pool_update USING btree (registered_tx_id, cert_index);
CREATE UNIQUE INDEX IF NOT EXISTS unique_pot_transfer ON public.pot_transfer USING btree (tx_id, cert_index);
CREATE UNIQUE INDEX IF NOT EXISTS unique_redeemer ON public.redeemer USING btree (tx_id, purpose, index);
CREATE UNIQUE INDEX IF NOT EXISTS unique_ref_tx_in ON reference_tx_in USING btree (tx_in_id, tx_out_id, tx_out_index);
CREATE UNIQUE INDEX IF NOT EXISTS unique_reserves ON public.reserve USING btree (addr_id, tx_id, cert_index);
CREATE UNIQUE INDEX IF NOT EXISTS unique_stake_deregistration ON public.stake_deregistration USING btree (tx_id, cert_index);
CREATE UNIQUE INDEX IF NOT EXISTS unique_stake_registration ON public.stake_registration USING btree (tx_id, cert_index);
CREATE UNIQUE INDEX IF NOT EXISTS unique_treasury ON public.treasury USING btree (addr_id, tx_id, cert_index);
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) ;
2 changes: 1 addition & 1 deletion files/grest/rpc/account/account_addresses.sql
Original file line number Diff line number Diff line change
Expand Up @@ -33,7 +33,7 @@ BEGIN
AND txo.index::smallint = tx_in.tx_out_index::smallint
WHERE
txo.stake_address_id = ANY(sa_id_list)
AND tx_in.id IS NULL
AND TX_IN.TX_OUT_ID IS NULL
) x
)
SELECT
Expand Down
6 changes: 3 additions & 3 deletions files/grest/rpc/account/account_assets.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
CREATE FUNCTION grest.account_assets (_stake_addresses text[])
CREATE OR REPLACE FUNCTION grest.account_assets (_stake_addresses text[])
RETURNS TABLE (
stake_address varchar,
asset_list json
Expand Down Expand Up @@ -34,9 +34,9 @@ BEGIN
AND TXO.INDEX::smallint = TX_IN.TX_OUT_INDEX::smallint
WHERE
sa.id = ANY(sa_id_list)
AND TX_IN.ID IS NULL
AND TX_IN.TX_OUT_ID IS NULL
GROUP BY
sa.view, MA.policy, MA.name, MA.fingerprint
sa.view, MA.policy, MA.name, MA.fingerprint, aic.decimals
)

SELECT
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/account/account_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -119,7 +119,7 @@ BEGIN
AND TX_OUT.INDEX::smallint = TX_IN.TX_OUT_INDEX::smallint
WHERE
TX_OUT.STAKE_ADDRESS_ID = ANY(sa_id_list)
AND TX_IN.ID IS NULL
AND TX_IN.TX_OUT_ID IS NULL
GROUP BY
tx_out.stake_address_id
) UTXO_T ON UTXO_T.stake_address_id = status_t.id
Expand Down
36 changes: 36 additions & 0 deletions files/grest/rpc/account/account_utxos.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,36 @@
CREATE OR REPLACE FUNCTION grest.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
LEFT JOIN tx_in ON tx_in.tx_out_id = tx_out.tx_id
AND tx_in.tx_out_index = tx_out.index
INNER JOIN tx ON tx.id = tx_out.tx_id
LEFT JOIN block b ON b.id = tx.block_id
WHERE
tx_in.tx_out_id IS NULL
AND
tx_out.stake_address_id = (select id from stake_address where view = _stake_address);

END;
$$;

COMMENT ON FUNCTION grest.account_utxos IS 'Get non-empty UTxOs associated with a given stake address';
4 changes: 2 additions & 2 deletions files/grest/rpc/address/address_assets.sql
Original file line number Diff line number Diff line change
Expand Up @@ -25,9 +25,9 @@ BEGIN
AND TXO.INDEX::smallint = TX_IN.TX_OUT_INDEX::smallint
WHERE
TXO.address = ANY(_addresses)
AND TX_IN.id IS NULL
AND TX_IN.tx_out_id IS NULL
GROUP BY
TXO.address, MA.policy, MA.name, ma.fingerprint
TXO.address, MA.policy, MA.name, ma.fingerprint, aic.decimals
)

SELECT
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/address/address_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -43,7 +43,7 @@ BEGIN
AND tx_in.tx_out_index = tx_out.index
INNER JOIN tx ON tx.id = tx_out.tx_id
WHERE
tx_in.id IS NULL
tx_in.tx_out_id IS NULL
AND
tx_out.address = ANY(_addresses)
)
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/address/credential_utxos.sql
Original file line number Diff line number Diff line change
Expand Up @@ -30,6 +30,6 @@ BEGIN
WHERE
payment_cred = any(_payment_cred_bytea)
AND
tx_in.id IS NULL;
tx_in.tx_out_id IS NULL;
END;
$$;
2 changes: 1 addition & 1 deletion files/grest/rpc/assets/asset_addresses.sql
Original file line number Diff line number Diff line change
Expand Up @@ -48,7 +48,7 @@ BEGIN
AND txo.index::smallint = tx_in.tx_out_index::smallint
WHERE
mto.ident = _asset_id
AND tx_in.id IS NULL
AND tx_in.tx_out_id IS NULL
) x
GROUP BY
x.address;
Expand Down
60 changes: 55 additions & 5 deletions files/grest/rpc/assets/asset_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,13 +14,63 @@ CREATE OR REPLACE FUNCTION grest.asset_info (_asset_policy text, _asset_name tex
)
LANGUAGE PLPGSQL
AS $$
DECLARE
_asset_id_list bigint[];
BEGIN


-- find all asset id's based on nested array input
SELECT INTO _asset_id_list ARRAY_AGG(id)
FROM (
SELECT DISTINCT mu.id
FROM
multi_asset mu
WHERE
mu.policy = DECODE(_asset_policy, 'hex') AND mu.name = DECODE(_asset_name, 'hex')
) AS tmp;

RETURN QUERY
SELECT grest.asset_info_bulk(array[array[_asset_policy, _asset_name]]);


SELECT
ENCODE(ma.policy, 'hex'),
ENCODE(ma.name, 'hex'),
ENCODE(ma.name, 'escape'),
ma.fingerprint,
ENCODE(tx.hash, 'hex'),
aic.total_supply::text,
aic.mint_cnt,
aic.burn_cnt,
EXTRACT(epoch from aic.creation_time)::integer,
metadata.minting_tx_metadata,
CASE WHEN arc.name IS NULL THEN NULL
ELSE
JSON_BUILD_OBJECT(
'name', arc.name,
'description', arc.description,
'ticker', arc.ticker,
'url', arc.url,
'logo', arc.logo,
'decimals', arc.decimals
)
END
FROM
multi_asset ma
INNER JOIN grest.asset_info_cache aic ON aic.asset_id = ma.id
INNER JOIN tx ON tx.id = aic.last_mint_tx_id
LEFT JOIN grest.asset_registry_cache arc ON arc.asset_policy = ENCODE(ma.policy,'hex') AND arc.asset_name = ENCODE(ma.name,'hex')
LEFT JOIN LATERAL (
SELECT
JSONB_OBJECT_AGG(
key::text,
json
) AS minting_tx_metadata
FROM
tx_metadata tm
WHERE
tm.tx_id = tx.id
) metadata ON TRUE
WHERE
ma.id = any (_asset_id_list);

END;
$$;

COMMENT ON FUNCTION grest.asset_info IS 'Get the information of an asset incl first minting & token registry metadata';

2 changes: 1 addition & 1 deletion files/grest/rpc/assets/asset_info_bulk.sql
Original file line number Diff line number Diff line change
Expand Up @@ -60,7 +60,7 @@ BEGIN
multi_asset ma
INNER JOIN grest.asset_info_cache aic ON aic.asset_id = ma.id
INNER JOIN tx ON tx.id = aic.last_mint_tx_id
LEFT JOIN grest.asset_registry_cache arc ON DECODE(arc.asset_policy, 'hex') = ma.policy AND DECODE(arc.asset_name, 'hex') = ma.name
LEFT JOIN grest.asset_registry_cache arc ON arc.asset_policy = ENCODE(ma.policy,'hex') AND arc.asset_name = ENCODE(ma.name,'hex')
LEFT JOIN LATERAL (
SELECT
JSONB_OBJECT_AGG(
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/assets/policy_asset_addresses.sql
Original file line number Diff line number Diff line change
Expand Up @@ -38,7 +38,7 @@ BEGIN
LEFT JOIN tx_in ON txo.tx_id = tx_in.tx_out_id
AND txo.index::smallint = tx_in.tx_out_index::smallint
WHERE
tx_in.id IS NULL
tx_in.tx_out_id IS NULL
) x
GROUP BY
x.asset_name, x.address;
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/assets/policy_asset_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -66,7 +66,7 @@ BEGIN
multi_asset ma
INNER JOIN grest.asset_info_cache aic ON aic.asset_id = ma.id
INNER JOIN tx ON tx.id = aic.last_mint_tx_id
LEFT JOIN grest.asset_registry_cache arc ON DECODE(arc.asset_policy, 'hex') = ma.policy AND DECODE(arc.asset_name, 'hex') = ma.name
LEFT JOIN grest.asset_registry_cache arc ON arc.asset_policy = ENCODE(ma.policy,'hex') AND arc.asset_name = ENCODE(ma.name, 'hex')
LEFT JOIN LATERAL (
SELECT
JSONB_OBJECT_AGG(
Expand Down
Loading

0 comments on commit b3b91b5

Please sign in to comment.