Skip to content

Commit

Permalink
create initial metric models for rf4 (#1406)
Browse files Browse the repository at this point in the history
* fix: remove EOA requirement to user model

* add: passport source file

* add passport staging model

* add: superchain core models

* fix typo

* fix: passport source

* fix: trusted user model

* add trusted transactions table

* add: initial metrics and summary table

* first batch of trusted user metrics

* (bug) remove duplicate artifact types from OP contract invocation events

* fix: lower case to/from_namespace for OP events

* (bug) apply artifact_type deduping to other superchain contract events

* fix: remove to/from_namespace from select in L2 contract events model

* add: dau/mau models and rename other metrics tables

* add: recurring users and onboarded users models
  • Loading branch information
ccerv1 committed May 15, 2024
1 parent 2e0327b commit 23d43c9
Show file tree
Hide file tree
Showing 16 changed files with 436 additions and 49 deletions.
51 changes: 31 additions & 20 deletions warehouse/dbt/macros/models/contract_invocation_events_with_l1.sql
Original file line number Diff line number Diff line change
@@ -1,16 +1,36 @@
{% macro contract_invocation_events_with_l1(network_name, start) %}
{% set lower_network_name = network_name.lower() %}
{% set upper_network_name = network_name.upper() %}
with all_transactions as (

with blockchain_artifacts as (
select
artifact_source_id,
MAX_BY(artifact_type, artifact_rank) as artifact_type
from (
select
LOWER(artifact_source_id) as artifact_source_id,
artifact_type,
case
when artifact_type = 'SAFE' then 5
when artifact_type = 'FACTORY' then 4
when artifact_type = 'CONTRACT' then 3
when artifact_type = 'DEPLOYER' then 2
when artifact_type = 'EOA' then 1
else 0
end as artifact_rank
from {{ ref('int_artifacts_by_project') }}
where artifact_source = "{{ upper_network_name }}"
)
group by artifact_source_id
),

all_transactions as (
select -- noqa: ST06
TIMESTAMP_TRUNC(transactions.block_timestamp, day) as `time`,
"{{ upper_network_name }}" as event_source,
LOWER(transactions.to_address) as to_name,
"{{ lower_network_name }}" as to_namespace,
COALESCE(to_artifacts.artifact_type, "CONTRACT") as to_type,
LOWER(transactions.to_address) as to_source_id,
LOWER(transactions.from_address) as from_name,
"{{ lower_network_name }}" as from_namespace,
COALESCE(from_artifacts.artifact_type, "EOA") as from_type,
LOWER(transactions.from_address) as from_source_id,
transactions.receipt_status,
Expand All @@ -19,16 +39,10 @@ with all_transactions as (
* transactions.receipt_effective_gas_price
) as l2_gas_fee
from {{ ref('int_%s_transactions' % lower_network_name) }} as transactions
left join {{ ref('int_artifacts_by_project') }} as to_artifacts
on
LOWER(transactions.to_address)
= LOWER(to_artifacts.artifact_source_id)
and to_artifacts.artifact_source = "{{ upper_network_name }}"
left join {{ ref('int_artifacts_by_project') }} as from_artifacts
on
LOWER(transactions.from_address)
= LOWER(from_artifacts.artifact_source_id)
and to_artifacts.artifact_source = "{{ upper_network_name }}"
left join blockchain_artifacts as to_artifacts
on LOWER(transactions.to_address) = to_artifacts.artifact_source_id
left join blockchain_artifacts as from_artifacts
on LOWER(transactions.from_address) = from_artifacts.artifact_source_id
where
transactions.input != "0x"
and transactions.block_timestamp >= {{ start }}
Expand All @@ -37,28 +51,25 @@ with all_transactions as (
contract_invocations as (
select
time,
event_source,
to_name,
to_namespace,
to_type,
to_source_id,
from_name,
from_namespace,
from_type,
from_source_id,
"{{ upper_network_name }}" as event_source,
"{{ lower_network_name }}" as to_namespace,
"{{ lower_network_name }}" as from_namespace,
SUM(l2_gas_fee) as total_l2_gas_used,
COUNT(*) as total_count,
SUM(case when receipt_status = 1 then 1 else 0 end) as success_count
from all_transactions
group by
time,
event_source,
to_name,
to_namespace,
to_type,
to_source_id,
from_name,
from_namespace,
from_type,
from_source_id
),
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -16,72 +16,83 @@
{% else %}
{% set start = "'1970-01-01'" %}
{% endif %}
with all_transactions as (

with blockchain_artifacts as (
select
artifact_source_id,
MAX_BY(artifact_type, artifact_rank) as artifact_type
from (
select
artifact_type,
LOWER(artifact_source_id) as artifact_source_id,
case
when artifact_type = 'SAFE' then 5
when artifact_type = 'FACTORY' then 4
when artifact_type = 'CONTRACT' then 3
when artifact_type = 'DEPLOYER' then 2
when artifact_type = 'EOA' then 1
else 0
end as artifact_rank
from {{ ref('int_artifacts_by_project') }}
where artifact_source = 'OPTIMISM'
)
group by artifact_source_id
),

all_transactions as (
select -- noqa: ST06
TIMESTAMP_TRUNC(transactions.block_timestamp, day) as `time`,
"OPTIMISM" as event_source,
LOWER(transactions.to_address) as to_name,
"OPTIMISM" as to_namespace,
COALESCE(to_artifacts.artifact_type, "CONTRACT") as to_type,
COALESCE(to_artifacts.artifact_type, 'CONTRACT') as to_type,
LOWER(transactions.to_address) as to_source_id,
LOWER(transactions.from_address) as from_name,
"OPTIMISM" as from_namespace,
COALESCE(from_artifacts.artifact_type, "EOA") as from_type,
COALESCE(from_artifacts.artifact_type, 'EOA') as from_type,
LOWER(transactions.from_address) as from_source_id,
transactions.receipt_status,
(
transactions.receipt_gas_used
* transactions.receipt_effective_gas_price
) as l2_gas_fee
from {{ ref('int_optimism_transactions') }} as transactions
left join {{ ref('int_artifacts_by_project') }} as to_artifacts
on
LOWER(transactions.to_address)
= LOWER(to_artifacts.artifact_source_id)
and to_artifacts.artifact_source = "OPTIMISM"
left join {{ ref('int_artifacts_by_project') }} as from_artifacts
on
LOWER(transactions.from_address)
= LOWER(from_artifacts.artifact_source_id)
and to_artifacts.artifact_source = "OPTIMISM"
left join blockchain_artifacts as to_artifacts
on LOWER(transactions.to_address) = to_artifacts.artifact_source_id
left join blockchain_artifacts as from_artifacts
on LOWER(transactions.from_address) = from_artifacts.artifact_source_id
where
transactions.input != "0x"
transactions.input != '0x'
and transactions.block_timestamp >= {{ start }}
),

contract_invocations as (
select
time,
event_source,
to_name,
to_namespace,
to_type,
to_source_id,
from_name,
from_namespace,
from_type,
from_source_id,
'OPTIMISM' as event_source,
'optimism' as to_namespace,
'optimism' as from_namespace,
SUM(l2_gas_fee) as total_l2_gas_used,
COUNT(*) as total_count,
SUM(case when receipt_status = 1 then 1 else 0 end) as success_count
from all_transactions
group by
time,
event_source,
to_name,
to_namespace,
to_type,
to_source_id,
from_name,
from_namespace,
from_type,
from_source_id
),

all_events as (
select
time,
"CONTRACT_INVOCATION_DAILY_L2_GAS_USED" as event_type,
'CONTRACT_INVOCATION_DAILY_L2_GAS_USED' as event_type,
event_source,
to_name,
to_namespace,
Expand All @@ -96,7 +107,7 @@ all_events as (
union all
select
time,
"CONTRACT_INVOCATION_DAILY_COUNT" as event_type,
'CONTRACT_INVOCATION_DAILY_COUNT' as event_type,
event_source,
to_name,
to_namespace,
Expand All @@ -111,7 +122,7 @@ all_events as (
union all
select
time,
"CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT" as event_type,
'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' as event_type,
event_source,
to_name,
to_namespace,
Expand Down
Original file line number Diff line number Diff line change
@@ -1,5 +1,7 @@
{#
Many to many relationship table for users and artifacts
Note: Currently this does not make any assumptions about
whether the artifact is an EOA address.
#}


Expand All @@ -17,9 +19,7 @@ with farcaster_users as (
on int_users.user_source_id = stg_farcaster__addresses.fid
inner join {{ ref('int_artifacts') }}
on stg_farcaster__addresses.address = int_artifacts.artifact_name
where
int_users.user_source = 'FARCASTER'
and int_artifacts.artifact_type = 'EOA'
where int_users.user_source = 'FARCASTER'
)

select
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
select
project_id,
'gas_fees' as metric,
SUM(amount / 1e18) as amount
from {{ ref('rf4_events_daily_to_project') }}
where
event_type = 'CONTRACT_INVOCATION_DAILY_L2_GAS_USED'
group by
project_id
10 changes: 10 additions & 0 deletions warehouse/dbt/models/marts/superchain/metrics/rf4_transactions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
select
project_id,
'transaction_count' as metric,
SUM(amount) as amount
from {{ ref('rf4_events_daily_to_project') }}
where
event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT'
and bucket_day >= '2023-10-01'
group by
project_id
Original file line number Diff line number Diff line change
@@ -0,0 +1,40 @@
with txns as (
select
project_id,
trusted_user_id,
bucket_day
from {{ ref('rf4_events_daily_to_project') }}
where
event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT'
and bucket_day >= '2023-10-01'
and trusted_user_id is not null
),

daus as (
select
project_id,
bucket_day,
COUNT(distinct trusted_user_id) as trusted_users
from txns
group by
project_id,
bucket_day
),

total_days as (
select DATE_DIFF(max_day, min_day, day) + 1 as days
from (
select
MIN(bucket_day) as min_day,
MAX(bucket_day) as max_day
from txns
)
)

select
project_id,
'trusted_daily_active_users' as metric,
SUM(trusted_users) / (select days from total_days) as amount
from daus
group by
project_id
Original file line number Diff line number Diff line change
@@ -0,0 +1,42 @@
with txns as (
select
project_id,
trusted_user_id,
TIMESTAMP_TRUNC(bucket_day, month) as bucket_month
from {{ ref('rf4_events_daily_to_project') }}
where
event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT'
and bucket_day >= '2023-10-01'
and trusted_user_id is not null
),

maus as (
select
project_id,
bucket_month,
COUNT(distinct trusted_user_id) as trusted_users
from txns
group by
project_id,
bucket_month
),

total_months as (
select
{# TODO: double check this math #}
(DATE_DIFF(max_month, min_month, day) + 30) / 30 as months
from (
select
MIN(bucket_month) as min_month,
MAX(bucket_month) as max_month
from txns
)
)

select
project_id,
'trusted_monthly_active_users' as metric,
SUM(trusted_users) / (select months from total_months) as amount
from maus
group by
project_id
Original file line number Diff line number Diff line change
@@ -0,0 +1,35 @@
with txns as (
select
project_id,
trusted_user_id,
bucket_day,
TIMESTAMP_TRUNC(bucket_day, month) as bucket_month
from {{ ref('rf4_events_daily_to_project') }}
where
event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT'
and bucket_day >= '2023-10-01'
and trusted_user_id is not null
),

user_stats as (
select
project_id,
trusted_user_id,
COUNT(distinct bucket_month) as months,
MAX(bucket_day) as last_day
from txns
group by
project_id,
trusted_user_id
)

select
project_id,
'trusted_recurring_users' as metric,
COUNT(distinct trusted_user_id) as amount
from user_stats
where
months >= 3
and last_day >= '2024-04-01'
group by
project_id
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
select
project_id,
'trusted_transaction_count' as metric,
SUM(amount) as amount
from {{ ref('rf4_events_daily_to_project') }}
where
event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT'
and bucket_day >= '2023-10-01'
and trusted_user_id is not null
group by
project_id
Loading

0 comments on commit 23d43c9

Please sign in to comment.