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

Refactors #78

Merged
merged 1 commit into from
Jun 7, 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
223 changes: 113 additions & 110 deletions build/db.sql

Large diffs are not rendered by default.

19 changes: 13 additions & 6 deletions sql/app/liquidity/active_liquidity_view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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;

Expand Down
60 changes: 30 additions & 30 deletions sql/app/liquidity/my_liquidity_view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -68,7 +68,7 @@ AS
(
stage1.chain_id,
stage1.vault_address
) AS cover_key
) AS cover_key
FROM stage1
)
SELECT
Expand All @@ -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;
4 changes: 2 additions & 2 deletions sql/app/policy/my_policies_view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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
)

Expand Down
24 changes: 16 additions & 8 deletions sql/app/reporting/votes_view.sql
Original file line number Diff line number Diff line change
@@ -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
Expand All @@ -14,7 +12,7 @@ AS
transaction_hash,
witness,
stake,
'attested' AS tx_type
'Attested' AS tx_type
FROM consensus.attested
UNION ALL
SELECT
Expand All @@ -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;
27 changes: 8 additions & 19 deletions sql/base/003-functions/get_capacity_till_date.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
2 changes: 1 addition & 1 deletion sql/base/003-functions/get_total_covered_till_date.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
39 changes: 8 additions & 31 deletions sql/base/003-functions/get_tvl_till_date.sql
Original file line number Diff line number Diff line change
@@ -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
Expand All @@ -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);
Expand All @@ -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
Expand All @@ -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;
Expand Down
14 changes: 8 additions & 6 deletions sql/base/004-views/0.capacity_view.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand All @@ -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)
Expand All @@ -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;

Expand Down
34 changes: 27 additions & 7 deletions sql/rds.sql
Original file line number Diff line number Diff line change
Expand Up @@ -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
Expand Down
Loading