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

# Fix for Datewise Liquidity Summary #77

Merged
merged 1 commit into from
Jun 6, 2024
Merged

Conversation

heyaibi
Copy link
Contributor

@heyaibi heyaibi commented Jun 6, 2024

  • Refactored function count_cover_purchase_during, get_total_capacity_by_date, get_total_covered_till_date, sum_cover_fee_earned_during and their respective overloads
  • Fixed mistakes of the get_datewise_liquidity_summary function

Replication Publisher

-- None
ROLLBACK TRANSACTION;

Replication Publisher and Subscribers (Both)

DO
$$
BEGIN
  IF EXISTS
  (
    SELECT * FROM information_schema.tables
    WHERE table_schema = 'public'
    AND table_name = 'datewise_liquidity_summary'
  ) THEN
    TRUNCATE TABLE public.datewise_liquidity_summary;
  END IF;
END
$$
LANGUAGE plpgsql;

DROP TABLE IF EXISTS public.datewise_liquidity_summary;

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 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
  )
  SELECT SUM(capacity)
  INTO _capacity
  FROM summary
  WHERE 1 = 1
  AND NOT (diversified = true AND product_key != string_to_bytes32(''));

  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(expires_on) <= _date;

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


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

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

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


CREATE OR REPLACE FUNCTION sum_cover_fee_earned_during
(
  _chain_id                                   uint256,
  _cover_key                                  bytes32,
  _start                                      TIMESTAMP WITH TIME ZONE,
  _end                                        TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
AS
$$
  DECLARE _result numeric;
BEGIN
  SELECT
    SUM(get_stablecoin_value(policy.cover_purchased.chain_id, policy.cover_purchased.fee))
  INTO
    _result
  FROM policy.cover_purchased
  WHERE 1 = 1
  AND (_chain_id IS NULL OR policy.cover_purchased.chain_id = _chain_id)
  AND (_cover_key IS NULL OR policy.cover_purchased.cover_key = _cover_key)
  AND to_timestamp(policy.cover_purchased.block_timestamp)
  BETWEEN _start AND _end;

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


CREATE OR REPLACE FUNCTION sum_cover_fee_earned_during
(
  _chain_id                                   uint256,
  _start                                      TIMESTAMP WITH TIME ZONE,
  _end                                        TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
AS
$$
BEGIN
  RETURN sum_cover_fee_earned_during(_chain_id, NULL, _start, _end);
END
$$
LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION sum_cover_fee_earned_during
(
  _start                                      TIMESTAMP WITH TIME ZONE,
  _end                                        TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
AS
$$
BEGIN
  RETURN sum_cover_fee_earned_during(NULL, NULL, _start, _end);
END
$$
LANGUAGE plpgsql;


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

CREATE OR REPLACE FUNCTION count_cover_purchase_during
(
  _chain_id                                   uint256,
  _cover_key                                  bytes32,
  _product_key                                bytes32,
  _start                                      TIMESTAMP WITH TIME ZONE,
  _end                                        TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
AS
$$
  DECLARE _result numeric;
BEGIN
  SELECT COUNT(*)
  INTO _result
  FROM policy.cover_purchased
  WHERE 1 = 1
  AND (_chain_id IS NULL OR policy.cover_purchased.chain_id = _chain_id)
  AND (_cover_key IS NULL OR policy.cover_purchased.cover_key = _cover_key)
  AND (_product_key IS NULL OR policy.cover_purchased.product_key = _product_key)
  AND to_timestamp(policy.cover_purchased.block_timestamp) BETWEEN _start AND _end;

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

CREATE OR REPLACE FUNCTION count_cover_purchase_during
(
  _chain_id                                   uint256,
  _cover_key                                  bytes32,
  _start                                      TIMESTAMP WITH TIME ZONE,
  _end                                        TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
AS
$$
BEGIN
  RETURN count_cover_purchase_during(_chain_id, _cover_key, NULL, _start, _end);
END
$$
LANGUAGE plpgsql;


CREATE OR REPLACE FUNCTION count_cover_purchase_during
(
  _chain_id                                   uint256,
  _start                                      TIMESTAMP WITH TIME ZONE,
  _end                                        TIMESTAMP WITH TIME ZONE
)
RETURNS numeric
STABLE
AS
$$
BEGIN
  RETURN count_cover_purchase_during(_chain_id, NULL, NULL, _start, _end);
END
$$
LANGUAGE plpgsql;


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


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

CREATE OR REPLACE FUNCTION get_datewise_liquidity_summary()
RETURNS TABLE
(
  id                                                        bigint,
  date                                                      TIMESTAMP WITH TIME ZONE,
  total_liquidity                                           numeric,
  total_capacity                                            numeric,
  total_covered                                             numeric,
  total_cover_fee                                           numeric,
  total_purchase_count                                      numeric  
)
SECURITY DEFINER
AS
$$
  DECLARE _start                                            TIMESTAMP WITH TIME ZONE;
  DECLARE _end                                              TIMESTAMP WITH TIME ZONE;
BEGIN
  CREATE UNLOGGED TABLE IF NOT EXISTS public.datewise_liquidity_summary
  (
    id                                                      BIGSERIAL,
    chain_id                                                uint256,
    date                                                    TIMESTAMP WITH TIME ZONE,
    total_liquidity                                         numeric,
    total_capacity                                          numeric,
    total_covered                                           numeric,
    total_cover_fee                                         numeric,
    total_purchase_count                                    numeric  
  );

  ALTER TABLE public.datewise_liquidity_summary OWNER TO writeuser;

  CREATE INDEX IF NOT EXISTS datewise_liquidity_summary_date_inx
  ON public.datewise_liquidity_summary(date);

  -- The final cache row is inevitably stale as its execution might have occurred prior to the end of the day.
  WITH stale_data
  AS
  (
    SELECT public.datewise_liquidity_summary.chain_id, MAX(public.datewise_liquidity_summary.date) AS date
    FROM public.datewise_liquidity_summary
    GROUP BY public.datewise_liquidity_summary.chain_id
  )
  DELETE FROM public.datewise_liquidity_summary
  WHERE (public.datewise_liquidity_summary.chain_id, public.datewise_liquidity_summary.date) IN
  (
    SELECT * FROM stale_data
  );

  WITH date_ranges
  AS
  (
    SELECT
      min(block_timestamp) AS min,
      max(block_timestamp) AS max
    FROM core.transactions
  )
  SELECT to_timestamp(min), to_timestamp(max)
  INTO _start, _end
  FROM date_ranges;


  SELECT COALESCE(summary.max_date, _start)
  INTO _start
  FROM
  (
    SELECT MAX(datewise_liquidity_summary.date) AS max_date
    FROM datewise_liquidity_summary
  ) AS summary;

  RAISE NOTICE 'Start date: %. End date: %', _start, _end;

  WITH chains
  AS
  (
    SELECT DISTINCT core.transactions.chain_id
    FROM core.transactions
  ),
  dates
  AS
  (
    SELECT date_trunc('day', dates)::date + interval '1 day' - interval '1 second' AS date
    FROM generate_series(_start, _end, INTERVAL '1 days') AS dates
  ),
  chainwise
  AS
  (
    SELECT DISTINCT chains.chain_id, dates.date
    FROM chains
    CROSS JOIN dates
  )
  INSERT INTO public.datewise_liquidity_summary(chain_id, date)
  SELECT chainwise.chain_id, chainwise.date
  FROM chainwise
  LEFT JOIN public.datewise_liquidity_summary
  ON chainwise.chain_id = public.datewise_liquidity_summary.chain_id
  AND chainwise.date = public.datewise_liquidity_summary.date
  WHERE public.datewise_liquidity_summary.chain_id IS NULL;

  UPDATE public.datewise_liquidity_summary
  SET total_liquidity = get_tvl_till_date(public.datewise_liquidity_summary.chain_id, public.datewise_liquidity_summary.date)
  WHERE public.datewise_liquidity_summary.total_liquidity IS NULL;

  UPDATE public.datewise_liquidity_summary
  SET total_capacity = get_total_capacity_by_date(public.datewise_liquidity_summary.chain_id, public.datewise_liquidity_summary.date)
  WHERE public.datewise_liquidity_summary.total_capacity IS NULL;

  UPDATE public.datewise_liquidity_summary
  SET total_covered = get_total_covered_till_date(public.datewise_liquidity_summary.chain_id, public.datewise_liquidity_summary.date)
  WHERE public.datewise_liquidity_summary.total_covered IS NULL;

  UPDATE public.datewise_liquidity_summary
  SET total_cover_fee = sum_cover_fee_earned_during(public.datewise_liquidity_summary.chain_id, '-infinity', public.datewise_liquidity_summary.date)
  WHERE public.datewise_liquidity_summary.total_cover_fee IS NULL;

  UPDATE public.datewise_liquidity_summary
  SET total_purchase_count = count_cover_purchase_during(public.datewise_liquidity_summary.chain_id, '-infinity', public.datewise_liquidity_summary.date)
  WHERE public.datewise_liquidity_summary.total_purchase_count IS NULL;

  RETURN QUERY
  SELECT
    row_number() OVER(ORDER BY public.datewise_liquidity_summary.date) AS id,
    public.datewise_liquidity_summary.date,
    SUM(public.datewise_liquidity_summary.total_liquidity) AS total_liquidity,
    SUM(public.datewise_liquidity_summary.total_capacity) AS total_capacity,
    SUM(public.datewise_liquidity_summary.total_covered) AS total_covered,
    SUM(public.datewise_liquidity_summary.total_cover_fee) AS total_cover_fee,
    SUM(public.datewise_liquidity_summary.total_purchase_count) AS total_purchase_count
  FROM public.datewise_liquidity_summary
  GROUP BY public.datewise_liquidity_summary.date;
END
$$
LANGUAGE plpgsql;

ALTER FUNCTION get_datewise_liquidity_summary() OWNER TO writeuser;
ALTER TABLE core.transactions owner to writeuser;
ALTER TABLE IF EXISTS public.datewise_liquidity_summary owner to writeuser;

SELECT * FROM get_datewise_liquidity_summary();

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;

- Refactored function `count_cover_purchase_during`, `get_total_capacity_by_date`, `get_total_covered_till_date`, `sum_cover_fee_earned_during` and their respective overloads
- Fixed mistakes of the `get_datewise_liquidity_summary` function
@flashburst flashburst merged commit e9440c4 into main Jun 6, 2024
1 check passed
@flashburst flashburst deleted the fix/datewise-summary branch June 6, 2024 13:25
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