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

Refactors #78

merged 1 commit into from
Jun 7, 2024

Conversation

flashburst
Copy link
Contributor

@flashburst flashburst commented Jun 7, 2024

  • 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

Replication Publisher

-- None
ROLLBACK TRANSACTION;

Replication Publisher and Subscribers (Both)

DROP FUNCTION format_stablecoin;

DROP VIEW IF EXISTS my_liquidity_view;

DROP VIEW IF EXISTS active_liquidity_view;

DROP VIEW IF EXISTS votes_view;

DROP FUNCTION IF EXISTS vault.update_cover_key_on_vault_event_trigger() CASCADE;

CREATE FUNCTION vault.update_cover_key_on_vault_event_trigger()
RETURNS TRIGGER
AS
$$
BEGIN
  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 VIEW active_liquidity_view
AS
WITH vaults
AS
(
  SELECT
    vault.pods_issued.chain_id,
    vault.pods_issued.account,
    vault.pods_issued.address                 AS vault_address
  FROM vault.pods_issued
  UNION
  SELECT
    vault.pods_redeemed.chain_id,
    vault.pods_redeemed.account,
    vault.pods_redeemed.address               AS vault_address
  FROM vault.pods_redeemed
),
balances
AS
(
  SELECT
    vaults.chain_id,
    vaults.account,
    vaults.vault_address,
    get_cover_key_by_vault_address
    (
      vaults.chain_id,
      vaults.vault_address
    )                                         AS cover_key,
    (
      SELECT COALESCE(SUM(vault.pods_issued.issued), 0)
      FROM vault.pods_issued
      WHERE 1 = 1
      AND chain_id                            = vaults.chain_id
      AND account                             = vaults.account
      AND vault.pods_issued.address           = vaults.vault_address
    ) -
    (
      SELECT COALESCE(SUM(vault.pods_redeemed.redeemed), 0)
      FROM vault.pods_redeemed
      WHERE 1 = 1
      AND chain_id                            = vaults.chain_id
      AND account                             = vaults.account
      AND vault.pods_redeemed.address         = vaults.vault_address
    ) AS balance
  FROM vaults
  GROUP BY
    vaults.chain_id,
    vaults.account,
    vaults.vault_address
)
SELECT
  balances.chain_id,
  account,
  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;

CREATE OR REPLACE VIEW my_liquidity_view
AS
WITH stage1
AS
(
  SELECT
    vault.pods_redeemed.chain_id,
    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
  FROM vault.pods_redeemed
  UNION ALL
  SELECT
    vault.pods_issued.chain_id,
    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
  FROM vault.pods_issued
  UNION ALL
  SELECT
    vault.npm_unstaken.chain_id,
    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
  FROM vault.npm_unstaken
  UNION ALL
  SELECT
    vault.npm_staken.chain_id,
    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
  FROM vault.npm_staken
),
stage2
AS
(
  SELECT
    stage1.chain_id,
    stage1.vault_address,
    stage1.block_timestamp,
    stage1.transaction_hash,
    stage1.account,
    stage1.pod_amount,
    stage1.npm_amount,
    stage1.stablecoin_amount,
    stage1.tx_type,
    get_cover_key_by_vault_address
    (
      stage1.chain_id,
      stage1.vault_address
    )                                                               AS cover_key
  FROM stage1
)
SELECT
  stage2.chain_id,
  stage2.vault_address,
  stage2.block_timestamp,
  stage2.transaction_hash,
  stage2.account,
  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
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;

CREATE OR REPLACE VIEW my_policies_view
AS
WITH policy_txs
AS
(
  SELECT
    chain_id,
    cover_key,
    product_key,
    block_timestamp,
    cx_token,
    transaction_hash,
    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,
    'CoverPurchased'                                    AS tx_type
  FROM policy.cover_purchased
  UNION ALL
  SELECT
    chain_id,
    cover_key,
    product_key,
    block_timestamp,
    cx_token,
    transaction_hash,
    account                                             AS account,
    wei_to_ether(amount)                                AS cxtoken_amount,
    wei_to_ether(claimed)                               AS stablecoin_amount,
    'Claimed'                                           AS tx_type
  FROM cxtoken.claimed
)

SELECT
  policy_txs.chain_id,
  policy_txs.cover_key,
  policy_txs.product_key,
  policy_txs.block_timestamp,
  policy_txs.cx_token,
  policy_txs.transaction_hash,
  policy_txs.account,
  policy_txs.cxtoken_amount,
  policy_txs.stablecoin_amount,
  policy_txs.tx_type,
  bytes32_to_string(policy_txs.cover_key)       AS cover_key_string,
  bytes32_to_string(policy_txs.product_key)     AS product_key_string,
  'cxUSD'                                       AS token_symbol,
  factory.cx_token_deployed.token_name
FROM policy_txs
INNER JOIN factory.cx_token_deployed
ON factory.cx_token_deployed.chain_id           = policy_txs.chain_id
AND factory.cx_token_deployed.cover_key         = policy_txs.cover_key
AND factory.cx_token_deployed.product_key       = policy_txs.product_key
AND factory.cx_token_deployed.cx_token          = policy_txs.cx_token;

CREATE OR REPLACE VIEW votes_view
AS
WITH vote_txs
AS
(
  SELECT
    chain_id,
    cover_key,
    product_key,
    incident_date,
    block_timestamp,
    transaction_hash,
    witness,
    stake,
    'Attested'                                    AS tx_type
  FROM consensus.attested
  UNION ALL
  SELECT
    chain_id,
    cover_key,
    product_key,
    incident_date,
    block_timestamp,
    transaction_hash,
    witness,
    stake,
    'Refuted'                                     AS tx_type
  FROM consensus.refuted
)
SELECT
  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;

CREATE OR REPLACE FUNCTION get_total_capacity_by_date
(
  _chain_id                                 uint256,
  _date                                     TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
AS
$$
  DECLARE _capacity                         uint256;
BEGIN
  WITH chains
  AS
  (
    SELECT DISTINCT core.transactions.chain_id
    FROM core.transactions
    WHERE 1 = 1
    AND (_chain_id IS NULL OR core.transactions.chain_id = _chain_id)
  ),
  unfiltered
  AS
  (
    SELECT chain_id, cover_key, product_key
    FROM config_product_view
    WHERE config_product_view.chain_id IN
    (
      SELECT chain_id FROM chains
    )
    UNION ALL
    SELECT  chain_id, cover_key, string_to_bytes32('') FROM config_cover_view
    WHERE config_cover_view.chain_id IN
    (
      SELECT chain_id FROM chains
    )
  ),
  products
  AS
  (
    SELECT DISTINCT chain_id, cover_key, product_key
    FROM unfiltered
    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(get_cover_capacity_till(chain_id, cover_key, product_key, _date))
  INTO _capacity
  FROM products;

  RETURN COALESCE(_capacity, 0);
END
$$
LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION get_total_capacity_by_date
(
  _date                                     TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
AS
$$
  DECLARE _capacity                         uint256;
BEGIN
  RETURN get_total_capacity_by_date(NULL, _date);
END
$$
LANGUAGE plpgsql;



ALTER FUNCTION get_total_capacity_by_date(TIMESTAMP WITH TIME ZONE) OWNER TO writeuser;
ALTER FUNCTION get_total_capacity_by_date(uint256, TIMESTAMP WITH TIME ZONE) OWNER TO writeuser;


CREATE OR REPLACE FUNCTION get_total_covered_till_date
(
  _chain_id                                 uint256,
  _cover_key                                bytes32,
  _date                                     TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
AS
$$
  DECLARE _result numeric;
BEGIN
  SELECT SUM(get_stablecoin_value(chain_id, amount_to_cover))
  INTO _result
  FROM policy.cover_purchased
  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(block_timestamp) <= _date;

  RETURN COALESCE(_result, 0);
END
$$
LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION get_tvl_till_date
(
  _chain_id                                 uint256,
  _cover_key                                bytes32,
  _date                                     TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
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 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);
END
$$
LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION get_tvl_till_date
(
  _chain_id                                 uint256,
  _date                                     TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
AS
$$
  DECLARE _result numeric;
BEGIN
  RETURN get_tvl_till_date(_chain_id, NULL, _date);
END
$$
LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION get_tvl_till_date
(
  _date                                     TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
AS
$$
  DECLARE _result numeric;
BEGIN
  RETURN get_tvl_till_date(NULL, NULL, _date);
END
$$
LANGUAGE plpgsql;

ALTER FUNCTION get_tvl_till_date( _date TIMESTAMP WITH TIME ZONE) OWNER TO writeuser;
ALTER FUNCTION get_tvl_till_date( _chain_id uint256, _date TIMESTAMP WITH TIME ZONE) OWNER TO writeuser;
ALTER FUNCTION get_tvl_till_date( _chain_id uint256, _cover_key bytes32, _date TIMESTAMP WITH TIME ZONE) OWNER TO writeuser;

CREATE OR REPLACE VIEW capacity_view
AS
WITH chains
AS
(
  SELECT DISTINCT core.transactions.chain_id
  FROM core.transactions
),
unfiltered
AS
(
  SELECT chain_id, cover_key, product_key
  FROM config_product_view
  WHERE config_product_view.chain_id IN
  (
    SELECT chain_id FROM chains
  )
  UNION ALL
  SELECT  chain_id, cover_key, string_to_bytes32('')
  FROM config_cover_view
  WHERE config_cover_view.chain_id IN
  (
    SELECT chain_id FROM chains
  )
),
products
AS
(
  SELECT DISTINCT chain_id, cover_key, product_key
  FROM unfiltered
  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)
  )
)
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, 'infinity') AS capacity
FROM products;

ROLLBACK TRANSACTION;

Update Ownerships (Optional)

DO
$$
  DECLARE _r record;
BEGIN
  FOR _r IN
    SELECT table_schema, table_name
    FROM information_schema.tables
    WHERE table_schema NOT IN('information_schema', 'pg_catalog')
    ORDER BY table_schema, table_name
  LOOP
    EXECUTE format('ALTER TABLE %I.%I OWNER TO writeuser;', _r.table_schema, _r.table_name);
  END LOOP;

  FOR _r IN
    SELECT table_schema, table_name
    FROM information_schema.views
    WHERE table_schema NOT IN ('information_schema', 'pg_catalog')
    ORDER BY table_schema, table_name
  LOOP
    EXECUTE format('ALTER VIEW %I.%I OWNER TO writeuser;', _r.table_schema, _r.table_name);
  END LOOP;

  FOR _r IN
    SELECT CONCAT(n.nspname, '.', p.proname, '(', pg_catalog.pg_get_function_identity_arguments(p.oid), ')') AS name
    FROM pg_catalog.pg_proc p
    INNER JOIN pg_catalog.pg_namespace n
    ON n.oid = p.pronamespace
    WHERE pg_catalog.pg_function_is_visible(p.oid)
    AND n.nspname NOT IN ('information_schema', 'pg_catalog')
    AND NOT p.proisstrict
  LOOP
    EXECUTE format('ALTER FUNCTION %s OWNER TO writeuser;', _r.name);
  END LOOP;
END
$$
LANGUAGE plpgsql;

- 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
@rudolfnep rudolfnep merged commit 55421ef into neptune-mutual-blue:main Jun 7, 2024
1 check passed
@flashburst flashburst deleted the refactors branch June 7, 2024 15:35
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

2 participants