-
Notifications
You must be signed in to change notification settings - Fork 25
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
## 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
Showing
26 changed files
with
787 additions
and
221 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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'; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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) ; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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'; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -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; | ||
$$; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.