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

Update APR calculations #37

Merged
merged 3 commits into from
Apr 9, 2024
Merged
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
28 changes: 23 additions & 5 deletions dashboard/modules/base_mainnet/core_stats.py
Original file line number Diff line number Diff line change
@@ -59,7 +59,7 @@ def fetch_data(filters):

df_pnl = pd.read_sql_query(
f"""
SELECT * FROM base_mainnet.fct_perp_pnl
SELECT * FROM base_mainnet.fct_pool_pnl
WHERE ts >= '{start_date}' and ts <= '{end_date}'
ORDER BY ts
""",
@@ -125,11 +125,27 @@ def make_charts(data):
["hourly_pnl"],
"Hourly Pnl",
),
"apr": chart_lines(
"apr_combined": chart_lines(
data["apr"],
"ts",
["apr_28d", "apy_28d"],
"APR",
["apr_7d", "apr_28d"],
"APR: Pool Pnl + Rewards",
smooth=True,
y_format="%",
),
"apr_pnl": chart_lines(
data["apr"],
"ts",
["apr_7d_pnl", "apr_28d_pnl"],
"APR: Pool Pnl Only",
smooth=True,
y_format="%",
),
"apr_rewards": chart_lines(
data["apr"],
"ts",
["apr_7d_rewards", "apr_28d_rewards"],
"APR: Rewards Only",
smooth=True,
y_format="%",
),
@@ -160,11 +176,13 @@ def main():
st.plotly_chart(charts["collateral"], use_container_width=True)
st.plotly_chart(charts["net_issuance"], use_container_width=True)
st.plotly_chart(charts["hourly_pnl"], use_container_width=True)
st.plotly_chart(charts["apr_pnl"], use_container_width=True)

with col2:
st.plotly_chart(charts["debt"], use_container_width=True)
st.plotly_chart(charts["pnl"], use_container_width=True)
st.plotly_chart(charts["apr"], use_container_width=True)
st.plotly_chart(charts["apr_combined"], use_container_width=True)
st.plotly_chart(charts["apr_rewards"], use_container_width=True)

st.markdown("## Top Delegators")
st.dataframe(
28 changes: 23 additions & 5 deletions dashboard/modules/base_sepolia/core_stats.py
Original file line number Diff line number Diff line change
@@ -59,7 +59,7 @@ def fetch_data(filters):

df_pnl = pd.read_sql_query(
f"""
SELECT * FROM base_sepolia.fct_perp_pnl
SELECT * FROM base_sepolia.fct_pool_pnl
WHERE ts >= '{start_date}' and ts <= '{end_date}'
ORDER BY ts
""",
@@ -125,11 +125,27 @@ def make_charts(data):
["hourly_pnl"],
"Hourly Pnl",
),
"apr": chart_lines(
"apr_combined": chart_lines(
data["apr"],
"ts",
["apr_28d", "apy_28d"],
"APR",
["apr_7d", "apr_28d"],
"APR: Pool Pnl + Rewards",
smooth=True,
y_format="%",
),
"apr_pnl": chart_lines(
data["apr"],
"ts",
["apr_7d_pnl", "apr_28d_pnl"],
"APR: Pool Pnl Only",
smooth=True,
y_format="%",
),
"apr_rewards": chart_lines(
data["apr"],
"ts",
["apr_7d_rewards", "apr_28d_rewards"],
"APR: Rewards Only",
smooth=True,
y_format="%",
),
@@ -160,11 +176,13 @@ def main():
st.plotly_chart(charts["collateral"], use_container_width=True)
st.plotly_chart(charts["net_issuance"], use_container_width=True)
st.plotly_chart(charts["hourly_pnl"], use_container_width=True)
st.plotly_chart(charts["apr_pnl"], use_container_width=True)

with col2:
st.plotly_chart(charts["debt"], use_container_width=True)
st.plotly_chart(charts["pnl"], use_container_width=True)
st.plotly_chart(charts["apr"], use_container_width=True)
st.plotly_chart(charts["apr_combined"], use_container_width=True)
st.plotly_chart(charts["apr_rewards"], use_container_width=True)

st.markdown("## Top Delegators")
st.dataframe(
14 changes: 7 additions & 7 deletions indexers/base-sepolia/squidgen.yaml
Original file line number Diff line number Diff line change
@@ -7,37 +7,37 @@ target:
type: postgres
contracts:
- name: CoreProxy
address: "0xF4Df9Dd327Fd30695d478c3c8a2fffAddcdD0d31"
address: "0x764F4C95FDA0D6f8114faC54f6709b1B45f919a1"
abi: ./abi/CoreProxy.json
events: true
functions: false
- name: PerpsAccountProxy
address: "0x87f578681CDE29F0701E7274708E1A67Ee9eEf94"
address: "0xc8eE218577545D5b38443C0eB5d7B9E4140085F2"
abi: ./abi/PerpsAccountProxy.json
events: true
functions: false
- name: AccountProxy
address: "0xa88694d0025dd96194D1B0237fDEbf7D1D34B02F"
address: "0x9EB560Cc26c2766929A41F8e46E87bd4b8b145d9"
abi: ./abi/AccountProxy.json
events: true
functions: false
- name: PerpsMarketProxy
address: "0xE6C5f05C415126E6b81FCc3619f65Db2fCAd58D0"
address: "0xf53Ca60F031FAf0E347D44FbaA4870da68250c8d"
abi: ./abi/PerpsMarketProxy.json
events: true
functions: false
- name: PerpsMarketProxyLegacy
address: "0xE6C5f05C415126E6b81FCc3619f65Db2fCAd58D0"
address: "0xf53Ca60F031FAf0E347D44FbaA4870da68250c8d"
abi: ./abi/PerpsMarketProxyLegacy.json
events: true
functions: false
- name: SpotMarketProxy
address: "0xA4fE63F8ea9657990eA8E05Ebfa5C19a7D4d7337"
address: "0xaD2fE7cd224c58871f541DAE01202F93928FEF72"
abi: ./abi/SpotMarketProxy.json
events: true
functions: false
- name: BuybackSnx
address: "0x1Cd30a3CCd177F37Bd7199723B4497d31A7209e4"
address: "0xC0552736788bFA357539D6FeB690b14e4977E871"
abi: ./abi/BuybackSnx.json
events: true
functions: false
4 changes: 2 additions & 2 deletions transformers/synthetix/dbt_project.yml
Original file line number Diff line number Diff line change
@@ -28,7 +28,7 @@ models:
perp:
enabled: "{{ target.name in ('base_sepolia', 'base_mainnet') }}"
buyback:
enabled: "{{ target.name in ('base_mainnet') }}"
enabled: "{{ target.name in ('base_mainnet', 'base_sepolia') }}"
marts:
core:
enabled: "{{ target.name in ('base_sepolia', 'optimism_mainnet', 'base_mainnet') }}"
@@ -39,4 +39,4 @@ models:
perp_stats:
enabled: "{{ target.name in ('base_sepolia', 'base_mainnet') }}"
buyback:
enabled: "{{ target.name in ('base_mainnet') }}"
enabled: "{{ target.name in ('base_mainnet', 'base_sepolia') }}"
23 changes: 16 additions & 7 deletions transformers/synthetix/macros/get_event_data.sql
Original file line number Diff line number Diff line change
@@ -1,9 +1,18 @@
{% macro get_event_data(contract_name, event_name) %}
WITH source_data AS (
SELECT *
FROM {{ source('raw_' ~ target.name, contract_name ~ '_event_' ~ event_name) }}
)
SELECT
{% macro get_event_data(
contract_name,
event_name
) %}
WITH source_data AS (
SELECT
*
FROM
{{ source(
'raw_' ~ target.name,
contract_name ~ '_event_' ~ event_name
) }}
)
SELECT
*
FROM source_data
FROM
source_data
{% endmacro %}
11 changes: 11 additions & 0 deletions transformers/synthetix/macros/get_reward_distributor_token.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
{% macro get_reward_distributor_token(
distributor
) %}
CASE
WHEN '{{ target.name }}' = 'base_mainnet'
AND distributor = '0xe92bcD40849BE5a5eb90065402e508aF4b28263b' THEN 'USDC'
WHEN '{{ target.name }}' = 'base_mainnet'
AND distributor = '0x45063DCd92f56138686810eacB1B510C941d6593' THEN 'SNX'
ELSE NULL
END
{% endmacro %}
Original file line number Diff line number Diff line change
@@ -4,6 +4,6 @@ SELECT
buyer,
{{ convert_wei('snx') }} AS snx,
{{ convert_wei('usd') }} AS usd,
{{ convert_wei('usd') }} / {{ convert_wei('snx') }} AS snx_price
({{ convert_wei('usd') }}) / ({{ convert_wei('snx') }}) AS snx_price
FROM
{{ ref('buyback_processed') }}
20 changes: 20 additions & 0 deletions transformers/synthetix/models/marts/core/fct_pool_pnl.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,20 @@
WITH debt AS (
SELECT
ts,
pool_id,
collateral_type,
2 AS market_id,
debt * -1 AS market_pnl
FROM
{{ ref('core_vault_debt') }}
)
SELECT
ts,
pool_id,
collateral_type,
market_id,
market_pnl
FROM
debt
ORDER BY
ts
262 changes: 262 additions & 0 deletions transformers/synthetix/models/marts/core/fct_pool_pnl_hourly.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,262 @@
WITH dim AS (
SELECT
generate_series(DATE_TRUNC('hour', MIN(t.ts)), DATE_TRUNC('hour', MAX(t.ts)), '1 hour' :: INTERVAL) AS ts,
m.market_id
FROM
(
SELECT
ts
FROM
{{ ref('fct_core_market_updated') }}
) AS t
CROSS JOIN (
SELECT
DISTINCT market_id
FROM
{{ ref('fct_core_market_updated') }}
) AS m
GROUP BY
m.market_id
),
pnls AS (
SELECT
DISTINCT DATE_TRUNC(
'hour',
ts
) AS ts,
market_id,
LAST_VALUE(market_pnl) over (PARTITION BY DATE_TRUNC('hour', ts), market_id
ORDER BY
ts rows BETWEEN unbounded preceding
AND unbounded following) AS pnl
FROM
{{ ref('fct_pool_pnl') }}
),
collateral AS (
SELECT
DISTINCT DATE_TRUNC(
'hour',
ts
) AS ts,
2 AS market_id,
LAST_VALUE(collateral_value) over (PARTITION BY DATE_TRUNC('hour', ts)
ORDER BY
ts rows BETWEEN unbounded preceding
AND unbounded following) AS collateral_value
FROM
{{ ref('core_vault_collateral') }}
WHERE
pool_id = 1
),
ffill AS (
SELECT
dim.ts,
dim.market_id,
pnls.pnl,
collateral.collateral_value,
SUM(
CASE
WHEN pnls.pnl IS NOT NULL THEN 1
ELSE 0
END
) over (
ORDER BY
dim.ts
) AS pnl_id,
SUM(
CASE
WHEN collateral.collateral_value IS NOT NULL THEN 1
ELSE 0
END
) over (
ORDER BY
dim.ts
) AS collateral_id
FROM
dim
LEFT JOIN pnls
ON dim.ts = pnls.ts
AND dim.market_id = pnls.market_id
LEFT JOIN collateral
ON dim.ts = collateral.ts
AND dim.market_id = collateral.market_id
),
hourly_index AS (
SELECT
ts,
market_id,
FIRST_VALUE(COALESCE(pnl, 0)) over (
PARTITION BY pnl_id,
market_id
ORDER BY
ts
) AS pnl,
FIRST_VALUE(COALESCE(collateral_value, 0)) over (
PARTITION BY collateral_id,
market_id
ORDER BY
ts
) AS collateral_value
FROM
ffill
),
hourly_pnl AS (
SELECT
ts,
market_id,
COALESCE(pnl - LAG(pnl) over (PARTITION BY market_id
ORDER BY
ts), 0) AS hourly_pnl,
collateral_value,
COALESCE(
(pnl - LAG(pnl) over (PARTITION BY market_id
ORDER BY
ts)) / NULLIF(
collateral_value,
0
),
0
) AS hourly_pnl_pct
FROM
hourly_index
),
hourly_rewards AS (
SELECT
ts,
market_id,
pool_id,
collateral_type,
rewards_usd
FROM
{{ ref('fct_pool_rewards_hourly') }}
),
hourly_returns AS (
SELECT
pnl.ts,
pnl.market_id,
pnl.collateral_value,
pnl.hourly_pnl,
pnl.hourly_pnl_pct,
COALESCE(
rewards.rewards_usd,
0
) AS rewards_usd,
CASE
WHEN pnl.collateral_value = 0 THEN 0
ELSE COALESCE(
rewards.rewards_usd,
0
) / pnl.collateral_value
END AS hourly_rewards_pct,
CASE
WHEN pnl.collateral_value = 0 THEN 0
ELSE (COALESCE(rewards.rewards_usd, 0) + pnl.hourly_pnl) / pnl.collateral_value
END AS hourly_total_pct
FROM
hourly_pnl pnl
LEFT JOIN hourly_rewards rewards
ON pnl.ts = rewards.ts
AND pnl.market_id = rewards.market_id
),
avg_returns AS (
SELECT
ts,
market_id,
AVG(
hourly_pnl_pct
) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '24 HOURS' preceding
AND CURRENT ROW
) AS avg_24h_pnl_pct,
AVG(
hourly_pnl_pct
) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '7 DAYS' preceding
AND CURRENT ROW
) AS avg_7d_pnl_pct,
AVG(
hourly_pnl_pct
) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '28 DAYS' preceding
AND CURRENT ROW
) AS avg_28d_pnl_pct,
AVG(
hourly_rewards_pct
) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '24 HOURS' preceding
AND CURRENT ROW
) AS avg_24h_rewards_pct,
AVG(
hourly_rewards_pct
) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '7 DAYS' preceding
AND CURRENT ROW
) AS avg_7d_rewards_pct,
AVG(
hourly_rewards_pct
) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '28 DAYS' preceding
AND CURRENT ROW
) AS avg_28d_rewards_pct,
AVG(
hourly_total_pct
) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '24 HOURS' preceding
AND CURRENT ROW
) AS avg_24h_total_pct,
AVG(
hourly_total_pct
) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '7 DAYS' preceding
AND CURRENT ROW
) AS avg_7d_total_pct,
AVG(
hourly_total_pct
) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '28 DAYS' preceding
AND CURRENT ROW
) AS avg_28d_total_pct
FROM
hourly_returns
)
SELECT
hourly_returns.ts,
hourly_returns.market_id,
hourly_returns.collateral_value,
hourly_returns.hourly_pnl,
hourly_returns.rewards_usd,
hourly_returns.hourly_pnl_pct,
hourly_returns.hourly_rewards_pct,
hourly_returns.hourly_total_pct,
avg_returns.avg_24h_pnl_pct,
avg_returns.avg_24h_rewards_pct,
avg_returns.avg_24h_total_pct,
avg_returns.avg_7d_pnl_pct,
avg_returns.avg_7d_rewards_pct,
avg_returns.avg_7d_total_pct,
avg_returns.avg_28d_pnl_pct,
avg_returns.avg_28d_rewards_pct,
avg_returns.avg_28d_total_pct
FROM
hourly_returns
JOIN avg_returns
ON hourly_returns.ts = avg_returns.ts
AND hourly_returns.market_id = avg_returns.market_id
28 changes: 28 additions & 0 deletions transformers/synthetix/models/marts/core/fct_pool_rewards.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
WITH rewards_distributed AS (
SELECT
block_timestamp AS ts,
pool_id,
collateral_type,
2 AS market_id,
distributor,
{{ get_reward_distributor_token('distributor') }} AS market_symbol,
{{ convert_wei('amount') }} AS amount,
TO_TIMESTAMP("start") AS ts_start,
"duration"
FROM
{{ ref('core_rewards_distributed') }}
)
SELECT
ts,
pool_id,
collateral_type,
market_id,
distributor,
market_symbol,
amount,
ts_start,
"duration"
FROM
rewards_distributed
ORDER BY
ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
WITH token_hourly AS (
SELECT
ts,
market_id,
pool_id,
collateral_type,
rewards_usd
FROM
{{ ref('fct_pool_rewards_token_hourly') }}
)
SELECT
ts,
market_id,
pool_id,
collateral_type,
SUM(rewards_usd) AS rewards_usd
FROM
token_hourly
GROUP BY
ts,
market_id,
pool_id,
collateral_type
Original file line number Diff line number Diff line change
@@ -0,0 +1,86 @@
WITH dim AS (
SELECT
generate_series(DATE_TRUNC('hour', MIN(t.ts)), DATE_TRUNC('hour', MAX(t.ts)), '1 hour' :: INTERVAL) AS ts,
m.market_id
FROM
(
SELECT
ts
FROM
{{ ref('fct_core_market_updated') }}
) AS t
CROSS JOIN (
SELECT
DISTINCT market_id
FROM
{{ ref('fct_core_market_updated') }}
) AS m
GROUP BY
m.market_id
),
rewards_distributed AS (
SELECT
ts,
pool_id,
collateral_type,
market_id,
distributor,
market_symbol,
amount,
ts_start,
"duration"
FROM
{{ ref('fct_pool_rewards') }}
),
hourly_rewards AS (
SELECT
dim.ts,
dim.market_id,
r.pool_id,
r.collateral_type,
r.ts_start,
dim.ts + '1 hour' :: INTERVAL AS ts_end,
r.distributor,
r.market_symbol,
p.price,
-- get the hourly amount distributed
r.amount / (
r."duration" / 3600
) AS hourly_amount,
-- get the amount of time distributed this hour
-- use the smaller of those two intervals
-- convert the interval to a number of hours
-- multiply the result by the hourly amount to get the amount distributed this hour
(
EXTRACT(
epoch
FROM
LEAST(
"duration" / 3600 * '1 hour' :: INTERVAL,
dim.ts + '1 hour' :: INTERVAL - GREATEST(
dim.ts,
r.ts_start
)
)
) / 3600
) * r.amount / (
r."duration" / 3600
) AS amount_distributed
FROM
dim
LEFT JOIN rewards_distributed r
ON dim.market_id = r.market_id
AND dim.ts + '1 hour' :: INTERVAL >= r.ts_start
AND dim.ts < r.ts_start + r."duration" * '1 second' :: INTERVAL
LEFT JOIN {{ ref('fct_prices_hourly') }}
p
ON dim.ts = p.ts
AND r.market_symbol = p.market_symbol
)
SELECT
*,
amount_distributed * price AS rewards_usd
FROM
hourly_rewards
WHERE
amount_distributed IS NOT NULL
202 changes: 51 additions & 151 deletions transformers/synthetix/models/marts/core_stat/fct_core_apr.sql
Original file line number Diff line number Diff line change
@@ -1,175 +1,61 @@
WITH dim AS (
SELECT
generate_series(DATE_TRUNC('hour', MIN(t.ts)), DATE_TRUNC('hour', MAX(t.ts)), '1 hour' :: INTERVAL) AS ts,
m.market_id
FROM
(
SELECT
ts
FROM
{{ ref('fct_core_market_updated') }}
) AS t
CROSS JOIN (
SELECT
DISTINCT market_id
FROM
{{ ref('fct_core_market_updated') }}
) AS m
GROUP BY
m.market_id
),
pnls AS (
SELECT
DISTINCT DATE_TRUNC(
'hour',
ts
) AS ts,
market_id,
LAST_VALUE(market_pnl) over (PARTITION BY DATE_TRUNC('hour', ts), market_id
ORDER BY
ts rows BETWEEN unbounded preceding
AND unbounded following) AS pnl
FROM
{{ ref('fct_perp_pnl') }}
),
collateral AS (
SELECT
DISTINCT DATE_TRUNC(
'hour',
ts
) AS ts,
2 AS market_id,
LAST_VALUE(collateral_value) over (PARTITION BY DATE_TRUNC('hour', ts)
ORDER BY
ts rows BETWEEN unbounded preceding
AND unbounded following) AS collateral_value
FROM
{{ ref('core_vault_collateral') }}
WHERE
pool_id = 1
),
ffill AS (
SELECT
dim.ts,
dim.market_id,
pnls.pnl,
collateral.collateral_value,
SUM(
CASE
WHEN pnls.pnl IS NOT NULL THEN 1
ELSE 0
END
) over (
ORDER BY
dim.ts
) AS pnl_id,
SUM(
CASE
WHEN collateral.collateral_value IS NOT NULL THEN 1
ELSE 0
END
) over (
ORDER BY
dim.ts
) AS collateral_id
FROM
dim
LEFT JOIN pnls
ON dim.ts = pnls.ts
AND dim.market_id = pnls.market_id
LEFT JOIN collateral
ON dim.ts = collateral.ts
AND dim.market_id = collateral.market_id
),
hourly_pnl AS (
SELECT
ts,
market_id,
FIRST_VALUE(COALESCE(pnl, 0)) over (
PARTITION BY pnl_id,
market_id
ORDER BY
ts
) AS pnl,
FIRST_VALUE(COALESCE(collateral_value, 0)) over (
PARTITION BY collateral_id,
market_id
ORDER BY
ts
) AS collateral_value
FROM
ffill
),
hourly_calculations AS (
SELECT
ts,
market_id,
COALESCE(pnl - LAG(pnl) over (PARTITION BY market_id
ORDER BY
ts), 0) AS hourly_pnl,
collateral_value,
COALESCE(
(pnl - LAG(pnl) over (PARTITION BY market_id
ORDER BY
ts)) / NULLIF(
collateral_value,
0
),
0
) AS hourly_pnl_pct
FROM
hourly_pnl
),
hourly_returns AS (
WITH pnl_hourly AS (
SELECT
ts,
market_id,
collateral_value,
hourly_pnl,
rewards_usd,
hourly_pnl_pct,
AVG(hourly_pnl_pct) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '24 HOURS' preceding
AND CURRENT ROW
) AS avg_24h_pnl_pct,
AVG(hourly_pnl_pct) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '7 DAYS' preceding
AND CURRENT ROW
) AS avg_7d_pnl_pct,
AVG(hourly_pnl_pct) over (
PARTITION BY market_id
ORDER BY
ts RANGE BETWEEN INTERVAL '28 DAYS' preceding
AND CURRENT ROW
) AS avg_28d_pnl_pct
hourly_rewards_pct,
hourly_total_pct,
avg_24h_pnl_pct,
avg_24h_rewards_pct,
avg_24h_total_pct,
avg_7d_pnl_pct,
avg_7d_rewards_pct,
avg_7d_total_pct,
avg_28d_pnl_pct,
avg_28d_rewards_pct,
avg_28d_total_pct
FROM
hourly_calculations
{{ ref('fct_pool_pnl_hourly') }}
),
apr_calculations AS (
SELECT
ts,
market_id,
collateral_value,
hourly_pnl,
rewards_usd,
hourly_pnl_pct,
avg_24h_pnl_pct,
avg_24h_pnl_pct * 24 * 365 AS apr_24h,
avg_7d_pnl_pct,
avg_7d_pnl_pct * 24 * 365 AS apr_7d,
avg_28d_pnl_pct,
avg_28d_pnl_pct * 24 * 365 AS apr_28d
hourly_rewards_pct,
-- total pnls
avg_24h_total_pct * 24 * 365 AS apr_24h,
avg_7d_total_pct * 24 * 365 AS apr_7d,
avg_28d_total_pct * 24 * 365 AS apr_28d,
-- pool pnls
avg_24h_pnl_pct * 24 * 365 AS apr_24h_pnl,
avg_7d_pnl_pct * 24 * 365 AS apr_7d_pnl,
avg_28d_pnl_pct * 24 * 365 AS apr_28d_pnl,
-- rewards pnls
avg_24h_rewards_pct * 24 * 365 AS apr_24h_rewards,
avg_7d_rewards_pct * 24 * 365 AS apr_7d_rewards,
avg_28d_rewards_pct * 24 * 365 AS apr_28d_rewards
FROM
hourly_returns
pnl_hourly
),
apy_calculations AS (
SELECT
*,
(power(1 + apr_24h / 8760, 8760) - 1) AS apy_24h,
(power(1 + apr_7d / 8760, 8760) - 1) AS apy_7d,
(power(1 + apr_28d / 8760, 8760) - 1) AS apy_28d
(power(1 + apr_28d / 8760, 8760) - 1) AS apy_28d,
(power(1 + apr_24h_pnl / 8760, 8760) - 1) AS apy_24h_pnl,
(power(1 + apr_7d_pnl / 8760, 8760) - 1) AS apy_7d_pnl,
(power(1 + apr_28d_pnl / 8760, 8760) - 1) AS apy_28d_pnl,
(power(1 + apr_24h_rewards / 8760, 8760) - 1) AS apy_24h_rewards,
(power(1 + apr_7d_rewards / 8760, 8760) - 1) AS apy_7d_rewards,
(power(1 + apr_28d_rewards / 8760, 8760) - 1) AS apy_28d_rewards
FROM
apr_calculations
)
@@ -178,13 +64,27 @@ SELECT
market_id,
collateral_value,
hourly_pnl,
rewards_usd,
hourly_pnl_pct,
hourly_rewards_pct,
apr_24h,
apy_24h,
apr_7d,
apy_7d,
apr_28d,
apy_28d
apy_28d,
apr_24h_pnl,
apy_24h_pnl,
apr_7d_pnl,
apy_7d_pnl,
apr_28d_pnl,
apy_28d_pnl,
apr_24h_rewards,
apy_24h_rewards,
apr_7d_rewards,
apy_7d_rewards,
apr_28d_rewards,
apy_28d_rewards
FROM
apy_calculations
ORDER BY
1 change: 1 addition & 0 deletions transformers/synthetix/models/marts/perp/fct_perp_pnl.sql
Original file line number Diff line number Diff line change
@@ -1,3 +1,4 @@
{# DEPRECATED: deprecate this table in dashboards and remove #}
WITH debt AS (
SELECT
ts,
46 changes: 46 additions & 0 deletions transformers/synthetix/models/marts/prices/fct_prices.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,46 @@
WITH perp_prices AS (
SELECT
ts,
market_symbol,
price
FROM
{{ ref('fct_perp_market_history') }}
),
snx_prices AS (
SELECT
ts,
'SNX' AS market_symbol,
snx_price AS price
FROM
{{ ref('fct_buyback') }}
WHERE
snx_price > 0
),
usdc_prices AS (
SELECT
ts,
'USDC' AS market_symbol,
1 AS price
FROM
{{ ref('core_vault_collateral') }}
)
SELECT
ts,
market_symbol,
price
FROM
perp_prices
UNION ALL
SELECT
ts,
market_symbol,
price
FROM
snx_prices
UNION ALL
SELECT
ts,
market_symbol,
price
FROM
usdc_prices
74 changes: 74 additions & 0 deletions transformers/synthetix/models/marts/prices/fct_prices_hourly.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
WITH prices AS (
SELECT
DISTINCT DATE_TRUNC(
'hour',
ts
) AS ts,
market_symbol,
LAST_VALUE(price) over (PARTITION BY DATE_TRUNC('hour', ts), market_symbol
ORDER BY
ts rows BETWEEN unbounded preceding
AND unbounded following) AS price
FROM
{{ ref('fct_prices') }}
),
dim AS (
SELECT
generate_series(DATE_TRUNC('hour', MIN(t.ts)), DATE_TRUNC('hour', MAX(t.ts)), '1 hour' :: INTERVAL) AS ts,
m.market_symbol
FROM
(
SELECT
ts
FROM
prices
) AS t
CROSS JOIN (
SELECT
DISTINCT market_symbol
FROM
prices
) AS m
GROUP BY
m.market_symbol
),
ffill AS (
SELECT
dim.ts,
dim.market_symbol,
prices.price,
SUM(
CASE
WHEN prices.price IS NOT NULL THEN 1
ELSE 0
END
) over (
PARTITION BY dim.market_symbol
ORDER BY
dim.ts
) AS price_id
FROM
dim
LEFT JOIN prices
ON dim.ts = prices.ts
AND dim.market_symbol = prices.market_symbol
),
hourly_prices AS (
SELECT
ts,
market_symbol,
FIRST_VALUE(price) over (
PARTITION BY price_id,
market_symbol
ORDER BY
ts
) AS price
FROM
ffill
)
SELECT
*
FROM
hourly_prices
WHERE
price IS NOT NULL
45 changes: 33 additions & 12 deletions transformers/synthetix/models/raw/buyback/buyback_processed.sql
Original file line number Diff line number Diff line change
@@ -1,15 +1,16 @@
WITH legacy_events AS (
{{ get_event_data(
'buyback_snx_legacy',
'buyback_processed'
) }}
),
current_events AS (
{{ get_event_data(
'buyback_snx',
'buyback_processed'
) }}
)
{% if target.name == 'base_mainnet' %}
WITH legacy_events AS (
{{ get_event_data(
'buyback_snx_legacy',
'buyback_processed'
) }}
),
current_events AS (
{{ get_event_data(
'buyback_snx',
'buyback_processed'
) }}
)
SELECT
id,
block_number,
@@ -35,3 +36,23 @@ SELECT
usd
FROM
current_events
{% else %}
WITH current_events AS (
{{ get_event_data(
'buyback_snx',
'buyback_processed'
) }}
)
SELECT
id,
block_number,
block_timestamp,
transaction_hash,
event_name,
contract,
buyer,
snx,
usd
FROM
current_events
{% endif %}