diff --git a/grafana/dashboards/DORA.json b/grafana/dashboards/DORA.json index e1309fef848..ab0cf67303f 100644 --- a/grafana/dashboards/DORA.json +++ b/grafana/dashboards/DORA.json @@ -15,8 +15,8 @@ "editable": true, "gnetId": null, "graphTooltip": 0, - "id": 28, - "iteration": 1681113037519, + "id": 12, + "iteration": 1681911584843, "links": [], "panels": [ { @@ -143,7 +143,7 @@ "metricColumn": "none", "queryType": "randomWalk", "rawQuery": true, - "rawSql": "-- Metric 1: Deployment Frequency\nwith last_few_calendar_months as(\n-- get the last few months within the selected time period in the top-right corner\n\tSELECT CAST((SYSDATE()-INTERVAL (H+T+U) DAY) AS date) day\n\tFROM ( SELECT 0 H\n\t\t\tUNION ALL SELECT 100 UNION ALL SELECT 200 UNION ALL SELECT 300\n\t\t) H CROSS JOIN ( SELECT 0 T\n\t\t\tUNION ALL SELECT 10 UNION ALL SELECT 20 UNION ALL SELECT 30\n\t\t\tUNION ALL SELECT 40 UNION ALL SELECT 50 UNION ALL SELECT 60\n\t\t\tUNION ALL SELECT 70 UNION ALL SELECT 80 UNION ALL SELECT 90\n\t\t) T CROSS JOIN ( SELECT 0 U\n\t\t\tUNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3\n\t\t\tUNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6\n\t\t\tUNION ALL SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9\n\t\t) U\n\tWHERE\n\t\t(SYSDATE()-INTERVAL (H+T+U) DAY) > $__timeFrom()\n),\n\n_days_weeks_deploy as(\n\tSELECT\n\t\t\tdate(DATE_ADD(last_few_calendar_months.day, INTERVAL -WEEKDAY(last_few_calendar_months.day) DAY)) as week,\n\t\t\tMAX(if(deployments.day is not null, 1, 0)) as week_deployed,\n\t\t\tCOUNT(distinct deployments.day) as days_deployed\n\tFROM \n\t\tlast_few_calendar_months\n\t\tLEFT JOIN(\n\t\t\tSELECT\n\t\t\t\tdistinct DATE(finished_date) AS day,\n\t\t\t\tid\n\t\t\tFROM cicd_tasks ct\n\t\t\tjoin project_mapping pm on ct.cicd_scope_id = pm.row_id\n\t\t\tWHERE\n\t\t\t pm.project_name in ($project)\n\t\t\t\tand type = 'DEPLOYMENT'\n\t\t\t\tand result = 'SUCCESS'\n\t\t\t\tand environment = 'PRODUCTION') deployments ON deployments.day = last_few_calendar_months.day\n\tGROUP BY week\n\t),\n\n_monthly_deploy as(\n\tSELECT\n\t\t\tdate(DATE_ADD(last_few_calendar_months.day, INTERVAL -DAY(last_few_calendar_months.day)+1 DAY)) as month,\n\t\t\tMAX(if(deployments.day is not null, 1, 0)) as months_deployed\n\tFROM \n\t\tlast_few_calendar_months\n\t\tLEFT JOIN(\n\t\t\tSELECT\n\t\t\t\tdistinct DATE(finished_date) AS day,\n\t\t\t\tid\n\t\t\tFROM cicd_tasks ct\n\t\t\tjoin project_mapping pm on ct.cicd_scope_id = pm.row_id\n\t\t\tWHERE\n\t\t\t pm.project_name in ($project)\n\t\t\t\tand type = 'DEPLOYMENT'\n\t\t\t\tand result = 'SUCCESS'\n\t\t\t\tand environment = 'PRODUCTION') deployments ON deployments.day = last_few_calendar_months.day\n\tGROUP BY month\n\t),\n\n_median_number_of_deployment_days_per_week_ranks as(\n\tSELECT *, percent_rank() over(order by days_deployed) as ranks\n\tFROM _days_weeks_deploy\n),\n\n_median_number_of_deployment_days_per_week as(\n\tSELECT max(days_deployed) as median_number_of_deployment_days_per_week\n\tFROM _median_number_of_deployment_days_per_week_ranks\n\tWHERE ranks <= 0.5\n),\n\n_median_number_of_deployment_days_per_month_ranks as(\n\tSELECT *, percent_rank() over(order by months_deployed) as ranks\n\tFROM _monthly_deploy\n),\n\n_median_number_of_deployment_days_per_month as(\n\tSELECT max(months_deployed) as median_number_of_deployment_days_per_month\n\tFROM _median_number_of_deployment_days_per_month_ranks\n\tWHERE ranks <= 0.5\n),\n\n_metric_deployment_frequency as (\n\tSELECT \n\t\t'Deployment frequency' as metric,\n\t\tCASE \n\t\t\tWHEN median_number_of_deployment_days_per_week >= 3 THEN 'On-demand'\n\t\t\tWHEN median_number_of_deployment_days_per_week >= 1 THEN 'Between once per week and once per month'\n\t\t\tWHEN median_number_of_deployment_days_per_month >= 1 THEN 'Between once per month and once every 6 months'\n\t\t\tELSE 'Fewer than once per six months' END AS value\n\tFROM _median_number_of_deployment_days_per_week, _median_number_of_deployment_days_per_month\n),\n\n-- Metric 2: median change lead time\n_pr_stats as (\n-- get PRs' cycle time in the selected period\n\tSELECT\n\t\tdistinct pr.id,\n\t\tprm.pr_cycle_time\n\tFROM\n\t\tpull_requests pr\n\t\tjoin project_pr_metrics prm on prm.id = pr.id\n\t\tjoin project_mapping pm on pr.base_repo_id = pm.row_id\n\tWHERE\n\t pm.project_name in ($project) \n\t\tand pr.merged_date is not null\n\t\tand prm.pr_cycle_time is not null\n\t\tand $__timeFilter(pr.merged_date)\n),\n\n_median_change_lead_time_ranks as(\n\tSELECT *, percent_rank() over(order by pr_cycle_time) as ranks\n\tFROM _pr_stats\n),\n\n_median_change_lead_time as(\n-- use median PR cycle time as the median change lead time\n\tSELECT max(pr_cycle_time) as median_change_lead_time\n\tFROM _median_change_lead_time_ranks\n\tWHERE ranks <= 0.5\n),\n\n_metric_change_lead_time as (\n\tSELECT \n\t\t'Lead time for changes' as metric,\n\t\tCASE\n\t\t\tWHEN median_change_lead_time < 60 then \"Less than one hour\"\n\t\t\tWHEN median_change_lead_time < 7 * 24 * 60 then \"Less than one week\"\n\t\t\tWHEN median_change_lead_time < 180 * 24 * 60 then \"Between one week and six months\"\n\t\t\tELSE \"More than six months\"\n\t\t\tEND as value\nFROM _median_change_lead_time\n),\n\n\n-- Metric 3: Median time to restore service \n_incidents as (\n-- get the incidents created within the selected time period in the top-right corner\n\tSELECT\n\t distinct i.id,\n\t\tcast(lead_time_minutes as signed) as lead_time_minutes\n\tFROM\n\t\tissues i\n\t join board_issues bi on i.id = bi.issue_id\n\t join boards b on bi.board_id = b.id\n\t join project_mapping pm on b.id = pm.row_id\n\tWHERE\n\t pm.project_name in ($project)\n\t\tand i.type = 'INCIDENT'\n\t\tand $__timeFilter(i.created_date)\n),\n\n_median_mttr_ranks as(\n\tSELECT *, percent_rank() over(order by lead_time_minutes) as ranks\n\tFROM _incidents\n),\n\n_median_mttr as(\n\tSELECT max(lead_time_minutes) as median_time_to_resolve\n\tFROM _median_mttr_ranks\n\tWHERE ranks <= 0.5\n),\n\n\n_metric_mttr as (\n\tSELECT \n\t\t'Time to restore service' as metric,\n\t\tcase\n\t\t\tWHEN median_time_to_resolve < 60 then \"Less than one hour\"\n\t\t\tWHEN median_time_to_resolve < 24 * 60 then \"Less than one Day\"\n\t\t\tWHEN median_time_to_resolve < 7 * 24 * 60 then \"Between one day and one week\"\n\t\t\tELSE \"More than one week\"\n\t\t\tEND as value\n\tFROM \n\t\t_median_mttr\n),\n\n-- Metric 4: change failure rate\n_deployments as (\n-- get the deployment deployed within the selected time period in the top-right corner\n\tSELECT\n\t\tct.id AS deployment_id,\n\t\tct.finished_date as deployment_finished_date\n\tFROM\n\t\tcicd_tasks ct\n\t\tjoin project_mapping pm on ct.cicd_scope_id = pm.row_id\n\tWHERE\n\t\tpm.project_name in ($project)\n\t\tand type = 'DEPLOYMENT'\n\t\tand result = 'SUCCESS'\n\t\tand environment = 'PRODUCTION'\n and $__timeFilter(finished_date)\n),\n\n_incident_caused_by_deployments as (\n-- get the incidents (caused by deployments) that are created within the selected time period in the top-right corner\n\tSELECT\n\t\ti.id AS incident_id,\n\t\tpim.deployment_id\n\tFROM\n\t\tissues i\n\t join project_issue_metrics pim on i.id = pim.id\n\tWHERE\n\t pim.project_name in ($project) and\n\t\ti.type = 'INCIDENT'\n\t\tand $__timeFilter(i.created_date)\n),\n\n_deployment_failures as (\n-- calculate the number of incidents caused by each deployment\n SELECT \n\t\tdistinct\n\t\t\td.deployment_id,\n\t\t\td.deployment_finished_date,\n\t\t\tcount(distinct i.incident_id) as incident_count\n FROM \n \t_deployments d\n \tleft join _incident_caused_by_deployments i on d.deployment_id = i.deployment_id\n\tGROUP BY 1,2\n),\n\n_change_failure_rate as (\n\tSELECT \n\t\tcase when count(deployment_id) is null then null\n\t\telse count(case when incident_count = 0 then null else 1 end)/count(deployment_id) end as change_failure_rate\n\tFROM\n\t\t_deployment_failures\n),\n\n_metric_cfr as (\n\tSELECT\n\t\t'Change failure rate' as metric,\n\t\tcase \n\t\t\twhen change_failure_rate <= .15 then \"0-15%\"\n\t\t\twhen change_failure_rate <= .20 then \"16%-20%\"\n\t\t\twhen change_failure_rate <= .30 then \"21%-30%\"\n\t\t\telse \"> 30%\" \n\t\tend as value\n\tFROM \n\t\t_change_failure_rate\n),\n\n_final_results as (\t\n\tSELECT distinct db.id,db.metric,db.low,db.medium,db.high,db.elite,m1.metric as _metric, m1.value FROM dora_benchmarks db\n\tleft join _metric_deployment_frequency m1 on db.metric = m1.metric\n\tWHERE m1.metric is not null\n\t\n\tunion \n\t\n\tSELECT distinct db.id,db.metric,db.low,db.medium,db.high,db.elite,m2.metric as _metric, m2.value FROM dora_benchmarks db\n\tleft join _metric_change_lead_time m2 on db.metric = m2.metric\n\tWHERE m2.metric is not null\n\t\n\tunion \n\t\n\tSELECT distinct db.id,db.metric,db.low,db.medium,db.high,db.elite,m3.metric as _metric, m3.value FROM dora_benchmarks db\n\tleft join _metric_mttr m3 on db.metric = m3.metric\n\tWHERE m3.metric is not null\n\t\n\tunion \n\t\n\tSELECT distinct db.id,db.metric,db.low,db.medium,db.high,db.elite,m4.metric as _metric, m4.value FROM dora_benchmarks db\n\tleft join _metric_cfr m4 on db.metric = m4.metric\n\tWHERE m4.metric is not null\n)\n\n\nSELECT \n\tmetric,\n\tcase when low = value then low else null end as low,\n\tcase when medium = value then medium else null end as medium,\n\tcase when high = value then high else null end as high,\n\tcase when elite = value then elite else null end as elite\nFROM _final_results\nORDER BY id", + "rawSql": "-- Metric 1: Deployment Frequency\nwith last_few_calendar_months as(\n-- get the last few months within the selected time period in the top-right corner\n\tSELECT CAST((SYSDATE()-INTERVAL (H+T+U) DAY) AS date) day\n\tFROM ( SELECT 0 H\n\t\t\tUNION ALL SELECT 100 UNION ALL SELECT 200 UNION ALL SELECT 300\n\t\t) H CROSS JOIN ( SELECT 0 T\n\t\t\tUNION ALL SELECT 10 UNION ALL SELECT 20 UNION ALL SELECT 30\n\t\t\tUNION ALL SELECT 40 UNION ALL SELECT 50 UNION ALL SELECT 60\n\t\t\tUNION ALL SELECT 70 UNION ALL SELECT 80 UNION ALL SELECT 90\n\t\t) T CROSS JOIN ( SELECT 0 U\n\t\t\tUNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3\n\t\t\tUNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6\n\t\t\tUNION ALL SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9\n\t\t) U\n\tWHERE\n\t\t(SYSDATE()-INTERVAL (H+T+U) DAY) > $__timeFrom()\n),\n\n_days_weeks_deploy as(\n\tSELECT\n\t\t\tdate(DATE_ADD(last_few_calendar_months.day, INTERVAL -WEEKDAY(last_few_calendar_months.day) DAY)) as week,\n\t\t\tMAX(if(deployments.day is not null, 1, 0)) as week_deployed,\n\t\t\tCOUNT(distinct deployments.day) as days_deployed\n\tFROM \n\t\tlast_few_calendar_months\n\t\tLEFT JOIN(\n\t\t\tSELECT\n\t\t\t\tdistinct DATE(finished_date) AS day,\n\t\t\t\tid\n\t\t\tFROM cicd_tasks ct\n\t\t\tjoin project_mapping pm on ct.cicd_scope_id = pm.row_id\n\t\t\tWHERE\n\t\t\t pm.project_name in ($project)\n\t\t\t\tand type = 'DEPLOYMENT'\n\t\t\t\tand result = 'SUCCESS'\n\t\t\t\tand environment = 'PRODUCTION') deployments ON deployments.day = last_few_calendar_months.day\n\tGROUP BY week\n\t),\n\n_monthly_deploy as(\n\tSELECT\n\t\t\tdate(DATE_ADD(last_few_calendar_months.day, INTERVAL -DAY(last_few_calendar_months.day)+1 DAY)) as month,\n\t\t\tMAX(if(deployments.day is not null, 1, 0)) as months_deployed\n\tFROM \n\t\tlast_few_calendar_months\n\t\tLEFT JOIN(\n\t\t\tSELECT\n\t\t\t\tdistinct DATE(finished_date) AS day,\n\t\t\t\tid\n\t\t\tFROM cicd_tasks ct\n\t\t\tjoin project_mapping pm on ct.cicd_scope_id = pm.row_id\n\t\t\tWHERE\n\t\t\t pm.project_name in ($project)\n\t\t\t\tand type = 'DEPLOYMENT'\n\t\t\t\tand result = 'SUCCESS'\n\t\t\t\tand environment = 'PRODUCTION') deployments ON deployments.day = last_few_calendar_months.day\n\tGROUP BY month\n\t),\n\n_median_number_of_deployment_days_per_week_ranks as(\n\tSELECT *, percent_rank() over(order by days_deployed) as ranks\n\tFROM _days_weeks_deploy\n),\n\n_median_number_of_deployment_days_per_week as(\n\tSELECT max(days_deployed) as median_number_of_deployment_days_per_week\n\tFROM _median_number_of_deployment_days_per_week_ranks\n\tWHERE ranks <= 0.5\n),\n\n_median_number_of_deployment_days_per_month_ranks as(\n\tSELECT *, percent_rank() over(order by months_deployed) as ranks\n\tFROM _monthly_deploy\n),\n\n_median_number_of_deployment_days_per_month as(\n\tSELECT max(months_deployed) as median_number_of_deployment_days_per_month\n\tFROM _median_number_of_deployment_days_per_month_ranks\n\tWHERE ranks <= 0.5\n),\n\n_metric_deployment_frequency as (\n\tSELECT \n\t\t'Deployment frequency' as metric,\n\t\tCASE \n\t\t\tWHEN median_number_of_deployment_days_per_week >= 3 THEN 'On-demand'\n\t\t\tWHEN median_number_of_deployment_days_per_week >= 1 THEN 'Between once per week and once per month'\n\t\t\tWHEN median_number_of_deployment_days_per_month >= 1 THEN 'Between once per month and once every 6 months'\n\t\t\tELSE 'Fewer than once per six months' END AS value\n\tFROM _median_number_of_deployment_days_per_week, _median_number_of_deployment_days_per_month\n),\n\n-- Metric 2: median change lead time\n_pr_stats as (\n-- get PRs' cycle time in the selected period\n\tSELECT\n\t\tdistinct pr.id,\n\t\tprm.pr_cycle_time\n\tFROM\n\t\tpull_requests pr\n\t\tjoin project_pr_metrics prm on prm.id = pr.id\n\t\tjoin project_mapping pm on pr.base_repo_id = pm.row_id\n\tWHERE\n\t pm.project_name in ($project) \n\t\tand pr.merged_date is not null\n\t\tand prm.pr_cycle_time is not null\n\t\tand $__timeFilter(pr.merged_date)\n),\n\n_median_change_lead_time_ranks as(\n\tSELECT *, percent_rank() over(order by pr_cycle_time) as ranks\n\tFROM _pr_stats\n),\n\n_median_change_lead_time as(\n-- use median PR cycle time as the median change lead time\n\tSELECT max(pr_cycle_time) as median_change_lead_time\n\tFROM _median_change_lead_time_ranks\n\tWHERE ranks <= 0.5\n),\n\n_metric_change_lead_time as (\n\tSELECT \n\t\t'Lead time for changes' as metric,\n\t\tCASE\n\t\t\tWHEN median_change_lead_time < 60 then \"Less than one hour\"\n\t\t\tWHEN median_change_lead_time < 7 * 24 * 60 then \"Less than one week\"\n\t\t\tWHEN median_change_lead_time < 180 * 24 * 60 then \"Between one week and six months\"\n\t\t\tELSE \"More than six months\"\n\t\t\tEND as value\nFROM _median_change_lead_time\n),\n\n\n-- Metric 3: Median time to restore service \n_incidents as (\n-- get the incidents created within the selected time period in the top-right corner\n\tSELECT\n\t distinct i.id,\n\t\tcast(lead_time_minutes as signed) as lead_time_minutes\n\tFROM\n\t\tissues i\n\t join board_issues bi on i.id = bi.issue_id\n\t join boards b on bi.board_id = b.id\n\t join project_mapping pm on b.id = pm.row_id\n\tWHERE\n\t pm.project_name in ($project)\n\t\tand i.type = 'INCIDENT'\n\t\tand $__timeFilter(i.created_date)\n),\n\n_median_mttr_ranks as(\n\tSELECT *, percent_rank() over(order by lead_time_minutes) as ranks\n\tFROM _incidents\n),\n\n_median_mttr as(\n\tSELECT max(lead_time_minutes) as median_time_to_resolve\n\tFROM _median_mttr_ranks\n\tWHERE ranks <= 0.5\n),\n\n\n_metric_mttr as (\n\tSELECT \n\t\t'Time to restore service' as metric,\n\t\tcase\n\t\t\tWHEN median_time_to_resolve < 60 then \"Less than one hour\"\n\t\t\tWHEN median_time_to_resolve < 24 * 60 then \"Less than one Day\"\n\t\t\tWHEN median_time_to_resolve < 7 * 24 * 60 then \"Between one day and one week\"\n\t\t\tELSE \"More than one week\"\n\t\t\tEND as value\n\tFROM \n\t\t_median_mttr\n),\n\n-- Metric 4: change failure rate\n_deployments as (\n-- get the deployment deployed within the selected time period in the top-right corner\n\tSELECT\n\t\tct.id AS deployment_id,\n\t\tct.finished_date as deployment_finished_date\n\tFROM\n\t\tcicd_tasks ct\n\t\tjoin project_mapping pm on ct.cicd_scope_id = pm.row_id\n\tWHERE\n\t pm.project_name in ($project)\n\t\tand type = 'DEPLOYMENT'\n\t\tand result = 'SUCCESS'\n\t\tand environment = 'PRODUCTION'\n and $__timeFilter(finished_date)\n),\n\n_failure_caused_by_deployments as (\n-- calculate the number of incidents caused by each deployment\n\tSELECT\n\t\td.deployment_id,\n\t\td.deployment_finished_date,\n\t\tcount(distinct case when i.type = 'incident' then d.deployment_id else null end) as has_incident\n\tFROM\n\t\t_deployments d\n\t\tleft join project_issue_metrics pim on d.deployment_id = pim.deployment_id\n\t\tleft join issues i on pim.id = i.id\n\tGROUP BY 1,2\n),\n\n_change_failure_rate as (\n\tSELECT \n\t\tcase \n\t\t\twhen count(deployment_id) is null then null\n\t\t\telse sum(has_incident)/count(deployment_id) end as change_failure_rate\n\tFROM\n\t\t_failure_caused_by_deployments\n),\n\n_metric_cfr as (\n\tSELECT\n\t\t'Change failure rate' as metric,\n\t\tcase \n\t\t\twhen change_failure_rate <= .15 then \"0-15%\"\n\t\t\twhen change_failure_rate <= .20 then \"16%-20%\"\n\t\t\twhen change_failure_rate <= .30 then \"21%-30%\"\n\t\t\telse \"> 30%\" \n\t\tend as value\n\tFROM \n\t\t_change_failure_rate\n),\n\n_final_results as (\t\n\tSELECT distinct db.id,db.metric,db.low,db.medium,db.high,db.elite,m1.metric as _metric, m1.value FROM dora_benchmarks db\n\tleft join _metric_deployment_frequency m1 on db.metric = m1.metric\n\tWHERE m1.metric is not null\n\t\n\tunion \n\t\n\tSELECT distinct db.id,db.metric,db.low,db.medium,db.high,db.elite,m2.metric as _metric, m2.value FROM dora_benchmarks db\n\tleft join _metric_change_lead_time m2 on db.metric = m2.metric\n\tWHERE m2.metric is not null\n\t\n\tunion \n\t\n\tSELECT distinct db.id,db.metric,db.low,db.medium,db.high,db.elite,m3.metric as _metric, m3.value FROM dora_benchmarks db\n\tleft join _metric_mttr m3 on db.metric = m3.metric\n\tWHERE m3.metric is not null\n\t\n\tunion \n\t\n\tSELECT distinct db.id,db.metric,db.low,db.medium,db.high,db.elite,m4.metric as _metric, m4.value FROM dora_benchmarks db\n\tleft join _metric_cfr m4 on db.metric = m4.metric\n\tWHERE m4.metric is not null\n)\n\n\nSELECT \n\tmetric,\n\tcase when low = value then low else null end as low,\n\tcase when medium = value then medium else null end as medium,\n\tcase when high = value then high else null end as high,\n\tcase when elite = value then elite else null end as elite\nFROM _final_results\nORDER BY id", "refId": "A", "select": [ [ @@ -543,7 +543,7 @@ "metricColumn": "none", "queryType": "randomWalk", "rawQuery": true, - "rawSql": "-- Metric 4: change failure rate\nwith _deployments as (\n-- get the deployment deployed within the selected time period in the top-right corner\n\tSELECT\n\t\tct.id AS deployment_id,\n\t\tct.finished_date as deployment_finished_date\n\tFROM\n\t\tcicd_tasks ct\n\t\tjoin project_mapping pm on ct.cicd_scope_id = pm.row_id\n\tWHERE\n\t pm.project_name in ($project)\n\t\tand type = 'DEPLOYMENT'\n\t\tand result = 'SUCCESS'\n\t\tand environment = 'PRODUCTION'\n and $__timeFilter(finished_date)\n),\n\n_incident_caused_by_deployments as (\n-- get the incidents (caused by deployments) that are created within the selected time period in the top-right corner\n\tSELECT\n\t\ti.id AS incident_id,\n\t\tpim.deployment_id\n\tFROM\n\t\tissues i\n\t join project_issue_metrics pim on i.id = pim.id\n\tWHERE\n\t pim.project_name in ($project) and\n\t\ti.type = 'INCIDENT'\n\t\tand $__timeFilter(i.created_date)\n),\n\n_deployment_failures as (\n-- calculate the number of incidents caused by each deployment\n SELECT \n\t\tdistinct\n\t\t\td.deployment_id,\n\t\t\td.deployment_finished_date,\n\t\t\tcount(distinct i.incident_id) as incident_count\n FROM \n \t_deployments d\n \tleft join _incident_caused_by_deployments i on d.deployment_id = i.deployment_id\n\tGROUP BY 1,2\n),\n\n_change_failure_rate as (\n\tSELECT \n\t\tcase when count(deployment_id) is null then null\n\t\telse count(case when incident_count = 0 then null else 1 end)/count(deployment_id) end as change_failure_rate\n\tFROM\n\t\t_deployment_failures\n)\n\nSELECT\n\tcase \n\t\twhen change_failure_rate <= .15 then \"0-15%\"\n\t\twhen change_failure_rate <= .20 then \"16%-20%\"\n\t\twhen change_failure_rate <= .30 then \"21%-30%\"\n\t\telse \"> 30%\" \n\tend as change_failure_rate\nFROM \n\t_change_failure_rate", + "rawSql": "-- Metric 4: change failure rate\nwith _deployments as (\n-- get the deployment deployed within the selected time period in the top-right corner\n\tSELECT\n\t\tct.id AS deployment_id,\n\t\tct.finished_date as deployment_finished_date\n\tFROM\n\t\tcicd_tasks ct\n\t\tjoin project_mapping pm on ct.cicd_scope_id = pm.row_id\n\tWHERE\n\t pm.project_name in ($project)\n\t\tand type = 'DEPLOYMENT'\n\t\tand result = 'SUCCESS'\n\t\tand environment = 'PRODUCTION'\n and $__timeFilter(finished_date)\n),\n\n_failure_caused_by_deployments as (\n-- calculate the number of incidents caused by each deployment\n\tSELECT\n\t\td.deployment_id,\n\t\td.deployment_finished_date,\n\t\tcount(distinct case when i.type = 'incident' then d.deployment_id else null end) as has_incident\n\tFROM\n\t\t_deployments d\n\t\tleft join project_issue_metrics pim on d.deployment_id = pim.deployment_id\n\t\tleft join issues i on pim.id = i.id\n\tGROUP BY 1,2\n),\n\n_change_failure_rate as (\n\tSELECT \n\t\tcase \n\t\t\twhen count(deployment_id) is null then null\n\t\t\telse sum(has_incident)/count(deployment_id) end as change_failure_rate\n\tFROM\n\t\t_failure_caused_by_deployments\n)\n\nSELECT\n\tcase \n\t\twhen change_failure_rate <= .15 then \"0-15%\"\n\t\twhen change_failure_rate <= .20 then \"16%-20%\"\n\t\twhen change_failure_rate <= .30 then \"21%-30%\"\n\t\telse \"> 30%\" \n\tend as change_failure_rate\nFROM \n\t_change_failure_rate", "refId": "A", "select": [ [ @@ -797,7 +797,7 @@ { "matcher": { "id": "byName", - "options": "med_time_to_resolve_in_hour" + "options": "median_time_to_resolve_in_hour" }, "properties": [ { @@ -940,9 +940,7 @@ }, "orientation": "auto", "showValue": "auto", - "text": { - "valueSize": 1 - }, + "text": {}, "tooltip": { "mode": "single" } @@ -955,7 +953,7 @@ "hide": false, "metricColumn": "none", "rawQuery": true, - "rawSql": "with _deployments as (\n-- get the deployments in each month\n\tSELECT\n\t date_format(ct.finished_date,'%y/%m') as month,\n\t\tct.id AS deployment_id\n\tFROM\n\t\tcicd_tasks ct\n\t\tjoin project_mapping pm on ct.cicd_scope_id = pm.row_id\n\tWHERE\n\t pm.project_name in ($project)\n\t\tand type = 'DEPLOYMENT'\n\t\tand result = 'SUCCESS'\n\t\tand environment = 'PRODUCTION'\n),\n\n_incidents as (\n-- get the incidents (caused by deployments) that are created within the selected time period in the top-right corner\n\tSELECT\n\t\tdate_format(i.created_date,'%y/%m') as month,\n\t\ti.id AS incident_id,\n\t\tpim.deployment_id\n\tFROM\n\t\tissues i\n\t join project_issue_metrics pim on i.id = pim.id\n\tWHERE\n\t pim.project_name in ($project) and\n\t\ti.type = 'INCIDENT'\n),\n\n_calendar_months as(\n-- deal with the month with no incidents\n\tSELECT date_format(CAST((SYSDATE()-INTERVAL (month_index) MONTH) AS date), '%y/%m') as month\n\tFROM ( SELECT 0 month_index\n\t\t\tUNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3\n\t\t\tUNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6\n\t\t\tUNION ALL SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9\n\t\t\tUNION ALL SELECT 10 UNION ALL SELECT 11\n\t\t) month_index\n\tWHERE (SYSDATE()-INTERVAL (month_index) MONTH) > SYSDATE()-INTERVAL 6 MONTH\t\n),\n\n_deployment_failures as (\n-- calculate the number of incidents caused by each deployment\n SELECT \n\t\tdistinct\n\t\t\tcm.month,\n\t\t\td.deployment_id,\n\t\t\tcount(distinct i.incident_id) as incident_count\n FROM \n \t_calendar_months cm\n \tleft join _deployments d on cm.month = d.month\n \tleft join _incidents i on d.deployment_id = i.deployment_id\n\tGROUP BY 1,2\n)\n\nSELECT\n month,\n\tcase when \n\t\tcount(deployment_id) is null then null\n\t\telse count(case when incident_count = 0 then null else incident_count end)/count(deployment_id) end as change_failure_rate\nFROM _deployment_failures\nGROUP BY 1\nORDER BY 1", + "rawSql": "-- Metric 4: change failure rate\nwith _deployments as (\n-- get the deployment deployed within the selected time period in the top-right corner\n\tSELECT\n\t\tct.id AS deployment_id,\n\t\tct.finished_date as deployment_finished_date\n\tFROM\n\t\tcicd_tasks ct\n\t\tjoin project_mapping pm on ct.cicd_scope_id = pm.row_id\n\tWHERE\n\t pm.project_name in ($project)\n\t\tand type = 'DEPLOYMENT'\n\t\tand result = 'SUCCESS'\n\t\tand environment = 'PRODUCTION'\n and $__timeFilter(finished_date)\n),\n\n_failure_caused_by_deployments as (\n-- calculate the number of incidents caused by each deployment\n\tSELECT\n\t\td.deployment_id,\n\t\td.deployment_finished_date,\n\t\tcount(distinct case when i.type = 'incident' then d.deployment_id else null end) as has_incident\n\tFROM\n\t\t_deployments d\n\t\tleft join project_issue_metrics pim on d.deployment_id = pim.deployment_id\n\t\tleft join issues i on pim.id = i.id\n\tGROUP BY 1,2\n),\n\n_change_failure_rate_for_each_month as (\n\tSELECT \n\t\tdate_format(deployment_finished_date,'%y/%m') as month,\n\t\tcase \n\t\t\twhen count(deployment_id) is null then null\n\t\t\telse sum(has_incident)/count(deployment_id) end as change_failure_rate\n\tFROM\n\t\t_failure_caused_by_deployments\n\tGROUP BY 1\n),\n\n_calendar_months as(\n-- deal with the month with no incidents\n\tSELECT date_format(CAST((SYSDATE()-INTERVAL (month_index) MONTH) AS date), '%y/%m') as month\n\tFROM ( SELECT 0 month_index\n\t\t\tUNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3\n\t\t\tUNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6\n\t\t\tUNION ALL SELECT 7 UNION ALL SELECT 8 UNION ALL SELECT 9\n\t\t\tUNION ALL SELECT 10 UNION ALL SELECT 11\n\t\t) month_index\n\tWHERE (SYSDATE()-INTERVAL (month_index) MONTH) > SYSDATE()-INTERVAL 6 MONTH\t\n)\n\nSELECT \n\tcm.month,\n\tcfr.change_failure_rate\nFROM \n\t_calendar_months cm\n\tleft join _change_failure_rate_for_each_month cfr on cm.month = cfr.month\nGROUP BY 1,2\nORDER BY 1 ", "refId": "A", "select": [ [ @@ -1029,5 +1027,5 @@ "timezone": "", "title": "DORA", "uid": "qNo8_0M4z", - "version": 5 + "version": 2 } \ No newline at end of file