-
Notifications
You must be signed in to change notification settings - Fork 16
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Update data type in calendar and add daily granular usage for OP chai…
…n addresses (#1871) * format * add macro * update macro * add staging for base * update macro * update macro * update macro * add staging for op chains
- Loading branch information
Showing
8 changed files
with
156 additions
and
1 deletion.
There are no files selected for viewing
64 changes: 64 additions & 0 deletions
64
warehouse/dbt/macros/models/addresses_daily_gas_and_usage.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,64 @@ | ||
{% macro addresses_daily_gas_and_usage(network_name, block_timestamp_column="block_timestamp", date_timestamp_column="date_timestamp") %} | ||
{% set lower_network_name = network_name.lower() %} | ||
|
||
with daily_gas_fees as ( | ||
select | ||
from_address as address | ||
,date_trunc(block_timestamp, day) as date_timestamp | ||
,sum( (gas_price * receipt_gas_used) / 1e18) as l2_gas_paid | ||
,sum(receipt_l1_fee / 1e18) as l1_gas_paid | ||
,sum(receipt_l1_fee / 1e18 + (gas_price * receipt_gas_used) / 1e18) as total_gas_fees_paid | ||
,count("hash") as num_txs | ||
,1 as num_days_active | ||
from {{ oso_source(lower_network_name, "transactions") }} | ||
where | ||
true | ||
and receipt_status = 1 | ||
and gas_price > 0 | ||
and receipt_gas_used > 0 | ||
{% if is_incremental() %} | ||
and block_timestamp > TIMESTAMP_SUB(_dbt_max_partition, INTERVAL 1 DAY) | ||
{% else %} | ||
{{ playground_filter(block_timestamp_column, is_start=False) }} | ||
{% endif %} | ||
group by 1, 2, 7 | ||
) | ||
|
||
-- generating daily record for each address that has ever been active | ||
,addition as ( | ||
select | ||
ft.address | ||
,ft.chain_name | ||
,ft.month_cohort | ||
,c.date_timestamp | ||
,date_diff(c.date_timestamp, ft.first_active_day, DAY) as days_since_first_active | ||
from {{ ref('stg_%s__first_time_addresses' % lower_network_name)}} as ft | ||
join {{ ref('stg_utility__calendar')}} as c | ||
on c.date_timestamp >= ft.first_block_timestamp | ||
{% if is_incremental() %} | ||
and c.date_timestamp < TIMESTAMP_SUB(_dbt_max_partition, INTERVAL 0 DAY) | ||
{% else %} | ||
and c.date_timestamp < CURRENT_TIMESTAMP() | ||
{% endif %} | ||
where | ||
true | ||
{% if is_incremental() %} | ||
and c.date_timestamp > TIMESTAMP_SUB(_dbt_max_partition, INTERVAL 1 DAY) | ||
{% else %} | ||
{{ playground_filter(date_timestamp_column, is_start=False) }} | ||
{% endif %} | ||
) | ||
|
||
select | ||
a.* | ||
,coalesce(d.l2_gas_paid, 0) as l2_gas_paid | ||
,coalesce(d.l1_gas_paid, 0) as l1_gas_paid | ||
,coalesce(d.total_gas_fees_paid, 0) as total_gas_fees_paid | ||
,coalesce(d.num_txs, 0) as num_txs | ||
,coalesce(d.num_days_active, 0) as num_days_active | ||
from addition as a | ||
left join daily_gas_fees as d | ||
on a.address = d.address | ||
and a.date_timestamp = d.date_timestamp | ||
|
||
{% endmacro %} |
15 changes: 15 additions & 0 deletions
15
warehouse/dbt/models/staging/base/stg_base__addresses_gas_and_usage.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,15 @@ | ||
{{ | ||
config( | ||
materialized='incremental', | ||
partition_by={ | ||
"field": "date_timestamp", | ||
"data_type": "timestamp", | ||
"granularity": "day", | ||
}, | ||
unique_id=["address", "date_timestamp"], | ||
on_schema_change="append_new_columns", | ||
incremental_strategy="insert_overwrite" | ||
) | ||
}} | ||
|
||
{{ addresses_daily_gas_and_usage("base") }} |
15 changes: 15 additions & 0 deletions
15
warehouse/dbt/models/staging/frax/stg_frax__addresses_gas_and_usage.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,15 @@ | ||
{{ | ||
config( | ||
materialized='incremental', | ||
partition_by={ | ||
"field": "date_timestamp", | ||
"data_type": "timestamp", | ||
"granularity": "day", | ||
}, | ||
unique_id=["address", "date_timestamp"], | ||
on_schema_change="append_new_columns", | ||
incremental_strategy="insert_overwrite" | ||
) | ||
}} | ||
|
||
{{ addresses_daily_gas_and_usage("frax") }} |
15 changes: 15 additions & 0 deletions
15
warehouse/dbt/models/staging/metal/stg_metal__addresses_gas_and_usage.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,15 @@ | ||
{{ | ||
config( | ||
materialized='incremental', | ||
partition_by={ | ||
"field": "date_timestamp", | ||
"data_type": "timestamp", | ||
"granularity": "day", | ||
}, | ||
unique_id=["address", "date_timestamp"], | ||
on_schema_change="append_new_columns", | ||
incremental_strategy="insert_overwrite" | ||
) | ||
}} | ||
|
||
{{ addresses_daily_gas_and_usage("metal") }} |
15 changes: 15 additions & 0 deletions
15
warehouse/dbt/models/staging/mode/stg_mode__addresses_gas_and_usage.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,15 @@ | ||
{{ | ||
config( | ||
materialized='incremental', | ||
partition_by={ | ||
"field": "date_timestamp", | ||
"data_type": "timestamp", | ||
"granularity": "day", | ||
}, | ||
unique_id=["address", "date_timestamp"], | ||
on_schema_change="append_new_columns", | ||
incremental_strategy="insert_overwrite" | ||
) | ||
}} | ||
|
||
{{ addresses_daily_gas_and_usage("mode") }} |
15 changes: 15 additions & 0 deletions
15
warehouse/dbt/models/staging/pgn/stg_pgn__addresses_gas_and_usage.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,15 @@ | ||
{{ | ||
config( | ||
materialized='incremental', | ||
partition_by={ | ||
"field": "date_timestamp", | ||
"data_type": "timestamp", | ||
"granularity": "day", | ||
}, | ||
unique_id=["address", "date_timestamp"], | ||
on_schema_change="append_new_columns", | ||
incremental_strategy="insert_overwrite" | ||
) | ||
}} | ||
|
||
{{ addresses_daily_gas_and_usage("pgn") }} |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
15 changes: 15 additions & 0 deletions
15
warehouse/dbt/models/staging/zora/stg_zora__addresses_gas_and_usage.sql
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,15 @@ | ||
{{ | ||
config( | ||
materialized='incremental', | ||
partition_by={ | ||
"field": "date_timestamp", | ||
"data_type": "timestamp", | ||
"granularity": "day", | ||
}, | ||
unique_id=["address", "date_timestamp"], | ||
on_schema_change="append_new_columns", | ||
incremental_strategy="insert_overwrite" | ||
) | ||
}} | ||
|
||
{{ addresses_daily_gas_and_usage("zora") }} |