diff --git a/warehouse/dbt/models/intermediate/analyses/int_time_intervals.sql b/warehouse/dbt/models/intermediate/analyses/int_time_intervals.sql new file mode 100644 index 000000000..17097c29b --- /dev/null +++ b/warehouse/dbt/models/intermediate/analyses/int_time_intervals.sql @@ -0,0 +1,30 @@ +with dates as ( + select + '7 DAYS' as time_interval, + DATE_SUB(CURRENT_DATE(), interval 7 day) as start_date + union all + select + '30 DAYS' as time_interval, + DATE_SUB(CURRENT_DATE(), interval 30 day) as start_date + union all + select + '90 DAYS' as time_interval, + DATE_SUB(CURRENT_DATE(), interval 90 day) as start_date + union all + select + '6 MONTHS' as time_interval, + DATE_SUB(CURRENT_DATE(), interval 6 month) as start_date + union all + select + '1 YEAR' as time_interval, + DATE_SUB(CURRENT_DATE(), interval 1 year) as start_date + union all + select + 'ALL' as time_interval, + DATE('1970-01-01') as start_date +) + +select + dates.time_interval, + TIMESTAMP(dates.start_date) as start_date +from dates diff --git a/warehouse/dbt/models/intermediate/events/int_time_intervals.sql b/warehouse/dbt/models/intermediate/events/int_time_intervals.sql deleted file mode 100644 index 7f4461cec..000000000 --- a/warehouse/dbt/models/intermediate/events/int_time_intervals.sql +++ /dev/null @@ -1,19 +0,0 @@ -select - '30D' as time_interval, - DATE_SUB(CURRENT_DATE(), interval 30 day) as start_date -union all -select - '90D' as time_interval, - DATE_SUB(CURRENT_DATE(), interval 90 day) as start_date -union all -select - '6M' as time_interval, - DATE_SUB(CURRENT_DATE(), interval 6 month) as start_date -union all -select - '1Y' as time_interval, - DATE_SUB(CURRENT_DATE(), interval 1 year) as start_date -union all -select - 'ALL' as time_interval, - DATE('1970-01-01') as start_date diff --git a/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__active_developers.sql b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__active_developers.sql new file mode 100644 index 000000000..fcd6f3720 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__active_developers.sql @@ -0,0 +1,13 @@ +select + events.project_id, + time_intervals.time_interval, + 'active_developer_count' as metric, + COUNT(distinct events.from_artifact_id) as amount +from {{ ref('int_events_daily_to_project') }} as events +cross join {{ ref('int_time_intervals') }} as time_intervals +where + events.event_type = 'COMMIT_CODE' + and events.bucket_day >= time_intervals.start_date +group by + events.project_id, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__bus_factor.sql b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__bus_factor.sql new file mode 100644 index 000000000..a5996da23 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__bus_factor.sql @@ -0,0 +1,77 @@ +with all_contributions as ( + select + project_id, + from_artifact_id, + bucket_month, + SUM(amount) as amount + from {{ ref('int_events_monthly_to_project') }} + where event_type = 'COMMIT_CODE' + group by + project_id, + from_artifact_id, + bucket_month +), + +contributions as ( + select * + from all_contributions + where amount < 1000 -- BOT FILTER +), + +aggregated_contributions as ( + select + contributions.project_id, + contributions.from_artifact_id, + time_intervals.time_interval, + SUM(contributions.amount) as amount + from contributions + cross join {{ ref('int_time_intervals') }} as time_intervals + where + contributions.bucket_month + >= TIMESTAMP_TRUNC(time_intervals.start_date, month) + group by + contributions.project_id, + contributions.from_artifact_id, + time_intervals.time_interval +), + +ranked_contributions as ( + select + project_id, + time_interval, + from_artifact_id, + amount, + RANK() + over ( + partition by project_id, time_interval + order by amount desc + ) as rank, + SUM(amount) + over ( + partition by project_id, time_interval + ) as total_project_amount, + SUM(amount) + over ( + partition by project_id, time_interval + order by amount desc + rows between unbounded preceding and current row + ) as cumulative_amount + from aggregated_contributions +) + +select + project_id, + time_interval, + 'bus_factor' as metric, + MAX( + case + when cumulative_amount <= total_project_amount * 0.5 + then rank + else 1 + end + ) as amount +from + ranked_contributions +group by + project_id, + time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__commits_prs_issues.sql b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__commits_prs_issues.sql new file mode 100644 index 000000000..634193ef7 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__commits_prs_issues.sql @@ -0,0 +1,20 @@ +select + events.project_id, + time_intervals.time_interval, + CONCAT(LOWER(events.event_type), '_count') as metric, + SUM(events.amount) as amount +from {{ ref('int_events_daily_to_project') }} as events +cross join {{ ref('int_time_intervals') }} as time_intervals +where + events.bucket_day >= time_intervals.start_date + and events.event_type in ( + 'COMMIT_CODE', + 'PULL_REQUEST_OPENED', + 'PULL_REQUEST_MERGED', + 'ISSUE_OPENED', + 'ISSUE_CLOSED' + ) +group by + events.project_id, + time_intervals.time_interval, + events.event_type diff --git a/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__contributors.sql b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__contributors.sql new file mode 100644 index 000000000..3a59fae6e --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__contributors.sql @@ -0,0 +1,17 @@ +select + events.project_id, + time_intervals.time_interval, + 'contributor_count' as metric, + COUNT(distinct events.from_artifact_id) as amount +from {{ ref('int_events_daily_to_project') }} as events +cross join {{ ref('int_time_intervals') }} as time_intervals +where + events.event_type in ( + 'COMMIT_CODE', + 'PULL_REQUEST_OPENED', + 'ISSUE_OPENED' + ) + and events.bucket_day >= time_intervals.start_date +group by + events.project_id, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__fulltime_developers_avg.sql b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__fulltime_developers_avg.sql new file mode 100644 index 000000000..8e1db8fbf --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__fulltime_developers_avg.sql @@ -0,0 +1,34 @@ +{% set fulltime_dev_days = 10 %} + +with dev_stats as ( + select + events.project_id, + time_intervals.time_interval, + events.from_artifact_id, + TIMESTAMP_TRUNC(events.bucket_day, month) as bucket_month, + COUNT(distinct events.bucket_day) as amount + from {{ ref('int_events_daily_to_project') }} as events + cross join {{ ref('int_time_intervals') }} as time_intervals + where + events.event_type = 'COMMIT_CODE' + and events.bucket_day >= time_intervals.start_date + group by + events.project_id, + time_intervals.time_interval, + events.from_artifact_id, + TIMESTAMP_TRUNC(events.bucket_day, month) +) + +select + project_id, + time_interval, + 'fulltime_developer_avg' as metric, + ( + COUNT(distinct from_artifact_id) + / COUNT(distinct bucket_month) + ) as amount +from dev_stats +where amount >= {{ fulltime_dev_days }} +group by + project_id, + time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__new_contributors.sql b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__new_contributors.sql new file mode 100644 index 000000000..324c25a52 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/code/int_code_metric__new_contributors.sql @@ -0,0 +1,44 @@ +with user_stats as ( + select + from_artifact_id, + project_id, + min(bucket_day) as first_day + from {{ ref('int_events_daily_to_project') }} + where + event_type in ( + 'COMMIT_CODE', + 'PULL_REQUEST_OPENED', + 'ISSUE_OPENED' + ) + group by + from_artifact_id, + project_id +) + +select + events.project_id, + time_intervals.time_interval, + 'new_contributor_count' as metric, + count( + distinct + case + when user_stats.first_day >= time_intervals.start_date + then events.from_artifact_id + end + ) as amount +from {{ ref('int_events_daily_to_project') }} as events +inner join user_stats + on + events.from_artifact_id = user_stats.from_artifact_id + and events.project_id = user_stats.project_id +cross join {{ ref('int_time_intervals') }} as time_intervals +where + events.event_type in ( + 'COMMIT_CODE', + 'PULL_REQUEST_OPENED', + 'ISSUE_OPENED' + ) + and events.bucket_day >= time_intervals.start_date +group by + events.project_id, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/int_code_metrics_by_project.sql b/warehouse/dbt/models/intermediate/metrics/int_code_metrics_by_project.sql index d6c18bb26..cfd0e288b 100644 --- a/warehouse/dbt/models/intermediate/metrics/int_code_metrics_by_project.sql +++ b/warehouse/dbt/models/intermediate/metrics/int_code_metrics_by_project.sql @@ -1,162 +1,149 @@ -{% set date_6_months = "DATE_TRUNC(CURRENT_DATE(), month) - INTERVAL 6 MONTH" %} - -with repos as ( - select - project_id, - MIN(first_commit_time) as first_commit_date, - MAX(last_commit_time) as last_commit_date, - COUNT(distinct artifact_id) as repositories, - SUM(star_count) as stars, - SUM(fork_count) as forks - from {{ ref('int_repo_metrics_by_project') }} - --WHERE r.is_fork = false - group by project_id -), - -project_repos_summary as ( - select - repos.project_id, - repos.first_commit_date, - repos.last_commit_date, - repos.repositories, - repos.stars, - repos.forks, - int_projects.project_source, - int_projects.project_namespace, - int_projects.project_name, - int_projects.display_name - from repos - left join {{ ref('int_projects') }} - on repos.project_id = int_projects.project_id -), - -dev_activity as ( - select - project_id, - from_artifact_id, - bucket_month, - user_segment_type, - case - when DATE(bucket_month) >= {{ date_6_months }} then 1 - else 0 - end as is_last_6_months, - case - when - DATE(bucket_month) >= {{ date_6_months }} - and LAG(bucket_month) over ( - partition by project_id, from_artifact_id - order by bucket_month - ) is null - then 1 - else 0 - end as is_new_last_6_months - from {{ ref('int_developer_status_monthly_by_project') }} +with metrics as ( + select * from {{ ref('int_code_metric__active_developers') }} + union all + select * from {{ ref('int_code_metric__commits_prs_issues') }} + union all + select * from {{ ref('int_code_metric__contributors') }} + union all + select * from {{ ref('int_code_metric__fulltime_developers_avg') }} + union all + select * from {{ ref('int_code_metric__new_contributors') }} ), -contribs_cte as ( +aggs as ( select project_id, - COUNT(distinct from_artifact_id) as contributors, - COUNT( - distinct + SUM( case - when is_last_6_months = 1 then from_artifact_id + when + metric = 'commit_code_count' + and time_interval = '6 MONTHS' + then amount + else 0 end - ) as contributors_6_months, - COUNT( - distinct + ) as commit_count_6_months, + SUM( case - when is_new_last_6_months = 1 then from_artifact_id + when + metric = 'pull_request_opened_count' + and time_interval = '6 MONTHS' + then amount + else 0 end - ) as new_contributors_6_months, - AVG( + ) as opened_pull_request_count_6_months, + SUM( case when - is_last_6_months = 1 - and user_segment_type = 'FULL_TIME_DEVELOPER' - then 1 + metric = 'pull_request_merged_count' + and time_interval = '6 MONTHS' + then amount else 0 end - ) as avg_fulltime_devs_6_months, - AVG( + ) as merged_pull_request_count_6_months, + SUM( case when - is_last_6_months = 1 - and user_segment_type in ( - 'FULL_TIME_DEVELOPER', - 'PART_TIME_DEVELOPER' - ) then 1 + metric = 'issue_opened_count' + and time_interval = '6 MONTHS' + then amount else 0 end - ) as avg_active_devs_6_months - from dev_activity - group by project_id -), - -activity_cte as ( - select - project_id, + ) as opened_issue_count_6_months, SUM( case - when event_type = 'COMMIT_CODE' then amount + when + metric = 'issue_closed_count' + and time_interval = '6 MONTHS' + then amount + else 0 end - ) as commits_6_months, + ) as closed_issue_count_6_months, SUM( case - when event_type = 'ISSUE_OPENED' then amount + when + metric = 'active_developer_count' + and time_interval = '6 MONTHS' + then amount + else 0 end - ) as issues_opened_6_months, + ) as active_developer_count_6_months, SUM( case - when event_type = 'ISSUE_CLOSED' then amount + when + metric = 'contributor_count' + and time_interval = 'ALL' + then amount + else 0 + end + ) as contributor_count, + SUM( + case + when + metric = 'contributor_count' + and time_interval = '6 MONTHS' + then amount + else 0 end - ) as issues_closed_6_months, + ) as contributor_count_6_months, SUM( case - when event_type = 'PULL_REQUEST_OPENED' then amount + when + metric = 'new_contributor_count' + and time_interval = '6 MONTHS' + then amount + else 0 end - ) as pull_requests_opened_6_months, + ) as new_contributor_count_6_months, SUM( case - when event_type = 'PULL_REQUEST_MERGED' then amount + when + metric = 'fulltime_developer_avg' + and time_interval = '6 MONTHS' + then amount + else 0 end - ) as pull_requests_merged_6_months - from {{ ref('int_events_daily_to_project') }} - where - event_source = 'GITHUB' - and event_type in ( - 'COMMIT_CODE', - 'ISSUE_OPENED', - 'ISSUE_CLOSED', - 'PULL_REQUEST_OPENED', - 'PULL_REQUEST_MERGED' - ) - and DATE_DIFF(CURRENT_DATE(), DATE(bucket_day), month) <= 6 + ) as fulltime_developer_avg_6_months + from metrics + group by project_id +), + +repos as ( + select + project_id, + MIN(first_commit_time) as first_commit_date, + MAX(last_commit_time) as last_commit_date, + COUNT(distinct artifact_id) as repository_count, + SUM(star_count) as star_count, + SUM(fork_count) as fork_count + from {{ ref('int_repo_metrics_by_project') }} + --WHERE r.is_fork = false group by project_id ) select - p.project_id, - p.project_source, - p.project_namespace, - p.project_name, - p.first_commit_date, - p.last_commit_date, - p.repositories, - p.stars, - p.forks, - c.contributors, - c.contributors_6_months, - c.new_contributors_6_months, - c.avg_fulltime_devs_6_months, - c.avg_active_devs_6_months, - a.commits_6_months, - a.issues_opened_6_months, - a.issues_closed_6_months, - a.pull_requests_opened_6_months, - a.pull_requests_merged_6_months -from project_repos_summary as p -left join contribs_cte as c - on p.project_id = c.project_id -left join activity_cte as a - on p.project_id = a.project_id + int_projects.project_id, + int_projects.project_source, + int_projects.project_namespace, + int_projects.project_name, + int_projects.display_name, + repos.first_commit_date, + repos.last_commit_date, + repos.repository_count, + repos.star_count, + repos.fork_count, + aggs.contributor_count, + aggs.contributor_count_6_months, + aggs.new_contributor_count_6_months, + aggs.fulltime_developer_avg_6_months, + aggs.active_developer_count_6_months, + aggs.commit_count_6_months, + aggs.opened_pull_request_count_6_months, + aggs.merged_pull_request_count_6_months, + aggs.opened_issue_count_6_months, + aggs.closed_issue_count_6_months, + 'GITHUB' as repository_source +from {{ ref('int_projects') }} +left join aggs + on int_projects.project_id = aggs.project_id +left join repos + on int_projects.project_id = repos.project_id diff --git a/warehouse/dbt/models/intermediate/metrics/int_onchain_metrics_by_project.sql b/warehouse/dbt/models/intermediate/metrics/int_onchain_metrics_by_project.sql index 51ed4b232..3488e3a73 100644 --- a/warehouse/dbt/models/intermediate/metrics/int_onchain_metrics_by_project.sql +++ b/warehouse/dbt/models/intermediate/metrics/int_onchain_metrics_by_project.sql @@ -4,141 +4,175 @@ }) }} -with txns as ( - select - project_id, - event_source, - SUM(case - when - event_type = 'CONTRACT_INVOCATION_DAILY_COUNT' - then amount - end) as total_txns, - SUM(case - when - event_type = 'CONTRACT_INVOCATION_DAILY_L2_GAS_USED' - then amount - end) as total_l2_gas, - SUM(case - when - event_type = 'CONTRACT_INVOCATION_DAILY_COUNT' - and DATE_DIFF(CURRENT_DATE(), DATE(bucket_day), month) <= 6 - then amount - end) as txns_6_months, - SUM(case - when - event_type = 'CONTRACT_INVOCATION_DAILY_L2_GAS_USED' - and DATE_DIFF(CURRENT_DATE(), DATE(bucket_day), month) <= 6 - then amount - end) as l2_gas_6_months - from {{ ref('int_events_daily_to_project') }} - group by - project_id, - event_source -), - -addresses as ( - select - project_id, - event_source, - SUM(case - when - impact_metric = 'NEW_ADDRESSES' - and time_interval = 'ALL' - then amount - end) as total_addresses, - SUM(case - when - impact_metric = 'NEW_ADDRESSES' - and time_interval = '3M' - then amount - end) as new_addresses, - SUM(case - when - impact_metric = 'RETURNING_ADDRESSES' - and time_interval = '3M' - then amount - end) as returning_addresses, - SUM(case - when - impact_metric = 'LOW_ACTIVITY_ADDRESSES' - and time_interval = '3M' - then amount - end) as low_activity_addresses, - SUM(case - when - impact_metric = 'MED_ACTIVITY_ADDRESSES' - and time_interval = '3M' - then amount - end) as med_activity_addresses, - SUM(case - when - impact_metric = 'HIGH_ACTIVITY_ADDRESSES' - and time_interval = '3M' - then amount - end) as high_activity_addresses - from {{ ref('int_address_totals_by_project') }} - group by - project_id, - event_source +with metrics as ( + select * from {{ ref('int_onchain_metric__active_addresses') }} + union all + select * from {{ ref('int_onchain_metric__active_contracts') }} + union all + select * from {{ ref('int_onchain_metric__gas_fees') }} + union all + select * + from {{ ref('int_onchain_metric__days_since_first_transaction') }} + union all + select * + from {{ ref('int_onchain_metric__high_low_activity_addresses') }} + union all + select * + from {{ ref('int_onchain_metric__multi_project_addresses') }} + union all + select * + from {{ ref('int_onchain_metric__new_addresses') }} + union all + select * + from {{ ref('int_onchain_metric__returning_addresses') }} + union all + select * from {{ ref('int_onchain_metric__transactions') }} ), -first_txn as ( +aggs as ( select project_id, - event_source, - MIN(bucket_day) as date_first_txn - from {{ ref('int_addresses_daily_activity') }} + network, + SUM( + case + when + metric = 'days_since_first_transaction' + and time_interval = 'ALL' + then amount + else 0 + end + ) as days_since_first_transaction, + SUM( + case + when + metric = 'active_contract_count' + and time_interval = '90 DAYS' + then amount + else 0 + end + ) as active_contract_count_90_days, + SUM( + case + when + metric = 'transaction_count' + and time_interval = 'ALL' + then amount + else 0 + end + ) as transaction_count, + SUM( + case + when + metric = 'transaction_count' + and time_interval = '6 MONTHS' + then amount + else 0 + end + ) as transaction_count_6_months, + SUM( + case + when + metric = 'gas_fees' + and time_interval = 'ALL' + then amount + else 0 + end + ) as gas_fees_sum, + SUM( + case + when + metric = 'gas_fees' + and time_interval = '6 MONTHS' + then amount + else 0 + end + ) as gas_fees_sum_6_months, + SUM( + case + when + metric = 'address_count' + and time_interval = 'ALL' + then amount + else 0 + end + ) as address_count, + SUM( + case + when + metric = 'address_count' + and time_interval = '90 DAYS' + then amount + else 0 + end + ) as address_count_90_days, + SUM( + case + when + metric = 'new_address_count' + and time_interval = '90 DAYS' + then amount + else 0 + end + ) as new_address_count_90_days, + SUM( + case + when + metric = 'returning_address_count' + and time_interval = '90 DAYS' + then amount + else 0 + end + ) as returning_address_count_90_days, + SUM( + case + when + metric = 'high_activity_address_count' + and time_interval = '90 DAYS' + then amount + else 0 + end + ) as high_activity_address_count_90_days, + SUM( + case + when + metric = 'medium_activity_address_count' + and time_interval = '90 DAYS' + then amount + else 0 + end + ) as medium_activity_address_count_90_days, + SUM( + case + when + metric = 'low_activity_address_count' + and time_interval = '90 DAYS' + then amount + else 0 + end + ) as low_activity_address_count_90_days, + SUM( + case + when + metric = 'multi_project_address_count' + and time_interval = '90 DAYS' + then amount + else 0 + end + ) as multi_project_address_count_90_days + from metrics group by project_id, - event_source -), - -contracts as ( - select - project_id, - artifact_namespace as event_source, - COUNT(distinct artifact_name) as num_contracts - from {{ ref('artifacts_by_project_v1') }} - where artifact_type in ('CONTRACT', 'FACTORY') - group by - project_id, - artifact_namespace -), - -metrics as ( - select - c.*, - f.* except (project_id, event_source), - t.* except (project_id, event_source), - a.* except (project_id, event_source) - from - contracts as c - inner join - txns as t - on - c.project_id = t.project_id - and c.event_source = t.event_source - left join - first_txn as f - on - t.project_id = f.project_id - and t.event_source = f.event_source - left join - addresses as a - on - t.project_id = a.project_id - and t.event_source = a.event_source + network ) select - metrics.*, - p.project_source, - p.project_namespace, - p.project_name, - p.display_name + aggs.* except (project_id), + int_projects.project_source, + int_projects.project_namespace, + int_projects.project_name, + int_projects.display_name, + int_projects.project_id from - {{ ref('projects_v1') }} as p -left join - metrics on p.project_id = metrics.project_id -where - metrics.total_txns is not null + {{ ref('int_projects') }} +left join aggs + on int_projects.project_id = aggs.project_id diff --git a/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__active_addresses.sql b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__active_addresses.sql new file mode 100644 index 000000000..d7348c244 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__active_addresses.sql @@ -0,0 +1,15 @@ +select + events.project_id, + events.event_source as network, + time_intervals.time_interval, + 'address_count' as metric, + COUNT(distinct events.from_artifact_id) as amount +from {{ ref('int_events_daily_to_project') }} as events +cross join {{ ref('int_time_intervals') }} as time_intervals +where + events.event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' + and events.bucket_day >= time_intervals.start_date +group by + events.project_id, + events.event_source, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__active_contracts.sql b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__active_contracts.sql new file mode 100644 index 000000000..727b7b7f4 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__active_contracts.sql @@ -0,0 +1,15 @@ +select + events.project_id, + events.event_source as network, + time_intervals.time_interval, + 'active_contract_count' as metric, + COUNT(distinct events.to_artifact_id) as amount +from {{ ref('int_events_daily_to_project') }} as events +cross join {{ ref('int_time_intervals') }} as time_intervals +where + events.event_type = 'CONTRACT_INVOCATION_DAILY_COUNT' + and events.bucket_day >= time_intervals.start_date +group by + events.project_id, + events.event_source, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__days_since_first_transaction.sql b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__days_since_first_transaction.sql new file mode 100644 index 000000000..fe51b41c4 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__days_since_first_transaction.sql @@ -0,0 +1,21 @@ +select + events.project_id, + events.event_source as network, + time_intervals.time_interval, + 'days_since_first_transaction' as metric, + MAX( + DATE_DIFF( + CURRENT_DATE(), + DATE(events.bucket_day), + day + ) + ) as amount +from {{ ref('int_events_daily_to_project') }} as events +cross join {{ ref('int_time_intervals') }} as time_intervals +where + events.event_type = 'CONTRACT_INVOCATION_DAILY_COUNT' + and events.bucket_day >= time_intervals.start_date +group by + events.project_id, + events.event_source, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__gas_fees.sql b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__gas_fees.sql new file mode 100644 index 000000000..df222bdda --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__gas_fees.sql @@ -0,0 +1,15 @@ +select + events.project_id, + events.event_source as network, + time_intervals.time_interval, + 'gas_fees' as metric, + SUM(events.amount / 1e18) as amount +from {{ ref('int_events_daily_to_project') }} as events +cross join {{ ref('int_time_intervals') }} as time_intervals +where + events.event_type = 'CONTRACT_INVOCATION_DAILY_L2_GAS_USED' + and events.bucket_day >= time_intervals.start_date +group by + events.project_id, + events.event_source, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__high_low_activity_addresses.sql b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__high_low_activity_addresses.sql new file mode 100644 index 000000000..a5491ca09 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__high_low_activity_addresses.sql @@ -0,0 +1,77 @@ +{% set high_activity_thresh = 100 %} +{% set med_activity_thresh = 10 %} +{% set low_activity_thresh = 1 %} + +with user_txn_totals as ( + select + events.from_artifact_id, + events.event_source as network, + events.project_id, + time_intervals.time_interval, + SUM(events.amount) as amount + from {{ ref('int_events_daily_to_project') }} as events + cross join {{ ref('int_time_intervals') }} as time_intervals + where + events.event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' + and events.bucket_day >= time_intervals.start_date + group by + events.from_artifact_id, + events.event_source, + events.project_id, + time_intervals.time_interval +), + +high_activity as ( + select + project_id, + network, + time_interval, + 'high_activity_address_count' as metric, + COUNT(distinct from_artifact_id) as amount + from user_txn_totals + where amount >= {{ high_activity_thresh }} + group by + project_id, + network, + time_interval +), + +low_activity as ( + select + project_id, + network, + time_interval, + 'low_activity_address_count' as metric, + COUNT(distinct from_artifact_id) as amount + from user_txn_totals + where + amount < {{ med_activity_thresh }} + and amount >= {{ low_activity_thresh }} + group by + project_id, + network, + time_interval +), + +medium_activity as ( + select + project_id, + network, + time_interval, + 'medium_activity_address_count' as metric, + COUNT(distinct from_artifact_id) as amount + from user_txn_totals + where + amount < {{ high_activity_thresh }} + and amount >= {{ med_activity_thresh }} + group by + project_id, + network, + time_interval +) + +select * from high_activity +union all +select * from low_activity +union all +select * from medium_activity diff --git a/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__multi_project_addresses.sql b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__multi_project_addresses.sql new file mode 100644 index 000000000..12adc43d2 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__multi_project_addresses.sql @@ -0,0 +1,38 @@ +with user_stats as ( + select + events.from_artifact_id, + events.event_source as network, + time_intervals.time_interval, + COUNT(distinct events.project_id) as project_count + from {{ ref('int_events_daily_to_project') }} as events + cross join {{ ref('int_time_intervals') }} as time_intervals + where + events.event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' + and events.bucket_day >= time_intervals.start_date + group by + events.from_artifact_id, + events.event_source, + time_intervals.time_interval +) + +select + events.project_id, + events.event_source as network, + time_intervals.time_interval, + 'multi_project_address_count' as metric, + COUNT(distinct events.from_artifact_id) as amount +from {{ ref('int_events_daily_to_project') }} as events +cross join {{ ref('int_time_intervals') }} as time_intervals +left join user_stats + on + events.from_artifact_id = user_stats.from_artifact_id + and events.event_source = user_stats.network + and time_intervals.time_interval = user_stats.time_interval +where + events.event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' + and events.bucket_day >= time_intervals.start_date + and user_stats.project_count > 2 +group by + events.project_id, + events.event_source, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__new_addresses.sql b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__new_addresses.sql new file mode 100644 index 000000000..dd459768e --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__new_addresses.sql @@ -0,0 +1,41 @@ +with user_stats as ( + select + from_artifact_id, + event_source as network, + project_id, + min(bucket_day) as first_day + from {{ ref('int_events_daily_to_project') }} + where + event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' + group by + from_artifact_id, + event_source, + project_id +) + +select + events.project_id, + events.event_source as network, + time_intervals.time_interval, + 'new_address_count' as metric, + count( + distinct + case + when user_stats.first_day >= time_intervals.start_date + then events.from_artifact_id + end + ) as amount +from {{ ref('int_events_daily_to_project') }} as events +inner join user_stats + on + events.from_artifact_id = user_stats.from_artifact_id + and events.event_source = user_stats.network + and events.project_id = user_stats.project_id +cross join {{ ref('int_time_intervals') }} as time_intervals +where + events.event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' + and events.bucket_day >= time_intervals.start_date +group by + events.project_id, + events.event_source, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__returning_addresses.sql b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__returning_addresses.sql new file mode 100644 index 000000000..e89d8977c --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__returning_addresses.sql @@ -0,0 +1,41 @@ +with user_stats as ( + select + from_artifact_id, + event_source as network, + project_id, + min(bucket_day) as first_day + from {{ ref('int_events_daily_to_project') }} + where + event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' + group by + from_artifact_id, + event_source, + project_id +) + +select + events.project_id, + events.event_source as network, + time_intervals.time_interval, + 'returning_address_count' as metric, + count( + distinct + case + when user_stats.first_day < time_intervals.start_date + then events.from_artifact_id + end + ) as amount +from {{ ref('int_events_daily_to_project') }} as events +inner join user_stats + on + events.from_artifact_id = user_stats.from_artifact_id + and events.event_source = user_stats.network + and events.project_id = user_stats.project_id +cross join {{ ref('int_time_intervals') }} as time_intervals +where + events.event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' + and events.bucket_day >= time_intervals.start_date +group by + events.project_id, + events.event_source, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__transactions.sql b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__transactions.sql new file mode 100644 index 000000000..6f8bd5fd7 --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__transactions.sql @@ -0,0 +1,15 @@ +select + events.project_id, + events.event_source as network, + time_intervals.time_interval, + 'transaction_count' as metric, + SUM(events.amount) as amount +from {{ ref('int_events_daily_to_project') }} as events +cross join {{ ref('int_time_intervals') }} as time_intervals +where + events.event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' + and events.bucket_day >= time_intervals.start_date +group by + events.project_id, + events.event_source, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__trusted_transactions.sql b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__trusted_transactions.sql new file mode 100644 index 000000000..e17e6711f --- /dev/null +++ b/warehouse/dbt/models/intermediate/metrics/onchain/int_onchain_metric__trusted_transactions.sql @@ -0,0 +1,18 @@ +select + events.project_id, + events.event_source as network, + time_intervals.time_interval, + 'transaction_count' as metric, + SUM(events.amount) as amount +from {{ ref('int_events_daily_to_project') }} as events +cross join {{ ref('int_time_intervals') }} as time_intervals +inner join {{ ref('int_artifacts_by_user') }} as artifacts_by_user + on events.from_artifact_id = artifacts_by_user.artifact_id +where + events.event_type = 'CONTRACT_INVOCATION_SUCCESS_DAILY_COUNT' + and events.bucket_day >= time_intervals.start_date + and artifacts_by_user.user_id is not null +group by + events.project_id, + events.event_source, + time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_busfactor_by_project.sql b/warehouse/dbt/models/intermediate/metrics/pms/int_pm_busfactor_by_project.sql deleted file mode 100644 index 8e4e95310..000000000 --- a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_busfactor_by_project.sql +++ /dev/null @@ -1,134 +0,0 @@ -{# - - This model calculates the bus factor for each project in the database. The bus factor is a metric that - measures the number of contributors that are responsible for at least 50% of the contributions to a project - over a given time period. - - The `contributions` CTE calculates the total amount of contributions for each contributor to each project. - The `project_periods` CTE calculates the start and end month for each project. - The `aggregated_contributions` CTE calculates the total amount of contributions for each contributor to each project - for different time periods (90 days, 6 months, 1 year, and all time). - The `ranked_contributions` CTE calculates the rank of each contributor for each project and time period, as well as the - total amount of contributions for each project and time period. The final select statement calculates the bus factor - for each project and time period by selecting the maximum rank of contributors whose cumulative contributions are - greater than or equal to 50% of the total contributions to the project. - - More information on the bus factor can be found here: https://chaoss.community/kb/metric-bus-factor/ - -#} - -with all_contributions as ( - select - project_id, - from_artifact_id, - SUM(amount) as total_amount, - DATE_TRUNC(DATE(time), month) as contribution_month - from {{ ref('int_events_to_project') }} - where event_type = 'COMMIT_CODE' -- CONTRIBUTION FILTER - group by - project_id, - from_artifact_id, - DATE_TRUNC(DATE(time), month) -), - -contributions as ( - select * - from all_contributions - where total_amount < 1000 -- BOT FILTER -), - -project_periods as ( - select - project_id, - MIN(contribution_month) as start_month, - MAX(contribution_month) as end_month - from contributions - group by project_id -), - -aggregated_contributions as ( - select - c.project_id, - c.from_artifact_id, - SUM(c.total_amount) as total_amount, - '90D' as period - from contributions as c - inner join project_periods as p on c.project_id = p.project_id - where c.contribution_month > DATE_SUB(p.end_month, interval 3 month) - group by - c.project_id, - c.from_artifact_id - union all - select - c.project_id, - c.from_artifact_id, - SUM(c.total_amount) as total_amount, - '6M' as period - from contributions as c - inner join project_periods as p on c.project_id = p.project_id - where c.contribution_month > DATE_SUB(p.end_month, interval 6 month) - group by - c.project_id, - c.from_artifact_id - union all - select - c.project_id, - c.from_artifact_id, - SUM(c.total_amount) as total_amount, - '1Y' as period - from contributions as c - inner join project_periods as p on c.project_id = p.project_id - where c.contribution_month > DATE_SUB(p.end_month, interval 12 month) - group by - c.project_id, - c.from_artifact_id - union all - select - c.project_id, - c.from_artifact_id, - SUM(c.total_amount) as total_amount, - 'ALL' as period - from contributions as c - group by - c.project_id, - c.from_artifact_id -), - -ranked_contributions as ( - select - project_id, - period, - from_artifact_id, - total_amount, - RANK() - over ( - partition by project_id, period order by total_amount desc - ) as rank, - SUM(total_amount) - over ( - partition by project_id, period - ) as total_project_amount, - SUM(total_amount) - over ( - partition by project_id, period - order by total_amount desc - rows between unbounded preceding and current row - ) as cumulative_amount - from aggregated_contributions -) - -select - project_id, - CONCAT('BUSFACTOR_', period) as impact_metric, - MAX( - case - when cumulative_amount <= total_project_amount * 0.5 - then rank - else 1 - end - ) as amount -from - ranked_contributions -group by - project_id, - period diff --git a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_contracts_deployed.sql b/warehouse/dbt/models/intermediate/metrics/pms/int_pm_contracts_deployed.sql deleted file mode 100644 index 67d314200..000000000 --- a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_contracts_deployed.sql +++ /dev/null @@ -1,35 +0,0 @@ -{# - WIP: Still in Development - Count the number of contracts deployed by a project - that have more than 100 users -#} - -{% set min_trusted_users = 100 %} - -with users_by_contract as ( - select - to_artifact_id as artifact_id, - COUNT(distinct from_artifact_id) as num_users - from {{ ref('int_events_with_artifact_id') }} - where - from_artifact_id in ( - select user_id - from {{ ref('int_users') }} - ) - and event_type = 'CONTRACT_INVOCATION_DAILY_COUNT' - group by 1 -), - -valid_contracts as ( - select artifact_id - from users_by_contract - where num_users >= {{ min_trusted_users }} -) - -select - a.project_id, - COUNT(distinct a.artifact_id) as amount -from valid_contracts as v -left join {{ ref('artifacts_by_project_v1') }} as a - on v.artifact_id = a.artifact_id -group by 1 diff --git a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_contributors.sql b/warehouse/dbt/models/intermediate/metrics/pms/int_pm_contributors.sql deleted file mode 100644 index 2f73b2e52..000000000 --- a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_contributors.sql +++ /dev/null @@ -1,14 +0,0 @@ -{# - Contributors to a project in a time interval -#} - -select - int_contributors_to_project.project_id, - int_time_intervals.time_interval, - CONCAT('CONTRIBUTORS_TOTAL') as impact_metric, - COUNT(distinct int_contributors_to_project.artifact_id) as amount -from {{ ref('int_contributors_to_project') }} -cross join {{ ref('int_time_intervals') }} -group by - int_contributors_to_project.project_id, - int_time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_dev_months.sql b/warehouse/dbt/models/intermediate/metrics/pms/int_pm_dev_months.sql deleted file mode 100644 index 71e5a74ff..000000000 --- a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_dev_months.sql +++ /dev/null @@ -1,23 +0,0 @@ -{# - This model calculates the total man-months of developer activity - for each project in various time ranges. - - The model uses the int_active_devs_monthly_to_project model to segment - developers based on monthly activity using the Electric Capital - Developer Report taxonomy. -#} - -select - e.project_id, - t.time_interval, - CONCAT(e.user_segment_type, '_TOTAL') as impact_metric, - COUNT(distinct e.from_artifact_id) as amount -from {{ ref('int_developer_status_monthly_by_project') }} as e -cross join {{ ref('int_time_intervals') }} as t -where - DATE(e.bucket_month) >= DATE_TRUNC(t.start_date, month) - and DATE(e.bucket_month) < DATE_TRUNC(CURRENT_DATE(), month) -group by - e.project_id, - t.time_interval, - e.user_segment_type diff --git a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_new_contribs.sql b/warehouse/dbt/models/intermediate/metrics/pms/int_pm_new_contribs.sql deleted file mode 100644 index 0178859b6..000000000 --- a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_new_contribs.sql +++ /dev/null @@ -1,30 +0,0 @@ -{# - New contributors to a project in a given time interval -#} - -with contributors as ( - select - project_id, - artifact_id, - MIN(first_contribution_time) as first_contribution_time - from {{ ref('int_contributors_to_project') }} - group by - project_id, - artifact_id -) - -select - contributors.project_id, - int_time_intervals.time_interval, - 'NEW_CONTRIBUTORS_TOTAL' as impact_metric, - COUNT(distinct case - when - DATE(contributors.first_contribution_time) - >= DATE_TRUNC(int_time_intervals.start_date, month) - then contributors.artifact_id - end) as amount -from contributors -cross join {{ ref('int_time_intervals') }} -group by - contributors.project_id, - int_time_intervals.time_interval diff --git a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_trusted_transactions.sql b/warehouse/dbt/models/intermediate/metrics/pms/int_pm_trusted_transactions.sql deleted file mode 100644 index 629b586f9..000000000 --- a/warehouse/dbt/models/intermediate/metrics/pms/int_pm_trusted_transactions.sql +++ /dev/null @@ -1,22 +0,0 @@ -{# - WIP: Still in Development - Count the number of transaction from trusted users -#} - -select - e.project_id, - t.time_interval, - 'TRUSTED_TRANSACTIONS_TOTAL' as impact_metric, - SUM(e.amount) as amount -from {{ ref('int_events_to_project') }} as e -cross join {{ ref('int_time_intervals') }} as t -where - DATE(e.time) >= t.start_date - and e.from_artifact_id in ( - select user_id - from {{ ref('int_users') }} - ) - and e.event_type = 'CONTRACT_INVOCATION_DAILY_COUNT' -group by - e.project_id, - t.time_interval diff --git a/warehouse/dbt/models/intermediate/users/int_active_devs_monthly_to_collection.sql b/warehouse/dbt/models/intermediate/users/int_active_devs_monthly_to_collection.sql deleted file mode 100644 index 3704a2db9..000000000 --- a/warehouse/dbt/models/intermediate/users/int_active_devs_monthly_to_collection.sql +++ /dev/null @@ -1,35 +0,0 @@ -{# - This model segments developers based on monthly activity - using the same taxonomy as in the Electric Capital - Developer Report by collection. - - The taxonomy is as follows: - - Full-time developer: A developer who has made at least 10 commits - - Part-time developer: A developer who has made less than 10 commits - - Other contributor: A user who has not made any commits -#} - -select - collection_id, - from_artifact_id, - event_source, - bucket_month, - 1 as amount, - case - when - event_type = 'COMMIT_CODE' and count_days >= 10 - then 'FULL_TIME_DEV' - when - event_type = 'COMMIT_CODE' and count_days < 10 - then 'PART_TIME_DEV' - else 'OTHER_CONTRIBUTOR' - end as user_segment_type -from {{ ref('int_user_events_monthly_to_collection') }} -where - event_type in ( - 'COMMIT_CODE', - 'PULL_REQUEST_OPENED', - 'PULL_REQUEST_MERGED', - 'ISSUE_OPENED', - 'ISSUE_CLOSED' - ) diff --git a/warehouse/dbt/models/intermediate/users/int_address_totals_by_project.sql b/warehouse/dbt/models/intermediate/users/int_address_totals_by_project.sql index 69bb25840..eb1bf2c2f 100644 --- a/warehouse/dbt/models/intermediate/users/int_address_totals_by_project.sql +++ b/warehouse/dbt/models/intermediate/users/int_address_totals_by_project.sql @@ -19,7 +19,7 @@ with user_data as ( int_addresses_daily_activity.amount, int_time_intervals.time_interval, int_time_intervals.start_date, - DATE(int_addresses_daily_activity.bucket_day) as bucket_day + int_addresses_daily_activity.bucket_day from {{ ref('int_addresses_daily_activity') }} left join {{ ref('int_addresses_to_project') }} on diff --git a/warehouse/dbt/models/intermediate/users/int_user_events_daily_to_collection.sql b/warehouse/dbt/models/intermediate/users/int_user_events_daily_to_collection.sql deleted file mode 100644 index f4da7abab..000000000 --- a/warehouse/dbt/models/intermediate/users/int_user_events_daily_to_collection.sql +++ /dev/null @@ -1,32 +0,0 @@ -{# - This model aggregates user events to collection level on - a daily basis. It is used to calculate various - user engagement metrics by project. -#} - -select - from_artifact_id, - event_source, - collection_id, - event_type, - TIMESTAMP_TRUNC(time, day) as bucket_day, - SUM(amount) as amount -from {{ ref('int_events_to_collection') }} -where - event_type in ( - 'COMMIT_CODE', - 'PULL_REQUEST_OPENED', - 'PULL_REQUEST_REOPENED', - 'PULL_REQUEST_CLOSED', - 'PULL_REQUEST_MERGED', - 'ISSUE_CLOSED', - 'ISSUE_OPENED', - 'ISSUE_REOPENED', - 'CONTRACT_INVOCATION_DAILY_COUNT' - ) -group by - from_artifact_id, - event_source, - collection_id, - event_type, - TIMESTAMP_TRUNC(time, day) diff --git a/warehouse/dbt/models/intermediate/users/int_user_events_daily_to_project.sql b/warehouse/dbt/models/intermediate/users/int_user_events_daily_to_project.sql deleted file mode 100644 index 2ade1f736..000000000 --- a/warehouse/dbt/models/intermediate/users/int_user_events_daily_to_project.sql +++ /dev/null @@ -1,32 +0,0 @@ -{# - This model aggregates user events to project level on - a daily basis. It is used to calculate various - user engagement metrics by project. -#} - -select - from_artifact_id, - event_source, - project_id, - event_type, - TIMESTAMP_TRUNC(time, day) as bucket_day, - SUM(amount) as amount -from {{ ref('int_events_to_project') }} -where - event_type in ( - 'COMMIT_CODE', - 'PULL_REQUEST_OPENED', - 'PULL_REQUEST_REOPENED', - 'PULL_REQUEST_CLOSED', - 'PULL_REQUEST_MERGED', - 'ISSUE_CLOSED', - 'ISSUE_OPENED', - 'ISSUE_REOPENED', - 'CONTRACT_INVOCATION_DAILY_COUNT' - ) -group by - from_artifact_id, - event_source, - project_id, - event_type, - TIMESTAMP_TRUNC(time, day) diff --git a/warehouse/dbt/models/intermediate/users/int_user_events_monthly_to_collection.sql b/warehouse/dbt/models/intermediate/users/int_user_events_monthly_to_collection.sql deleted file mode 100644 index b424eb8da..000000000 --- a/warehouse/dbt/models/intermediate/users/int_user_events_monthly_to_collection.sql +++ /dev/null @@ -1,21 +0,0 @@ -{# - This model aggregates user events to collections on - a monthly basis. It is used to calculate various - user engagement metrics. -#} - -select - from_artifact_id, - event_source, - collection_id, - event_type, - TIMESTAMP_TRUNC(bucket_day, month) as bucket_month, - COUNT(distinct bucket_day) as count_days, - SUM(amount) as total_amount -from {{ ref('int_user_events_daily_to_collection') }} -group by - from_artifact_id, - event_source, - collection_id, - event_type, - TIMESTAMP_TRUNC(bucket_day, month) diff --git a/warehouse/dbt/models/intermediate/users/int_user_events_monthly_to_project.sql b/warehouse/dbt/models/intermediate/users/int_user_events_monthly_to_project.sql deleted file mode 100644 index 44ac55f1b..000000000 --- a/warehouse/dbt/models/intermediate/users/int_user_events_monthly_to_project.sql +++ /dev/null @@ -1,21 +0,0 @@ -{# - This model aggregates user events to project level on - a monthly basis. It is used to calculate various - user engagement metrics by project. -#} - -select - from_artifact_id, - event_source, - project_id, - event_type, - TIMESTAMP_TRUNC(bucket_day, month) as bucket_month, - COUNT(distinct bucket_day) as count_days, - SUM(amount) as total_amount -from {{ ref('int_user_events_daily_to_project') }} -group by - from_artifact_id, - event_source, - project_id, - event_type, - TIMESTAMP_TRUNC(bucket_day, month) diff --git a/warehouse/dbt/models/intermediate/users/int_user_events_to_project_by_time_interval.sql b/warehouse/dbt/models/intermediate/users/int_user_events_to_project_by_time_interval.sql deleted file mode 100644 index 4f7555f42..000000000 --- a/warehouse/dbt/models/intermediate/users/int_user_events_to_project_by_time_interval.sql +++ /dev/null @@ -1,23 +0,0 @@ -{# - This model aggregates user events to project level by time interval. - It is used to calculate various user engagement metrics by project. -#} - -select - int_user_events_daily_to_project.from_artifact_id, - int_user_events_daily_to_project.event_source, - int_user_events_daily_to_project.project_id, - int_time_intervals.time_interval, - int_user_events_daily_to_project.event_type, - SUM(int_user_events_daily_to_project.amount) as amount -from {{ ref('int_user_events_daily_to_project') }} -cross join {{ ref('int_time_intervals') }} -where - DATE(int_user_events_daily_to_project.bucket_day) - >= int_time_intervals.start_date -group by - int_user_events_daily_to_project.from_artifact_id, - int_user_events_daily_to_project.project_id, - int_user_events_daily_to_project.event_source, - int_time_intervals.time_interval, - int_user_events_daily_to_project.event_type diff --git a/warehouse/dbt/models/intermediate/users/int_users_monthly_to_project.sql b/warehouse/dbt/models/intermediate/users/int_users_monthly_to_project.sql deleted file mode 100644 index 82cf2c31a..000000000 --- a/warehouse/dbt/models/intermediate/users/int_users_monthly_to_project.sql +++ /dev/null @@ -1,36 +0,0 @@ -{{ - config(meta = { - 'sync_to_db': True - }) -}} - -with users as ( - select - project_id, - event_source, - event_type, - bucket_month, - COUNT(distinct from_artifact_id) as amount - from {{ ref('int_user_events_monthly_to_project') }} - group by - project_id, - event_source, - event_type, - bucket_month -) - -select - project_id, - 'Developers' as user_segment_type, - bucket_month, - amount -from users -where event_type = 'COMMIT_CODE' -union all -select - project_id, - 'Active Addresses' as user_segment_type, - bucket_month, - amount -from users -where event_type = 'CONTRACT_INVOCATION_DAILY_COUNT' diff --git a/warehouse/dbt/models/marts/metrics/code_metrics_by_project_v1.sql b/warehouse/dbt/models/marts/metrics/code_metrics_by_project_v1.sql index a8fed6bdc..b572bd785 100644 --- a/warehouse/dbt/models/marts/metrics/code_metrics_by_project_v1.sql +++ b/warehouse/dbt/models/marts/metrics/code_metrics_by_project_v1.sql @@ -1,22 +1,3 @@ -{# - TODO: this should go into a yml file for doc generation - Summary GitHub metrics for a project: - - first_commit_date: The date of the first commit to the project - - last_commit_date: The date of the last commit to the project - - repos: The number of repositories in the project - - stars: The number of stars the project has - - forks: The number of forks the project has - - contributors: The number of contributors to the project - - contributors_6_months: The number of contributors to the project in the last 6 months - - new_contributors_6_months: The number of new contributors to the project in the last 6 months - - avg_fulltime_devs_6_months: The number of full-time developers in the last 6 months - - avg_active_devs_6_months: The average number of active developers in the last 6 months - - commits_6_months: The number of commits to the project in the last 6 months - - issues_opened_6_months: The number of issues opened in the project in the last 6 months - - issues_closed_6_months: The number of issues closed in the project in the last 6 months - - pull_requests_opened_6_months: The number of pull requests opened in the project in the last 6 months - - pull_requests_merged_6_months: The number of pull requests merged in the project in the last 6 months -#} {{ config(meta = { 'sync_to_db': True @@ -28,19 +9,21 @@ select project_source, project_namespace, project_name, + display_name, + repository_source, + repository_count, first_commit_date, last_commit_date, - repositories as `repository_count_all`, - stars as `star_count_all`, - forks as `fork_count_all`, - contributors as `contributor_count_all`, - contributors_6_months as `contributor_count_6_months`, - new_contributors_6_months as `new_contributor_count_6_months`, - avg_fulltime_devs_6_months as `fulltime_developer_count_6_months`, - avg_active_devs_6_months as `active_developer_count_6_month`, - commits_6_months as `commit_count_6_months`, - issues_opened_6_months as `opened_issue_count_6m`, - issues_closed_6_months as `closed_issue_count_6m`, - pull_requests_opened_6_months as `opened_pull_request_count_6m`, - pull_requests_merged_6_months as `merged_pull_request_count_6m` + star_count, + fork_count, + contributor_count, + contributor_count_6_months, + new_contributor_count_6_months, + fulltime_developer_avg_6_months, + active_developer_count_6_months, + commit_count_6_months, + opened_pull_request_count_6_months, + merged_pull_request_count_6_months, + opened_issue_count_6_months, + closed_issue_count_6_months from {{ ref('int_code_metrics_by_project') }} diff --git a/warehouse/dbt/models/marts/metrics/onchain_metrics_by_project_v1.sql b/warehouse/dbt/models/marts/metrics/onchain_metrics_by_project_v1.sql index 8e407d58b..23b413dfb 100644 --- a/warehouse/dbt/models/marts/metrics/onchain_metrics_by_project_v1.sql +++ b/warehouse/dbt/models/marts/metrics/onchain_metrics_by_project_v1.sql @@ -1,23 +1,3 @@ -{# - TODO: this should go into a yml file for doc generation - Summary onchain metrics for a project: - - project_id: The unique identifier for the project - - network: The network the project is deployed on - - num_contracts: The number of contracts in the project - - first_txn_date: The date of the first transaction to the project - - total_txns: The total number of transactions to the project - - total_l2_gas: The total L2 gas used by the project - - total_users: The number of unique users interacting with the project - - txns_6_months: The total number of transactions to the project in the last 6 months - - l2_gas_6_months: The total L2 gas used by the project in the last 6 months - - users_6_months: The number of unique users interacting with the project in the last 6 months - - new_users: The number of users interacting with the project for the first time in the last 3 months - - active_users: The number of active users interacting with the project in the last 3 months - - high_frequency_users: The number of users who have made 1000+ transactions with the project in the last 3 months - - more_active_users: The number of users who have made 10-999 transactions with the project in the last 3 months - - less_active_users: The number of users who have made 1-9 transactions with the project in the last 3 months - - multi_project_users: The number of users who have interacted with 3+ projects in the last 3 months -#} {{ config(meta = { 'sync_to_db': True @@ -30,18 +10,19 @@ select project_namespace, project_name, display_name, - event_source, - date_first_txn as `first_transaction_date`, - total_txns as `transaction_count_all`, - txns_6_months as `transaction_count_6_months`, - total_l2_gas as `l2_gas_sum_all`, - l2_gas_6_months as `l2_gas_sum_6_months`, - total_addresses as `address_count_all`, - new_addresses as `new_address_count_3_months`, - returning_addresses as `returning_address_count_3_months`, - high_activity_addresses as `high_activity_address_count_3_months`, - med_activity_addresses as `medium_activity_address_count_3_months`, - low_activity_addresses as `low_activity_address_count_3_months`, - --multi_project_addresses as `multi_project_address_count_3_months`, - (new_addresses + returning_addresses) as `address_count_3_months` + network, + days_since_first_transaction, + active_contract_count_90_days, + transaction_count, + transaction_count_6_months, + gas_fees_sum, + gas_fees_sum_6_months, + address_count, + address_count_90_days, + new_address_count_90_days, + returning_address_count_90_days, + high_activity_address_count_90_days, + medium_activity_address_count_90_days, + low_activity_address_count_90_days, + multi_project_address_count_90_days from {{ ref('int_onchain_metrics_by_project') }} diff --git a/warehouse/dbt/models/marts/superchain/rf4_events_daily_to_project.sql b/warehouse/dbt/models/marts/superchain/rf4_events_daily_to_project.sql index bef42d230..7676c93fc 100644 --- a/warehouse/dbt/models/marts/superchain/rf4_events_daily_to_project.sql +++ b/warehouse/dbt/models/marts/superchain/rf4_events_daily_to_project.sql @@ -50,3 +50,5 @@ left join {{ ref('projects_v1') }} on events.project_id = projects_v1.project_id left join {{ ref('rf4_trusted_users') }} on from_artifacts.artifact_name = rf4_trusted_users.artifact_name +where + to_artifacts.artifact_type = 'CONTRACT'