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

enable day fill for prices #7525

Open
wants to merge 6 commits into
base: main
Choose a base branch
from
Open
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
134 changes: 67 additions & 67 deletions dbt_subprojects/tokens/models/prices_v2/prices_v2_day.sql
Original file line number Diff line number Diff line change
@@ -1,7 +1,6 @@
{{ config(
schema='prices_v2',
alias = 'day',
tags = ['prod_exclude'],
materialized = 'incremental',
file_format = 'delta',
partition_by = ['date'],
Expand All @@ -12,70 +11,71 @@
}}


--WITH sparse_prices as (
-- select
-- *
-- , lead(timestamp) over (partition by blockchain, contract_address order by timestamp asc) as next_update
-- from (
-- select
-- blockchain
-- , contract_address
-- , timestamp
-- , price
-- , volume
-- , source
-- , date -- this is redundant here as date = timestamp, but we keep it in to be consistent across intervals
-- , source_timestamp
-- from {{ ref('prices_v2_day_sparse') }}
-- {% if is_incremental() %}
-- where {{ incremental_predicate('timestamp') }}
-- {% endif %}
-- -- If we're running incremental, we also need to add the last known prices from before the incremental window, to forward fill them
-- {% if is_incremental() %}
-- UNION ALL
-- SELECT * FROM (
-- select
-- blockchain
-- , contract_address
-- , max(timestamp) -- we get the last updated price
-- , max_by(price,timestamp) as price
-- , max_by(volume,timestamp) as volume
-- , max_by(source,timestamp) as source
-- , max(date) as date
-- , max_by(source_timestamp,timestamp) as source_timestamp
-- from {{ ref('prices_v2_day_sparse') }}
-- where not {{ incremental_predicate('timestamp') }} -- not in the current incremental window (so before that)
-- group by blockchain, contract_address
-- )
-- {% endif %}
-- )
--)
--
---- construct the time spline we want to fill
--, timeseries as (
-- select timestamp
-- from unnest(
-- sequence(cast((select date_trunc('day', min(timestamp)) from sparse_prices) as timestamp)
-- , cast(date_trunc('day', now()) as timestamp)
-- , interval '1' day
-- )
-- ) as foo(timestamp)
-- {% if is_incremental() %}
-- where {{ incremental_predicate('timestamp') }} -- reduce to the incremental window if running incrementally
-- {% endif %}
--)
--
--SELECT
-- p.blockchain
-- , p.contract_address
-- , t.timestamp
-- , p.price
-- , p.volume
-- , p.source
-- , t.timestamp as date
-- , p.source_timestamp
--FROM timeseries t
--INNER JOIN sparse_prices p
-- on p.timestamp <= t.timestamp
-- and (p.next_update is null or p.next_update > t.timestamp)
WITH sparse_prices as (
select
*
, lead(timestamp) over (partition by blockchain, contract_address order by timestamp asc) as next_update
from (
select
blockchain
, contract_address
, timestamp
, price
, volume
, source
, date -- this is redundant here as date = timestamp, but we keep it in to be consistent across intervals
, source_timestamp
from {{ ref('prices_v2_day_sparse') }}
where 1=1
{% if is_incremental() %}
and {{ incremental_predicate('timestamp') }}
{% endif %}
-- If we're running incremental, we also need to add the last known prices from before the incremental window, to forward fill them
{% if is_incremental() %}
UNION ALL
SELECT * FROM (
select
blockchain
, contract_address
, max(timestamp) -- we get the last updated price
, max_by(price,timestamp) as price
, max_by(volume,timestamp) as volume
, max_by(source,timestamp) as source
, max(date) as date
, max_by(source_timestamp,timestamp) as source_timestamp
from {{ ref('prices_v2_day_sparse') }}
where not {{ incremental_predicate('timestamp') }} -- not in the current incremental window (so before that)
group by blockchain, contract_address
)
{% endif %}
)
)

-- construct the time spline we want to fill
, timeseries as (
select timestamp
from unnest(
sequence(cast((select date_trunc('day', min(timestamp)) from sparse_prices) as timestamp)
, cast(date_trunc('day', now()) as timestamp)
, interval '1' day
)
) as foo(timestamp)
{% if is_incremental() %}
where {{ incremental_predicate('timestamp') }} -- reduce to the incremental window if running incrementally
{% endif %}
)

SELECT
p.blockchain
, p.contract_address
, t.timestamp
, p.price
, p.volume
, p.source
, t.timestamp as date
, p.source_timestamp
FROM timeseries t
INNER JOIN sparse_prices p
on p.timestamp <= t.timestamp
and (p.next_update is null or p.next_update > t.timestamp)

85 changes: 85 additions & 0 deletions dbt_subprojects/tokens/models/prices_v2/prices_v2_day_expiring.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,85 @@
{{ config(
schema='prices_v2',
alias = 'day_expiring',
materialized = 'incremental',
file_format = 'delta',
partition_by = ['date'],
incremental_strategy = 'merge',
unique_key = ['blockchain', 'contract_address', 'timestamp'],
incremental_predicates = [incremental_predicate('DBT_INTERNAL_DEST.timestamp')]
)
}}

{% set expiration_days = '30' %}


WITH sparse_prices as (
select
*
, lead(timestamp) over (partition by blockchain, contract_address order by timestamp asc) as next_update
from (
select
blockchain
, contract_address
, timestamp
, price
, volume
, source
, date -- this is redundant here as date = timestamp, but we keep it in to be consistent across intervals
, source_timestamp
from {{ ref('prices_v2_day_sparse') }}
where 1=1
{% if is_incremental() %}
and {{ incremental_predicate('timestamp') }}
{% endif %}
-- If we're running incremental, we also need to add the last known prices from before the incremental window, to forward fill them
{% if is_incremental() %}
UNION ALL
SELECT * FROM (
select
blockchain
, contract_address
, max(timestamp) -- we get the last updated price
, max_by(price,timestamp) as price
, max_by(volume,timestamp) as volume
, max_by(source,timestamp) as source
, max(date) as date
, max_by(source_timestamp,timestamp) as source_timestamp
from {{ ref('prices_v2_day_sparse') }}
where not {{ incremental_predicate('timestamp') }} -- not in the current incremental window (so before that)
and timestamp > now() - interval '{{expiration_days}}' day
group by blockchain, contract_address
)
{% endif %}
)
)

-- construct the time spline we want to fill
, timeseries as (
select timestamp
from unnest(
sequence(cast((select date_trunc('day', min(timestamp)) from sparse_prices) as timestamp)
, cast(date_trunc('day', now()) as timestamp)
, interval '1' day
)
) as foo(timestamp)
{% if is_incremental() %}
where {{ incremental_predicate('timestamp') }} -- reduce to the incremental window if running incrementally
{% endif %}
)

SELECT
p.blockchain
, p.contract_address
, t.timestamp
, p.price
, p.volume
, p.source
, t.timestamp as date
, p.source_timestamp
FROM timeseries t
INNER JOIN sparse_prices p
on p.timestamp <= t.timestamp
and p.timestamp + interval '{{expiration_days}}' day > t.timestamp
and (p.next_update is null or p.next_update > t.timestamp)