From 6f65f411ba8fb2627aa238859ed4df167de925c7 Mon Sep 17 00:00:00 2001 From: Carl Cervone <42869436+ccerv1@users.noreply.github.com> Date: Fri, 9 Aug 2024 10:57:55 -0400 Subject: [PATCH] feat: implement superchain metrics as timeseries (#1911) * add: pre-macro metrics for gas fees and transactions * add: preprocessing macro * add: DAAs model * add: MAAs model * feat: add trusted user model * add: trusted transactions * fix: windowing on monthly metrics * fix: address reference * join artifacts_by_address on trusted_user_model * fix: simplify user model joins * fix: filter out events before first of the month * refactor: add windowing macro * refactor: add project join to macro * make metrics ephemeral and unify into single model * fix: linting error --- warehouse/dbt/macros/models/timeseries.sql | 145 ++++++++++++++++++ ...int_timeseries_superchain_metrics__all.sql | 17 ++ ...c__daily_active_addresses_avg_6_months.sql | 64 ++++++++ ...perchain_metric__gas_fees_sum_6_months.sql | 62 ++++++++ ..._monthly_active_addresses_avg_6_months.sql | 64 ++++++++ ...hain_metric__transactions_sum_6_months.sql | 62 ++++++++ ...rusted_daily_active_users_avg_6_months.sql | 65 ++++++++ ...sted_monthly_active_users_avg_6_months.sql | 65 ++++++++ ...ric__trusted_transactions_sum_6_months.sql | 65 ++++++++ ...__trusted_users_onboarded_sum_6_months.sql | 98 ++++++++++++ .../users/int_superchain_trusted_users.sql | 56 +++++++ 11 files changed, 763 insertions(+) create mode 100644 warehouse/dbt/macros/models/timeseries.sql create mode 100644 warehouse/dbt/models/intermediate/metrics/timeseries/superchain/int_timeseries_superchain_metrics__all.sql create mode 100644 warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__daily_active_addresses_avg_6_months.sql create mode 100644 warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__gas_fees_sum_6_months.sql create mode 100644 warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__monthly_active_addresses_avg_6_months.sql create mode 100644 warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__transactions_sum_6_months.sql create mode 100644 warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_daily_active_users_avg_6_months.sql create mode 100644 warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_monthly_active_users_avg_6_months.sql create mode 100644 warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_transactions_sum_6_months.sql create mode 100644 warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_users_onboarded_sum_6_months.sql create mode 100644 warehouse/dbt/models/intermediate/users/int_superchain_trusted_users.sql diff --git a/warehouse/dbt/macros/models/timeseries.sql b/warehouse/dbt/macros/models/timeseries.sql new file mode 100644 index 000000000..647f50c49 --- /dev/null +++ b/warehouse/dbt/macros/models/timeseries.sql @@ -0,0 +1,145 @@ +{% macro to_sql_array(string_list) %} + {% set formatted_list = [] %} + {% for item in string_list %} + {% do formatted_list.append("'{}'".format(item)) %} + {% endfor %} + {{ return("(" ~ formatted_list | join(', ') ~ ")") }} +{% endmacro %} + +{% macro timeseries_events( + event_sources, + event_types, + to_artifact_types, + from_artifact_types, + time_interval='DAY', + missing_dates='ignore', + event_model='int_events' +) %} + +with filtered_events as ( + select + TIMESTAMP_TRUNC(`time`, {{ time_interval }}) as sample_date, + from_artifact_id, + to_artifact_id, + event_source, + amount + from {{ ref(event_model) }} + where + event_type in {{ to_sql_array(event_types) }} + and event_source in {{ to_sql_array(event_sources) }} + and to_artifact_type in {{ to_sql_array(to_artifact_types) }} + and from_artifact_type in {{ to_sql_array(from_artifact_types) }} + and `time` < TIMESTAMP_TRUNC(CURRENT_TIMESTAMP(), {{ time_interval }}) +), + +grouped_events as ( + select + sample_date, + from_artifact_id, + to_artifact_id, + event_source, + SUM(amount) as amount + from filtered_events + group by + sample_date, + from_artifact_id, + to_artifact_id, + event_source +), + +{% if missing_dates == "fill_with_zero" %} + + calendar as ( + select distinct + TIMESTAMP_TRUNC(date_timestamp, {{ time_interval }}) as calendar_time + from {{ ref('stg_utility__calendar') }} + where TIMESTAMP(date_timestamp) <= CURRENT_TIMESTAMP() + ), + + first_event_times as ( + select + to_artifact_id, + MIN(sample_date) as first_event_time + from grouped_events + group by to_artifact_id + ), + + timeseries_events as ( + select + calendar.calendar_time as sample_date, + event_dates.from_artifact_id, + event_dates.to_artifact_id, + event_dates.event_source, + COALESCE(grouped_events.amount, 0) as amount + from + calendar + cross join ( + select + from_artifact_id, + to_artifact_id, + event_source + from grouped_events + group by + from_artifact_id, + to_artifact_id, + event_source + ) as event_dates + left join grouped_events + on calendar.calendar_time = grouped_events.sample_date + and event_dates.from_artifact_id = grouped_events.from_artifact_id + and event_dates.to_artifact_id = grouped_events.to_artifact_id + and event_dates.event_source = grouped_events.event_source + where + calendar.calendar_time >= ( + select MIN(first_event_time) + from first_event_times + where first_event_times.to_artifact_id = event_dates.to_artifact_id + ) + ) + +{% else %} + + timeseries_events as ( + select + sample_date, + from_artifact_id, + to_artifact_id, + event_source, + amount + from grouped_events + ) + +{% endif %} + +select + timeseries_events.sample_date, + timeseries_events.from_artifact_id, + timeseries_events.to_artifact_id, + artifacts_by_project.project_id, + timeseries_events.event_source, + timeseries_events.amount +from timeseries_events +inner join {{ ref('artifacts_by_project_v1')}} as artifacts_by_project + on timeseries_events.to_artifact_id = artifacts_by_project.artifact_id + +{% endmacro %} + +{% macro window_events( + agg_events_table, + agg_func, + window_size, + entity_type +) %} + +select + {{ entity_type }}_id, + sample_date, + event_source, + {{ agg_func }}(amount) over ( + partition by {{entity_type}}_id, event_source + order by sample_date + rows between {{ window_size-1 }} preceding and current row + ) as amount +from {{ agg_events_table }} + +{% endmacro %} \ No newline at end of file diff --git a/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/int_timeseries_superchain_metrics__all.sql b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/int_timeseries_superchain_metrics__all.sql new file mode 100644 index 000000000..6cc8f20f8 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/int_timeseries_superchain_metrics__all.sql @@ -0,0 +1,17 @@ +{% set models = [ + 'gas_fees_sum', + 'transactions_sum', + 'trusted_transactions_sum', + 'trusted_daily_active_users_avg', + 'trusted_monthly_active_users_avg', + 'daily_active_addresses_avg', + 'monthly_active_addresses_avg', + 'trusted_users_onboarded_sum' +] %} + +{% for model in models %} + select * from {{ ref('superchain_metric__%s_6_months' % model) }} + {% if not loop.last %} + union all + {% endif %} +{% endfor %} diff --git a/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__daily_active_addresses_avg_6_months.sql b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__daily_active_addresses_avg_6_months.sql new file mode 100644 index 000000000..88861b230 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__daily_active_addresses_avg_6_months.sql @@ -0,0 +1,64 @@ +{# + config( + materialized='ephemeral', + ) +#} + +{% set metric = { + "metric_name": "daily_active_addresses_avg_6_months", + "metric_unit": "addresses", + "event_sources": [ + "OPTIMISM", + "BASE", + "FRAX", + "METAL", + "MODE", + "ZORA" + ], + "event_types": ["CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT"], + "to_artifact_types": ["CONTRACT"], + "from_artifact_types": ["EOA"], + "window_interval": "DAY", + "window_size": 180, + "window_missing_dates": "fill_with_zero", + "sampling_interval": "daily" +} %} + +with events as ( + {{ timeseries_events( + metric.event_sources, + metric.event_types, + metric.to_artifact_types, + metric.from_artifact_types, + time_interval=metric.window_interval, + missing_dates=metric.window_missing_dates + ) }} +), + +agg_events as ( + select + events.sample_date, + events.event_source, + events.project_id, + COUNT(distinct artifacts_by_address.artifact_name) as amount + from events + inner join {{ ref('int_artifacts_by_address') }} as artifacts_by_address + on events.from_artifact_id = artifacts_by_address.artifact_id + group by + events.sample_date, + events.event_source, + events.project_id +), + +windowed_events as ({{ + window_events('agg_events', 'AVG', metric.window_size, 'project') +}}) + +select + project_id, + sample_date, + event_source, + amount, + '{{ metric.metric_name }}' as metric, + '{{ metric.metric_unit }}' as unit +from windowed_events diff --git a/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__gas_fees_sum_6_months.sql b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__gas_fees_sum_6_months.sql new file mode 100644 index 000000000..e6806fb3d --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__gas_fees_sum_6_months.sql @@ -0,0 +1,62 @@ +{# + config( + materialized='ephemeral', + ) +#} + +{% set metric = { + "metric_name": "gas_fees_sum_6_months", + "metric_unit": "L2 ETH", + "event_sources": [ + "OPTIMISM", + "BASE", + "FRAX", + "METAL", + "MODE", + "ZORA" + ], + "event_types": ["CONTRACT_INVOCATION_DAILY_L2_GAS_USED"], + "to_artifact_types": ["CONTRACT"], + "from_artifact_types": ["EOA", "SAFE"], + "window_interval": "DAY", + "window_size": 180, + "window_missing_dates": "ignore", + "sampling_interval": "daily" +} %} + +with events as ( + {{ timeseries_events( + metric.event_sources, + metric.event_types, + metric.to_artifact_types, + metric.from_artifact_types, + time_interval=metric.window_interval, + missing_dates=metric.window_missing_dates + ) }} +), + +agg_events as ( + select + events.sample_date, + events.event_source, + events.project_id, + SUM(events.amount / 1e18) as amount + from events + group by + events.sample_date, + events.event_source, + events.project_id +), + +windowed_events as ({{ + window_events('agg_events', 'SUM', metric.window_size, 'project') +}}) + +select + project_id, + sample_date, + event_source, + amount, + '{{ metric.metric_name }}' as metric, + '{{ metric.metric_unit }}' as unit +from windowed_events diff --git a/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__monthly_active_addresses_avg_6_months.sql b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__monthly_active_addresses_avg_6_months.sql new file mode 100644 index 000000000..b0bb8f6ed --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__monthly_active_addresses_avg_6_months.sql @@ -0,0 +1,64 @@ +{# + config( + materialized='ephemeral', + ) +#} + +{% set metric = { + "metric_name": "monthly_active_addresses_avg_6_months", + "metric_unit": "addresses", + "event_sources": [ + "OPTIMISM", + "BASE", + "FRAX", + "METAL", + "MODE", + "ZORA" + ], + "event_types": ["CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT"], + "to_artifact_types": ["CONTRACT"], + "from_artifact_types": ["EOA"], + "window_interval": "MONTH", + "window_size": 6, + "window_missing_dates": "fill_with_zero", + "sampling_interval": "daily" +} %} + +with events as ( + {{ timeseries_events( + metric.event_sources, + metric.event_types, + metric.to_artifact_types, + metric.from_artifact_types, + time_interval=metric.window_interval, + missing_dates=metric.window_missing_dates + ) }} +), + +agg_events as ( + select + events.sample_date, + events.event_source, + events.project_id, + COUNT(distinct artifacts_by_address.artifact_name) as amount + from events + inner join {{ ref('int_artifacts_by_address') }} as artifacts_by_address + on events.from_artifact_id = artifacts_by_address.artifact_id + group by + events.sample_date, + events.event_source, + events.project_id +), + +windowed_events as ({{ + window_events('agg_events', 'AVG', metric.window_size, 'project') +}}) + +select + project_id, + sample_date, + event_source, + amount, + '{{ metric.metric_name }}' as metric, + '{{ metric.metric_unit }}' as unit +from windowed_events diff --git a/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__transactions_sum_6_months.sql b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__transactions_sum_6_months.sql new file mode 100644 index 000000000..998dbbc64 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__transactions_sum_6_months.sql @@ -0,0 +1,62 @@ +{# + config( + materialized='ephemeral', + ) +#} + +{% set metric = { + "metric_name": "transactions_sum_6_months", + "metric_unit": "successful transactions", + "event_sources": [ + "OPTIMISM", + "BASE", + "FRAX", + "METAL", + "MODE", + "ZORA" + ], + "event_types": ["CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT"], + "to_artifact_types": ["CONTRACT"], + "from_artifact_types": ["EOA", "SAFE"], + "window_interval": "DAY", + "window_size": 180, + "window_missing_dates": "ignore", + "sampling_interval": "daily" +} %} + +with events as ( + {{ timeseries_events( + metric.event_sources, + metric.event_types, + metric.to_artifact_types, + metric.from_artifact_types, + time_interval=metric.window_interval, + missing_dates=metric.window_missing_dates + ) }} +), + +agg_events as ( + select + events.sample_date, + events.event_source, + events.project_id, + SUM(events.amount) as amount + from events + group by + events.sample_date, + events.event_source, + events.project_id +), + +windowed_events as ({{ + window_events('agg_events', 'SUM', metric.window_size, 'project') +}}) + +select + project_id, + sample_date, + event_source, + amount, + '{{ metric.metric_name }}' as metric, + '{{ metric.metric_unit }}' as unit +from windowed_events diff --git a/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_daily_active_users_avg_6_months.sql b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_daily_active_users_avg_6_months.sql new file mode 100644 index 000000000..1d099fec5 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_daily_active_users_avg_6_months.sql @@ -0,0 +1,65 @@ +{# + config( + materialized='ephemeral', + ) +#} + +{% set metric = { + "metric_name": "trusted_daily_active_users_avg_6_months", + "metric_unit": "trusted user addresses", + "event_sources": [ + "OPTIMISM", + "BASE", + "FRAX", + "METAL", + "MODE", + "ZORA" + ], + "event_types": ["CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT"], + "to_artifact_types": ["CONTRACT"], + "from_artifact_types": ["EOA"], + "window_interval": "DAY", + "window_size": 180, + "window_missing_dates": "fill_with_zero", + "sampling_interval": "daily" +} %} + +with events as ( + {{ timeseries_events( + metric.event_sources, + metric.event_types, + metric.to_artifact_types, + metric.from_artifact_types, + time_interval=metric.window_interval, + missing_dates=metric.window_missing_dates + ) }} +), + +agg_events as ( + select + events.sample_date, + events.event_source, + events.project_id, + COUNT(distinct trusted_users.address) as amount + from events + inner join {{ ref('int_superchain_trusted_users') }} as trusted_users + on events.from_artifact_id = trusted_users.artifact_id + where trusted_users.is_trusted_user = true + group by + events.sample_date, + events.event_source, + events.project_id +), + +windowed_events as ({{ + window_events('agg_events', 'AVG', metric.window_size, 'project') +}}) + +select + project_id, + sample_date, + event_source, + amount, + '{{ metric.metric_name }}' as metric, + '{{ metric.metric_unit }}' as unit +from windowed_events diff --git a/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_monthly_active_users_avg_6_months.sql b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_monthly_active_users_avg_6_months.sql new file mode 100644 index 000000000..355ef8433 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_monthly_active_users_avg_6_months.sql @@ -0,0 +1,65 @@ +{# + config( + materialized='ephemeral', + ) +#} + +{% set metric = { + "metric_name": "trusted_monthly_active_users_avg_6_months", + "metric_unit": "trusted user addresses", + "event_sources": [ + "OPTIMISM", + "BASE", + "FRAX", + "METAL", + "MODE", + "ZORA" + ], + "event_types": ["CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT"], + "to_artifact_types": ["CONTRACT"], + "from_artifact_types": ["EOA"], + "window_interval": "MONTH", + "window_size": 6, + "window_missing_dates": "fill_with_zero", + "sampling_interval": "daily" +} %} + +with events as ( + {{ timeseries_events( + metric.event_sources, + metric.event_types, + metric.to_artifact_types, + metric.from_artifact_types, + time_interval=metric.window_interval, + missing_dates=metric.window_missing_dates + ) }} +), + +agg_events as ( + select + events.sample_date, + events.event_source, + events.project_id, + COUNT(distinct trusted_users.address) as amount + from events + inner join {{ ref('int_superchain_trusted_users') }} as trusted_users + on events.from_artifact_id = trusted_users.artifact_id + where trusted_users.is_trusted_user = true + group by + events.sample_date, + events.event_source, + events.project_id +), + +windowed_events as ({{ + window_events('agg_events', 'AVG', metric.window_size, 'project') +}}) + +select + project_id, + sample_date, + event_source, + amount, + '{{ metric.metric_name }}' as metric, + '{{ metric.metric_unit }}' as unit +from windowed_events diff --git a/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_transactions_sum_6_months.sql b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_transactions_sum_6_months.sql new file mode 100644 index 000000000..01eaa2615 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_transactions_sum_6_months.sql @@ -0,0 +1,65 @@ +{# + config( + materialized='ephemeral', + ) +#} + +{% set metric = { + "metric_name": "trusted_transactions_sum_6_months", + "metric_unit": "successful transactions", + "event_sources": [ + "OPTIMISM", + "BASE", + "FRAX", + "METAL", + "MODE", + "ZORA" + ], + "event_types": ["CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT"], + "to_artifact_types": ["CONTRACT"], + "from_artifact_types": ["EOA", "SAFE"], + "window_interval": "DAY", + "window_size": 180, + "window_missing_dates": "ignore", + "sampling_interval": "daily" +} %} + +with events as ( + {{ timeseries_events( + metric.event_sources, + metric.event_types, + metric.to_artifact_types, + metric.from_artifact_types, + time_interval=metric.window_interval, + missing_dates=metric.window_missing_dates + ) }} +), + +agg_events as ( + select + events.sample_date, + events.event_source, + events.project_id, + SUM(events.amount) as amount + from events + inner join {{ ref('int_superchain_trusted_users') }} as trusted_users + on events.from_artifact_id = trusted_users.artifact_id + where trusted_users.is_trusted_user = true + group by + events.sample_date, + events.event_source, + events.project_id +), + +windowed_events as ({{ + window_events('agg_events', 'SUM', metric.window_size, 'project') +}}) + +select + project_id, + sample_date, + event_source, + amount, + '{{ metric.metric_name }}' as metric, + '{{ metric.metric_unit }}' as unit +from windowed_events diff --git a/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_users_onboarded_sum_6_months.sql b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_users_onboarded_sum_6_months.sql new file mode 100644 index 000000000..b20164584 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/timeseries/superchain/superchain_metric__trusted_users_onboarded_sum_6_months.sql @@ -0,0 +1,98 @@ +{# + config( + materialized='ephemeral', + ) +#} + +{% set metric = { + "metric_name": "trusted_users_onboarded_sum_6_months", + "metric_unit": "trusted user addresses", + "event_sources": [ + "OPTIMISM", + "BASE", + "FRAX", + "METAL", + "MODE", + "ZORA" + ], + "event_types": ["CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT"], + "to_artifact_types": ["CONTRACT"], + "from_artifact_types": ["EOA"], + "window_interval": "DAY", + "window_size": 180, + "window_missing_dates": "fill_with_zero", + "sampling_interval": "daily" +} %} + +with events as ( + {{ timeseries_events( + metric.event_sources, + metric.event_types, + metric.to_artifact_types, + metric.from_artifact_types, + time_interval=metric.window_interval, + missing_dates=metric.window_missing_dates + ) }} +), + +user_stats as ( + select + addresses.address, + trusted_users.artifact_id, + MIN(addresses.first_active_day) as first_day + from {{ ref('int_first_time_addresses') }} as addresses + left join {{ ref('int_superchain_trusted_users') }} as trusted_users + on addresses.address = trusted_users.address + where trusted_users.is_trusted_user = true + group by + addresses.address, + trusted_users.artifact_id +), + +new_users as ( + select + events.event_source, + events.project_id, + user_stats.address, + MIN(events.sample_date) as onboarding_date + from events + inner join user_stats + on events.from_artifact_id = user_stats.artifact_id + where + events.sample_date <= DATE_ADD(user_stats.first_day, interval 30 day) + group by + events.event_source, + events.project_id, + user_stats.address +), + +agg_events as ( + select + events.sample_date, + events.event_source, + new_users.project_id, + COUNT(distinct new_users.address) as amount + from events + inner join new_users + on + events.sample_date = new_users.onboarding_date + and events.event_source = new_users.event_source + and events.to_artifact_id = new_users.project_id + group by + events.sample_date, + events.event_source, + new_users.project_id +), + +windowed_events as ({{ + window_events('agg_events', 'SUM', metric.window_size, 'project') +}}) + +select + project_id, + sample_date, + event_source, + amount, + '{{ metric.metric_name }}' as metric, + '{{ metric.metric_unit }}' as unit +from windowed_events diff --git a/warehouse/dbt/models/intermediate/users/int_superchain_trusted_users.sql b/warehouse/dbt/models/intermediate/users/int_superchain_trusted_users.sql new file mode 100644 index 000000000..294d2b7c8 --- /dev/null +++ b/warehouse/dbt/models/intermediate/users/int_superchain_trusted_users.sql @@ -0,0 +1,56 @@ +with optimist_nft_holders as ( + select LOWER(optimist_address) as address + from {{ source("static_data_sources", "optimist_nft_holders") }} +), + +airdrop_recipients as ( + select + LOWER(address) as address, + COUNT(distinct airdrop_round) as num_airdrops + from {{ ref('stg_optimism__airdrop_addresses') }} + group by LOWER(address) +), + +user_model as ( + select + addresses.address, + artifacts_by_address.artifact_id, + COALESCE(optimist_nft_holders.address is not null, false) + as is_optimist_nft_holder, + COALESCE(airdrop_recipients.num_airdrops, 0) as num_optimism_airdrops, + COALESCE(addresses.potential_bot, false) as is_potential_bot, + COALESCE(addresses.farcaster_username is not null, false) + as is_farcaster_user, + COALESCE(addresses.farcaster_id < 20939, false) + as is_farcaster_prepermissionless + from {{ ref('int_addresses_by_user') }} as addresses + left join optimist_nft_holders + on addresses.address = optimist_nft_holders.address + left join airdrop_recipients + on addresses.address = airdrop_recipients.address + left join {{ ref('int_artifacts_by_address') }} as artifacts_by_address + on addresses.address = artifacts_by_address.artifact_name +) + +select + address, + artifact_id, + num_optimism_airdrops, + is_optimist_nft_holder, + is_potential_bot, + is_farcaster_user, + is_farcaster_prepermissionless, + ( + not is_potential_bot and ( + is_farcaster_user and ( + num_optimism_airdrops > 1 + or is_farcaster_prepermissionless + or is_optimist_nft_holder + ) + or ( + num_optimism_airdrops > 1 + and is_optimist_nft_holder + ) + ) + ) as is_trusted_user +from user_model