Skip to content
This repository has been archived by the owner on Apr 4, 2023. It is now read-only.

Commit

Permalink
Migrate engineering performance dashboard to DBT (singer-io#87)
Browse files Browse the repository at this point in the history
* Migrate engineering performance dashboard to DBT

* Remove unnecessary coalesce
  • Loading branch information
jacobfrackson authored Nov 30, 2018
1 parent b1e4528 commit f787f4a
Show file tree
Hide file tree
Showing 7 changed files with 154 additions and 22 deletions.
29 changes: 29 additions & 0 deletions models/dimension/base/dimension_working_minutes.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
with series as (
select generate_series(0,
(extract(days from timezone('America/Montreal', '2021-01-01 00:00:00')
- timezone('America/Montreal', '2018-01-01 00:00:00'))::integer
* 1440) ) as n
)

select
(timezone('America/Montreal', '2018-01-01 00:00:00')
+ n * interval '1min') as minute
from series
where extract(isodow from (timezone('America/Montreal', '2018-01-01 00:00:00')
+ (n || ' minutes')::interval)) < 6
and (timezone('America/Montreal', '2018-01-01 00:00:00')
+ n * interval '1min')::time >= '09:00'::time
and (timezone('America/Montreal', '2018-01-01 00:00:00')
+ n * interval '1min')::time < '17:00'::time
and date_trunc('day', (timezone('America/Montreal', '2018-01-01 00:00:00')
+ n * interval '1min'))
not in ('2018-01-01',
'2018-03-30',
'2018-04-02',
'2018-05-21',
'2018-06-24',
'2018-07-01',
'2018-09-03',
'2018-10-08',
'2018-12-25'
)
27 changes: 27 additions & 0 deletions models/github/transform/github_deploys.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
with prs as (
select * from {{ ref( 'github_pull_requests' ) }}
)

, nonprod_repos as (
select * from {{ ref( 'github_nonprod_repos' ) }}
)

select prs.number
, prs.title
, prs.state
, prs.html_url
, prs.created_at
, prs.merged_at
, prs.base_branch
, coalesce(prs.repo_name,
split_part(
replace(prs.html_url, 'https://github.com/dialoguemd/', ''),
'/',1),
null) as repo_name
from prs
left join nonprod_repos using (repo_name)
where (prs.base_branch = 'master'
or (prs.base_branch = 'beta' and prs.repo_name = 'care-platform'))
and prs.merged_at is not null
and date_trunc('week', current_date) <> date_trunc('week', prs.merged_at)
and nonprod_repos.repo_name is null
20 changes: 5 additions & 15 deletions models/github/transform/github_deploys_daily.sql
Original file line number Diff line number Diff line change
@@ -1,18 +1,8 @@
with prs as (
select * from {{ ref( 'github_pull_requests' ) }}
)

, nonprod_repos as (
select * from {{ ref( 'github_nonprod_repos' ) }}
)
with deploys as (
select * from {{ ref( 'github_deploys' ) }}
)

select date_trunc('day', merged_at) as merged_at_date
, coalesce(count(*),0) as deploys_count
from prs
left join nonprod_repos using (repo_name)
where (base_branch = 'master'
or (base_branch = 'beta' and repo_name = 'care-platform'))
and merged_at is not null
and date_trunc('week', current_date) <> date_trunc('week', merged_at)
and nonprod_repos.repo_name is null
, count(*) as deploys_count
from deploys
group by 1
29 changes: 22 additions & 7 deletions models/github/transform/schema.yml
Original file line number Diff line number Diff line change
@@ -1,12 +1,27 @@
version: 2

models:
- name: github_deploys
columns:
- name: number
tests:
- not_null
- name: repo_name
tests:
- not_null
- name: created_at
tests:
- not_null
tests:
- unique:
column_name: "concat(number, repo_name)"

- name: github_deploys_daily
columns:
- name: merged_at_date
tests:
- unique
- not_null
- name: deploys_count
tests:
- not_null
- name: merged_at_date
tests:
- unique
- not_null
- name: deploys_count
tests:
- not_null
22 changes: 22 additions & 0 deletions models/meta/product/product_mean_time_to_resolve.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
with jira_issues as (
select * from {{ ref('jira_issues') }}
)

, working_minutes as (
select * from {{ ref('dimension_working_minutes') }}
)

select jira_issues.created_at
, jira_issues.issue_id
, jira_issues.issue_type
, jira_issues.resolved_at
, count(working_minutes.minute) as time_to_resolve_working_min
, count(working_minutes.minute) / 480 as time_to_resolve_working_days
from jira_issues
left join working_minutes
on working_minutes.minute between jira_issues.created_at
and coalesce(jira_issues.resolved_at, current_date)
where jira_issues.issue_type in ('P1 Bug', 'P2 Bug')
and jira_issues.resolved_at
< date_trunc('week', current_date) - interval '1 day'
group by 1,2,3,4
17 changes: 17 additions & 0 deletions models/meta/product/product_open_problems.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,17 @@
with dates as (
select * from {{ ref('dimension_days') }}
)

, bugs as (
select * from {{ ref('product_bugs') }}
)

select date_day
, count(distinct bug_id) as all_bugs
, count(distinct bug_id) filter(where issue_type = 'P1 Bug') as p1_bugs
, count(distinct bug_id) filter(where issue_type = 'P2 Bug') as p2_bugs
, count(distinct bug_id) filter(where issue_type = 'P3 Bug') as p3_bugs
from dates
left join bugs
on dates.date_day between bugs.created_at and bugs.closed_at
group by 1
32 changes: 32 additions & 0 deletions models/meta/product/schema.yml
Original file line number Diff line number Diff line change
Expand Up @@ -28,3 +28,35 @@ models:
- name: deploys_count
tests:
- not_null

- name: product_mean_time_to_resolve
columns:
- name: issue_id
tests:
- not_null
- unique
- name: time_to_resolve_working_min
tests:
- not_null
- name: time_to_resolve_working_days
tests:
- not_null

- name: product_open_problems
columns:
- name: date_day
tests:
- not_null
- unique
- name: p1_bugs
tests:
- not_null
- name: p2_bugs
tests:
- not_null
- name: p3_bugs
tests:
- not_null
- name: all_bugs
tests:
- not_null

0 comments on commit f787f4a

Please sign in to comment.