Skip to content

Commit

Permalink
Merge pull request #8 from flashburst/updates/policy-views
Browse files Browse the repository at this point in the history
Updated policy views to contain same columns
  • Loading branch information
rudolfnep committed Apr 17, 2023
2 parents 4678df7 + 6668b5e commit e13d85a
Show file tree
Hide file tree
Showing 3 changed files with 57 additions and 10 deletions.
2 changes: 1 addition & 1 deletion sql/app/home/top_accounts_by_protection_view.sql
Expand Up @@ -5,7 +5,7 @@ AS
SELECT
on_behalf_of,
COUNT(*) AS policies,
SUM(amount_to_cover) AS protection
SUM(get_stablecoin_value(chain_id, amount_to_cover)) AS protection
FROM policy.cover_purchased
WHERE expires_on > extract(epoch FROM NOW() AT TIME ZONE 'UTC')
GROUP BY on_behalf_of
Expand Down
37 changes: 31 additions & 6 deletions sql/app/policy/active_policies_view.sql
Expand Up @@ -5,17 +5,37 @@ AS
SELECT
chain_id,
cover_key,
bytes32_to_string(cover_key) AS cover_key_string,
bytes32_to_string(cover_key) AS cover_key_string,
product_key,
bytes32_to_string(product_key) AS product_key_string,
bytes32_to_string(product_key) AS product_key_string,
cx_token,
expires_on,
on_behalf_of,
SUM(amount_to_cover),
get_active_product_status(chain_id, cover_key, product_key) AS product_status_enum,
array_length(enum_range(NULL, get_active_product_status(chain_id, cover_key, product_key)), 1) - 1 AS product_status,
SUM(amount_to_cover) AS amount,
get_active_product_status
(
chain_id,
cover_key,
product_key
) AS product_status_enum,
array_length(
enum_range(NULL, get_active_product_status(chain_id, cover_key, product_key)),
1
) - 1 AS product_status,
(get_cover_info(chain_id, cover_key)).*,
(get_product_info(chain_id, cover_key, product_key)).*
(get_product_info(chain_id, cover_key, product_key)).*,
(get_report_insight(
chain_id,
cover_key,
product_key,
get_active_incident_date(chain_id, cover_key, product_key)
)).claim_begins_from,
(get_report_insight(
chain_id,
cover_key,
product_key,
get_active_incident_date(chain_id, cover_key, product_key)
)).claim_expires_at
FROM policy.cover_purchased
WHERE expires_on > extract(epoch FROM NOW() AT TIME ZONE 'UTC')
GROUP BY
Expand All @@ -25,3 +45,8 @@ GROUP BY
cx_token,
expires_on,
on_behalf_of;


-- SELECT * FROM active_policies_view
-- WHERE on_behalf_of = '0x201bcc0d375f10543e585fbb883b36c715c959b3'
-- AND chain_id = 84531
28 changes: 25 additions & 3 deletions sql/app/policy/expired_policies_view.sql
Expand Up @@ -12,6 +12,7 @@ AS
on_behalf_of,
block_timestamp,
expires_on,
cx_token,
get_incident_date_by_expiry_date
(
chain_id,
Expand All @@ -27,18 +28,34 @@ AS
SELECT
chain_id,
cover_key,
bytes32_to_string(cover_key) AS cover_key_string,
product_key,
bytes32_to_string(product_key) AS product_key_string,
cx_token,
expires_on,
on_behalf_of,
expires_on,
SUM(amount_to_cover) AS amount,
incident_date,
get_product_status
(
chain_id,
cover_key,
product_key,
incident_date
) AS product_status,
SUM(amount_to_cover) AS amount,
) AS product_status_enum,
array_length(
enum_range(
NULL,
get_product_status
(
chain_id,
cover_key,
product_key,
incident_date
)
),
1
) - 1 AS product_status,
(get_cover_info(chain_id, cover_key)).*,
(get_product_info(chain_id, cover_key, product_key)).*
FROM summary
Expand All @@ -47,5 +64,10 @@ GROUP BY
cover_key,
product_key,
on_behalf_of,
cx_token,
expires_on,
incident_date;

-- SELECT * FROM expired_policies_view
-- WHERE on_behalf_of = '0x201bcc0d375f10543e585fbb883b36c715c959b3'
-- AND chain_id = 84531

0 comments on commit e13d85a

Please sign in to comment.