From bcaf9c2583407dd8734d89557d99ce66ce960789 Mon Sep 17 00:00:00 2001 From: flashburst <82953782+flashburst@users.noreply.github.com> Date: Fri, 7 Jun 2024 14:57:47 +0530 Subject: [PATCH] Refactors - Fixed indentation and spacing issues in `capacity_view` - Refactored `get_tvl_till_date` and it's overloads - Refactored `get_total_capacity_by_date` to make it similar to `capacity_view` - Refactored `active_liquidity_view`, `my_liquidity_view`, `my_policies_view`, `votes_view` - Fixed mistakes of `get_total_covered_till_date` - Added triggers to fix `ck` cover key if tables are populated in a different order - Removed incorrect `format_stablecoin` function --- build/db.sql | 223 +++++++++--------- sql/app/liquidity/active_liquidity_view.sql | 19 +- sql/app/liquidity/my_liquidity_view.sql | 60 ++--- sql/app/policy/my_policies_view.sql | 4 +- sql/app/reporting/votes_view.sql | 24 +- .../003-functions/get_capacity_till_date.sql | 27 +-- .../get_total_covered_till_date.sql | 2 +- sql/base/003-functions/get_tvl_till_date.sql | 39 +-- sql/base/004-views/0.capacity_view.sql | 14 +- sql/rds.sql | 34 ++- 10 files changed, 226 insertions(+), 220 deletions(-) diff --git a/build/db.sql b/build/db.sql index 541c0b7..20214f5 100644 --- a/build/db.sql +++ b/build/db.sql @@ -3574,21 +3574,41 @@ FOR EACH ROW EXECUTE FUNCTION policy.cover_purchased_product_key_trigger(); /********************************************/ +DROP FUNCTION IF EXISTS vault.update_cover_key_on_vault_event_trigger() CASCADE; -CREATE OR REPLACE FUNCTION format_stablecoin -( - _amount numeric -) -RETURNS money -IMMUTABLE +CREATE FUNCTION vault.update_cover_key_on_vault_event_trigger() +RETURNS TRIGGER AS $$ BEGIN - RETURN _amount / POWER(10, 6); + UPDATE core.transactions + SET ck = get_cover_key_by_vault_address(core.transactions.chain_id, core.transactions.address) + WHERE core.transactions.event_name IN ('PodsIssued', 'PodsRedeemed') + AND core.transactions.ck IS NULL; + + RETURN NEW; END $$ LANGUAGE plpgsql; +CREATE TRIGGER update_cover_key_on_vault_event_trigger +AFTER INSERT ON vault.pods_issued +FOR EACH ROW +EXECUTE FUNCTION vault.update_cover_key_on_vault_event_trigger(); + +CREATE TRIGGER update_cover_key_on_vault_event_trigger +AFTER INSERT ON vault.pods_redeemed +FOR EACH ROW +EXECUTE FUNCTION vault.update_cover_key_on_vault_event_trigger(); + +CREATE TRIGGER update_cover_key_on_vault_event_trigger +AFTER INSERT ON factory.vault_deployed +FOR EACH ROW +EXECUTE FUNCTION vault.update_cover_key_on_vault_event_trigger(); + + +/********************************************/ + CREATE OR REPLACE FUNCTION get_npm_value(_amount uint256) RETURNS numeric IMMUTABLE @@ -5945,27 +5965,16 @@ BEGIN ( SELECT DISTINCT chain_id, cover_key, product_key FROM unfiltered - WHERE cover_key IS NOT NULL - ), - summary - AS - ( - SELECT - chain_id, - cover_key, - bytes32_to_string(cover_key) AS cover, - is_diversified(chain_id, cover_key) AS diversified, - product_key, - bytes32_to_string(product_key) AS product, - get_cover_capacity_till(chain_id, cover_key, product_key, _date) AS capacity, - format_stablecoin(get_cover_capacity_till(chain_id, cover_key, product_key, _date)) AS formatted_capacity - FROM products + WHERE COALESCE(cover_key, string_to_bytes32('')) != string_to_bytes32('') + AND + ( + COALESCE(product_key, string_to_bytes32('')) != string_to_bytes32('') + OR NOT is_diversified(chain_id, cover_key) + ) ) - SELECT SUM(capacity) + SELECT SUM(get_cover_capacity_till(chain_id, cover_key, product_key, _date)) INTO _capacity - FROM summary - WHERE 1 = 1 - AND NOT (diversified = true AND product_key != string_to_bytes32('')); + FROM products; RETURN COALESCE(_capacity, 0); END @@ -7035,7 +7044,7 @@ BEGIN WHERE 1 = 1 AND (_chain_id IS NULL OR chain_id = _chain_id) AND (_cover_key IS NULL OR cover_key = _cover_key) - AND to_timestamp(expires_on) <= _date; + AND to_timestamp(block_timestamp) <= _date; RETURN COALESCE(_result, 0); END @@ -7082,6 +7091,8 @@ ALTER FUNCTION get_total_covered_till_date(uint256, bytes32, TIMESTAMP WITH TIME CREATE OR REPLACE FUNCTION get_tvl_till_date ( + _chain_id uint256, + _cover_key bytes32, _date TIMESTAMP WITH TIME ZONE ) RETURNS numeric @@ -7098,7 +7109,10 @@ BEGIN ) INTO _result FROM core.transactions - WHERE core.transactions.event_name IN ('CoverPurchased', 'PodsIssued', 'PodsRedeemed', 'Claimed', 'PoolCapitalized') + WHERE 1 = 1 + AND (_chain_id IS NULL OR core.transactions.chain_id = _chain_id) + AND (_cover_key IS NULL OR core.transactions.ck = _cover_key) + AND core.transactions.event_name IN ('CoverPurchased', 'PodsIssued', 'PodsRedeemed', 'Claimed', 'PoolCapitalized') AND to_timestamp(core.transactions.block_timestamp) <= _date; RETURN COALESCE(_result, 0); @@ -7117,28 +7131,13 @@ AS $$ DECLARE _result numeric; BEGIN - SELECT SUM - ( - get_stablecoin_value(core.transactions.chain_id, core.transactions.transaction_stablecoin_amount) - * - CASE WHEN core.transactions.event_name IN ('Claimed') THEN -1 ELSE 1 END - ) - INTO _result - FROM core.transactions - WHERE core.transactions.chain_id = _chain_id - AND core.transactions.event_name IN ('CoverPurchased', 'PodsIssued', 'PodsRedeemed', 'Claimed', 'PoolCapitalized') - AND to_timestamp(core.transactions.block_timestamp) <= _date; - - RETURN COALESCE(_result, 0); + RETURN get_tvl_till_date(_chain_id, NULL, _date); END $$ LANGUAGE plpgsql; - CREATE OR REPLACE FUNCTION get_tvl_till_date ( - _chain_id uint256, - _cover_key bytes32, _date TIMESTAMP WITH TIME ZONE ) RETURNS numeric @@ -7147,20 +7146,7 @@ AS $$ DECLARE _result numeric; BEGIN - SELECT SUM - ( - get_stablecoin_value(core.transactions.chain_id, core.transactions.transaction_stablecoin_amount) - * - CASE WHEN core.transactions.event_name IN ('Claimed') THEN -1 ELSE 1 END - ) - INTO _result - FROM core.transactions - WHERE core.transactions.chain_id = _chain_id - AND core.transactions.ck = _cover_key - AND core.transactions.event_name IN ('CoverPurchased', 'PodsIssued', 'PodsRedeemed', 'Claimed', 'PoolCapitalized') - AND to_timestamp(core.transactions.block_timestamp) <= _date; - - RETURN COALESCE(_result, 0); + RETURN get_tvl_till_date(NULL, NULL, _date); END $$ LANGUAGE plpgsql; @@ -7322,7 +7308,8 @@ AS SELECT chain_id FROM chains ) UNION ALL - SELECT chain_id, cover_key, string_to_bytes32('') FROM config_cover_view + SELECT chain_id, cover_key, string_to_bytes32('') + FROM config_cover_view WHERE config_cover_view.chain_id IN ( SELECT chain_id FROM chains @@ -7333,8 +7320,9 @@ AS ( SELECT DISTINCT chain_id, cover_key, product_key FROM unfiltered - WHERE COALESCE(cover_key, string_to_bytes32('')) != string_to_bytes32('') - AND + WHERE 1 = 1 + AND COALESCE(cover_key, string_to_bytes32('')) != string_to_bytes32('') + AND ( COALESCE(product_key, string_to_bytes32('')) != string_to_bytes32('') OR NOT is_diversified(chain_id, cover_key) @@ -7343,10 +7331,10 @@ AS SELECT chain_id, cover_key, - bytes32_to_string(cover_key) AS cover, - is_diversified(chain_id, cover_key) AS diversified, + bytes32_to_string(cover_key) AS cover, + is_diversified(chain_id, cover_key) AS diversified, product_key, - bytes32_to_string(product_key) AS product, + bytes32_to_string(product_key) AS product, get_cover_capacity_till(chain_id, cover_key, product_key, 'infinity') AS capacity FROM products; @@ -8684,13 +8672,20 @@ AS vaults.vault_address ) SELECT - chain_id, + balances.chain_id, account, - balance, - vault_address, - cover_key, - bytes32_to_string(cover_key) AS cover_key_string -FROM balances; + wei_to_ether(balances.balance) AS balance, + balances.vault_address, + balances.cover_key, + bytes32_to_string(balances.cover_key) AS cover_key_string, + factory.vault_deployed.name AS token_name, + factory.vault_deployed.symbol AS token_symbol +FROM balances +LEFT JOIN factory.vault_deployed +ON 1=1 +AND factory.vault_deployed.chain_id = balances.chain_id +AND factory.vault_deployed.cover_key = balances.cover_key +AND factory.vault_deployed.vault = balances.vault_address; ALTER VIEW active_liquidity_view OWNER TO writeuser; @@ -8706,50 +8701,50 @@ AS ( SELECT vault.pods_redeemed.chain_id, - vault.pods_redeemed.address AS vault_address, + vault.pods_redeemed.address AS vault_address, vault.pods_redeemed.block_timestamp, vault.pods_redeemed.transaction_hash, vault.pods_redeemed.account, - vault.pods_redeemed.redeemed AS pod_amount, - 0 AS npm_amount, - vault.pods_redeemed.liquidity_released AS stablecoin_amount, - 'PodsRedeemed' AS tx_type + vault.pods_redeemed.redeemed AS pod_amount, + 0 AS npm_amount, + vault.pods_redeemed.liquidity_released AS stablecoin_amount, + 'PodsRedeemed' AS tx_type FROM vault.pods_redeemed UNION ALL SELECT vault.pods_issued.chain_id, - vault.pods_issued.address AS vault_address, + vault.pods_issued.address AS vault_address, vault.pods_issued.block_timestamp, vault.pods_issued.transaction_hash, vault.pods_issued.account, - vault.pods_issued.issued AS pod_amount, - 0 AS npm_amount, - vault.pods_issued.liquidity_added AS stablecoin_amount, - 'PodsIssued' AS tx_type + vault.pods_issued.issued AS pod_amount, + 0 AS npm_amount, + vault.pods_issued.liquidity_added AS stablecoin_amount, + 'PodsIssued' AS tx_type FROM vault.pods_issued UNION ALL SELECT vault.npm_unstaken.chain_id, - vault.npm_unstaken.address AS vault_address, + vault.npm_unstaken.address AS vault_address, vault.npm_unstaken.block_timestamp, vault.npm_unstaken.transaction_hash, vault.npm_unstaken.account, - 0 AS pod_amount, - vault.npm_unstaken.amount AS npm_amount, - 0 AS stablecoin_amount, - 'NpmUnstaken' AS tx_type + 0 AS pod_amount, + vault.npm_unstaken.amount AS npm_amount, + 0 AS stablecoin_amount, + 'NpmUnstaken' AS tx_type FROM vault.npm_unstaken UNION ALL SELECT vault.npm_staken.chain_id, - vault.npm_staken.address AS vault_address, + vault.npm_staken.address AS vault_address, vault.npm_staken.block_timestamp, vault.npm_staken.transaction_hash, vault.npm_staken.account, - 0 AS pod_amount, - vault.npm_staken.amount AS npm_amount, - 0 AS stablecoin_amount, - 'NpmStaken' AS tx_type + 0 AS pod_amount, + vault.npm_staken.amount AS npm_amount, + 0 AS stablecoin_amount, + 'NpmStaken' AS tx_type FROM vault.npm_staken ), stage2 @@ -8769,7 +8764,7 @@ AS ( stage1.chain_id, stage1.vault_address - ) AS cover_key + ) AS cover_key FROM stage1 ) SELECT @@ -8778,20 +8773,20 @@ SELECT stage2.block_timestamp, stage2.transaction_hash, stage2.account, - stage2.pod_amount, - stage2.npm_amount, - stage2.stablecoin_amount, + wei_to_ether(stage2.pod_amount) AS pod_amount, + wei_to_ether(stage2.npm_amount) AS npm_amount, + get_stablecoin_value(stage2.chain_id, stage2.stablecoin_amount) AS stablecoin_amount, stage2.tx_type, stage2.cover_key, - get_products_of(stage2.chain_id, stage2.cover_key) AS product_keys, - factory.vault_deployed.name AS token_name, - factory.vault_deployed.symbol AS token_symbol + get_products_of(stage2.chain_id, stage2.cover_key) AS product_keys, + factory.vault_deployed.name AS token_name, + factory.vault_deployed.symbol AS token_symbol FROM stage2 LEFT JOIN factory.vault_deployed ON 1=1 -AND factory.vault_deployed.chain_id = stage2.chain_id -AND factory.vault_deployed.cover_key = stage2.cover_key -AND factory.vault_deployed.vault = stage2.vault_address; +AND factory.vault_deployed.chain_id = stage2.chain_id +AND factory.vault_deployed.cover_key = stage2.cover_key +AND factory.vault_deployed.vault = stage2.vault_address; ALTER VIEW my_liquidity_view OWNER TO writeuser; @@ -8962,7 +8957,7 @@ AS on_behalf_of AS account, get_stablecoin_value(chain_id, amount_to_cover) AS cxtoken_amount, get_stablecoin_value(chain_id, fee) AS stablecoin_amount, - 'cover_purchased' AS tx_type + 'CoverPurchased' AS tx_type FROM policy.cover_purchased UNION ALL SELECT @@ -8975,7 +8970,7 @@ AS account AS account, wei_to_ether(amount) AS cxtoken_amount, wei_to_ether(claimed) AS stablecoin_amount, - 'claimed' AS tx_type + 'Claimed' AS tx_type FROM cxtoken.claimed ) @@ -9003,9 +8998,7 @@ AND factory.cx_token_deployed.cx_token = policy_txs.cx_token; ALTER VIEW my_policies_view OWNER TO writeuser; -DROP VIEW IF EXISTS votes_view; - -CREATE VIEW votes_view +CREATE OR REPLACE VIEW votes_view AS WITH vote_txs AS @@ -9019,7 +9012,7 @@ AS transaction_hash, witness, stake, - 'attested' AS tx_type + 'Attested' AS tx_type FROM consensus.attested UNION ALL SELECT @@ -9031,15 +9024,25 @@ AS transaction_hash, witness, stake, - 'refuted' AS tx_type + 'Refuted' AS tx_type FROM consensus.refuted ) SELECT - *, - bytes32_to_string(cover_key) AS cover_key_string, - bytes32_to_string(product_key) AS product_key_string + vote_txs.chain_id, + vote_txs.cover_key, + vote_txs.product_key, + vote_txs.incident_date, + vote_txs.block_timestamp, + vote_txs.transaction_hash, + vote_txs.witness, + get_npm_value(vote_txs.stake) AS stake, + vote_txs.tx_type, + bytes32_to_string(vote_txs.cover_key) AS cover_key_string, + bytes32_to_string(vote_txs.product_key) AS product_key_string FROM vote_txs; +ALTER VIEW votes_view OWNER TO writeuser; + DROP FUNCTION IF EXISTS get_cover_stats ( _chain_id uint256, diff --git a/sql/app/liquidity/active_liquidity_view.sql b/sql/app/liquidity/active_liquidity_view.sql index be0d798..fea5dd4 100644 --- a/sql/app/liquidity/active_liquidity_view.sql +++ b/sql/app/liquidity/active_liquidity_view.sql @@ -50,13 +50,20 @@ AS vaults.vault_address ) SELECT - chain_id, + balances.chain_id, account, - balance, - vault_address, - cover_key, - bytes32_to_string(cover_key) AS cover_key_string -FROM balances; + wei_to_ether(balances.balance) AS balance, + balances.vault_address, + balances.cover_key, + bytes32_to_string(balances.cover_key) AS cover_key_string, + factory.vault_deployed.name AS token_name, + factory.vault_deployed.symbol AS token_symbol +FROM balances +LEFT JOIN factory.vault_deployed +ON 1=1 +AND factory.vault_deployed.chain_id = balances.chain_id +AND factory.vault_deployed.cover_key = balances.cover_key +AND factory.vault_deployed.vault = balances.vault_address; ALTER VIEW active_liquidity_view OWNER TO writeuser; diff --git a/sql/app/liquidity/my_liquidity_view.sql b/sql/app/liquidity/my_liquidity_view.sql index 9028090..635c2f4 100644 --- a/sql/app/liquidity/my_liquidity_view.sql +++ b/sql/app/liquidity/my_liquidity_view.sql @@ -5,50 +5,50 @@ AS ( SELECT vault.pods_redeemed.chain_id, - vault.pods_redeemed.address AS vault_address, + vault.pods_redeemed.address AS vault_address, vault.pods_redeemed.block_timestamp, vault.pods_redeemed.transaction_hash, vault.pods_redeemed.account, - vault.pods_redeemed.redeemed AS pod_amount, - 0 AS npm_amount, - vault.pods_redeemed.liquidity_released AS stablecoin_amount, - 'PodsRedeemed' AS tx_type + vault.pods_redeemed.redeemed AS pod_amount, + 0 AS npm_amount, + vault.pods_redeemed.liquidity_released AS stablecoin_amount, + 'PodsRedeemed' AS tx_type FROM vault.pods_redeemed UNION ALL SELECT vault.pods_issued.chain_id, - vault.pods_issued.address AS vault_address, + vault.pods_issued.address AS vault_address, vault.pods_issued.block_timestamp, vault.pods_issued.transaction_hash, vault.pods_issued.account, - vault.pods_issued.issued AS pod_amount, - 0 AS npm_amount, - vault.pods_issued.liquidity_added AS stablecoin_amount, - 'PodsIssued' AS tx_type + vault.pods_issued.issued AS pod_amount, + 0 AS npm_amount, + vault.pods_issued.liquidity_added AS stablecoin_amount, + 'PodsIssued' AS tx_type FROM vault.pods_issued UNION ALL SELECT vault.npm_unstaken.chain_id, - vault.npm_unstaken.address AS vault_address, + vault.npm_unstaken.address AS vault_address, vault.npm_unstaken.block_timestamp, vault.npm_unstaken.transaction_hash, vault.npm_unstaken.account, - 0 AS pod_amount, - vault.npm_unstaken.amount AS npm_amount, - 0 AS stablecoin_amount, - 'NpmUnstaken' AS tx_type + 0 AS pod_amount, + vault.npm_unstaken.amount AS npm_amount, + 0 AS stablecoin_amount, + 'NpmUnstaken' AS tx_type FROM vault.npm_unstaken UNION ALL SELECT vault.npm_staken.chain_id, - vault.npm_staken.address AS vault_address, + vault.npm_staken.address AS vault_address, vault.npm_staken.block_timestamp, vault.npm_staken.transaction_hash, vault.npm_staken.account, - 0 AS pod_amount, - vault.npm_staken.amount AS npm_amount, - 0 AS stablecoin_amount, - 'NpmStaken' AS tx_type + 0 AS pod_amount, + vault.npm_staken.amount AS npm_amount, + 0 AS stablecoin_amount, + 'NpmStaken' AS tx_type FROM vault.npm_staken ), stage2 @@ -68,7 +68,7 @@ AS ( stage1.chain_id, stage1.vault_address - ) AS cover_key + ) AS cover_key FROM stage1 ) SELECT @@ -77,19 +77,19 @@ SELECT stage2.block_timestamp, stage2.transaction_hash, stage2.account, - stage2.pod_amount, - stage2.npm_amount, - stage2.stablecoin_amount, + wei_to_ether(stage2.pod_amount) AS pod_amount, + wei_to_ether(stage2.npm_amount) AS npm_amount, + get_stablecoin_value(stage2.chain_id, stage2.stablecoin_amount) AS stablecoin_amount, stage2.tx_type, stage2.cover_key, - get_products_of(stage2.chain_id, stage2.cover_key) AS product_keys, - factory.vault_deployed.name AS token_name, - factory.vault_deployed.symbol AS token_symbol + get_products_of(stage2.chain_id, stage2.cover_key) AS product_keys, + factory.vault_deployed.name AS token_name, + factory.vault_deployed.symbol AS token_symbol FROM stage2 LEFT JOIN factory.vault_deployed ON 1=1 -AND factory.vault_deployed.chain_id = stage2.chain_id -AND factory.vault_deployed.cover_key = stage2.cover_key -AND factory.vault_deployed.vault = stage2.vault_address; +AND factory.vault_deployed.chain_id = stage2.chain_id +AND factory.vault_deployed.cover_key = stage2.cover_key +AND factory.vault_deployed.vault = stage2.vault_address; ALTER VIEW my_liquidity_view OWNER TO writeuser; diff --git a/sql/app/policy/my_policies_view.sql b/sql/app/policy/my_policies_view.sql index d31e208..d8cba3a 100644 --- a/sql/app/policy/my_policies_view.sql +++ b/sql/app/policy/my_policies_view.sql @@ -13,7 +13,7 @@ AS on_behalf_of AS account, get_stablecoin_value(chain_id, amount_to_cover) AS cxtoken_amount, get_stablecoin_value(chain_id, fee) AS stablecoin_amount, - 'cover_purchased' AS tx_type + 'CoverPurchased' AS tx_type FROM policy.cover_purchased UNION ALL SELECT @@ -26,7 +26,7 @@ AS account AS account, wei_to_ether(amount) AS cxtoken_amount, wei_to_ether(claimed) AS stablecoin_amount, - 'claimed' AS tx_type + 'Claimed' AS tx_type FROM cxtoken.claimed ) diff --git a/sql/app/reporting/votes_view.sql b/sql/app/reporting/votes_view.sql index 6646b92..c8c86e0 100644 --- a/sql/app/reporting/votes_view.sql +++ b/sql/app/reporting/votes_view.sql @@ -1,6 +1,4 @@ -DROP VIEW IF EXISTS votes_view; - -CREATE VIEW votes_view +CREATE OR REPLACE VIEW votes_view AS WITH vote_txs AS @@ -14,7 +12,7 @@ AS transaction_hash, witness, stake, - 'attested' AS tx_type + 'Attested' AS tx_type FROM consensus.attested UNION ALL SELECT @@ -26,11 +24,21 @@ AS transaction_hash, witness, stake, - 'refuted' AS tx_type + 'Refuted' AS tx_type FROM consensus.refuted ) SELECT - *, - bytes32_to_string(cover_key) AS cover_key_string, - bytes32_to_string(product_key) AS product_key_string + vote_txs.chain_id, + vote_txs.cover_key, + vote_txs.product_key, + vote_txs.incident_date, + vote_txs.block_timestamp, + vote_txs.transaction_hash, + vote_txs.witness, + get_npm_value(vote_txs.stake) AS stake, + vote_txs.tx_type, + bytes32_to_string(vote_txs.cover_key) AS cover_key_string, + bytes32_to_string(vote_txs.product_key) AS product_key_string FROM vote_txs; + +ALTER VIEW votes_view OWNER TO writeuser; diff --git a/sql/base/003-functions/get_capacity_till_date.sql b/sql/base/003-functions/get_capacity_till_date.sql index 24a96fe..1fb2f12 100644 --- a/sql/base/003-functions/get_capacity_till_date.sql +++ b/sql/base/003-functions/get_capacity_till_date.sql @@ -38,27 +38,16 @@ BEGIN ( SELECT DISTINCT chain_id, cover_key, product_key FROM unfiltered - WHERE cover_key IS NOT NULL - ), - summary - AS - ( - SELECT - chain_id, - cover_key, - bytes32_to_string(cover_key) AS cover, - is_diversified(chain_id, cover_key) AS diversified, - product_key, - bytes32_to_string(product_key) AS product, - get_cover_capacity_till(chain_id, cover_key, product_key, _date) AS capacity, - format_stablecoin(get_cover_capacity_till(chain_id, cover_key, product_key, _date)) AS formatted_capacity - FROM products + WHERE COALESCE(cover_key, string_to_bytes32('')) != string_to_bytes32('') + AND + ( + COALESCE(product_key, string_to_bytes32('')) != string_to_bytes32('') + OR NOT is_diversified(chain_id, cover_key) + ) ) - SELECT SUM(capacity) + SELECT SUM(get_cover_capacity_till(chain_id, cover_key, product_key, _date)) INTO _capacity - FROM summary - WHERE 1 = 1 - AND NOT (diversified = true AND product_key != string_to_bytes32('')); + FROM products; RETURN COALESCE(_capacity, 0); END diff --git a/sql/base/003-functions/get_total_covered_till_date.sql b/sql/base/003-functions/get_total_covered_till_date.sql index a205522..a24c8ec 100644 --- a/sql/base/003-functions/get_total_covered_till_date.sql +++ b/sql/base/003-functions/get_total_covered_till_date.sql @@ -16,7 +16,7 @@ BEGIN WHERE 1 = 1 AND (_chain_id IS NULL OR chain_id = _chain_id) AND (_cover_key IS NULL OR cover_key = _cover_key) - AND to_timestamp(expires_on) <= _date; + AND to_timestamp(block_timestamp) <= _date; RETURN COALESCE(_result, 0); END diff --git a/sql/base/003-functions/get_tvl_till_date.sql b/sql/base/003-functions/get_tvl_till_date.sql index af80e6a..b4ca75f 100644 --- a/sql/base/003-functions/get_tvl_till_date.sql +++ b/sql/base/003-functions/get_tvl_till_date.sql @@ -1,5 +1,7 @@ CREATE OR REPLACE FUNCTION get_tvl_till_date ( + _chain_id uint256, + _cover_key bytes32, _date TIMESTAMP WITH TIME ZONE ) RETURNS numeric @@ -16,7 +18,10 @@ BEGIN ) INTO _result FROM core.transactions - WHERE core.transactions.event_name IN ('CoverPurchased', 'PodsIssued', 'PodsRedeemed', 'Claimed', 'PoolCapitalized') + WHERE 1 = 1 + AND (_chain_id IS NULL OR core.transactions.chain_id = _chain_id) + AND (_cover_key IS NULL OR core.transactions.ck = _cover_key) + AND core.transactions.event_name IN ('CoverPurchased', 'PodsIssued', 'PodsRedeemed', 'Claimed', 'PoolCapitalized') AND to_timestamp(core.transactions.block_timestamp) <= _date; RETURN COALESCE(_result, 0); @@ -35,28 +40,13 @@ AS $$ DECLARE _result numeric; BEGIN - SELECT SUM - ( - get_stablecoin_value(core.transactions.chain_id, core.transactions.transaction_stablecoin_amount) - * - CASE WHEN core.transactions.event_name IN ('Claimed') THEN -1 ELSE 1 END - ) - INTO _result - FROM core.transactions - WHERE core.transactions.chain_id = _chain_id - AND core.transactions.event_name IN ('CoverPurchased', 'PodsIssued', 'PodsRedeemed', 'Claimed', 'PoolCapitalized') - AND to_timestamp(core.transactions.block_timestamp) <= _date; - - RETURN COALESCE(_result, 0); + RETURN get_tvl_till_date(_chain_id, NULL, _date); END $$ LANGUAGE plpgsql; - CREATE OR REPLACE FUNCTION get_tvl_till_date ( - _chain_id uint256, - _cover_key bytes32, _date TIMESTAMP WITH TIME ZONE ) RETURNS numeric @@ -65,20 +55,7 @@ AS $$ DECLARE _result numeric; BEGIN - SELECT SUM - ( - get_stablecoin_value(core.transactions.chain_id, core.transactions.transaction_stablecoin_amount) - * - CASE WHEN core.transactions.event_name IN ('Claimed') THEN -1 ELSE 1 END - ) - INTO _result - FROM core.transactions - WHERE core.transactions.chain_id = _chain_id - AND core.transactions.ck = _cover_key - AND core.transactions.event_name IN ('CoverPurchased', 'PodsIssued', 'PodsRedeemed', 'Claimed', 'PoolCapitalized') - AND to_timestamp(core.transactions.block_timestamp) <= _date; - - RETURN COALESCE(_result, 0); + RETURN get_tvl_till_date(NULL, NULL, _date); END $$ LANGUAGE plpgsql; diff --git a/sql/base/004-views/0.capacity_view.sql b/sql/base/004-views/0.capacity_view.sql index 6976d37..bf0373c 100644 --- a/sql/base/004-views/0.capacity_view.sql +++ b/sql/base/004-views/0.capacity_view.sql @@ -16,7 +16,8 @@ AS SELECT chain_id FROM chains ) UNION ALL - SELECT chain_id, cover_key, string_to_bytes32('') FROM config_cover_view + SELECT chain_id, cover_key, string_to_bytes32('') + FROM config_cover_view WHERE config_cover_view.chain_id IN ( SELECT chain_id FROM chains @@ -27,8 +28,9 @@ AS ( SELECT DISTINCT chain_id, cover_key, product_key FROM unfiltered - WHERE COALESCE(cover_key, string_to_bytes32('')) != string_to_bytes32('') - AND + WHERE 1 = 1 + AND COALESCE(cover_key, string_to_bytes32('')) != string_to_bytes32('') + AND ( COALESCE(product_key, string_to_bytes32('')) != string_to_bytes32('') OR NOT is_diversified(chain_id, cover_key) @@ -37,10 +39,10 @@ AS SELECT chain_id, cover_key, - bytes32_to_string(cover_key) AS cover, - is_diversified(chain_id, cover_key) AS diversified, + bytes32_to_string(cover_key) AS cover, + is_diversified(chain_id, cover_key) AS diversified, product_key, - bytes32_to_string(product_key) AS product, + bytes32_to_string(product_key) AS product, get_cover_capacity_till(chain_id, cover_key, product_key, 'infinity') AS capacity FROM products; diff --git a/sql/rds.sql b/sql/rds.sql index 5b646b8..ff3f22a 100644 --- a/sql/rds.sql +++ b/sql/rds.sql @@ -3574,21 +3574,41 @@ FOR EACH ROW EXECUTE FUNCTION policy.cover_purchased_product_key_trigger(); /********************************************/ +DROP FUNCTION IF EXISTS vault.update_cover_key_on_vault_event_trigger() CASCADE; -CREATE OR REPLACE FUNCTION format_stablecoin -( - _amount numeric -) -RETURNS money -IMMUTABLE +CREATE FUNCTION vault.update_cover_key_on_vault_event_trigger() +RETURNS TRIGGER AS $$ BEGIN - RETURN _amount / POWER(10, 6); + UPDATE core.transactions + SET ck = get_cover_key_by_vault_address(core.transactions.chain_id, core.transactions.address) + WHERE core.transactions.event_name IN ('PodsIssued', 'PodsRedeemed') + AND core.transactions.ck IS NULL; + + RETURN NEW; END $$ LANGUAGE plpgsql; +CREATE TRIGGER update_cover_key_on_vault_event_trigger +AFTER INSERT ON vault.pods_issued +FOR EACH ROW +EXECUTE FUNCTION vault.update_cover_key_on_vault_event_trigger(); + +CREATE TRIGGER update_cover_key_on_vault_event_trigger +AFTER INSERT ON vault.pods_redeemed +FOR EACH ROW +EXECUTE FUNCTION vault.update_cover_key_on_vault_event_trigger(); + +CREATE TRIGGER update_cover_key_on_vault_event_trigger +AFTER INSERT ON factory.vault_deployed +FOR EACH ROW +EXECUTE FUNCTION vault.update_cover_key_on_vault_event_trigger(); + + +/********************************************/ + CREATE OR REPLACE FUNCTION get_npm_value(_amount uint256) RETURNS numeric IMMUTABLE