Skip to content

Commit

Permalink
break metrics into smaller parts and finish refactor of metrics marts (
Browse files Browse the repository at this point in the history
…#1438)

* add: transactions model

* add: gas fees

* fix: cleanup time intervals

* add: address metrics

* add: multiproject addresses

* int onchain metrics model

* refactor onchain_metrics_by_project_v1 mart

* move time intervals and update trusted_transactions metric

* add: code metric commits/prs/issue counts

* add fulltime_developers

* add: code contributor metrics

* refactor: code_metrics_by_project tables

* refactor: pm metrics

* fix projects join

* add: display name and repo source to code metrics

* remove outdated int models from users directory

* fix: ensure rf4 events only consider contract interactions
  • Loading branch information
ccerv1 committed May 20, 2024
1 parent 5560b42 commit f063d16
Show file tree
Hide file tree
Showing 37 changed files with 840 additions and 799 deletions.
30 changes: 30 additions & 0 deletions warehouse/dbt/models/intermediate/analyses/int_time_intervals.sql
Original file line number Diff line number Diff line change
@@ -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
19 changes: 0 additions & 19 deletions warehouse/dbt/models/intermediate/events/int_time_intervals.sql

This file was deleted.

Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
@@ -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
Original file line number Diff line number Diff line change
@@ -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
Loading

0 comments on commit f063d16

Please sign in to comment.