diff --git a/warehouse/dbt/models/marts/metrics/optimism/int_superchain_trace_level_events.sql b/warehouse/dbt/models/marts/metrics/optimism/int_superchain_trace_level_events.sql new file mode 100644 index 000000000..ec321a254 --- /dev/null +++ b/warehouse/dbt/models/marts/metrics/optimism/int_superchain_trace_level_events.sql @@ -0,0 +1,132 @@ +{{ + config( + materialized='table' + ) +}} + +with events as ( + select + `time`, + event_source, + transaction_hash, + from_address_tx, + from_address_trace, + to_address_trace, + to_address_tx, + gas, + gas_used_trace, + gas_price, + {{ oso_id('event_source', 'from_address_tx') }} as from_address_tx_id, + {{ oso_id('event_source', 'from_address_trace') }} as from_address_trace_id, + {{ oso_id('event_source', 'to_address_trace') }} as to_address_trace_id, + {{ oso_id('event_source', 'to_address_tx') }} as to_address_tx_id + from {{ ref('int_superchain_traces_transactions_joined') }} +), + +known_contracts as ( + select distinct artifact_id + from {{ ref('artifacts_by_project_v1') }} + where artifact_id not in ( + select artifact_id + from {{ ref('int_artifacts_in_ossd_by_project') }} + where artifact_type = 'WALLET' + ) +), + +bot_filtered_events as ( + select * from events + left join {{ ref('int_superchain_potential_bots') }} as bots + on events.from_address_tx_id = bots.artifact_id + where bots.artifact_id is null +), + +filtered_traces as ( + select bot_filtered_events.* + from bot_filtered_events + inner join known_contracts + on bot_filtered_events.to_address_trace_id = known_contracts.artifact_id +), + +filtered_txns as ( + select distinct + `time`, + event_source, + transaction_hash, + from_address_tx_id, + to_address_tx_id, + gas, + gas_price + from bot_filtered_events + inner join known_contracts + on bot_filtered_events.to_address_tx_id = known_contracts.artifact_id +), + +trace_counts as ( + select + date_trunc(`time`, day) as `time`, + event_source, + from_address_tx_id as from_artifact_id, + to_address_trace_id as to_artifact_id, + 'CONTRACT_INVOCATION_SUCCESS_DAILY_TRACE_COUNT' as event_type, + count(distinct transaction_hash) as amount + from filtered_traces + group by 1, 2, 3, 4 +), + +trace_gas_used as ( + select + date_trunc(`time`, day) as `time`, + event_source, + from_address_tx_id as from_artifact_id, + to_address_trace_id as to_artifact_id, + 'CONTRACT_INVOCATION_SUCCESS_DAILY_TRACE_L2_GAS_USED' as event_type, + sum(gas_used_trace) as amount + from filtered_traces + group by 1, 2, 3, 4 +), + +txn_counts as ( + select + date_trunc(`time`, day) as `time`, + event_source, + from_address_tx_id as from_artifact_id, + to_address_tx_id as to_artifact_id, + 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' as event_type, + count(distinct transaction_hash) as amount + from filtered_txns + group by 1, 2, 3, 4 +), + +txn_gas_used as ( + select + date_trunc(`time`, day) as `time`, + event_source, + from_address_tx_id as from_artifact_id, + to_address_tx_id as to_artifact_id, + 'CONTRACT_INVOCATION_SUCCESS_DAILY_L2_GAS_USED' as event_type, + sum(gas) as amount + from filtered_txns + group by 1, 2, 3, 4 +), + +txn_gas_fees as ( + select + date_trunc(`time`, day) as `time`, + event_source, + from_address_tx_id as from_artifact_id, + to_address_tx_id as to_artifact_id, + 'CONTRACT_INVOCATION_SUCCESS_DAILY_L2_GAS_FEES' as event_type, + sum(gas_price * gas) / 1e18 as amount + from filtered_txns + group by 1, 2, 3, 4 +) + +select * from trace_counts +union all +select * from trace_gas_used +union all +select * from txn_counts +union all +select * from txn_gas_used +union all +select * from txn_gas_fees diff --git a/warehouse/dbt/models/marts/metrics/optimism/int_superchain_traces_transactions_joined.sql b/warehouse/dbt/models/marts/metrics/optimism/int_superchain_traces_transactions_joined.sql new file mode 100644 index 000000000..f67304607 --- /dev/null +++ b/warehouse/dbt/models/marts/metrics/optimism/int_superchain_traces_transactions_joined.sql @@ -0,0 +1,66 @@ +{{ + config( + materialized='incremental', + partition_by={ + "field": "time", + "data_type": "date", + "granularity": "day", + } + ) +}} + + +with traces as ( + select + dt, + chain, + gas_used, + transaction_hash, + from_address, + to_address + from {{ source('optimism_superchain_raw_onchain_data', 'traces') }} + where + dt >= '2024-11-01' + and network = 'mainnet' + and `status` = 1 + and call_type in ('delegatecall', 'call') +), + +transactions as ( + select + dt, + chain, + gas, + gas_price, + `hash` as transaction_hash, + from_address, + to_address + from {{ source('optimism_superchain_raw_onchain_data', 'transactions') }} + where + dt >= '2024-11-01' + and network = 'mainnet' + and receipt_status = 1 +) + +select + transactions.dt as `time`, + transactions.transaction_hash, + transactions.from_address as from_address_tx, + traces.from_address as from_address_trace, + traces.to_address as to_address_trace, + transactions.to_address as to_address_tx, + transactions.gas as gas, + traces.gas_used as gas_used_trace, + transactions.gas_price as gas_price, + upper( + case + when transactions.chain = 'op' then 'optimism' + when transactions.chain = 'fraxtal' then 'frax' + else transactions.chain + end + ) as event_source +from transactions +left join traces + on + transactions.transaction_hash = traces.transaction_hash + and transactions.chain = traces.chain diff --git a/warehouse/metrics_mesh/models/intermediate/superchain/int_superchain__traces_joined.sql b/warehouse/metrics_mesh/models/intermediate/superchain/int_superchain__traces_joined.sql new file mode 100644 index 000000000..235e01d33 --- /dev/null +++ b/warehouse/metrics_mesh/models/intermediate/superchain/int_superchain__traces_joined.sql @@ -0,0 +1,40 @@ +MODEL ( + name metrics.int_superchain__traces_joined, + kind INCREMENTAL_BY_TIME_RANGE ( + time_column block_timestamp, + batch_size 90, + batch_concurrency 1, + lookback 7 + ), + start '2015-01-01', + cron '@daily', + partitioned_by (DAY("block_timestamp"), "chain"), + grain ( + block_timestamp, + chain, + transaction_hash, + from_address_tx, + to_address_tx, + from_address_trace, + to_address_trace, + gas_used_tx, + gas_used_trace, + gas_price + ) +); + +select + transactions.block_timestamp, + transactions.chain as chain, + transactions.transaction_hash, + transactions.from_address as from_address_tx, + transactions.to_address as to_address_tx, + traces.from_address as from_address_trace, + traces.to_address as to_address_trace, + transactions.gas_used as gas_used_tx, + traces.gas_used as gas_used_trace, + transactions.gas_price as gas_price +from metrics.stg_superchain__transactions as transactions +left join metrics.stg_superchain__traces as traces + on transactions.transaction_hash = traces.transaction_hash + and transactions.chain = traces.chain \ No newline at end of file diff --git a/warehouse/metrics_mesh/models/intermediate/superchain/int_superchain_filtered_trace_events.sql b/warehouse/metrics_mesh/models/intermediate/superchain/int_superchain_filtered_trace_events.sql new file mode 100644 index 000000000..1520bebb9 --- /dev/null +++ b/warehouse/metrics_mesh/models/intermediate/superchain/int_superchain_filtered_trace_events.sql @@ -0,0 +1,135 @@ +MODEL ( + name metrics.int_superchain_filtered_trace_events, + kind INCREMENTAL_BY_TIME_RANGE ( + time_column "time", + batch_size 90, + batch_concurrency 1, + lookback 7 + ), + start '2015-01-01', + cron '@daily', + partitioned_by (DAY("time"), "event_source"), + grain ( + "time", + event_source, + from_artifact_id, + to_artifact_id, + event_type + ) +); + +with events as ( + select + block_timestamp, + chain as event_source, + transaction_hash, + from_address_tx, + from_address_trace, + to_address_trace, + to_address_tx, + gas_used_tx, + gas_used_trace, + gas_price, + @oso_id('chain', 'from_address_tx') as from_address_tx_id, + @oso_id('chain', 'from_address_trace') as from_address_trace_id, + @oso_id('chain', 'to_address_trace') as to_address_trace_id, + @oso_id('chain', 'to_address_tx') as to_address_tx_id + from metrics.int_superchain__traces_joined +), + +filtered_traces as ( + select distinct + events.block_timestamp, + events.event_source, + events.transaction_hash, + events.from_address_tx_id, + events.to_address_trace_id, + events.gas_used_trace + from events + inner join metrics.int_artifacts_by_project as known_addresses + on events.to_address_trace_id = known_addresses.artifact_id +), + +filtered_txns as ( + select distinct + events.block_timestamp, + events.event_source, + events.transaction_hash, + events.from_address_tx_id, + events.to_address_tx_id, + events.gas_used_tx, + events.gas_price + from events + inner join metrics.int_artifacts_by_project as known_addresses + on events.to_address_tx_id = known_addresses.artifact_id +), + +trace_counts as ( + select + date_trunc('DAY', block_timestamp::DATE) as "time", + event_source, + from_address_tx_id as from_artifact_id, + to_address_trace_id as to_artifact_id, + 'CONTRACT_INVOCATION_SUCCESS_DAILY_TRACE_COUNT' as event_type, + count(distinct transaction_hash) as amount + from filtered_traces + group by 1, 2, 3, 4 +), + +trace_gas_used as ( + select + date_trunc('DAY', block_timestamp::DATE) as "time", + event_source, + from_address_tx_id as from_artifact_id, + to_address_trace_id as to_artifact_id, + 'CONTRACT_INVOCATION_SUCCESS_DAILY_TRACE_L2_GAS_USED' as event_type, + sum(gas_used_trace) as amount + from filtered_traces + group by 1, 2, 3, 4 +), + +txn_counts as ( + select + date_trunc('DAY', block_timestamp::DATE) as "time", + event_source, + from_address_tx_id as from_artifact_id, + to_address_tx_id as to_artifact_id, + 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' as event_type, + count(distinct transaction_hash) as amount + from filtered_txns + group by 1, 2, 3, 4 +), + +txn_gas_used as ( + select + date_trunc('DAY', block_timestamp::DATE) as "time", + event_source, + from_address_tx_id as from_artifact_id, + to_address_tx_id as to_artifact_id, + 'CONTRACT_INVOCATION_SUCCESS_DAILY_L2_GAS_USED' as event_type, + sum(gas_used_tx) as amount + from filtered_txns + group by 1, 2, 3, 4 +), + +txn_gas_fees as ( + select + date_trunc('DAY', block_timestamp::DATE) as "time", + event_source, + from_address_tx_id as from_artifact_id, + to_address_tx_id as to_artifact_id, + 'CONTRACT_INVOCATION_SUCCESS_DAILY_L2_GAS_FEES' as event_type, + sum(gas_price * gas_used_tx) / 1e18 as amount + from filtered_txns + group by 1, 2, 3, 4 +) + +select * from trace_counts +union all +select * from trace_gas_used +union all +select * from txn_counts +union all +select * from txn_gas_used +union all +select * from txn_gas_fees \ No newline at end of file diff --git a/warehouse/metrics_mesh/models/staging/superchain/stg_superchain__traces.sql b/warehouse/metrics_mesh/models/staging/superchain/stg_superchain__traces.sql new file mode 100644 index 000000000..55b0db7a0 --- /dev/null +++ b/warehouse/metrics_mesh/models/staging/superchain/stg_superchain__traces.sql @@ -0,0 +1,33 @@ +MODEL ( + name metrics.stg_superchain__traces, + kind INCREMENTAL_BY_TIME_RANGE ( + time_column block_timestamp, + batch_size 90, + batch_concurrency 1, + lookback 7 + ), + start '2015-01-01', + cron '@daily', + partitioned_by (DAY("block_timestamp"), "chain"), + grain (block_timestamp, chain, transaction_hash, from_address, to_address) +); + +select + @from_unix_timestamp(block_timestamp) as block_timestamp, + transaction_hash, + from_address, + to_address, + gas_used, + upper( + case + when chain = 'op' then 'optimism' + when chain = 'fraxtal' then 'frax' + else chain + end + ) as chain +from @oso_source('bigquery.optimism_superchain_raw_onchain_data.traces') +where + network = 'mainnet' + and "status" = 1 + and call_type in ('delegatecall', 'call') + and gas_used > 0 diff --git a/warehouse/metrics_mesh/models/staging/superchain/stg_superchain__transactions.sql b/warehouse/metrics_mesh/models/staging/superchain/stg_superchain__transactions.sql new file mode 100644 index 000000000..cce32d01e --- /dev/null +++ b/warehouse/metrics_mesh/models/staging/superchain/stg_superchain__transactions.sql @@ -0,0 +1,34 @@ +MODEL ( + name metrics.stg_superchain__transactions, + kind INCREMENTAL_BY_TIME_RANGE ( + time_column block_timestamp, + batch_size 90, + batch_concurrency 1, + lookback 7 + ), + start '2015-01-01', + cron '@daily', + partitioned_by (DAY("block_timestamp"), "chain"), + grain (block_timestamp, chain, transaction_hash, from_address, to_address) +); + +select + @from_unix_timestamp(block_timestamp) as block_timestamp, + "hash" as transaction_hash, + from_address, + to_address, + gas as gas_used, + gas_price, + value_lossless, + upper( + case + when chain = 'op' then 'optimism' + when chain = 'fraxtal' then 'frax' + else chain + end + ) as chain +from @oso_source('bigquery.optimism_superchain_raw_onchain_data.transactions') +where + network = 'mainnet' + and receipt_status = 1 + and gas > 0