Skip to content

Instantly share code, notes, and snippets.

@sminnee
Created May 14, 2019 05:47
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save sminnee/6b8d81395961e31527f320cc9a1d45da to your computer and use it in GitHub Desktop.
Save sminnee/6b8d81395961e31527f320cc9a1d45da to your computer and use it in GitHub Desktop.
diff --git a/ss_dbt/models/platform/github_metrics.sql b/ss_dbt/models/platform/github_metrics.sql
index 0d80597..aa5dba3 100644
--- a/ss_dbt/models/platform/github_metrics.sql
+++ b/ss_dbt/models/platform/github_metrics.sql
@@ -22,92 +22,41 @@ SELECT
coalesce(prs_closed, 0) AS prs_closed,
-- Backlog sizes at end of week
- (
- SELECT COUNT(*)
- FROM {{ ref('github_issues') }}
- WHERE created_at < weeks.weeks + INTERVAL '7 day' AND (closed_at IS NULL OR closed_at > weeks.weeks + INTERVAL '7 day')
- AND repository = repos.repository
- AND NOT is_pr
- ) issues_total_open,
- (
- SELECT COUNT(*)
- FROM {{ ref('github_issues') }}
- WHERE closed_at < weeks.weeks + INTERVAL '7 day'
- AND repository = repos.repository
- AND NOT is_pr
- ) issues_total_closed,
- (
- SELECT COUNT(*)
- FROM github_data.issues i INNER JOIN github_data.issues__labels il ON il._sdc_source_key_id = i.id AND il.name = 'type/bug'
- WHERE created_at < weeks.weeks + INTERVAL '7 day' AND (closed_at IS NULL OR closed_at > weeks.weeks + INTERVAL '7 day')
- AND _sdc_repository = repos.repository
- AND pull_request__url IS NULL
- ) bugs_total_open,
- (
- SELECT COUNT(*)
- FROM github_data.issues i INNER JOIN github_data.issues__labels il ON il._sdc_source_key_id = i.id AND il.name = 'type/bug'
- WHERE closed_at < weeks.weeks + INTERVAL '7 day'
- AND _sdc_repository = repos.repository
- AND pull_request__url IS NULL
- ) bugs_total_closed,
- (
- SELECT COUNT(*)
- FROM github_data.issues i INNER JOIN github_data.issues__labels il ON il._sdc_source_key_id = i.id AND il.name IN ('type/enhancement', 'feature', 'enhancement')
- WHERE created_at < weeks.weeks + INTERVAL '7 day' AND (closed_at IS NULL OR closed_at > weeks.weeks + INTERVAL '7 day')
- AND _sdc_repository = repos.repository
- AND pull_request__url IS NULL
- ) enhancements_total_open,
- (
- SELECT COUNT(*)
- FROM github_data.issues i INNER JOIN github_data.issues__labels il ON il._sdc_source_key_id = i.id AND il.name IN ('type/enhancement', 'feature', 'enhancement')
- WHERE closed_at < weeks.weeks + INTERVAL '7 day'
- AND _sdc_repository = repos.repository
- AND pull_request__url IS NULL
- ) enhancements_total_closed,
- (
- SELECT COUNT(*)
- FROM github_data.issues i INNER JOIN github_data.issues__labels il ON il._sdc_source_key_id = i.id AND il.name = 'type/docs'
- WHERE created_at < weeks.weeks + INTERVAL '7 day' AND (closed_at IS NULL OR closed_at > weeks.weeks + INTERVAL '7 day')
- AND _sdc_repository = repos.repository
- AND pull_request__url IS NULL
- ) docissues_total_open,
- (
- SELECT COUNT(*)
- FROM github_data.issues i INNER JOIN github_data.issues__labels il ON il._sdc_source_key_id = i.id AND il.name = 'type/docs'
- WHERE closed_at < weeks.weeks + INTERVAL '7 day'
- AND _sdc_repository = repos.repository
- AND pull_request__url IS NULL
- ) docissues_total_closed,
- (
- SELECT COUNT(*)
- FROM {{ ref('github_issues') }}
- WHERE created_at < weeks.weeks + INTERVAL '7 day' AND (closed_at IS NULL OR closed_at > weeks.weeks + INTERVAL '7 day')
- AND repository = repos.repository
- AND NOT is_pr
- AND type IS NULL
- ) notype_total_open,
- (
- SELECT COUNT(*)
- FROM {{ ref('github_issues') }}
- WHERE closed_at < weeks.weeks + INTERVAL '7 day'
- AND repository = repos.repository
- AND NOT is_pr
- AND type IS NULL
- ) notype_total_closed,
- (
- SELECT COUNT(*)
- FROM {{ ref('github_issues') }}
- WHERE created_at < weeks.weeks + INTERVAL '7 day' AND (closed_at IS NULL OR closed_at > weeks.weeks + INTERVAL '7 day')
- AND repository = repos.repository
- AND is_pr
- ) prs_total_open,
- (
- SELECT COUNT(*)
- FROM {{ ref('github_issues') }}
- WHERE closed_at < weeks.weeks + INTERVAL '7 day'
- AND repository = repos.repository
- AND is_pr
- ) prs_total_closed,
+ SUM(issues_created) OVER (PARTITION BY created.repository ORDER BY created.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row)
+ - COALESCE(SUM(issues_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS issues_total_open,
+ COALESCE(SUM(issues_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS issues_total_closed,
+
+ SUM(bugs_created) OVER (PARTITION BY created.repository ORDER BY created.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row)
+ - COALESCE(SUM(bugs_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS bugs_total_open,
+ COALESCE(SUM(bugs_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS bugs_total_closed,
+
+ SUM(enhancements_created) OVER (PARTITION BY created.repository ORDER BY created.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row)
+ - COALESCE(SUM(enhancements_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS enhancements_total_open,
+ COALESCE(SUM(enhancements_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS enhancements_total_closed,
+
+ SUM(docissues_created) OVER (PARTITION BY created.repository ORDER BY created.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row)
+ - COALESCE(SUM(docissues_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS docissues_total_open,
+ COALESCE(SUM(docissues_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS docissues_total_closed,
+
+ SUM(notype_created) OVER (PARTITION BY created.repository ORDER BY created.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row)
+ - COALESCE(SUM(notype_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS notype_total_open,
+ COALESCE(SUM(notype_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS notype_total_closed,
+
+ SUM(prs_created) OVER (PARTITION BY created.repository ORDER BY created.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row)
+ - COALESCE(SUM(prs_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS prs_total_open,
+ COALESCE(SUM(prs_closed) OVER (PARTITION BY closed.repository ORDER BY closed.week ASC ROWS BETWEEN unbounded preceding AND CURRENT row), 0)
+ AS prs_total_closed,
gmd.total_triaged,
gmd.total_untriaged,
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment