Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Koios v1.3.0 #306

Merged
merged 15 commits into from
Nov 20, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
2 changes: 1 addition & 1 deletion files/grest/.sqlfluff
Original file line number Diff line number Diff line change
Expand Up @@ -7,7 +7,7 @@ extended_capitalisation_policy = upper
idented_joins = True
indented_using_on = False
tab_space_size = 2
large_file_skip_byte_limit=35000
large_file_skip_byte_limit=50000

[sqlfluff:indentation]
tab_space_size = 2
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/000_utilities/cip129.sql
Original file line number Diff line number Diff line change
Expand Up @@ -142,7 +142,7 @@ END;
$$;

CREATE OR REPLACE FUNCTION grest.cip129_from_gov_action_id(_proposal_id text)
RETURNS text[]
RETURNS text []
LANGUAGE plpgsql STABLE
AS $$
DECLARE
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/000_utilities/cip5.sql
Original file line number Diff line number Diff line change
Expand Up @@ -16,4 +16,4 @@ BEGIN
RETURN b32_encode('stake', _raw::text);
END IF;
END;
$$;
$$;
2 changes: 1 addition & 1 deletion files/grest/rpc/01_cached_tables/pool_history_cache.sql
Original file line number Diff line number Diff line change
Expand Up @@ -219,7 +219,7 @@ $$;

COMMENT ON FUNCTION grest.get_pool_history_data_bulk IS 'Pool block production and reward history from a given epoch until optional later epoch, for all or particular subset of pools'; -- noqa: LT01

CREATE OR REPLACE FUNCTION grest.pool_history_cache_update(_epoch_no_to_insert_from bigint DEFAULT NULL)
CREATE OR REPLACE FUNCTION grest.pool_history_cache_update(_epoch_no_to_insert_from bigint DEFAULT null)
RETURNS void
LANGUAGE plpgsql
AS $$
Expand Down
2 changes: 1 addition & 1 deletion files/grest/rpc/01_cached_tables/pool_info_cache.sql
Original file line number Diff line number Diff line change
Expand Up @@ -63,7 +63,7 @@ BEGIN
_pool_status := 'retired';
END IF;

DELETE FROM grest.pool_info_cache WHERE pool_hash_id = _hash_id;
-- not sure why we would want to delete all historic update records: DELETE FROM grest.pool_info_cache WHERE pool_hash_id = _hash_id;

INSERT INTO grest.pool_info_cache (
tx_id,
Expand Down
6 changes: 3 additions & 3 deletions files/grest/rpc/02_indexes/13_3_00.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
CREATE INDEX IF NOT EXISTS pool_stat_pool_hash_id ON pool_stat(pool_hash_id);
CREATE INDEX IF NOT EXISTS pool_stat_epoch_no ON pool_stat(epoch_no);
CREATE INDEX IF NOT EXISTS pool_stat_pool_hash_id ON pool_stat (pool_hash_id);
CREATE INDEX IF NOT EXISTS pool_stat_epoch_no ON pool_stat (epoch_no);
CREATE INDEX IF NOT EXISTS idx_reward_rest_addr_id ON reward_rest (addr_id);
CREATE INDEX IF NOT EXISTS idx_reward_rest_spendable_epoch ON reward_rest (spendable_epoch);
CREATE INDEX IF NOT EXISTS idx_reward_rest_spendable_epoch ON reward_rest (spendable_epoch);
2 changes: 1 addition & 1 deletion files/grest/rpc/02_indexes/13_5_0_2.sql
Original file line number Diff line number Diff line change
@@ -1,3 +1,3 @@
DROP INDEX IF EXISTS idx_stake_address_view;
CREATE INDEX IF NOT EXISTS idx_stake_address_hash_raw ON stake_address (hash_raw);
CREATE INDEX IF NOT EXISTS idx_drep_hash_raw ON drep_hash (raw);
CREATE INDEX IF NOT EXISTS idx_drep_hash_raw ON drep_hash (raw);
4 changes: 4 additions & 0 deletions files/grest/rpc/02_indexes/13_6_0_1.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,4 @@
CREATE INDEX IF NOT EXISTS idx_address_address ON address USING hash (address);
CREATE INDEX IF NOT EXISTS idx_tx_out_stake_address_id ON tx_out(stake_address_id) ;
CREATE INDEX IF NOT EXISTS idx_tx_out_address_id ON tx_out(address_id) ;
CREATE INDEX IF NOT EXISTS idx_address_stake_address_id ON address(stake_address_id) ;
6 changes: 4 additions & 2 deletions files/grest/rpc/account/account_addresses.sql
Original file line number Diff line number Diff line change
Expand Up @@ -27,10 +27,11 @@ BEGIN
FROM
(
SELECT
txo.address,
a.address,
txo.stake_address_id,
txo.id
FROM tx_out AS txo
INNER JOIN address AS a ON a.id = txo.address_id
WHERE txo.stake_address_id = ANY(sa_id_list)
AND txo.consumed_by_tx_id IS NULL
) AS x
Expand All @@ -53,10 +54,11 @@ BEGIN
FROM
(
SELECT
txo.address,
a.address,
txo.stake_address_id,
txo.id
FROM tx_out AS txo
INNER JOIN address AS a ON a.id = txo.address_id
WHERE txo.stake_address_id = ANY(sa_id_list)
LIMIT (CASE WHEN _first_only IS TRUE THEN 1 ELSE NULL END)
) AS x
Expand Down
5 changes: 5 additions & 0 deletions files/grest/rpc/account/account_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -87,6 +87,11 @@ BEGIN
FROM delegation_vote AS dv1
WHERE dv1.addr_id = dv.addr_id
AND dv1.id > dv.id)
AND NOT EXISTS (
SELECT TRUE
FROM stake_deregistration
WHERE stake_deregistration.addr_id = dv.addr_id
AND stake_deregistration.tx_id > dv.tx_id)
) AS vote_t ON vote_t.addr_id = status_t.id
LEFT JOIN (
SELECT
Expand Down
69 changes: 36 additions & 33 deletions files/grest/rpc/account/account_rewards.sql
Original file line number Diff line number Diff line change
Expand Up @@ -18,44 +18,47 @@ BEGIN
FROM UNNEST(_stake_addresses) AS n
);

IF _epoch_no IS NULL THEN
RETURN QUERY
RETURN QUERY
SELECT
grest.cip5_hex_to_stake_addr(all_rewards.stake_address_raw)::varchar,
JSONB_AGG(
JSONB_BUILD_OBJECT(
'earned_epoch', all_rewards.earned_epoch,
'spendable_epoch', all_rewards.spendable_epoch,
'amount', all_rewards.amount::text,
'type', all_rewards.type,
'pool_id', CASE WHEN all_rewards.pool_id_raw IS NULL THEN NULL ELSE b32_encode('pool', all_rewards.pool_id_raw::text) END
)
) AS rewards
FROM (
SELECT
grest.cip5_hex_to_stake_addr(sa.hash_raw)::varchar,
JSONB_AGG(
JSONB_BUILD_OBJECT(
'earned_epoch', r.earned_epoch,
'spendable_epoch', r.spendable_epoch,
'amount', r.amount::text,
'type', r.type,
'pool_id', b32_encode('pool', ph.hash_raw::text)
)
) AS rewards
sa.hash_raw as stake_address_raw,
r.type,
r.amount,
r.earned_epoch,
r.spendable_epoch,
ph.hash_raw as pool_id_raw
FROM reward AS r
LEFT JOIN pool_hash AS ph ON r.pool_id = ph.id
INNER JOIN pool_hash AS ph ON r.pool_id = ph.id
INNER JOIN stake_address AS sa ON sa.id = r.addr_id
WHERE r.addr_id = ANY(sa_id_list)
GROUP BY sa.hash_raw;
ELSE
RETURN QUERY
AND CASE WHEN _epoch_no IS NULL THEN TRUE ELSE r.earned_epoch = _epoch_no END
--
UNION ALL
--
SELECT
grest.cip5_hex_to_stake_addr(sa.hash_raw)::varchar,
JSONB_AGG(
JSONB_BUILD_OBJECT(
'earned_epoch', r.earned_epoch,
'spendable_epoch', r.spendable_epoch,
'amount', r.amount::text,
'type', r.type,
'pool_id', b32_encode('pool', ph.hash_raw::text)
)
) AS rewards
FROM reward AS r
LEFT JOIN pool_hash AS ph ON r.pool_id = ph.id
INNER JOIN stake_address AS sa ON sa.id = r.addr_id
WHERE r.addr_id = ANY(sa_id_list)
AND r.earned_epoch = _epoch_no
GROUP BY sa.hash_raw;
END IF;
sa.hash_raw as stake_address_raw,
rr.type,
rr.amount,
rr.earned_epoch,
rr.spendable_epoch,
null as pool_id_raw
FROM reward_rest AS rr
INNER JOIN stake_address AS sa ON sa.id = rr.addr_id
WHERE rr.addr_id = ANY(sa_id_list)
AND CASE WHEN _epoch_no IS NULL THEN TRUE ELSE rr.earned_epoch = _epoch_no END
) as all_rewards
GROUP BY all_rewards.stake_address_raw;
END;
$$;

Expand Down
5 changes: 3 additions & 2 deletions files/grest/rpc/account/account_utxos.sql
Original file line number Diff line number Diff line change
Expand Up @@ -54,10 +54,10 @@ BEGIN
SELECT
ENCODE(tx.hash, 'hex')::text AS tx_hash,
tx_out.index::smallint,
tx_out.address::text,
a.address::text,
tx_out.value::text,
grest.cip5_hex_to_stake_addr(sa.hash_raw) as stake_address,
ENCODE(tx_out.payment_cred, 'hex') AS payment_cred,
ENCODE(a.payment_cred, 'hex') AS payment_cred,
b.epoch_no,
b.block_no,
EXTRACT(EPOCH FROM b.time)::integer AS block_time,
Expand Down Expand Up @@ -89,6 +89,7 @@ BEGIN
END) AS is_spent
FROM tx_out
INNER JOIN tx ON tx_out.tx_id = tx.id
INNER JOIN address AS a ON a.id = tx_out.address_id
LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id
LEFT JOIN block AS b ON b.id = tx.block_id
LEFT JOIN datum ON datum.id = tx_out.inline_datum_id
Expand Down
7 changes: 4 additions & 3 deletions files/grest/rpc/address/address_assets.sql
Original file line number Diff line number Diff line change
Expand Up @@ -14,7 +14,7 @@ BEGIN

WITH _all_assets AS (
SELECT
txo.address,
a.address,
ma.policy,
ma.name,
ma.fingerprint,
Expand All @@ -24,10 +24,11 @@ BEGIN
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)
INNER JOIN address AS a ON a.id = txo.address_id
WHERE a.address = ANY(_addresses)
AND txo.consumed_by_tx_id IS NULL
GROUP BY
txo.address, ma.policy, ma.name, ma.fingerprint, aic.decimals
a.address, ma.policy, ma.name, ma.fingerprint, aic.decimals
)

SELECT
Expand Down
12 changes: 7 additions & 5 deletions files/grest/rpc/address/address_info.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,30 +13,32 @@ DECLARE
BEGIN
CREATE TEMPORARY TABLE _known_addresses AS
SELECT
DISTINCT ON (tx_out.address) tx_out.address,
DISTINCT ON (tx_out.address_id) a.address,
sa.hash_raw AS stake_address_raw,
COALESCE(tx_out.address_has_script, 'false') AS script_address
COALESCE(a.has_script, 'false') AS script_address
FROM tx_out
INNER JOIN address AS a ON a.id = tx_out.address_id
LEFT JOIN stake_address AS sa ON sa.id = tx_out.stake_address_id
WHERE tx_out.address = ANY(_addresses);
WHERE a.address = ANY(_addresses);

RETURN QUERY
WITH _all_utxos AS (
SELECT
tx.id,
tx.hash,
tx_out.id AS txo_id,
tx_out.address,
a.address,
tx_out.value,
tx_out.index,
tx.block_id,
tx_out.data_hash,
tx_out.inline_datum_id,
tx_out.reference_script_id
FROM tx_out
INNER JOIN address AS a ON a.id = tx_out.address_id
INNER JOIN tx ON tx.id = tx_out.tx_id
WHERE tx_out.consumed_by_tx_id IS NULL
AND tx_out.address = ANY(_addresses)
AND a.address = ANY(_addresses)
)

SELECT
Expand Down
6 changes: 4 additions & 2 deletions files/grest/rpc/address/address_txs.sql
Original file line number Diff line number Diff line change
Expand Up @@ -21,15 +21,17 @@ BEGIN
FROM (
SELECT tx_id
FROM tx_out
WHERE address = ANY (_addresses)
INNER JOIN address AS a on a.id = tx_out.address_id
WHERE a.address = ANY (_addresses)
AND tx_id >= _tx_id_min
--
UNION
--
SELECT consumed_by_tx_id
FROM tx_out
INNER JOIN address AS a ON a.id = tx_out.address_id
WHERE tx_out.consumed_by_tx_id IS NOT NULL
AND tx_out.address = ANY(_addresses)
AND a.address = ANY(_addresses)
AND tx_out.consumed_by_tx_id >= _tx_id_min
) AS tmp;

Expand Down
10 changes: 6 additions & 4 deletions files/grest/rpc/address/address_utxos.sql
Original file line number Diff line number Diff line change
Expand Up @@ -35,20 +35,21 @@ BEGIN
)
END) as assets
FROM tx_out AS txo
INNER JOIN address AS a ON a.id = txo.address_id
INNER JOIN ma_tx_out AS mto ON mto.tx_out_id = txo.id
LEFT JOIN multi_asset AS ma ON ma.id = mto.ident
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id
WHERE txo.address = ANY(_addresses)
WHERE a.address = ANY(_addresses)
AND txo.consumed_by_tx_id IS NULL
GROUP BY txo.id
)
SELECT
ENCODE(tx.hash, 'hex')::text AS tx_hash,
tx_out.index::smallint,
tx_out.address::text,
a.address::text,
tx_out.value::text,
grest.cip5_hex_to_stake_addr(sa.hash_raw)::text as stake_address,
ENCODE(tx_out.payment_cred, 'hex') AS payment_cred,
ENCODE(a.payment_cred, 'hex') AS payment_cred,
b.epoch_no,
b.block_no,
EXTRACT(EPOCH FROM b.time)::integer AS block_time,
Expand Down Expand Up @@ -79,13 +80,14 @@ BEGIN
ELSE true
END) AS is_spent
FROM tx_out
INNER JOIN address AS a ON a.id = tx_out.address_id
INNER JOIN tx ON tx_out.tx_id = tx.id
LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id
LEFT JOIN block AS b ON b.id = tx.block_id
LEFT JOIN datum ON datum.id = tx_out.inline_datum_id
LEFT JOIN script ON script.id = tx_out.reference_script_id
LEFT JOIN _assets ON tx_out.id = _assets.id
WHERE tx_out.address = ANY(_addresses)
WHERE a.address = ANY(_addresses)
AND tx_out.consumed_by_tx_id IS NULL
;
END;
Expand Down
6 changes: 4 additions & 2 deletions files/grest/rpc/address/credential_txs.sql
Original file line number Diff line number Diff line change
Expand Up @@ -29,15 +29,17 @@ BEGIN
FROM (
SELECT tx_id
FROM tx_out
WHERE payment_cred = ANY(_payment_cred_bytea)
INNER JOIN address AS a ON tx_out.address_id = a.id
WHERE a.payment_cred = ANY(_payment_cred_bytea)
AND tx_id >= _tx_id_min
--
UNION
--
SELECT consumed_by_tx_id AS tx_id
FROM tx_out
INNER JOIN address AS a ON tx_out.address_id = a.id
WHERE tx_out.consumed_by_tx_id IS NOT NULL
AND tx_out.payment_cred = ANY(_payment_cred_bytea)
AND a.payment_cred = ANY(_payment_cred_bytea)
AND tx_out.consumed_by_tx_id >= _tx_id_min
) AS tmp;

Expand Down
10 changes: 6 additions & 4 deletions files/grest/rpc/address/credential_utxos.sql
Original file line number Diff line number Diff line change
Expand Up @@ -41,20 +41,21 @@ BEGIN
)
END) as assets
FROM tx_out AS txo
INNER JOIN address AS a ON a.id = txo.address_id
INNER JOIN ma_tx_out AS mto ON mto.tx_out_id = txo.id
LEFT JOIN multi_asset AS ma ON ma.id = mto.ident
LEFT JOIN grest.asset_info_cache AS aic ON aic.asset_id = ma.id
WHERE txo.payment_cred = ANY(_payment_cred_bytea)
WHERE a.payment_cred = ANY(_payment_cred_bytea)
AND txo.consumed_by_tx_id IS NULL
GROUP BY txo.id
)
SELECT
ENCODE(tx.hash, 'hex')::text AS tx_hash,
tx_out.index::smallint,
tx_out.address::text,
a.address::text,
tx_out.value::text,
grest.cip5_hex_to_stake_addr(sa.hash_raw)::text as stake_address,
ENCODE(tx_out.payment_cred, 'hex') AS payment_cred,
ENCODE(a.payment_cred, 'hex') AS payment_cred,
b.epoch_no,
b.block_no,
EXTRACT(EPOCH FROM b.time)::integer AS block_time,
Expand Down Expand Up @@ -85,13 +86,14 @@ BEGIN
ELSE true
END) AS is_spent
FROM tx_out
INNER JOIN address AS a ON a.id = tx_out.address_id
INNER JOIN tx ON tx_out.tx_id = tx.id
LEFT JOIN stake_address AS sa ON tx_out.stake_address_id = sa.id
LEFT JOIN block AS b ON b.id = tx.block_id
LEFT JOIN datum ON datum.id = tx_out.inline_datum_id
LEFT JOIN script ON script.id = tx_out.reference_script_id
LEFT JOIN _assets ON tx_out.id = _assets.id
WHERE tx_out.payment_cred = ANY(_payment_cred_bytea)
WHERE a.payment_cred = ANY(_payment_cred_bytea)
AND tx_out.consumed_by_tx_id IS NULL
;
END;
Expand Down
Loading
Loading