diff --git a/files/grest/rpc/01_cached_tables/pool_info_cache.sql b/files/grest/rpc/01_cached_tables/pool_info_cache.sql index eb2b4150..dd589cd3 100644 --- a/files/grest/rpc/01_cached_tables/pool_info_cache.sql +++ b/files/grest/rpc/01_cached_tables/pool_info_cache.sql @@ -65,6 +65,8 @@ BEGIN _pool_status := 'retired'; END IF; + DELETE FROM grest.pool_info_cache WHERE pool_hash_id = _hash_id; + INSERT INTO grest.pool_info_cache ( tx_id, update_id, @@ -188,8 +190,8 @@ BEGIN UPDATE grest.pool_info_cache SET - pool_status = _pool_status, - retiring_epoch = _retiring_epoch + pool_status = _pool_status, + retiring_epoch = _retiring_epoch WHERE pool_hash_id = _pool_hash_id AND tx_id = _latest_pool_update_tx_id; diff --git a/files/grest/rpc/pool/pool_info.sql b/files/grest/rpc/pool/pool_info.sql index f2528ebf..c5ac76fd 100644 --- a/files/grest/rpc/pool/pool_info.sql +++ b/files/grest/rpc/pool/pool_info.sql @@ -42,30 +42,52 @@ BEGIN RETURN QUERY WITH _all_pool_info AS ( - SELECT DISTINCT ON (pic.pool_id_bech32) - * + SELECT DISTINCT ON (pic.pool_hash_id) + pic.pool_hash_id, + pic.active_epoch_no, + pic.update_id, + pic.pool_status, + pic.retiring_epoch, + pic.meta_id, + ph.view, + ph.hash_raw FROM grest.pool_info_cache AS pic - WHERE pic.pool_id_bech32 = ANY(SELECT UNNEST(_pool_bech32_ids)) + INNER JOIN public.pool_hash AS ph ON ph.id = pic.pool_hash_id + WHERE ph.view = ANY(SELECT UNNEST(_pool_bech32_ids)) ORDER BY - pic.pool_id_bech32, + pic.pool_hash_id, pic.tx_id DESC ) - SELECT - api.pool_id_bech32, - api.pool_id_hex, - api.active_epoch_no, - api.vrf_key_hash, - api.margin, - api.fixed_cost::text, - api.pledge::text, - api.deposit::text, - api.reward_addr, - api.owners, - api.relays, - api.meta_url, - api.meta_hash, - offline_data.json, + ph.view AS pool_id_bech32, + ENCODE(ph.hash_raw::bytea, 'hex') AS pool_id_hex, + pu.active_epoch_no, + ENCODE(pu.vrf_key_hash, 'hex') AS vrf_key_hash, + pu.margin, + pu.fixed_cost::text, + pu.pledge::text, + pu.deposit::text, + sa.view AS reward_addr, + ARRAY( + SELECT sa.view + FROM public.pool_owner AS po + INNER JOIN public.stake_address AS sa ON sa.id = po.addr_id + WHERE po.pool_update_id = api.update_id + ) AS owners, + ARRAY( + SELECT JSONB_BUILD_OBJECT( + 'ipv4', pr.ipv4, + 'ipv6', pr.ipv6, + 'dns', pr.dns_name, + 'srv', pr.dns_srv_name, + 'port', pr.port + ) relay + FROM public.pool_relay AS pr + WHERE pr.update_id = api.update_id + ) AS relays, + pmr.url AS meta_url, + ENCODE(pmr.hash,'hex') AS meta_hash, + ocpd.json, api.pool_status, api.retiring_epoch, ENCODE(block_data.op_cert::bytea, 'hex'), @@ -78,14 +100,11 @@ BEGIN live.delegators, ROUND((live.stake / _saturation_limit) * 100, 2) FROM _all_pool_info AS api - LEFT JOIN LATERAL ( - SELECT ocpd.json - FROM public.off_chain_pool_data AS ocpd - WHERE ocpd.pool_id = api.pool_hash_id - AND ocpd.pmr_id = api.meta_id - ORDER BY ocpd.pmr_id DESC - LIMIT 1 - ) AS offline_data ON TRUE + LEFT JOIN public.pool_hash AS ph ON ph.id = api.pool_hash_id + LEFT JOIN public.pool_update AS pu ON pu.id = api.update_id + LEFT JOIN public.stake_address AS sa ON pu.reward_addr_id = sa.id + LEFT JOIN public.pool_metadata_ref AS pmr ON pmr.id = api.meta_id + LEFT JOIN public.off_chain_pool_data AS ocpd ON api.meta_id = ocpd.pmr_id LEFT JOIN LATERAL ( SELECT SUM(COUNT(b.id)) OVER () AS cnt, @@ -103,7 +122,7 @@ BEGIN LEFT JOIN LATERAL( SELECT amount::lovelace AS as_sum FROM grest.pool_active_stake_cache AS pasc - WHERE pasc.pool_id = api.pool_id_bech32 + WHERE pasc.pool_id = api.view AND pasc.epoch_no = _epoch_no ) AS active_stake ON TRUE LEFT JOIN LATERAL( @@ -127,9 +146,17 @@ BEGIN CASE WHEN api.pool_status = 'retired' THEN NULL ELSE - SUM(CASE WHEN pool_delegs.stake_address = ANY(api.owners) THEN amount::numeric ELSE 0 END)::lovelace + SUM(CASE + WHEN pool_delegs.stake_address IN ( + SELECT sa.view + FROM public.pool_owner AS po + INNER JOIN public.stake_address AS sa ON sa.id = po.addr_id + WHERE po.pool_update_id = api.update_id + ) THEN amount::numeric + ELSE 0 + END)::lovelace END AS pledge - FROM grest.pool_delegators_list(api.pool_id_bech32) AS pool_delegs + FROM grest.pool_delegators_list(api.view) AS pool_delegs ) AS live ON TRUE; END; $$; diff --git a/files/grest/rpc/pool/pool_list.sql b/files/grest/rpc/pool/pool_list.sql index 9c0dbfb5..94a15b39 100644 --- a/files/grest/rpc/pool/pool_list.sql +++ b/files/grest/rpc/pool/pool_list.sql @@ -6,6 +6,7 @@ RETURNS TABLE ( margin double precision, fixed_cost text, pledge text, + deposit text, reward_addr character varying, owners character varying [], relays jsonb [], @@ -15,58 +16,47 @@ RETURNS TABLE ( pool_status text, retiring_epoch word31type ) -LANGUAGE plpgsql +LANGUAGE sql STABLE AS $$ -# variable_conflict use_column -BEGIN - RETURN QUERY ( - WITH - -- Get last pool update for each pool - _pool_list AS ( - SELECT - ph.view as pool_id_bech32, - ph.hash_raw as pool_id_hex - FROM pool_hash AS ph - ), - - _pool_meta AS ( - SELECT DISTINCT ON (pic.pool_id_bech32) - pic.pool_id_bech32, - pic.active_epoch_no, - pic.margin, - pic.fixed_cost, - pic.pledge, - pic.reward_addr, - pic.owners, - pic.relays, - ocpd.ticker_name, - pic.meta_url, - pic.meta_hash, - pic.pool_status, - pic.retiring_epoch - FROM grest.pool_info_cache AS pic - LEFT JOIN public.off_chain_pool_data AS ocpd ON ocpd.pmr_id = pic.meta_id - ORDER BY - pic.pool_id_bech32, - pic.tx_id DESC - ) - SELECT - pl.pool_id_bech32, - encode(pl.pool_id_hex,'hex') as pool_id_hex, - pm.active_epoch_no, - pm.margin, - pm.fixed_cost::text, - pm.pledge::text, - pm.reward_addr, - pm.owners, - pm.relays, - pm.ticker_name, - pm.meta_url, - pm.meta_hash, - pm.pool_status, - pm.retiring_epoch - FROM _pool_list AS pl - LEFT JOIN _pool_meta AS pm ON pl.pool_id_bech32 = pm.pool_id_bech32 - ); -END; + SELECT DISTINCT ON (pic.pool_hash_id) + ph.view AS pool_id_bech32, + ENCODE(ph.hash_raw,'hex') as pool_id_hex, + pu.active_epoch_no, + pu.margin, + pu.fixed_cost::text, + pu.pledge::text, + pu.deposit::text, + sa.view AS reward_addr, + ARRAY( + SELECT sa.view + FROM public.pool_owner AS po + INNER JOIN public.stake_address AS sa ON sa.id = po.addr_id + WHERE po.pool_update_id = pic.update_id + ) AS owners, + ARRAY( + SELECT JSONB_BUILD_OBJECT( + 'ipv4', pr.ipv4, + 'ipv6', pr.ipv6, + 'dns', pr.dns_name, + 'srv', pr.dns_srv_name, + 'port', pr.port + ) relay + FROM public.pool_relay AS pr + WHERE pr.update_id = pic.update_id + ) AS relays, + ocpd.ticker_name, + pmr.url AS meta_url, + pmr.hash AS meta_hash, + pic.pool_status, + pic.retiring_epoch + FROM grest.pool_info_cache AS pic + LEFT JOIN public.pool_hash AS ph ON ph.id = pic.pool_hash_id + LEFT JOIN public.pool_update AS pu ON pu.id = pic.update_id + LEFT JOIN public.stake_address AS sa ON pu.reward_addr_id = sa.id + LEFT JOIN public.pool_metadata_ref AS pmr ON pmr.id = pic.meta_id + LEFT JOIN public.off_chain_pool_data AS ocpd ON ocpd.pmr_id = pic.meta_id + ORDER BY + pic.pool_hash_id, + pic.tx_id DESC + ; $$; diff --git a/files/grest/rpc/pool/pool_metadata.sql b/files/grest/rpc/pool/pool_metadata.sql index 100268ec..e2fcf732 100644 --- a/files/grest/rpc/pool/pool_metadata.sql +++ b/files/grest/rpc/pool/pool_metadata.sql @@ -3,31 +3,29 @@ RETURNS TABLE ( pool_id_bech32 character varying, meta_url character varying, meta_hash text, - meta_json jsonb, - pool_status text + meta_json jsonb ) LANGUAGE plpgsql AS $$ #variable_conflict use_column BEGIN RETURN QUERY - SELECT DISTINCT ON (pic.pool_id_bech32) + SELECT DISTINCT ON (ph.view) ph.view AS pool_id_bech32, - pic.meta_url, - pic.meta_hash, - ocpd.json, - pic.pool_status + pmr.url AS meta_url, + ENCODE(pmr.hash, 'hex') AS meta_hash, + ocpd.json AS meta_json FROM public.pool_hash AS ph - LEFT JOIN grest.pool_info_cache AS pic ON ph.view = pic.pool_id_bech32 - LEFT JOIN public.off_chain_pool_data AS ocpd ON ocpd.pmr_id = pic.meta_id + LEFT JOIN public.off_chain_pool_data AS ocpd ON ocpd.pool_id = ph.id + LEFT JOIN public.pool_metadata_ref AS pmr ON pmr.id = ocpd.pmr_id WHERE CASE WHEN _pool_bech32_ids IS NULL THEN TRUE - WHEN _pool_bech32_ids IS NOT NULL THEN pic.pool_id_bech32 = ANY(SELECT UNNEST(_pool_bech32_ids)) + WHEN _pool_bech32_ids IS NOT NULL THEN ph.view = ANY(SELECT UNNEST(_pool_bech32_ids)) END ORDER BY - pic.pool_id_bech32, - pic.tx_id DESC; + ph.view, + pmr.registered_tx_id DESC; END; $$; diff --git a/files/grest/rpc/pool/pool_relays.sql b/files/grest/rpc/pool/pool_relays.sql index 2b3e2c09..e821bb9a 100644 --- a/files/grest/rpc/pool/pool_relays.sql +++ b/files/grest/rpc/pool/pool_relays.sql @@ -1,23 +1,27 @@ CREATE OR REPLACE FUNCTION grest.pool_relays() RETURNS TABLE ( pool_id_bech32 character varying, - relays jsonb [], - pool_status text + relays jsonb ) -LANGUAGE plpgsql +LANGUAGE sql STABLE AS $$ -#variable_conflict use_column -BEGIN - RETURN QUERY - SELECT DISTINCT ON (pool_id_bech32) - pool_id_bech32, - relays, - pool_status - FROM grest.pool_info_cache + SELECT DISTINCT ON (ph.view) + ph.view AS pool_id_bech32, + JSONB_AGG(JSONB_BUILD_OBJECT ( + 'ipv4', pr.ipv4, + 'ipv6', pr.ipv6, + 'dns', pr.dns_name, + 'srv', pr.dns_srv_name, + 'port', pr.port + )) AS relays + FROM public.pool_hash AS ph + LEFT JOIN public.pool_update AS pu ON pu.hash_id = ph.id + LEFT JOIN public.pool_relay AS pr ON pu.id = pr.update_id + GROUP BY ph.view,pu.registered_tx_id ORDER BY - pool_id_bech32, - tx_id DESC; -END; + ph.view, + pu.registered_tx_id DESC + ; $$; COMMENT ON FUNCTION grest.pool_relays IS 'A list of registered relays for all pools'; --noqa: LT01 diff --git a/specs/results/koiosapi-guild.yaml b/specs/results/koiosapi-guild.yaml index 3f21e814..e6eed36d 100644 --- a/specs/results/koiosapi-guild.yaml +++ b/specs/results/koiosapi-guild.yaml @@ -2978,6 +2978,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/fixed_cost" pledge: $ref: "#/components/schemas/pool_info/items/properties/pledge" + deposit: + $ref: "#/components/schemas/pool_info/items/properties/deposit" reward_addr: $ref: "#/components/schemas/pool_info/items/properties/reward_addr" owners: @@ -3400,8 +3402,6 @@ components: $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" relays: $ref: "#/components/schemas/pool_info/items/properties/relays" - pool_status: - $ref: "#/components/schemas/pool_info/items/properties/pool_status" pool_metadata: description: Array of pool metadata type: array @@ -3416,8 +3416,6 @@ components: $ref: "#/components/schemas/pool_info/items/properties/meta_hash" meta_json: $ref: "#/components/schemas/pool_info/items/properties/meta_json" - pool_status: - $ref: "#/components/schemas/pool_info/items/properties/pool_status" epoch_info: description: Array of detailed summary for each epoch type: array diff --git a/specs/results/koiosapi-mainnet.yaml b/specs/results/koiosapi-mainnet.yaml index a533bd91..eb367a19 100644 --- a/specs/results/koiosapi-mainnet.yaml +++ b/specs/results/koiosapi-mainnet.yaml @@ -2978,6 +2978,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/fixed_cost" pledge: $ref: "#/components/schemas/pool_info/items/properties/pledge" + deposit: + $ref: "#/components/schemas/pool_info/items/properties/deposit" reward_addr: $ref: "#/components/schemas/pool_info/items/properties/reward_addr" owners: @@ -3400,8 +3402,6 @@ components: $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" relays: $ref: "#/components/schemas/pool_info/items/properties/relays" - pool_status: - $ref: "#/components/schemas/pool_info/items/properties/pool_status" pool_metadata: description: Array of pool metadata type: array @@ -3416,8 +3416,6 @@ components: $ref: "#/components/schemas/pool_info/items/properties/meta_hash" meta_json: $ref: "#/components/schemas/pool_info/items/properties/meta_json" - pool_status: - $ref: "#/components/schemas/pool_info/items/properties/pool_status" epoch_info: description: Array of detailed summary for each epoch type: array diff --git a/specs/results/koiosapi-preprod.yaml b/specs/results/koiosapi-preprod.yaml index dcf4f6dd..9d40ccd7 100644 --- a/specs/results/koiosapi-preprod.yaml +++ b/specs/results/koiosapi-preprod.yaml @@ -2978,6 +2978,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/fixed_cost" pledge: $ref: "#/components/schemas/pool_info/items/properties/pledge" + deposit: + $ref: "#/components/schemas/pool_info/items/properties/deposit" reward_addr: $ref: "#/components/schemas/pool_info/items/properties/reward_addr" owners: @@ -3400,8 +3402,6 @@ components: $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" relays: $ref: "#/components/schemas/pool_info/items/properties/relays" - pool_status: - $ref: "#/components/schemas/pool_info/items/properties/pool_status" pool_metadata: description: Array of pool metadata type: array @@ -3416,8 +3416,6 @@ components: $ref: "#/components/schemas/pool_info/items/properties/meta_hash" meta_json: $ref: "#/components/schemas/pool_info/items/properties/meta_json" - pool_status: - $ref: "#/components/schemas/pool_info/items/properties/pool_status" epoch_info: description: Array of detailed summary for each epoch type: array diff --git a/specs/results/koiosapi-preview.yaml b/specs/results/koiosapi-preview.yaml index 55497526..e0de23de 100644 --- a/specs/results/koiosapi-preview.yaml +++ b/specs/results/koiosapi-preview.yaml @@ -2978,6 +2978,8 @@ components: $ref: "#/components/schemas/pool_info/items/properties/fixed_cost" pledge: $ref: "#/components/schemas/pool_info/items/properties/pledge" + deposit: + $ref: "#/components/schemas/pool_info/items/properties/deposit" reward_addr: $ref: "#/components/schemas/pool_info/items/properties/reward_addr" owners: @@ -3400,8 +3402,6 @@ components: $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" relays: $ref: "#/components/schemas/pool_info/items/properties/relays" - pool_status: - $ref: "#/components/schemas/pool_info/items/properties/pool_status" pool_metadata: description: Array of pool metadata type: array @@ -3416,8 +3416,6 @@ components: $ref: "#/components/schemas/pool_info/items/properties/meta_hash" meta_json: $ref: "#/components/schemas/pool_info/items/properties/meta_json" - pool_status: - $ref: "#/components/schemas/pool_info/items/properties/pool_status" epoch_info: description: Array of detailed summary for each epoch type: array diff --git a/specs/templates/4-api-schemas.yaml b/specs/templates/4-api-schemas.yaml index 108e7c60..60175e31 100644 --- a/specs/templates/4-api-schemas.yaml +++ b/specs/templates/4-api-schemas.yaml @@ -188,6 +188,8 @@ schemas: $ref: "#/components/schemas/pool_info/items/properties/fixed_cost" pledge: $ref: "#/components/schemas/pool_info/items/properties/pledge" + deposit: + $ref: "#/components/schemas/pool_info/items/properties/deposit" reward_addr: $ref: "#/components/schemas/pool_info/items/properties/reward_addr" owners: @@ -610,8 +612,6 @@ schemas: $ref: "#/components/schemas/pool_info/items/properties/pool_id_bech32" relays: $ref: "#/components/schemas/pool_info/items/properties/relays" - pool_status: - $ref: "#/components/schemas/pool_info/items/properties/pool_status" pool_metadata: description: Array of pool metadata type: array @@ -626,8 +626,6 @@ schemas: $ref: "#/components/schemas/pool_info/items/properties/meta_hash" meta_json: $ref: "#/components/schemas/pool_info/items/properties/meta_json" - pool_status: - $ref: "#/components/schemas/pool_info/items/properties/pool_status" epoch_info: description: Array of detailed summary for each epoch type: array