Skip to content

Commit

Permalink
Merge pull request #28 from Synthetixio/apr-calculation
Browse files Browse the repository at this point in the history
APR calculation
  • Loading branch information
Tburm authored Feb 14, 2024
2 parents c1e7008 + 95eeba8 commit 78a159f
Show file tree
Hide file tree
Showing 8 changed files with 145 additions and 134 deletions.
17 changes: 9 additions & 8 deletions dashboard/modules/base_mainnet/core_stats.py
Original file line number Diff line number Diff line change
Expand Up @@ -139,13 +139,14 @@ def make_charts(data):
["hourly_pnl"],
"Hourly Pnl",
),
# "apr": chart_lines(
# data["apr"],
# "ts",
# ["pnl_pct_24_hr", "pnl_pct_7_day", "apr"],
# "APR",
# smooth=True,
# ),
"apr": chart_lines(
data["apr"],
"ts",
["apr_7d", "apy_7d"],
"APR and APY",
smooth=True,
y_format="%",
),
}


Expand Down Expand Up @@ -179,7 +180,7 @@ def main():
st.plotly_chart(charts["delegation"], use_container_width=True)
st.plotly_chart(charts["credit_capacity"], 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"], use_container_width=True)

st.markdown("## Top Delegators")
st.dataframe(
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -18,7 +18,10 @@ WITH market_updated AS (
{{ ref('core_market_updated') }}
)
SELECT
id,
block_timestamp AS ts,
transaction_hash,
event_name,
market_id,
collateral_type,
{{ convert_wei("credit_capacity") }} AS credit_capacity,
Expand Down
159 changes: 74 additions & 85 deletions transformers/synthetix/models/marts/core_stat/fct_core_apr.sql
Original file line number Diff line number Diff line change
Expand Up @@ -32,28 +32,28 @@ pnls AS (
FROM
{{ ref('fct_perp_pnl') }}
),
debt AS (
collateral AS (
SELECT
DISTINCT DATE_TRUNC(
'hour',
ts
) AS ts,
market_id,
LAST_VALUE(reported_debt) over (PARTITION BY DATE_TRUNC('hour', ts), market_id
2 AS market_id,
LAST_VALUE(amount_delegated) over (PARTITION BY DATE_TRUNC('hour', ts)
ORDER BY
ts rows BETWEEN unbounded preceding
AND unbounded following) AS debt
AND unbounded following) AS collateral_value
FROM
{{ ref('fct_core_market_updated') }}
{{ ref('fct_core_pool_delegation') }}
WHERE
collateral_type != 'USD'
pool_id = 1
),
ffill AS (
SELECT
dim.ts,
dim.market_id,
pnls.pnl,
debt.debt,
collateral.collateral_value,
SUM(
CASE
WHEN pnls.pnl IS NOT NULL THEN 1
Expand All @@ -65,21 +65,21 @@ ffill AS (
) AS pnl_id,
SUM(
CASE
WHEN debt.debt IS NOT NULL THEN 1
WHEN collateral.collateral_value IS NOT NULL THEN 1
ELSE 0
END
) over (
ORDER BY
dim.ts
) AS debt_id
) AS collateral_id
FROM
dim
LEFT JOIN pnls
ON dim.ts = pnls.ts
AND dim.market_id = pnls.market_id
LEFT JOIN debt
ON dim.ts = debt.ts
AND dim.market_id = debt.market_id
LEFT JOIN collateral
ON dim.ts = collateral.ts
AND dim.market_id = collateral.market_id
),
hourly_pnl AS (
SELECT
Expand All @@ -91,102 +91,91 @@ hourly_pnl AS (
ORDER BY
ts
) AS pnl,
FIRST_VALUE(COALESCE(debt, 0)) over (
PARTITION BY debt_id
FIRST_VALUE(COALESCE(collateral_value, 0)) over (
PARTITION BY collateral_id,
market_id
ORDER BY
ts
) AS debt
) AS collateral_value
FROM
ffill
),
ranked_pnl AS (
hourly_calculations AS (
SELECT
ts,
market_id,
pnl,
debt,
LAG(pnl) over (
PARTITION BY 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
) AS prev_pnl
ts)) / NULLIF(
collateral_value,
0
),
0
) AS hourly_pnl_pct
FROM
hourly_pnl
),
hourly_calculations AS (
hourly_returns AS (
SELECT
ts,
market_id,
COALESCE(
pnl - prev_pnl,
0
) AS hourly_pnl,
debt,
(COALESCE(pnl - prev_pnl, 0) / NULLIF(debt, 0)) AS hourly_pnl_pct
collateral_value,
hourly_pnl,
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
FROM
hourly_calculations
),
apr_calculations AS (
SELECT
ts,
market_id,
collateral_value,
hourly_pnl,
hourly_pnl_pct,
avg_24h_pnl_pct,
avg_7d_pnl_pct,
avg_24h_pnl_pct * 24 * 365 AS apr_24h,
avg_7d_pnl_pct * 24 * 365 AS apr_7d
FROM
ranked_pnl
hourly_returns
),
apy_calculations AS (
SELECT
*,
(power(1 + apr_24h / 8760, 8760) - 1) AS apy_24h,
(power(1 + apr_7d / 8760, 8760) - 1) AS apy_7d
FROM
apr_calculations
)
SELECT
ts,
market_id,
collateral_value,
hourly_pnl,
debt,
hourly_pnl_pct,
(
COALESCE(
EXP(
SUM(
LN(
1 + hourly_pnl_pct
)
) over (
PARTITION BY market_id
ORDER BY
ts rows BETWEEN 23 preceding
AND CURRENT ROW
)
) - 1,
0
)
) AS pnl_pct_24_hr,
(
COALESCE(
(
EXP(
SUM(
LN(
1 + hourly_pnl_pct
)
) over (
PARTITION BY market_id
ORDER BY
ts rows BETWEEN 168 preceding
AND CURRENT ROW
)
) - 1
) / 7,
0
)
) AS pnl_pct_7_day,
(
COALESCE(
EXP(
SUM(
LN(
1 + hourly_pnl_pct
)
) over (
PARTITION BY market_id
ORDER BY
ts rows BETWEEN 23 preceding
AND CURRENT ROW
)
) - 1,
0
)
) * 365 AS apr
apr_24h,
apr_7d,
apy_24h,
apy_7d
FROM
hourly_calculations
apy_calculations
ORDER BY
market_id,
ts
55 changes: 14 additions & 41 deletions transformers/synthetix/models/marts/perp/fct_perp_pnl.sql
Original file line number Diff line number Diff line change
@@ -1,52 +1,25 @@
WITH market_updated AS (
SELECT
DISTINCT block_number,
LAST_VALUE((reported_debt + token_amount) / 1e18) over (
PARTITION BY block_number
DISTINCT id,
ts,
market_id,
LAST_VALUE((-1 * net_issuance) - (reported_debt + token_amount)) over (
PARTITION BY ts,
market_id
ORDER BY
id
) AS reported_debt
) AS market_pnl
FROM
{{ ref('core_market_updated') }}
{{ ref('fct_core_market_updated') }}
WHERE
market_id = 2
),
net_transfers AS (
SELECT
DISTINCT block_timestamp,
block_number,
LAST_VALUE(net_transfers) over (
PARTITION BY block_number
ORDER BY
id
) AS net_transfers
FROM
(
SELECT
id,
block_timestamp,
block_number,
SUM(
amount_delta / 1e18
) over (
ORDER BY
id
) AS net_transfers
FROM
{{ ref('perp_collateral_modified') }}
) modified
)
SELECT
nt.block_timestamp AS ts,
nt.block_number,
2 AS market_id,
nt.net_transfers,
mu.reported_debt,
mu.reported_debt - nt.net_transfers AS trader_pnl,
nt.net_transfers - mu.reported_debt AS market_pnl
id,
ts,
market_id,
market_pnl
FROM
net_transfers nt
JOIN market_updated mu
ON nt.block_number = mu.block_number
market_updated
ORDER BY
nt.block_number
id
11 changes: 11 additions & 0 deletions transformers/synthetix/models/raw/block.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
SELECT
id,
"timestamp" AS ts,
CAST(
"number" AS INTEGER
) AS block_number
FROM
{{ source(
'raw_' ~ target.name,
'block'
) }}
18 changes: 18 additions & 0 deletions transformers/synthetix/models/raw/core/core_market_updated.sql
Original file line number Diff line number Diff line change
Expand Up @@ -41,6 +41,24 @@ combined AS (
FROM
collateral_deposits
UNION ALL
SELECT
id,
block_timestamp,
block_number,
transaction_hash,
contract,
event_name,
market_id,
net_issuance,
deposited_collateral_value,
sender,
collateral_type,
credit_capacity,
token_amount,
reported_debt
FROM
collateral_withdrawals
UNION ALL
SELECT
id,
block_timestamp,
Expand Down
10 changes: 10 additions & 0 deletions transformers/synthetix/models/raw/schema.yml
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
version: 2

models:
- name: block
description: "Block numbers and timestamps"
columns:
- name: id
tests:
- unique
- not_null
Loading

0 comments on commit 78a159f

Please sign in to comment.