-
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.
feat: rf4 contract verification models (#1611)
* feat: rf4 contract verification models * fix: linting issue * fix: rename source
- Loading branch information
Showing
4 changed files
with
258 additions
and
1 deletion.
There are no files selected for viewing
137 changes: 137 additions & 0 deletions
137
warehouse/dbt/models/marts/superchain/verification/rf4_contracts_by_app.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,137 @@ | ||
{{ | ||
config( | ||
materialized='table' | ||
) | ||
}} | ||
|
||
{% set networks = ["optimism", "base", "frax", "metal", "mode", "zora"] %} | ||
|
||
{% set union_factory_queries = [] %} | ||
{% set union_deployer_queries = [] %} | ||
|
||
{% for network in networks %} | ||
|
||
{% set network_upper = network.upper() %} | ||
|
||
{% set factory_table = "stg_" ~ network ~ "__factories" %} | ||
{% set query %} | ||
select | ||
factory_address, | ||
contract_address, | ||
'{{ network_upper }}' as network | ||
from {{ ref(factory_table) }} | ||
{% endset %} | ||
{% do union_factory_queries.append(query) %} | ||
|
||
{% set deployer_table = "stg_" ~ network ~ "__deployers" %} | ||
{% set query %} | ||
select | ||
deployer_address, | ||
contract_address, | ||
'{{ network_upper }}' as network | ||
from {{ ref(deployer_table) }} | ||
{% endset %} | ||
{% do union_deployer_queries.append(query) %} | ||
|
||
{% endfor %} | ||
|
||
{% set all_factories = union_factory_queries | join(' union all ') %} | ||
{% set all_deployers = union_deployer_queries | join(' union all ') %} | ||
|
||
with factories as ( | ||
{{ all_factories }} | ||
), | ||
|
||
deployers as ( | ||
{{ all_deployers }} | ||
), | ||
|
||
oso_addresses as ( | ||
select distinct | ||
apps.application_id, | ||
artifacts_by_project.artifact_source as network, | ||
artifacts_by_project.artifact_name as contract_address | ||
from {{ source('static_data_sources', 'agora_rf4_applications') }} as apps | ||
left join {{ ref('artifacts_by_project_v1') }} as artifacts_by_project | ||
on apps.oso_project_name = artifacts_by_project.project_name | ||
where | ||
artifacts_by_project.artifact_source in ( | ||
'OPTIMISM', 'BASE', 'FRAX', 'METAL', 'MODE', 'ZORA' | ||
) | ||
), | ||
|
||
oso_contracts as ( | ||
select | ||
oso_addresses.application_id, | ||
oso_addresses.network, | ||
oso_addresses.contract_address | ||
from oso_addresses | ||
left join deployers | ||
on | ||
oso_addresses.contract_address = deployers.contract_address | ||
and oso_addresses.network = deployers.network | ||
where deployers.contract_address is not null | ||
), | ||
|
||
agora_contracts as ( | ||
select | ||
application_id, | ||
artifact_source as network, | ||
artifact as contract_address | ||
from {{ source('static_data_sources', 'agora_rf4_artifacts_by_app') }} | ||
where artifact_type = 'CONTRACT' | ||
), | ||
|
||
app_contracts as ( | ||
select | ||
application_id, | ||
network, | ||
contract_address, | ||
'oso' as contract_source | ||
from oso_contracts | ||
union all | ||
select | ||
application_id, | ||
network, | ||
contract_address, | ||
'agora' as contract_source | ||
from agora_contracts | ||
), | ||
|
||
discovered_contracts as ( | ||
select | ||
app_contracts.application_id, | ||
factories.contract_address, | ||
factories.network, | ||
'discovered' as contract_source | ||
from factories | ||
left join app_contracts | ||
on | ||
factories.factory_address = app_contracts.contract_address | ||
and factories.network = app_contracts.network | ||
where app_contracts.application_id is not null | ||
), | ||
|
||
contracts as ( | ||
select | ||
application_id, | ||
contract_address, | ||
network, | ||
contract_source | ||
from discovered_contracts | ||
union all | ||
select | ||
application_id, | ||
contract_address, | ||
network, | ||
contract_source | ||
from app_contracts | ||
) | ||
|
||
select distinct | ||
application_id, | ||
contract_address, | ||
network, | ||
contract_source | ||
from contracts | ||
where application_id is not null |
40 changes: 40 additions & 0 deletions
40
warehouse/dbt/models/marts/superchain/verification/rf4_transactions_by_app.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,40 @@ | ||
{{ | ||
config( | ||
materialized='table', | ||
partition_by={ | ||
"field": "txn_date", | ||
"data_type": "timestamp", | ||
"granularity": "day", | ||
} | ||
) | ||
}} | ||
|
||
with all_txns as ( | ||
select | ||
txn_date, | ||
from_address, | ||
to_address, | ||
network | ||
from {{ ref('rf4_transactions_window') }} | ||
), | ||
|
||
contracts as ( | ||
select distinct | ||
application_id, | ||
contract_address, | ||
network | ||
from {{ ref('rf4_contracts_by_app') }} | ||
) | ||
|
||
select | ||
contracts.application_id, | ||
all_txns.txn_date, | ||
all_txns.from_address, | ||
all_txns.to_address, | ||
all_txns.network | ||
from all_txns | ||
left join contracts | ||
on | ||
all_txns.to_address = contracts.contract_address | ||
and all_txns.network = contracts.network | ||
where contracts.application_id is not null |
76 changes: 76 additions & 0 deletions
76
warehouse/dbt/models/marts/superchain/verification/rf4_transactions_window.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,76 @@ | ||
{{ | ||
config( | ||
materialized='table', | ||
partition_by={ | ||
"field": "txn_date", | ||
"data_type": "timestamp", | ||
"granularity": "day", | ||
} | ||
) | ||
}} | ||
|
||
{% set networks = ["base", "frax", "metal", "mode", "zora"] %} | ||
{% set start_date = '2023-10-01' %} | ||
{% set end_date = '2024-06-01' %} | ||
{% set union_queries = [] %} | ||
|
||
{% for network in networks %} | ||
{% set network_upper = network.upper() %} | ||
|
||
{% set query %} | ||
select | ||
date_trunc(block_timestamp, day) as txn_date, | ||
lower(from_address) as from_address, | ||
lower(to_address) as to_address, | ||
'{{ network_upper }}' as network, | ||
from {{ source(network, "transactions") }} | ||
where | ||
block_timestamp > '{{ start_date }}' | ||
and block_timestamp < '{{ end_date }}' | ||
and `receipt_status` = 1 | ||
{% endset %} | ||
|
||
{% do union_queries.append(query) %} | ||
{% endfor %} | ||
|
||
{% set final_query = union_queries | join(' union all ') %} | ||
|
||
with superchain_txns as ( | ||
{{ final_query }} | ||
), | ||
|
||
op_txns as ( | ||
select | ||
'OPTIMISM' as network, | ||
lower(from_address) as from_address, | ||
lower(to_address) as to_address, | ||
date_trunc(block_timestamp, day) as txn_date | ||
from {{ source("optimism", "receipts") }} | ||
where | ||
block_timestamp > '{{ start_date }}' | ||
and block_timestamp < '{{ end_date }}' | ||
and status = 1 | ||
), | ||
|
||
txns as ( | ||
select | ||
txn_date, | ||
from_address, | ||
to_address, | ||
network | ||
from superchain_txns | ||
union all | ||
select | ||
txn_date, | ||
from_address, | ||
to_address, | ||
network | ||
from op_txns | ||
) | ||
|
||
select distinct | ||
txn_date, | ||
from_address, | ||
to_address, | ||
network | ||
from txns |
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