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

Wes/dydx pricing data #598

Merged
merged 6 commits into from
Nov 8, 2024
Merged
Show file tree
Hide file tree
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
7 changes: 7 additions & 0 deletions macros/is_nyc_operating_hours.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
{% macro is_nyc_operating_hours(timestamp_column) %}
case
when date_part('DOW', convert_timezone('UTC', 'America/New_York', {{ timestamp_column }})) in (0, 6) then false
when convert_timezone('UTC', 'America/New_York', {{ timestamp_column }})::time between '09:00:00' and '15:59:59' then true
else false
end
{% endmacro %}
30 changes: 30 additions & 0 deletions models/projects/dydx_v4/raw/ez_dydx_v4_price_performance.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,30 @@
{{
config(
materialized = "table",
snowflake_warehouse = "DYDX",
database = "dydx_v4",
schema = "raw",
alias = "ez_price_performance"
)
}}

with prices as (
select
date_trunc('hour', block_timestamp) as hour
, symbol
, price
, {{ is_nyc_operating_hours('hour') }} as nyc_operating_hours
from {{ref('fact_dydx_v4_perps_prices')}} t1
WHERE symbol in ('BTC', 'ETH')
)

select
hour
, symbol
, max(price) as high
, min(price) as low
, avg(price) as average
, median(price) as median
, nyc_operating_hours
from prices
group by hour, symbol, nyc_operating_hours
19 changes: 19 additions & 0 deletions models/projects/dydx_v4/raw/fact_dydx_v4_perps_token_prices.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,19 @@
{{
config(
materialized = "table",
snowflake_warehouse = "DYDX",
database = "dydx_v4",
schema = "raw",
alias = "fact_perps_token_prices"
)
}}

select
block_timestamp
, tx_hash
, 'dydx_v4' as chain
, 'dydx_v4' as app
, symbol
, price
, null as token_address
from {{ ref('fact_dydx_v4_perps_prices') }}
Original file line number Diff line number Diff line change
Expand Up @@ -14,11 +14,7 @@ with agg as (
agg.price,
agg.mint,
m.symbol,
CASE
when date_part('DOW', convert_timezone('UTC', 'America/New_York', block_timestamp)) IN (0, 6) then 'FALSE'
when convert_timezone('UTC', 'America/New_York', block_timestamp)::time between '09:00:00' and '15:59:59' then 'TRUE'
else 'FALSE'
END AS nyc_operating_hours
{{ is_nyc_operating_hours('hour') }} as nyc_operating_hours
FROM {{ ref('fact_jupiter_perps_txs') }} agg
LEFT JOIN solana_flipside.price.ez_asset_metadata m ON m.token_address = agg.mint
)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -10,11 +10,11 @@

SELECT
block_timestamp,
tx_id,
tx_id as tx_hash,
chain,
app,
mint,
symbol,
price,
size_usd,
fee_usd
FROM {{ ref('fact_jupiter_perps_txs') }}
mint as token_address
FROM {{ ref('fact_jupiter_perps_txs') }} t
LEFT JOIN solana_flipside.price.ez_asset_metadata m ON m.token_address = t.mint
Original file line number Diff line number Diff line change
Expand Up @@ -19,11 +19,7 @@ prices as (
date_trunc('hour', block_timestamp) as hour
, unwrapped_symbol as symbol
, price
, CASE
when date_part('DOW', convert_timezone('UTC', 'America/New_York', block_timestamp)) IN (0, 6) then 'FALSE'
when convert_timezone('UTC', 'America/New_York', block_timestamp)::time between '09:00:00' and '15:59:59' then 'TRUE'
else 'FALSE'
END AS nyc_operating_hours
, {{ is_nyc_operating_hours('hour') }} as nyc_operating_hours
from {{ref('fact_uniswap_dex_token_prices')}} t1
inner join tracked_metadata
on lower(t1.token_address) = lower(tracked_metadata.contract_address)
Expand Down
2 changes: 2 additions & 0 deletions models/staging/dydx/__dydx__sources.yml
Original file line number Diff line number Diff line change
Expand Up @@ -9,3 +9,5 @@ sources:
- name: raw_dydx_v4_txn_and_trading_fees
- name: raw_dydx_v4_unique_traders
- name: raw_dydx_v4_fees
- name: raw_dydx_v4_perpetuals_markets_metadata
- name: raw_dydx_v4_price
32 changes: 32 additions & 0 deletions models/staging/dydx/dim_dydx_perps_markets.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@
{{
config({
"materialized": "table"
})
}}

with max_extraction as (
SELECT
max(extraction_date) as max_extraction
FROM
{{ source("PROD_LANDING", "raw_dydx_v4_perpetuals_markets_metadata") }}
),
latest_data as (
SELECT
parse_json(source_json) as data
FROM
{{ source("PROD_LANDING", "raw_dydx_v4_perpetuals_markets_metadata") }}
WHERE
extraction_date = (
select
max_extraction
from
max_extraction
)
)
select
value:ticker::string as ticker
, value:clobPairId::number as clob_pair_id
, value:atomicResolution::number as atomic_resolution
from
latest_data
, lateral flatten (input => data:markets)
54 changes: 54 additions & 0 deletions models/staging/dydx/fact_dydx_v4_perps_prices.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,54 @@
{{
config({
"materialized": "incremental",
"snowflake_warehouse": "DYDX",
})
}}

with all_dates as (
select
extraction_date,
TO_TIMESTAMP_NTZ(value:block_timestamp)::date as date
from {{ source("PROD_LANDING", "raw_dydx_v4_price") }},
lateral flatten (input => parse_json(source_json)) as flat_json
{% if is_incremental() %}
where TO_TIMESTAMP_NTZ(value:block_timestamp)::date >= (select max(block_timestamp) from {{ this }})
{% endif %}
)
, dates as (
SELECT
MAX(extraction_date) as max_extraction,
date
FROM all_dates
GROUP BY 2
)
, flattened_json as (
SELECT
TO_TIMESTAMP_NTZ(value:block_timestamp)::timestamp as block_timestamp,
value:tx_hash::string as tx_hash,
value:E::number as E,
value:G::number as G,
value:I::number as I,
value:perpetual_id::number as perpetual_id,
extraction_date
FROM {{ source("PROD_LANDING", "raw_dydx_v4_price") }} raw,
LATERAL FLATTEN (input => PARSE_JSON(source_json)) AS flat_json
{% if is_incremental() %}
where TO_TIMESTAMP_NTZ(value:block_timestamp)::date >= (select max(block_timestamp) from {{ this }})
{% endif %}
)
select
f.block_timestamp,
f.tx_hash,
f.perpetual_id,
left(ticker, length(ticker)-4) as symbol,
abs((f.E + f.G) / f.I) * POW(10, (-6 - m.atomic_resolution)) as price, -- based on equation found here https://docs.dydx.exchange/api_integration-guides/how_to_interpret_block_data_for_trades
f.E,
f.G,
f.I,
m.clob_pair_id,
m.atomic_resolution
from flattened_json f
join dates d on d.max_extraction = f.extraction_date AND d.date = date(f.block_timestamp)
left join {{ ref("dim_dydx_perps_markets") }} m on f.perpetual_id = m.clob_pair_id
where m.ticker like '%USD%' -- in case they add non-USD pairs
16 changes: 6 additions & 10 deletions models/staging/jupiter/fact_jupiter_perps_txs.sql
Original file line number Diff line number Diff line change
Expand Up @@ -53,17 +53,13 @@ with hex_cte as (
{{ hex_to_base58("SUBSTRING(hex_data,456+1,64)") }} as owner, -- owner/trader address
{{ hex_to_base58("SUBSTRING(hex_data,243,64)") }} as mint,
-- Price calculation with dynamic offset
{{ big_endian_hex_to_decimal("SUBSTRING(hex_data,619+1,16)") }}/1e6 as price,
SUBSTRING(
{{ big_endian_hex_to_decimal(
"SUBSTRING(
hex_data,
619 -- Base offset to price
+ (CASE WHEN SUBSTRING(hex_data, 618, 1) = '1'
THEN 16
ELSE 0
END) -- Add offset if transferToken present
, 16
)
)/1e6 as price,
619 + (CASE WHEN SUBSTRING(hex_data, 618, 1) = '1' THEN 16 ELSE 0 END),
16
)"
) }}/1e6 as price,
hex_data
FROM hex_cte
WHERE substring(hex_data,1+16,16) = '409c2b4a6d83107f' -- DecreasePosition
Expand Down
Loading