Skip to content

Commit

Permalink
Merge pull request #43 from fivetran/customer/add-repo-cols
Browse files Browse the repository at this point in the history
Customer/add repo cols
  • Loading branch information
fivetran-catfritz authored Feb 2, 2023
2 parents 5ff7c4f + e774c60 commit bf66d97
Show file tree
Hide file tree
Showing 7 changed files with 108 additions and 31 deletions.
9 changes: 9 additions & 0 deletions CHANGELOG.md
Original file line number Diff line number Diff line change
@@ -1,3 +1,12 @@
# dbt_github v0.7.0
## 🚨 Breaking Change 🚨
- Updated the following models to aggregate at the repository grain in addition to their time period grain. ([#42](https://github.com/fivetran/dbt_github/pull/42), [#43](https://github.com/fivetran/dbt_github/pull/43))
- `github__daily_metrics`
- `github__weekly_metrics`
- `github__monthly_metrics`
- `github__quarterly_metrics`
## Contributors 📝
- @onimsha ([#42](https://github.com/fivetran/dbt_github/pull/42))
# dbt_github v0.6.0
[PR #35](https://github.com/fivetran/dbt_github/pull/35) includes the following breaking changes:
## 🚨 Breaking Changes 🚨:
Expand Down
8 changes: 4 additions & 4 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -27,10 +27,10 @@ The following table provides a detailed list of all models materialized within t
| -------------------------- | ------------------------------------------------------------------------------------------------------------------------------------------------------------- |
| [github__issues](https://fivetran.github.io/dbt_github/#!/model/model.github.github__issues) | Each record represents a GitHub issue, enriched with data about its assignees, milestones, and time comparisons. |
| [github__pull_requests](https://fivetran.github.io/dbt_github/#!/model/model.github.github__pull_requests) | Each record represents a GitHub pull request, enriched with data about its repository, reviewers, and durations between review requests, merges and reviews. |
| [github__daily_metrics](https://fivetran.github.io/dbt_github/#!/model/model.github.github__daily_metrics) | Each record represents a single day, enriched with metrics about PRs and issues that were created and closed during that period. |
| [github__weekly_metrics](https://fivetran.github.io/dbt_github/#!/model/model.github.github__weekly_metrics) | Each record represents a single week, enriched with metrics about PRs and issues that were created and closed during that period. |
| [github__monthly_metrics](https://fivetran.github.io/dbt_github/#!/model/model.github.github__monthly_metrics) | Each record represents a single month, enriched with metrics about PRs and issues that were created and closed during that period. |
| [github__quarterly_metrics](https://fivetran.github.io/dbt_github/#!/model/model.github.github__quarterly_metrics) | Each record represents a single quarter, enriched with metrics about PRs and issues that were created and closed during that period. |
| [github__daily_metrics](https://fivetran.github.io/dbt_github/#!/model/model.github.github__daily_metrics) | Each record represents a single day and repository, enriched with metrics about PRs and issues that were created and closed during that period. |
| [github__weekly_metrics](https://fivetran.github.io/dbt_github/#!/model/model.github.github__weekly_metrics) | Each record represents a single week and repository, enriched with metrics about PRs and issues that were created and closed during that period. |
| [github__monthly_metrics](https://fivetran.github.io/dbt_github/#!/model/model.github.github__monthly_metrics) | Each record represents a single month and repository, enriched with metrics about PRs and issues that were created and closed during that period. |
| [github__quarterly_metrics](https://fivetran.github.io/dbt_github/#!/model/model.github.github__quarterly_metrics) | Each record represents a single quarter and repository, enriched with metrics about PRs and issues that were created and closed during that period. |
<!--section-end-->

# 🎯 How do I use the dbt package?
Expand Down
45 changes: 40 additions & 5 deletions models/github.yml
Original file line number Diff line number Diff line change
Expand Up @@ -180,11 +180,15 @@ models:
- name: github__daily_metrics
description: >
Summary numbers for issues and pull requests by day
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- repository
- day
columns:
- name: day
description: The reporting day
tests:
- unique
- not_null
- name: number_issues_opened
description: The total number of issues created during this time period
Expand All @@ -207,6 +211,11 @@ models:
- name: number_prs_closed_without_merge
description: The total number of pull requests closed without a merge during this time period

- name: repository
description: The name of the repository
tests:
- not_null

- name: sum_days_pr_open
description: The total number of days a pull request opened during this time period was open

Expand All @@ -217,11 +226,15 @@ models:
- name: github__weekly_metrics
description: >
Summary numbers for issues and pull requests by week
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- repository
- week
columns:
- name: week
description: The reporting week
tests:
- unique
- not_null
- name: number_issues_opened
description: The total number of issues created during this time period
Expand Down Expand Up @@ -249,15 +262,24 @@ models:

- name: longest_days_pr_open
description: The longest number of days a pull request opened during this time period was open

- name: repository
description: The name of the repository
tests:
- not_null

- name: github__monthly_metrics
description: >
Summary numbers for issues and pull requests by month
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- repository
- month
columns:
- name: month
description: The reporting month
tests:
- unique
- not_null
- name: number_issues_opened
description: The total number of issues created during this time period
Expand Down Expand Up @@ -285,15 +307,24 @@ models:

- name: longest_days_pr_open
description: The longest number of days a pull request opened during this time period was open

- name: repository
description: The name of the repository
tests:
- not_null

- name: github__quarterly_metrics
description: >
Summary numbers for issues and pull requests by quarter
tests:
- dbt_utils.unique_combination_of_columns:
combination_of_columns:
- repository
- quarter
columns:
- name: quarter
description: The reporting quarter
tests:
- unique
- not_null
- name: number_issues_opened
description: The total number of issues created during this time period
Expand Down Expand Up @@ -321,4 +352,8 @@ models:

- name: longest_days_pr_open
description: The longest number of days a pull request opened during this time period was open


- name: repository
description: The name of the repository
tests:
- not_null
66 changes: 48 additions & 18 deletions models/github__daily_metrics.sql
Original file line number Diff line number Diff line change
Expand Up @@ -9,64 +9,80 @@ pull_requests as (
),

issues_opened_per_day as (
select
{{ dbt.date_trunc('day', 'created_at') }} as day,
select
{{ dbt.date_trunc('day', 'created_at') }} as day,
repository as repository,
count(*) as number_issues_opened,
sum(days_issue_open) as sum_days_issue_open,
max(days_issue_open) as longest_days_issue_open
from github_issues
group by 1
group by
1,2
),

issues_closed_per_day as (
select
{{ dbt.date_trunc('day', 'closed_at') }} as day,
select
{{ dbt.date_trunc('day', 'closed_at') }} as day,
repository as repository,
count(*) as number_issues_closed
from github_issues
where closed_at is not null
group by 1
group by
1,2
),

prs_opened_per_day as (
select
{{ dbt.date_trunc('day', 'created_at') }} as day,
select
{{ dbt.date_trunc('day', 'created_at') }} as day,
repository as repository,
count(*) as number_prs_opened,
sum(days_issue_open) as sum_days_pr_open,
max(days_issue_open) as longest_days_pr_open
from pull_requests
group by 1
group by
1,2
),

prs_merged_per_day as (
select
select
{{ dbt.date_trunc('day', 'merged_at') }} as day,
repository as repository,
count(*) as number_prs_merged
from pull_requests
where merged_at is not null
group by 1
group by
1,2
),

prs_closed_without_merge_per_day as (
select
{{ dbt.date_trunc('day', 'closed_at') }} as day,
select
{{ dbt.date_trunc('day', 'closed_at') }} as day,
repository as repository,
count(*) as number_prs_closed_without_merge
from pull_requests
where closed_at is not null
and merged_at is null
group by 1
group by
1,2
),

issues_per_day as (
select
coalesce(issues_opened_per_day.day,
issues_closed_per_day.day
) as day,
coalesce(issues_opened_per_day.repository,
issues_closed_per_day.repository
) as repository,
number_issues_opened,
number_issues_closed,
sum_days_issue_open,
longest_days_issue_open
from issues_opened_per_day
full outer join issues_closed_per_day on issues_opened_per_day.day = issues_closed_per_day.day
full outer join issues_closed_per_day
on
issues_opened_per_day.day = issues_closed_per_day.day
and issues_opened_per_day.repository = issues_closed_per_day.repository
),

prs_per_day as (
Expand All @@ -75,18 +91,29 @@ prs_per_day as (
prs_merged_per_day.day,
prs_closed_without_merge_per_day.day
) as day,
coalesce(prs_opened_per_day.repository,
prs_merged_per_day.repository,
prs_closed_without_merge_per_day.repository
) as repository,
number_prs_opened,
number_prs_merged,
number_prs_closed_without_merge,
sum_days_pr_open,
longest_days_pr_open
from prs_opened_per_day
full outer join prs_merged_per_day on prs_opened_per_day.day = prs_merged_per_day.day
full outer join prs_closed_without_merge_per_day on coalesce(prs_opened_per_day.day, prs_merged_per_day.day) = prs_closed_without_merge_per_day.day
full outer join prs_merged_per_day
on
prs_opened_per_day.day = prs_merged_per_day.day
and prs_opened_per_day.repository = prs_merged_per_day.repository
full outer join prs_closed_without_merge_per_day
on
coalesce(prs_opened_per_day.day, prs_merged_per_day.day) = prs_closed_without_merge_per_day.day
and coalesce(prs_opened_per_day.repository, prs_merged_per_day.repository) = prs_closed_without_merge_per_day.repository
)

select
coalesce(issues_per_day.day, prs_per_day.day) as day,
coalesce(issues_per_day.repository, prs_per_day.repository) as repository,
coalesce(number_issues_opened, 0) as number_issues_opened,
coalesce(number_issues_closed, 0) as number_issues_closed,
sum_days_issue_open,
Expand All @@ -97,5 +124,8 @@ select
sum_days_pr_open,
longest_days_pr_open
from issues_per_day
full outer join prs_per_day on issues_per_day.day = prs_per_day.day
full outer join prs_per_day
on
issues_per_day.day = prs_per_day.day
and issues_per_day.repository = prs_per_day.repository
order by day desc
3 changes: 2 additions & 1 deletion models/github__monthly_metrics.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,7 @@ with daily_metrics as (

select
{{ dbt.date_trunc('month', 'day') }} as month,
repository as repository,
sum(number_issues_opened) as number_issues_opened,
sum(number_issues_closed) as number_issues_closed,
sum(sum_days_issue_open) / sum(number_issues_opened) as avg_days_issue_open,
Expand All @@ -15,5 +16,5 @@ select
sum(sum_days_pr_open) / sum(number_prs_opened) as avg_days_pr_open,
max(longest_days_pr_open) as longest_days_pr_open
from daily_metrics
group by 1
group by 1,2
order by 1 desc
3 changes: 2 additions & 1 deletion models/github__quarterly_metrics.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,7 @@ with daily_metrics as (

select
{{ dbt.date_trunc('quarter', 'day') }} as quarter,
repository as repository,
sum(number_issues_opened) as number_issues_opened,
sum(number_issues_closed) as number_issues_closed,
sum(sum_days_issue_open) / sum(number_issues_opened) as avg_days_issue_open,
Expand All @@ -16,5 +17,5 @@ select
max(longest_days_pr_open) as longest_days_pr_open

from daily_metrics
group by 1
group by 1,2
order by 1 desc
5 changes: 3 additions & 2 deletions models/github__weekly_metrics.sql
Original file line number Diff line number Diff line change
Expand Up @@ -4,7 +4,8 @@ with daily_metrics as (
)

select
{{ dbt.date_trunc('week', 'day') }} as week,
{{ dbt.date_trunc('week', 'day') }} as week,
repository as repository,
sum(number_issues_opened) as number_issues_opened,
sum(number_issues_closed) as number_issues_closed,
sum(sum_days_issue_open) / sum(number_issues_opened) as avg_days_issue_open,
Expand All @@ -15,5 +16,5 @@ select
sum(sum_days_pr_open) / sum(number_prs_opened) as avg_days_pr_open,
max(longest_days_pr_open) as longest_days_pr_open
from daily_metrics
group by 1
group by 1,2
order by 1 desc

0 comments on commit bf66d97

Please sign in to comment.