blob: ca7d9873f28d121dfc337c5261baa2e3f0f31bb6 [file] [log] [blame]
{
"annotations": {
"list": [
{
"builtIn": 1,
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"enable": true,
"hide": true,
"iconColor": "rgba(0, 211, 255, 1)",
"name": "Annotations & Alerts",
"type": "dashboard"
}
]
},
"editable": true,
"fiscalYearStartMonth": 0,
"graphTooltip": 0,
"id": 36,
"links": [],
"liveNow": false,
"panels": [
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"gridPos": {
"h": 2,
"w": 24,
"x": 0,
"y": 0
},
"id": 63,
"links": [],
"options": {
"code": {
"language": "plaintext",
"showLineNumbers": false,
"showMiniMap": false
},
"content": "This dashboard is designed to validate the [DORA dashboard](/grafana/d/qNo8_0M4z/dora?orgId=1).",
"mode": "markdown"
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"queryType": "randomWalk",
"refId": "A"
}
],
"title": "Dashboard Introduction",
"type": "text"
},
{
"collapsed": false,
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"gridPos": {
"h": 1,
"w": 24,
"x": 0,
"y": 2
},
"id": 20,
"panels": [],
"targets": [
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"refId": "A"
}
],
"title": "Check \"Deployment Frequency\"",
"type": "row"
},
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"gridPos": {
"h": 3,
"w": 24,
"x": 0,
"y": 3
},
"id": 64,
"options": {
"code": {
"language": "plaintext",
"showLineNumbers": false,
"showMiniMap": false
},
"content": "- See the definition and calculation logic of [Deployment Frequency](https://devlake.apache.org/docs/Metrics/DeploymentFrequency)\n- Data Sources Required: \n - `Deployments` from Jenkins, GitLab CI, GitHub Action, BitBucket Pipelines, or Webhook, etc. \n- Transformation Required: Define `deployments` in [data transformations](https://devlake.apache.org/docs/Configuration/Tutorial#step-3---add-transformations-optional) while configuring the blueprint of a project.",
"mode": "markdown"
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"queryType": "randomWalk",
"refId": "A"
}
],
"type": "text"
},
{
"datasource": "mysql",
"description": "",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "left",
"cellOptions": {
"mode": "basic",
"type": "color-background"
},
"inspect": false
},
"mappings": [
{
"options": {
"DEPLOYMENT": {
"color": "green",
"index": 1
},
"PRODUCTION": {
"color": "green",
"index": 0
},
"SUCCESS": {
"color": "green",
"index": 2
},
"This project is selected": {
"color": "green",
"index": 3
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 5,
"w": 16,
"x": 0,
"y": 6
},
"id": 16,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "SELECT\n\tpm.project_name,\n\tIF(pm.project_name in ($project),'This project is selected','Not Selected') as select_status,\n\tIF(cdc._raw_data_table != '', cdc._raw_data_table, cdc.cicd_scope_id) as _raw_data_table,\n\tresult,\n\tenvironment,\n\tcount(distinct cdc.id) as deployment_commit_count, \n\tcount(distinct cdc.cicd_deployment_id) as deployment_count\nFROM cicd_deployment_commits cdc\nLEFT join project_mapping pm on cdc.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\nWHERE $__timeFilter(cdc.finished_date)\nGROUP BY pm.project_name, select_status, _raw_data_table,result,environment",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 1. All cicd_deployment_commits (the rows with 3 green columns will be used in the following steps)",
"type": "table"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [
{
"options": {
"pattern": ".*elite.*",
"result": {
"color": "purple",
"index": 0
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*high.*",
"result": {
"color": "green",
"index": 1
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*medium.*",
"result": {
"color": "yellow",
"index": 2
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*low.*",
"result": {
"color": "red",
"index": 3
}
},
"type": "regex"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 9,
"w": 8,
"x": 16,
"y": 6
},
"id": 15,
"links": [],
"options": {
"colorMode": "value",
"graphMode": "area",
"justifyMode": "auto",
"orientation": "auto",
"reduceOptions": {
"calcs": [
"lastNotNull"
],
"fields": "/^Deployment Frequency$/",
"values": false
},
"text": {},
"textMode": "auto"
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"editorMode": "code",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "-- Metric 1: Deployment Frequency\nwith last_few_calendar_months as(\n-- construct the last few calendar 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_production_deployment_days as(\n-- When deploying multiple commits in one pipeline, GitLab and BitBucket may generate more than one deployment. However, DevLake consider these deployments as ONE production deployment and use the last one's finished_date as the finished date.\n\tSELECT\n\t\tcdc.cicd_deployment_id as deployment_id,\n\t\tmax(DATE(cdc.finished_date)) as day\n\tFROM cicd_deployment_commits cdc\n\tJOIN project_mapping pm on cdc.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\n\tWHERE\n\t\tpm.project_name in (${project})\n\t\tand cdc.result = 'SUCCESS'\n\t\tand cdc.environment = 'PRODUCTION'\n\tGROUP BY 1\n),\n\n_days_weekly_deploy as(\n-- calculate the number of deployment days every week\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(_production_deployment_days.day is not null, 1, null)) as weeks_deployed,\n\t\t\tCOUNT(distinct _production_deployment_days.day) as days_deployed\n\tFROM \n\t\tlast_few_calendar_months\n\t\tLEFT JOIN _production_deployment_days ON _production_deployment_days.day = last_few_calendar_months.day\n\tGROUP BY week\n\t),\n\n_days_monthly_deploy as(\n-- calculate the number of deployment days every month\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(_production_deployment_days.day is not null, 1, null)) as months_deployed,\n\t\t COUNT(distinct _production_deployment_days.day) as days_deployed\n\tFROM \n\t\tlast_few_calendar_months\n\t\tLEFT JOIN _production_deployment_days ON _production_deployment_days.day = last_few_calendar_months.day\n\tGROUP BY month\n\t),\n\n_days_six_months_deploy AS (\n SELECT\n month,\n SUM(days_deployed) OVER (\n ORDER BY month\n ROWS BETWEEN 5 PRECEDING AND CURRENT ROW\n ) AS days_deployed_per_six_months,\n COUNT(months_deployed) OVER (\n ORDER BY month\n ROWS BETWEEN 5 PRECEDING AND CURRENT ROW\n ) AS months_deployed_count,\n ROW_NUMBER() OVER (\n PARTITION BY DATE_FORMAT(month, '%Y-%m') DIV 6\n ORDER BY month DESC\n ) AS rn\n FROM _days_monthly_deploy\n),\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_weekly_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 days_deployed) as ranks\n\tFROM _days_monthly_deploy\n),\n\n_median_number_of_deployment_days_per_month as(\n\tSELECT max(days_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_days_per_six_months_deploy_by_filter AS (\nSELECT\n month,\n days_deployed_per_six_months,\n months_deployed_count\nFROM _days_six_months_deploy\nWHERE rn%6 = 1\n),\n\n\n_median_number_of_deployment_days_per_six_months_ranks as(\n\tSELECT *, percent_rank() over(order by days_deployed_per_six_months) as ranks\n\tFROM _days_per_six_months_deploy_by_filter\n),\n\n_median_number_of_deployment_days_per_six_months as(\n\tSELECT min(days_deployed_per_six_months) as median_number_of_deployment_days_per_six_months, min(months_deployed_count) as is_collected\n\tFROM _median_number_of_deployment_days_per_six_months_ranks\n\tWHERE ranks >= 0.5\n)\n\nSELECT \n CASE\n WHEN ('$benchmarks') = '2023 report' THEN\n\t\t\tCASE \n\t\t\t\tWHEN median_number_of_deployment_days_per_week >= 7 THEN 'On-demand(elite)'\n\t\t\t\tWHEN median_number_of_deployment_days_per_week >= 1 THEN 'Between once per day and once per week(high)'\n\t\t\t\tWHEN median_number_of_deployment_days_per_month >= 1 THEN 'Between once per week and once per month(medium)'\n\t\t\t\tWHEN median_number_of_deployment_days_per_month < 1 and is_collected != NULL THEN 'Fewer than once per month(low)'\n\t\t\t\tELSE \"N/A. Please check if you have collected deployments.\" END\n\t \tWHEN ('$benchmarks') = '2021 report' THEN\n\t\t\tCASE \n\t\t\t\tWHEN median_number_of_deployment_days_per_week >= 7 THEN 'On-demand(elite)'\n\t\t\t\tWHEN median_number_of_deployment_days_per_month >= 1 THEN 'Between once per day and once per month(high)'\n\t\t\t\tWHEN median_number_of_deployment_days_per_six_months >= 1 THEN 'Between once per month and once every 6 months(medium)'\n\t\t\t\tWHEN median_number_of_deployment_days_per_six_months < 1 and is_collected != NULL THEN 'Fewer than once per six months(low)'\n\t\t\t\tELSE \"N/A. Please check if you have collected deployments.\" END\n\t\tELSE 'Invalid Benchmarks'\n\tEND AS 'Deployment Frequency'\nFROM _median_number_of_deployment_days_per_week, _median_number_of_deployment_days_per_month, _median_number_of_deployment_days_per_six_months",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"sql": {
"columns": [
{
"parameters": [],
"type": "function"
}
],
"groupBy": [
{
"property": {
"type": "string"
},
"type": "groupBy"
}
],
"limit": 50
},
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Figure 1 - Deployment Frequency",
"type": "stat"
},
{
"datasource": "mysql",
"description": "",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "left",
"cellOptions": {
"mode": "basic",
"type": "color-background"
},
"inspect": false
},
"mappings": [
{
"options": {
"DEPLOYMENT": {
"color": "green",
"index": 1
},
"PRODUCTION": {
"color": "green",
"index": 0
},
"SUCCESS": {
"color": "green",
"index": 2
},
"This project is selected": {
"color": "green",
"index": 3
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 5,
"w": 16,
"x": 0,
"y": 11
},
"id": 29,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "SELECT\n\tpm.project_name,\n\tIF(pm.project_name in ($project),'This project is selected','Not Selected') as select_status,\n\tIF(cdc._raw_data_table != '', cdc._raw_data_table, cdc.cicd_scope_id) as _raw_data_table,\n\tresult,\n\tenvironment,\n\tcount(distinct cdc.id) as deployment_commit_count, \n\tcount(distinct cdc.cicd_deployment_id) as deployment_count\nFROM cicd_deployment_commits cdc\njoin project_mapping pm on cdc.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\nWHERE\n pm.project_name in ($project)\n\tand result = 'SUCCESS'\n\tand environment = 'PRODUCTION'\n\tand $__timeFilter(cdc.finished_date)\nGROUP BY 1,2,3,4,5",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 2. Find the number of successful production deployments in this project (Last column)",
"type": "table"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "palette-classic"
},
"custom": {
"axisCenteredZero": false,
"axisColorMode": "text",
"axisLabel": "",
"axisPlacement": "auto",
"axisSoftMin": 0,
"fillOpacity": 80,
"gradientMode": "none",
"hideFrom": {
"legend": false,
"tooltip": false,
"viz": false
},
"lineWidth": 1,
"scaleDistribution": {
"type": "linear"
},
"thresholdsStyle": {
"mode": "off"
}
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
},
{
"color": "red",
"value": 80
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 11,
"w": 8,
"x": 16,
"y": 15
},
"id": 34,
"links": [],
"options": {
"barRadius": 0,
"barWidth": 0.6,
"fullHighlight": false,
"groupWidth": 0.7,
"legend": {
"calcs": [],
"displayMode": "list",
"placement": "bottom",
"showLegend": true
},
"orientation": "auto",
"showValue": "auto",
"stacking": "none",
"text": {},
"tooltip": {
"mode": "single",
"sort": "none"
},
"xTickLabelRotation": 0,
"xTickLabelSpacing": 0
},
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "-- Metric 1: Number of deployments per month\nwith _deployments as(\n-- When deploying multiple commits in one pipeline, GitLab and BitBucket may generate more than one deployment. However, DevLake consider these deployments as ONE production deployment and use the last one's finished_date as the finished date.\n\tSELECT \n\t\tdate_format(deployment_finished_date,'%y/%m') as month,\n\t\tcount(cicd_deployment_id) as deployment_count\n\tFROM (\n\t\tSELECT\n\t\t\tcdc.cicd_deployment_id,\n\t\t\tmax(cdc.finished_date) as deployment_finished_date\n\t\tFROM cicd_deployment_commits cdc\n\t\tJOIN project_mapping pm on cdc.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\n\t\tWHERE\n\t\t\tpm.project_name in ($project)\n\t\t\tand cdc.result = 'SUCCESS'\n\t\t\tand cdc.environment = 'PRODUCTION'\n\t\tGROUP BY 1\n\t\tHAVING $__timeFilter(max(cdc.finished_date))\n\t) _production_deployments\n\tGROUP BY 1\n)\n\nSELECT \n\tcm.month, \n\tcase when d.deployment_count is null then 0 else d.deployment_count end as deployment_count\nFROM \n\tcalendar_months cm\n\tLEFT JOIN _deployments d on cm.month = d.month\n\tWHERE $__timeFilter(cm.month_timestamp)",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_blueprints",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Figure 2 - Monthly deployments",
"type": "barchart"
},
{
"datasource": "mysql",
"description": "",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "left",
"cellOptions": {
"mode": "basic",
"type": "color-background"
},
"inspect": false
},
"mappings": [
{
"options": {
"DEPLOYMENT": {
"color": "green",
"index": 1
},
"PRODUCTION": {
"color": "green",
"index": 0
},
"SUCCESS": {
"color": "green",
"index": 2
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": [
{
"matcher": {
"id": "byName",
"options": "deployment_id"
},
"properties": [
{
"id": "custom.width"
}
]
}
]
},
"gridPos": {
"h": 5,
"w": 16,
"x": 0,
"y": 16
},
"id": 49,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "with _deployment_commit_rank as(\n SELECT\n \tpm.project_name,\n \tIF(cdc._raw_data_table != '', cdc._raw_data_table, cdc.cicd_scope_id) as _raw_data_table,\n \tcdc.id,\n \tcdc.cicd_deployment_id,\n \tcdc.cicd_scope_id,\n \tresult,\n \tenvironment,\n finished_date,\n row_number() over(partition by cdc.cicd_deployment_id order by finished_date desc) as _deployment_commit_rank\n FROM cicd_deployment_commits cdc\n left join project_mapping pm on cdc.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\n WHERE\n pm.project_name in ($project)\n \tand result = 'SUCCESS'\n \tand environment = 'PRODUCTION'\n)\n\nSELECT \n project_name, \n cicd_deployment_id as deployment_id,\n -- a deployment may have multiple deployment_commits\n id as deployment_commit_id, \n result,\n environment,\n finished_date\nFROM _deployment_commit_rank\nWHERE \n _deployment_commit_rank = 1\n and $__timeFilter(finished_date)",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 3. Use the last finished_date of deployment commits as the finished date of deployments in this project",
"type": "table"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "fixed"
},
"custom": {
"align": "auto",
"cellOptions": {
"type": "auto"
},
"inspect": false
},
"mappings": [
{
"options": {
"Between once per month and once every 6 months": {
"color": "yellow",
"index": 1
},
"Between once per week and once per month": {
"color": "green",
"index": 2
},
"Fewer than once per six months": {
"color": "red",
"index": 0
},
"On-demand": {
"color": "purple",
"index": 3
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": [
{
"matcher": {
"id": "byName",
"options": "day"
},
"properties": [
{
"id": "custom.width"
}
]
}
]
},
"gridPos": {
"h": 5,
"w": 8,
"x": 0,
"y": 21
},
"id": 11,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "with _deployment_commit_rank as(\n SELECT\n \tpm.project_name,\n \tIF(cdc._raw_data_table != '', cdc._raw_data_table, cdc.cicd_scope_id) as _raw_data_table,\n \tcdc.id,\n \tcdc.cicd_deployment_id,\n \tcdc.cicd_scope_id,\n \tresult,\n \tenvironment,\n finished_date,\n row_number() over(partition by cdc.cicd_deployment_id order by finished_date desc) as _deployment_commit_rank\n FROM cicd_deployment_commits cdc\n left join project_mapping pm on cdc.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\n WHERE\n pm.project_name in ($project)\n \tand result = 'SUCCESS'\n \tand environment = 'PRODUCTION'\n),\n\n_deployments as (\n SELECT \n project_name, \n cicd_deployment_id as deployment_id,\n -- a deployment may have multiple deployment_commits\n id as deployment_commit_id, \n result,\n environment,\n finished_date\n FROM _deployment_commit_rank\n WHERE \n _deployment_commit_rank = 1\n and $__timeFilter(finished_date)\n)\n\nSELECT\n\tdistinct DATE(finished_date) AS day,\n\tcount(1) as deployment_count\nFROM _deployments\nGROUP BY 1",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 4. Daily deployments in this project [To check Figure 1]",
"type": "table"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"custom": {
"align": "auto",
"cellOptions": {
"type": "auto"
},
"inspect": false
},
"mappings": [
{
"options": {
"Between once per month and once every 6 months": {
"color": "yellow",
"index": 1
},
"Between once per week and once per month": {
"color": "green",
"index": 2
},
"Fewer than once per six months": {
"color": "red",
"index": 0
},
"On-demand": {
"color": "purple",
"index": 3
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": [
{
"matcher": {
"id": "byName",
"options": "day"
},
"properties": [
{
"id": "custom.width"
}
]
}
]
},
"gridPos": {
"h": 5,
"w": 8,
"x": 8,
"y": 21
},
"id": 50,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "with _deployment_commit_rank as(\n SELECT\n \tpm.project_name,\n \tIF(cdc._raw_data_table != '', cdc._raw_data_table, cdc.cicd_scope_id) as _raw_data_table,\n \tcdc.id,\n \tcdc.cicd_deployment_id,\n \tcdc.cicd_scope_id,\n \tresult,\n \tenvironment,\n finished_date,\n row_number() over(partition by cdc.cicd_deployment_id order by finished_date desc) as _deployment_commit_rank\n FROM cicd_deployment_commits cdc\n left join project_mapping pm on cdc.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\n WHERE\n pm.project_name in ($project)\n \tand result = 'SUCCESS'\n \tand environment = 'PRODUCTION'\n),\n\n_deployments as (\n SELECT \n project_name, \n cicd_deployment_id as deployment_id,\n -- a deployment may have multiple deployment_commits\n id as deployment_commit_id, \n result,\n environment,\n finished_date\n FROM _deployment_commit_rank\n WHERE \n _deployment_commit_rank = 1\n and $__timeFilter(finished_date)\n),\n\n_deployment_days as (\n SELECT\n \tdistinct DATE(finished_date) AS day,\n \tcount(1) as deployment_count\n FROM _deployments\n GROUP BY 1\n)\n\nSELECT \n date_format(day,'%y/%m') as month,\n sum(deployment_count) as monthly_deployment_counts\nFROM \n _deployment_days\nGROUP BY 1\nORDER BY 1",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 5. Monthly deployments in this project [To check Figure 2]",
"type": "table"
},
{
"collapsed": false,
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"gridPos": {
"h": 1,
"w": 24,
"x": 0,
"y": 26
},
"id": 28,
"panels": [],
"targets": [
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"refId": "A"
}
],
"title": "Check \"Median Lead Time for Changes\"",
"type": "row"
},
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"gridPos": {
"h": 7,
"w": 24,
"x": 0,
"y": 27
},
"id": 72,
"options": {
"code": {
"language": "plaintext",
"showLineNumbers": false,
"showMiniMap": false
},
"content": "- See the definition and calculation logic of [Median Lead Time for Changes](https://devlake.apache.org/docs/Metrics/LeadTimeForChanges)\n- Data Sources Required: \n - `Deployments` from Jenkins, GitLab CI, GitHub Action, BitBucket Pipelines, or Webhook, etc. \n - `Pull Requests` from GitHub PRs, GitLab MRs, BitBucket PRs, Azure DevOps PRs, etc.\n- Transformation Required: Define `deployments` in [data transformations](https://devlake.apache.org/docs/Configuration/Tutorial#step-3---add-transformations-optional) while configuring the blueprint of a project.\n- Validatation Steps below:\n - Step 1 - check the data integrity of PRs in table `pull_requests`\n - Step 2 - check the data integrity of deployment_commit in table `cicd_deployment_commits`\n - Step 3 - check if a deployment_commit is associated with the correct PR in table `project_pr_metrics`\n - Step 4 - check if metrics like PR Coding/Pickup/Review/Deploy/cycle time are correct in table `project_pr_metrics`\n - Step 5 - check if the median lead time for changes in each month is correct",
"mode": "markdown"
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"queryType": "randomWalk",
"refId": "A"
}
],
"type": "text"
},
{
"datasource": "mysql",
"description": "",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 254, 254, 1)",
"mode": "fixed"
},
"custom": {
"align": "auto",
"cellOptions": {
"mode": "gradient",
"type": "color-background"
},
"inspect": false
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 5,
"w": 16,
"x": 0,
"y": 34
},
"id": 18,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "SELECT\n\tpm.project_name,pr._raw_data_table,count(*) as total_number_of_PRs\nFROM\n\tpull_requests pr \n-- \tjoin project_pr_metrics prm on prm.id = pr.id\n\tjoin project_mapping pm on pr.base_repo_id = pm.row_id AND pm.`table`='repos'\nWHERE\n pm.project_name in ($project)\n-- \tand pr.merged_date is not null\n-- \tand prm.pr_cycle_time is not null\n\tand $__timeFilter(pr.created_date)\nGROUP BY 1,2\n",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 1-1. Check if the total PR number in the selected project(s) is correct",
"type": "table"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [
{
"options": {
"pattern": ".*elite.*",
"result": {
"color": "purple",
"index": 0
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*high.*",
"result": {
"color": "green",
"index": 1
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*medium.*",
"result": {
"color": "yellow",
"index": 2
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*low.*",
"result": {
"color": "red",
"index": 3
}
},
"type": "regex"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 6,
"w": 8,
"x": 16,
"y": 34
},
"id": 40,
"links": [],
"options": {
"colorMode": "value",
"graphMode": "area",
"justifyMode": "auto",
"orientation": "auto",
"reduceOptions": {
"calcs": [
"lastNotNull"
],
"fields": "/^median_change_lead_time$/",
"values": false
},
"text": {},
"textMode": "auto"
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"editorMode": "code",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "-- Metric 2: median lead time for changes\nwith _pr_stats as (\n-- get the cycle time of PRs deployed by the deployments finished in the selected period\n\tSELECT\n\t\tdistinct pr.id,\n\t\tppm.pr_cycle_time\n\tFROM\n\t\tpull_requests pr \n\t\tjoin project_pr_metrics ppm on ppm.id = pr.id\n\t\tjoin project_mapping pm on pr.base_repo_id = pm.row_id and pm.`table` = 'repos'\n\t\tjoin cicd_deployment_commits cdc on ppm.deployment_commit_id = cdc.id\n\tWHERE\n\t pm.project_name in (${project}) \n\t\tand pr.merged_date is not null\n\t\tand ppm.pr_cycle_time is not null\n\t\tand $__timeFilter(cdc.finished_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\nSELECT \n CASE\n WHEN ('$benchmarks') = '2023 report' THEN\n\t\t\tCASE\n\t\t\t\tWHEN median_change_lead_time < 24 * 60 THEN \"Less than one day(elite)\"\n\t\t\t\tWHEN median_change_lead_time < 7 * 24 * 60 THEN \"Between one day and one week(high)\"\n\t\t\t\tWHEN median_change_lead_time < 30 * 24 * 60 THEN \"Between one week and one month(medium)\"\n\t\t\t\tWHEN median_change_lead_time >= 30 * 24 * 60 THEN \"More than one month(low)\"\n\t\t\t\tELSE \"N/A. Please check if you have collected deployments/pull_requests.\"\n\t\t\t\tEND\n WHEN ('$benchmarks') = '2021 report' THEN\n\t\t CASE\n\t\t\t\tWHEN median_change_lead_time < 60 THEN \"Less than one hour(elite)\"\n\t\t\t\tWHEN median_change_lead_time < 7 * 24 * 60 THEN \"Less than one week(high)\"\n\t\t\t\tWHEN median_change_lead_time < 180 * 24 * 60 THEN \"Between one week and six months(medium)\"\n\t\t\t\tWHEN median_change_lead_time >= 180 * 24 * 60 THEN \"More than six months(low)\"\n\t\t\t\tELSE \"N/A. Please check if you have collected deployments/pull_requests.\"\n\t\t\t\tEND\n\t\tELSE 'Invalid Benchmarks'\n\tEND AS median_change_lead_time\nFROM _median_change_lead_time",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"sql": {
"columns": [
{
"parameters": [],
"type": "function"
}
],
"groupBy": [
{
"property": {
"type": "string"
},
"type": "groupBy"
}
],
"limit": 50
},
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Figure 3 - Median Lead Time for Changes",
"type": "stat"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "auto",
"cellOptions": {
"mode": "basic",
"type": "color-background"
},
"filterable": false,
"inspect": false
},
"mappings": [
{
"options": {
"This Project": {
"color": "green",
"index": 0
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "red",
"value": null
}
]
}
},
"overrides": [
{
"matcher": {
"id": "byName",
"options": "merged_date"
},
"properties": [
{
"id": "color"
},
{
"id": "custom.cellOptions",
"value": {
"mode": "basic",
"type": "color-background"
}
}
]
},
{
"matcher": {
"id": "byType",
"options": "time"
},
"properties": [
{
"id": "thresholds",
"value": {
"mode": "absolute",
"steps": [
{
"color": "red",
"value": null
},
{
"color": "green",
"value": 0
}
]
}
}
]
},
{
"matcher": {
"id": "byName",
"options": "project_name"
},
"properties": [
{
"id": "custom.cellOptions",
"value": {
"mode": "basic",
"type": "color-background"
}
}
]
}
]
},
"gridPos": {
"h": 3,
"w": 16,
"x": 0,
"y": 39
},
"id": 53,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "SELECT\n pm.project_name,\n\t-- pr.status,\n\tpr.title,\n\tpr.author_name,\n\tpr.url,\n\tpr.merged_date,\n\tpr.created_date\nFROM\n\tpull_requests pr \n\tjoin project_mapping pm on pr.base_repo_id = pm.row_id AND pm.`table`='repos'\nWHERE\n -- pm.project_name in ($project)\n\tpr.id = '$pr_id'\n\tand $__timeFilter(pr.created_date)\n",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 1-2. Check if the attributes of the selected pull request is correct (Use the Pull Request URL filter above)",
"type": "table"
},
{
"datasource": "mysql",
"description": "",
"fieldConfig": {
"defaults": {
"color": {
"mode": "palette-classic"
},
"custom": {
"axisCenteredZero": false,
"axisColorMode": "text",
"axisLabel": "Hours",
"axisPlacement": "auto",
"axisSoftMin": 0,
"fillOpacity": 80,
"gradientMode": "none",
"hideFrom": {
"legend": false,
"tooltip": false,
"viz": false
},
"lineWidth": 1,
"scaleDistribution": {
"type": "linear"
},
"thresholdsStyle": {
"mode": "off"
}
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 7,
"w": 8,
"x": 16,
"y": 40
},
"id": 38,
"links": [],
"options": {
"barRadius": 0,
"barWidth": 0.7,
"fullHighlight": false,
"groupWidth": 0.7,
"legend": {
"calcs": [],
"displayMode": "list",
"placement": "bottom",
"showLegend": true
},
"orientation": "auto",
"showValue": "auto",
"stacking": "none",
"text": {},
"tooltip": {
"mode": "single",
"sort": "none"
},
"xTickLabelRotation": 0,
"xTickLabelSpacing": 0
},
"pluginVersion": "8.0.6",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"hide": false,
"metricColumn": "none",
"rawQuery": true,
"rawSql": "-- Metric 2: median change lead time per month\nwith _pr_stats as (\n-- get the cycle time of PRs deployed by the deployments finished each month\n\tSELECT\n\t\tdistinct pr.id,\n\t\tdate_format(cdc.finished_date,'%y/%m') as month,\n\t\tppm.pr_cycle_time\n\tFROM\n\t\tpull_requests pr\n\t\tjoin project_pr_metrics ppm on ppm.id = pr.id\n\t\tjoin project_mapping pm on pr.base_repo_id = pm.row_id and pm.`table` = 'repos'\n\t\tjoin cicd_deployment_commits cdc on ppm.deployment_commit_id = cdc.id\n\tWHERE\n\t\tpm.project_name in ($project) \n\t\tand pr.merged_date is not null\n\t\tand ppm.pr_cycle_time is not null\n\t\tand $__timeFilter(cdc.finished_date)\n),\n\n_find_median_clt_each_month_ranks as(\n\tSELECT *, percent_rank() over(PARTITION BY month order by pr_cycle_time) as ranks\n\tFROM _pr_stats\n),\n\n_clt as(\n\tSELECT month, max(pr_cycle_time) as median_change_lead_time\n\tFROM _find_median_clt_each_month_ranks\n\tWHERE ranks <= 0.5\n\tgroup by month\n)\n\nSELECT \n\tcm.month,\n\tcase \n\t\twhen _clt.median_change_lead_time is null then 0 \n\t\telse _clt.median_change_lead_time/60 end as median_change_lead_time_in_hour\nFROM \n\tcalendar_months cm\n\tLEFT JOIN _clt on cm.month = _clt.month\n WHERE $__timeFilter(cm.month_timestamp)",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "ae_projects",
"timeColumn": "ae_create_time",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Figure 4 - Median Lead Time for Changes",
"type": "barchart"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 254, 254, 1)",
"mode": "fixed"
},
"mappings": [
{
"options": {
"from": 1,
"result": {
"color": "green",
"index": 0
},
"to": 10000000
},
"type": "range"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 4,
"w": 16,
"x": 0,
"y": 42
},
"id": 12,
"links": [],
"options": {
"orientation": "auto",
"reduceOptions": {
"calcs": [
"lastNotNull"
],
"fields": "",
"values": false
},
"showThresholdLabels": false,
"showThresholdMarkers": true,
"text": {}
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "select \n count(distinct pr.id) as 'No. of merged PRs in table.pull_requests'\nfrom \n pull_requests pr\n join project_mapping pm on pr.base_repo_id = pm.row_id and pm.`table` = 'repos'\nwhere \n pm.project_name in ($project)\n and pr.merged_date is not null\n",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
},
{
"datasource": "mysql",
"format": "table",
"group": [],
"hide": false,
"metricColumn": "none",
"rawQuery": true,
"rawSql": "select \n count(distinct id) as 'No. of PRs in table.project_pr_metrics'\nfrom \n project_pr_metrics \nwhere \n project_name in ($project)",
"refId": "B",
"select": [
[
{
"params": [
"blueprint_id"
],
"type": "column"
}
]
],
"table": "_devlake_blueprint_labels",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 1-3. Check if the No. of records in project_pr_metrics is the same as the No. of MERGED PRs in the selected project(s)",
"type": "gauge"
},
{
"datasource": "mysql",
"description": "",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "left",
"cellOptions": {
"mode": "basic",
"type": "color-background"
},
"inspect": false
},
"mappings": [
{
"options": {
"DEPLOYMENT": {
"color": "green",
"index": 1
},
"PRODUCTION": {
"color": "green",
"index": 0
},
"SUCCESS": {
"color": "green",
"index": 2
},
"This project is selected": {
"color": "green",
"index": 3
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 4,
"w": 16,
"x": 0,
"y": 46
},
"id": 68,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "SELECT\n\tpm.project_name,\n\tIF(pm.project_name in ($project),'This project is selected','Not Selected') as select_status,\n\tIF(cdc._raw_data_table != '', cdc._raw_data_table, cdc.cicd_scope_id) as _raw_data_table,\n\tresult,\n\tenvironment,\n\tcount(distinct cdc.id) as deployment_commit_count, \n\tcount(distinct cdc.cicd_deployment_id) as deployment_count\nFROM cicd_deployment_commits cdc\njoin project_mapping pm on cdc.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\nWHERE\n pm.project_name in ($project)\n\tand result = 'SUCCESS'\n\tand environment = 'PRODUCTION'\n\tand $__timeFilter(cdc.finished_date)\nGROUP BY 1,2,3,4,5",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 2. Check if the number of successful production deployments in the selected project(s) is correct",
"type": "table"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "auto",
"cellOptions": {
"mode": "basic",
"type": "color-background"
},
"filterable": true,
"inspect": false
},
"mappings": [
{
"options": {
"This Project": {
"color": "green",
"index": 0
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "red",
"value": null
}
]
}
},
"overrides": [
{
"matcher": {
"id": "byName",
"options": "merged_date"
},
"properties": [
{
"id": "custom.cellOptions",
"value": {
"mode": "basic",
"type": "color-background"
}
},
{
"id": "color"
},
{
"id": "thresholds",
"value": {
"mode": "absolute",
"steps": [
{
"color": "red",
"value": null
},
{
"color": "green",
"value": 0
}
]
}
}
]
},
{
"matcher": {
"id": "byName",
"options": "select_status"
},
"properties": [
{
"id": "custom.cellOptions",
"value": {
"mode": "basic",
"type": "color-background"
}
},
{
"id": "mappings",
"value": [
{
"options": {
"This project is selected": {
"color": "green",
"index": 0
}
},
"type": "value"
}
]
}
]
}
]
},
"gridPos": {
"h": 7,
"w": 8,
"x": 16,
"y": 47
},
"id": 51,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "SELECT\n pm.project_name,\n\tIF(pm.project_name in ($project),'This project is selected','Not Selected') as select_status,\n\t-- pr.status,\n\tpr.title,\n -- \tpr.author_name,\n\tpr.url,\n\tpr.merged_date,\n\tpr.created_date\nFROM\n\tpull_requests pr \n\tjoin project_mapping pm on pr.base_repo_id = pm.row_id AND pm.`table`='repos'\nWHERE\n -- pm.project_name in ($project)\n\t$__timeFilter(pr.created_date)\n",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Appendix 1 - All PRs in this project (Only the rows with 2 green columns should appear in project_pr_metrics)",
"type": "table"
},
{
"datasource": "mysql",
"description": "",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "left",
"cellOptions": {
"mode": "basic",
"type": "color-background"
},
"inspect": false
},
"mappings": [
{
"options": {
"NO": {
"color": "red",
"index": 1
},
"YES": {
"color": "green",
"index": 0
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 4,
"w": 16,
"x": 0,
"y": 50
},
"id": 69,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "-- This query can be used to test if the column `deployment_commit_id` is associated with the correct PR\nWITH pr_merge_commits AS (\n\tSELECT\n\t\tppm.id AS pr_id,\n\t\tppm.deployment_commit_id AS id_1,\n\t\tpr.merge_commit_sha,\n\t\tppm.project_name \n\tFROM\n\t\tproject_pr_metrics ppm\n\t\tLEFT JOIN pull_requests pr ON ppm.id = pr.id \n\tWHERE\n\t\tppm.project_name in ($project) \n\t\tAND ppm.id = '$pr_id'\n\t),\n\t_deployment_commits AS (\n\tSELECT DISTINCT\n\t\tcdc1.id AS id_2,\n\t\tcdc1.prev_success_deployment_commit_id,\n\t\tcdc1.commit_sha AS new_commit_sha,\n\t\tcdc2.commit_sha AS old_commit_sha,\n\t\tcdc1.finished_date,\n\t\tcd.commit_sha AS deployed_commits \n\tFROM\n\t\tcicd_deployment_commits cdc1\n\t\tLEFT JOIN cicd_deployment_commits cdc2 ON cdc1.prev_success_deployment_commit_id = cdc2.id\n\t\tJOIN commits_diffs cd ON cdc1.commit_sha = cd.new_commit_sha \n\t\tAND COALESCE ( cdc2.commit_sha, '' ) = cd.old_commit_sha\n\t\tJOIN project_mapping pm ON cdc1.cicd_scope_id = pm.row_id \n\tWHERE\n\t\tcdc1.result = 'SUCCESS' \n\t\tAND cdc1.environment = 'PRODUCTION' \n\t\tAND pm.project_name in ($project)\n\t),\n\t_find_deployment_commit_id_from_pr AS (\n\tSELECT\n\t\tpmc.pr_id,\n\t\tpmc.id_1,\n\t\tpmc.merge_commit_sha,\n\t\tpmc.project_name,\n\t\tdc.id_2,\n\t\tdc.prev_success_deployment_commit_id,\n\t\tdc.deployed_commits,\n\t\trank() over ( PARTITION BY pr_id ORDER BY dc.finished_date ) AS deployment_rank \n\tFROM\n\t\tpr_merge_commits pmc\n\t\tLEFT JOIN _deployment_commits dc ON pmc.merge_commit_sha = dc.deployed_commits \n\t) SELECT\n\tpr_id,\n\t-- If `id_1` equals `id_2`, then pass\n\tid_1 as deployment_commit_id,\n-- \tid_2,\n\tcase when id_1 = COALESCE(id_2,'') then 'YES' else 'NO' end as if_the_mapping_logic_is_correct\nFROM\n\t_find_deployment_commit_id_from_pr \nWHERE\n\tdeployment_rank = 1",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 3. Check if a `pull request` is associated with the correct `depoloyment commit` in table project_pr_metrics",
"type": "table"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
},
{
"color": "red",
"value": 80
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 4,
"w": 12,
"x": 0,
"y": 54
},
"id": 52,
"links": [],
"options": {
"orientation": "auto",
"reduceOptions": {
"calcs": [
"lastNotNull"
],
"fields": "",
"values": false
},
"showThresholdLabels": false,
"showThresholdMarkers": true,
"text": {}
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "with _pr_commit_ranks as(\n select \n pr.id,\n pr.created_date as pr_created_date,\n prc.commit_sha,\n prc.commit_authored_date,\n row_number() over(partition by pr.id order by prc.commit_authored_date asc) as commit_rank\n from \n pull_requests pr\n left join pull_request_commits prc on pr.id = prc.pull_request_id\n where pr.id = '$pr_id'\n)\n\nselect \n id,\n -- commit_sha as first_commit_sha,\n -- commit_authored_date as first_commit_authored_date,\n CEILING(TIMESTAMPDIFF(Second,commit_authored_date,pr_created_date)/60) as 'PR coding time from PRs and commits'\nfrom\n _pr_commit_ranks\nwhere \n commit_rank = 1\n",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
},
{
"datasource": "mysql",
"format": "table",
"group": [],
"hide": false,
"metricColumn": "none",
"rawQuery": true,
"rawSql": "select \n id, \n -- first_commit_sha,\n pr_coding_time as 'PR coding time from project_pr_metrics'\nfrom project_pr_metrics\nwhere id = '$pr_id'",
"refId": "B",
"select": [
[
{
"params": [
"blueprint_id"
],
"type": "column"
}
]
],
"table": "_devlake_blueprint_labels",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 4-1. Check if PR coding time in project_pr_metrics is correct (Adopt the Pull Request filter above)",
"type": "gauge"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 4,
"w": 12,
"x": 12,
"y": 54
},
"id": 54,
"links": [],
"options": {
"orientation": "auto",
"reduceOptions": {
"calcs": [
"lastNotNull"
],
"fields": "",
"values": false
},
"showThresholdLabels": false,
"showThresholdMarkers": true,
"text": {}
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "with _pr_comment_ranks as(\n select \n pr.id as pr_id,\n pr.created_date as pr_created_date,\n prc.id as review_id,\n prc.created_date as review_created_date,\n row_number() over(partition by pr.id order by prc.created_date asc) as comment_rank\n from \n pull_requests pr\n left join pull_request_comments prc on pr.id = prc.pull_request_id\n where \n pr.id = '$pr_id'\n and prc.account_id!=pr.author_id\n)\n\nselect\n pr_id,\n review_id as first_review_id,\n pr_created_date,\n review_created_date as first_review_time,\n CEILING(TIMESTAMPDIFF(second,pr_created_date,review_created_date)/60) as 'PR pickup time from pr_comments'\nfrom \n _pr_comment_ranks\nwhere\n comment_rank = 1\n",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
},
{
"datasource": "mysql",
"format": "table",
"group": [],
"hide": false,
"metricColumn": "none",
"rawQuery": true,
"rawSql": "select \n id, \n -- first_review_id,\n pr_pickup_time as 'PR pickup time from project_pr_metrics'\nfrom project_pr_metrics\nwhere \n id = '$pr_id'\n and project_name in ($project)\n",
"refId": "B",
"select": [
[
{
"params": [
"blueprint_id"
],
"type": "column"
}
]
],
"table": "_devlake_blueprint_labels",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 4-2. Check if PR pickup time in project_pr_metrics is correct (Adopt the Pull Request filter above)",
"type": "gauge"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 4,
"w": 12,
"x": 0,
"y": 58
},
"id": 55,
"links": [],
"options": {
"orientation": "auto",
"reduceOptions": {
"calcs": [
"last"
],
"fields": "",
"values": false
},
"showThresholdLabels": false,
"showThresholdMarkers": true,
"text": {}
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "with _pr_comment_ranks as(\n select \n pr.id as pr_id,\n pr.merged_date as pr_merged_date,\n prc.id as review_id,\n prc.created_date as review_created_date,\n row_number() over(partition by pr.id order by prc.created_date asc) as comment_rank_asc\n from \n pull_requests pr\n left join pull_request_comments prc on pr.id = prc.pull_request_id\n where \n pr.id = '$pr_id'\n and prc.account_id!=pr.author_id\n)\n\nselect\n pr_id,\n review_id as first_review_id,\n review_created_date as first_review_time,\n CEILING(TIMESTAMPDIFF(second,review_created_date,pr_merged_date)/60) as 'PR review time from pr_comments'\nfrom \n _pr_comment_ranks\nwhere\n comment_rank_asc = 1",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
},
{
"datasource": "mysql",
"format": "table",
"group": [],
"hide": false,
"metricColumn": "none",
"rawQuery": true,
"rawSql": "select \n id, \n -- first_review_id,\n pr_review_time as 'PR review time from project_pr_metrics'\nfrom project_pr_metrics\nwhere \n id = '$pr_id'\n and project_name in ($project)\n",
"refId": "B",
"select": [
[
{
"params": [
"blueprint_id"
],
"type": "column"
}
]
],
"table": "_devlake_blueprint_labels",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 4-3. Check if PR review time in project_pr_metrics is correct (Adopt the Pull Request filter above)",
"type": "gauge"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 4,
"w": 12,
"x": 12,
"y": 58
},
"id": 56,
"links": [],
"options": {
"orientation": "auto",
"reduceOptions": {
"calcs": [
"last"
],
"fields": "",
"values": false
},
"showThresholdLabels": false,
"showThresholdMarkers": true,
"text": {}
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "select \n ppm.id as pr_id,\n ppm.deployment_commit_id,\n CEILING(TIMESTAMPDIFF(second,pr.merged_date,cdc.finished_date)/60) as 'PR deploy time from cicd_deployment_commits'\nfrom \n project_pr_metrics ppm\n left join cicd_deployment_commits cdc on ppm.deployment_commit_id = cdc.id\n left join pull_requests pr on ppm.id = pr.id\nwhere \n project_name in ($project)\n and cdc.result = 'SUCCESS'\n and cdc.`environment` = 'PRODUCTION'\n and ppm.id = '$pr_id'",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
},
{
"datasource": "mysql",
"format": "table",
"group": [],
"hide": false,
"metricColumn": "none",
"rawQuery": true,
"rawSql": "select \n id, \n pr_deploy_time as 'PR deploy time from project_pr_metrics'\nfrom project_pr_metrics\nwhere \n id = '$pr_id'\n and project_name in ($project)\n",
"refId": "B",
"select": [
[
{
"params": [
"blueprint_id"
],
"type": "column"
}
]
],
"table": "_devlake_blueprint_labels",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 4-4. Check if PR deploy time in project_pr_metrics is correct (Adopt the Pull Request filter above)",
"type": "gauge"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 4,
"w": 12,
"x": 0,
"y": 62
},
"id": 57,
"links": [],
"options": {
"orientation": "auto",
"reduceOptions": {
"calcs": [
"last"
],
"fields": "",
"values": false
},
"showThresholdLabels": false,
"showThresholdMarkers": true,
"text": {}
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "select \n ppm.id,\n (pr_coding_time + CEILING(TIMESTAMPDIFF(second,pr.created_date,pr.merged_date)/60) + pr_deploy_time) as 'PR cycle time from lower-level metrics',\n ppm.`pr_cycle_time` as 'PR cycle time from project_pr_metrics'\nfrom project_pr_metrics ppm\nleft join pull_requests pr on ppm.id = pr.id\nwhere \n project_name in ($project)\n and pr.id = '$pr_id'",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 4-5. Check if PR cycle time in project_pr_metrics is correct (Adopt the Pull Request filter above)",
"type": "gauge"
},
{
"datasource": "mysql",
"description": "",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"custom": {
"align": "auto",
"cellOptions": {
"type": "auto"
},
"inspect": false
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": [
{
"matcher": {
"id": "byName",
"options": "ranks"
},
"properties": [
{
"id": "mappings",
"value": [
{
"options": {
"from": 0,
"result": {
"color": "green",
"index": 0
},
"to": 0.5
},
"type": "range"
},
{
"options": {
"from": 0.5,
"result": {
"color": "orange",
"index": 1
},
"to": 1
},
"type": "range"
}
]
},
{
"id": "custom.cellOptions",
"value": {
"type": "color-text"
}
}
]
},
{
"matcher": {
"id": "byName",
"options": "month"
},
"properties": [
{
"id": "custom.filterable",
"value": true
}
]
}
]
},
"gridPos": {
"h": 8,
"w": 24,
"x": 0,
"y": 66
},
"id": 70,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"hide": false,
"metricColumn": "none",
"rawQuery": true,
"rawSql": "with _pr_stats as (\n-- get the cycle time of PRs deployed by the deployments finished each month\n\tSELECT\n\t\tdistinct\n\t\tdate_format(cdc.finished_date,'%y/%m') as month,\n\t\tpr.id,\n\t\tppm.pr_cycle_time\n\tFROM\n\t\tpull_requests pr\n\t\tjoin project_pr_metrics ppm on ppm.id = pr.id\n\t\tjoin project_mapping pm on pr.base_repo_id = pm.row_id and pm.`table` = 'repos'\n\t\tjoin cicd_deployment_commits cdc on ppm.deployment_commit_id = cdc.id\n\tWHERE\n\t\tpm.project_name in ($project) \n\t\tand pr.merged_date is not null\n\t\tand ppm.pr_cycle_time is not null\n\t\tand $__timeFilter(cdc.finished_date)\n),\n\n_find_median_clt_each_month_ranks as(\n\tSELECT *, percent_rank() over(PARTITION BY month order by pr_cycle_time) as ranks\n\tFROM _pr_stats\n)\n\nSELECT \n month, \n id, \n pr_cycle_time as change_lead_time_in_minutes, \n pr_cycle_time/60 as change_lead_time_in_hours, \n ranks \nFROM _find_median_clt_each_month_ranks\n",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "ae_projects",
"timeColumn": "ae_create_time",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 5 - check the median change lead time for each month in Figure 4 (Compare the change_lead_time with the max ranks in GREEN before the first occurence of ORANGE in each month)",
"type": "table"
},
{
"collapsed": false,
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"gridPos": {
"h": 1,
"w": 24,
"x": 0,
"y": 74
},
"id": 26,
"panels": [],
"targets": [
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"refId": "A"
}
],
"title": "Check \"Change Failure Rate\" & \"Median Time to Restore Service\"",
"type": "row"
},
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"gridPos": {
"h": 4,
"w": 24,
"x": 0,
"y": 75
},
"id": 66,
"options": {
"code": {
"language": "plaintext",
"showLineNumbers": false,
"showMiniMap": false
},
"content": "- See the definition and calculation logic of [Median Time to Restore Service](https://devlake.apache.org/docs/Metrics/MTTR)\n- Data Sources Required: \n - `Deployments` from Jenkins, GitLab CI, GitHub Action, BitBucket Pipelines, or Webhook, etc. \n - `Incidents` from Jira issues, GitHub issues, TAPD issues, PagerDuty Incidents, etc. \n- Transformation Required: Define `deployments` and `incidents` in [data transformations](https://devlake.apache.org/docs/Configuration/Tutorial#step-3---add-transformations-optional) while configuring the blueprint of a project.",
"mode": "markdown"
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"queryType": "randomWalk",
"refId": "A"
}
],
"type": "text"
},
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"gridPos": {
"h": 4,
"w": 24,
"x": 0,
"y": 79
},
"id": 67,
"options": {
"code": {
"language": "plaintext",
"showLineNumbers": false,
"showMiniMap": false
},
"content": "- See the definition and calculation logic of [Change Failure Rate](https://devlake.apache.org/docs/Metrics/CFR)\n- Data Sources Required: \n - `Deployments` from Jenkins, GitLab CI, GitHub Action, BitBucket Pipelines, or Webhook, etc. \n - `Incidents` from Jira issues, GitHub issues, TAPD issues, PagerDuty Incidents, etc. \n- Transformation Required: Define `deployments` and `incidents` in [data transformations](https://devlake.apache.org/docs/Configuration/Tutorial#step-3---add-transformations-optional) while configuring the blueprint of a project.",
"mode": "markdown"
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"queryType": "randomWalk",
"refId": "A"
}
],
"type": "text"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "auto",
"cellOptions": {
"mode": "gradient",
"type": "color-background"
},
"inspect": false
},
"mappings": [
{
"options": {
"INCIDENT": {
"color": "green",
"index": 0
},
"This project is selected": {
"color": "green",
"index": 1
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 6,
"w": 16,
"x": 0,
"y": 83
},
"id": 31,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "-- get the incident created within the selected time period in the top-right corner\nSELECT\n\tpm.project_name,\n\tIF(pm.project_name in ($project),'This project is selected','Not Selected') as select_status,\n\ti._raw_data_table,\n\ti.type, \n\tcount(1) as issue_count\nFROM\n\tissues i\n join board_issues bi on i.id = bi.issue_id\n join boards b on bi.board_id = b.id\n join project_mapping pm on b.id = pm.row_id and pm.`table` = 'boards'\nWHERE\n pm.project_name in ($project)\n-- \tand i.type = 'INCIDENT'\n\tand $__timeFilter(i.created_date)\nGROUP BY pm.project_name, select_status,i._raw_data_table, i.type",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 1. All types of issues in table.issues (rows with 2 green columns will be used to construct project_issue_metrics)",
"type": "table"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [
{
"options": {
"pattern": ".*elite.*",
"result": {
"color": "purple",
"index": 0
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*high.*",
"result": {
"color": "green",
"index": 1
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*medium.*",
"result": {
"color": "yellow",
"index": 2
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*low.*",
"result": {
"color": "red",
"index": 3
}
},
"type": "regex"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
},
{
"color": "red",
"value": 80
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 10,
"w": 8,
"x": 16,
"y": 83
},
"id": 42,
"links": [],
"options": {
"colorMode": "value",
"graphMode": "area",
"justifyMode": "auto",
"orientation": "auto",
"reduceOptions": {
"calcs": [
"lastNotNull"
],
"fields": "/^median_time_to_resolve$/",
"values": false
},
"text": {},
"textMode": "auto"
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"editorMode": "code",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "-- Metric 3: Median time to restore service \nwith _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 and pm.`table` = 'boards'\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\nSELECT \n CASE\n WHEN ('$benchmarks') = '2023 report' THEN\n\t\t\tCASE\n\t\t\t\tWHEN median_time_to_resolve < 60 THEN \"Less than one hour(elite)\"\n\t\t\t\tWHEN median_time_to_resolve < 24 * 60 THEN \"Less than one day(high)\"\n\t\t\t\tWHEN median_time_to_resolve < 7 * 24 * 60 THEN \"Between one day and one week(medium)\"\n\t\t\t\tWHEN median_time_to_resolve >= 7 * 24 * 60 THEN \"More than one week(low)\"\n\t\t\t\tELSE \"N/A. Please check if you have collected incidents.\"\n\t\t\t\tEND \n\t\tWHEN ('$benchmarks') = '2021 report' THEN\n\t\t\tCASE\n\t\t\t\tWHEN median_time_to_resolve < 60 THEN \"Less than one hour(elite)\"\n\t\t\t\tWHEN median_time_to_resolve < 24 * 60 THEN \"Less than one day(high)\"\n\t\t\t\tWHEN median_time_to_resolve < 7 * 24 * 60 THEN \"Between one day and one week(medium)\"\n\t\t\t\tWHEN median_time_to_resolve >= 7 * 24 * 60 THEN \"More than one week(low)\"\n\t\t\t\tELSE \"N/A. Please check if you have collected incidents.\"\n \t\tEND\n\t\tELSE 'Invalid Benchmarks'\n\tEND AS median_time_to_resolve\nFROM \n\t_median_mttr",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"sql": {
"columns": [
{
"parameters": [],
"type": "function"
}
],
"groupBy": [
{
"property": {
"type": "string"
},
"type": "groupBy"
}
],
"limit": 50
},
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Figure 5 - Median Time to Restore Service",
"type": "stat"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "auto",
"cellOptions": {
"mode": "gradient",
"type": "color-background"
},
"inspect": false
},
"mappings": [
{
"options": {
"INCIDENT": {
"color": "green",
"index": 0
},
"This project is selected": {
"color": "green",
"index": 1
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 4,
"w": 16,
"x": 0,
"y": 89
},
"id": 14,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "-- get the incident created within the selected time period in the top-right corner\nSELECT\n\tpm.project_name,\n\tIF(pm.project_name in ($project),'This project is selected','Not Selected') as select_status,\n\ti._raw_data_table,\n\ti.type, \n\tcount(1) as issue_count\nFROM\n\tissues i\n join board_issues bi on i.id = bi.issue_id\n join boards b on bi.board_id = b.id\n join project_mapping pm on b.id = pm.row_id and pm.`table` = 'boards'\nWHERE\n pm.project_name in ($project)\n\tand i.type = 'INCIDENT'\n\tand $__timeFilter(i.created_date)\nGROUP BY pm.project_name,select_status, i._raw_data_table, i.type",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 2. Number of Incidents in the selected project(s)",
"type": "table"
},
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"gridPos": {
"h": 15,
"w": 16,
"x": 0,
"y": 93
},
"id": 61,
"links": [],
"options": {
"code": {
"language": "plaintext",
"showLineNumbers": false,
"showMiniMap": false
},
"content": "<img src = 'https://devlake.apache.org/assets/images/cfr-definition-94d92cc75f857f183443ad5390d31d65.png' />\n\nIn this case:\n\n- Deployment-1 maps to Incident-1\n- Deployment-3 maps to Incident-2 and Incident-3\n- Deployment-2,4,5 doesn't map to any Incident",
"mode": "markdown"
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"queryType": "randomWalk",
"refId": "A"
}
],
"title": "Deployment - Incident Mapping and CFR calculation logic",
"type": "text"
},
{
"datasource": "mysql",
"description": "",
"fieldConfig": {
"defaults": {
"color": {
"mode": "palette-classic"
},
"custom": {
"axisCenteredZero": false,
"axisColorMode": "text",
"axisLabel": "Hours",
"axisPlacement": "auto",
"axisSoftMin": 0,
"fillOpacity": 80,
"gradientMode": "none",
"hideFrom": {
"legend": false,
"tooltip": false,
"viz": false
},
"lineWidth": 1,
"scaleDistribution": {
"type": "linear"
},
"thresholdsStyle": {
"mode": "off"
}
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
},
{
"color": "red",
"value": 80
}
]
},
"unit": "none"
},
"overrides": [
{
"matcher": {
"id": "byName",
"options": "median_time_to_resolve_in_hour"
},
"properties": [
{
"id": "color",
"value": {
"fixedColor": "blue",
"mode": "fixed"
}
}
]
}
]
},
"gridPos": {
"h": 10,
"w": 8,
"x": 16,
"y": 93
},
"id": 46,
"links": [],
"options": {
"barRadius": 0,
"barWidth": 0.6,
"fullHighlight": false,
"groupWidth": 0.7,
"legend": {
"calcs": [],
"displayMode": "list",
"placement": "bottom",
"showLegend": true
},
"orientation": "auto",
"showValue": "auto",
"stacking": "none",
"text": {},
"tooltip": {
"mode": "single",
"sort": "none"
},
"xTickLabelRotation": 0,
"xTickLabelSpacing": 0
},
"pluginVersion": "8.0.6",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"hide": false,
"metricColumn": "none",
"rawQuery": true,
"rawSql": "-- Metric 3: median time to restore service - MTTR\nwith _incidents as (\n-- get the number of incidents created each month\n\tSELECT\n\t distinct i.id,\n\t\tdate_format(i.created_date,'%y/%m') as month,\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 and pm.`table` = 'boards'\n\tWHERE\n\t pm.project_name in ($project)\n\t\tand i.type = 'INCIDENT'\n\t\tand i.lead_time_minutes is not null\n),\n\n_find_median_mttr_each_month_ranks as(\n\tSELECT *, percent_rank() over(PARTITION BY month order by lead_time_minutes) as ranks\n\tFROM _incidents\n),\n\n_mttr as(\n\tSELECT month, max(lead_time_minutes) as median_time_to_resolve\n\tFROM _find_median_mttr_each_month_ranks\n\tWHERE ranks <= 0.5\n\tGROUP BY month\n)\n\nSELECT \n\tcm.month,\n\tcase \n\t\twhen m.median_time_to_resolve is null then 0 \n\t\telse m.median_time_to_resolve/60 end as median_time_to_resolve_in_hour\nFROM \n\tcalendar_months cm\n\tLEFT JOIN _mttr m on cm.month = m.month\n WHERE $__timeFilter(cm.month_timestamp)",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "ae_projects",
"timeColumn": "ae_create_time",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Figure 6 - Median Time to Restore Service",
"type": "barchart"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [
{
"options": {
"pattern": ".*elite.*",
"result": {
"color": "purple",
"index": 0
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*high.*",
"result": {
"color": "green",
"index": 1
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*medium.*",
"result": {
"color": "yellow",
"index": 2
}
},
"type": "regex"
},
{
"options": {
"pattern": ".*low.*",
"result": {
"color": "red",
"index": 3
}
},
"type": "regex"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 8,
"w": 8,
"x": 16,
"y": 103
},
"id": 44,
"links": [],
"options": {
"colorMode": "value",
"graphMode": "area",
"justifyMode": "auto",
"orientation": "auto",
"reduceOptions": {
"calcs": [
"lastNotNull"
],
"fields": "/^change_failure_rate$/",
"values": false
},
"text": {},
"textMode": "auto"
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"editorMode": "code",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "-- Metric 4: change failure rate\nwith _deployments as (\n-- When deploying multiple commits in one pipeline, GitLab and BitBucket may generate more than one deployment. However, DevLake consider these deployments as ONE production deployment and use the last one's finished_date as the finished date.\n\tSELECT\n\t\tcdc.cicd_deployment_id as deployment_id,\n\t\tmax(cdc.finished_date) as deployment_finished_date\n\tFROM \n\t\tcicd_deployment_commits cdc\n\t\tJOIN project_mapping pm on cdc.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\n\tWHERE\n\t\tpm.project_name in (${project})\n\t\tand cdc.result = 'SUCCESS'\n\t\tand cdc.environment = 'PRODUCTION'\n\tGROUP BY 1\n\tHAVING $__timeFilter(max(cdc.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_is_collected_data as(\n\tSELECT\n CASE \n WHEN COUNT(i.id) = 0 AND COUNT(cdc.id) = 0 THEN 'No All'\n WHEN COUNT(i.id) = 0 THEN 'No Incidents' \n WHEN COUNT(cdc.id) = 0 THEN 'No Deployments'\n END AS is_collected\nFROM\n (SELECT 1) AS dummy\nLEFT JOIN\n issues i ON i.type = 'INCIDENT'\nLEFT JOIN\n cicd_deployment_commits cdc ON 1=1\n)\n\nSELECT\n CASE\n WHEN ('$benchmarks') = '2023 report' THEN\n\t\t\tCASE \n\t\t\t\tWHEN is_collected = \"No All\" THEN \"N/A. Please check if you have collected deployments/incidents.\"\n\t\t\t\tWHEN is_collected = \"No Incidents\" THEN \"N/A. Please check if you have collected incidents.\"\n\t\t\t\tWHEN is_collected = \"No Deployments\" THEN \"N/A. Please check if you have collected deployments.\"\n\t\t\t\tWHEN change_failure_rate <= 5 THEN \"0-5%(elite)\"\n\t\t\t\tWHEN change_failure_rate <= .10 THEN \"5%-10%(high)\"\n\t\t\t\tWHEN change_failure_rate <= .15 THEN \"10%-15%(medium)\"\n\t\t\t\tWHEN change_failure_rate > .15 THEN \"> 15%(low)\"\n\t\t\t\tELSE \"N/A. Please check if you have collected deployments/incidents.\"\n\t\t\t\tEND\n\t\tWHEN ('$benchmarks') = '2021 report' THEN\n\t\t\tCASE \n\t\t\t WHEN is_collected = \"No All\" THEN \"N/A. Please check if you have collected deployments/incidents.\"\n\t\t\t\tWHEN is_collected = \"No Incidents\" THEN \"N/A. Please check if you have collected incidents.\"\n\t\t\t\tWHEN is_collected = \"No Deployments\" THEN \"N/A. Please check if you have collected deployments.\"\n\t\t\t\tWHEN change_failure_rate <= .15 THEN \"0-15%(elite)\"\n\t\t\t\tWHEN change_failure_rate <= .20 THEN \"16%-20%(high)\"\n\t\t\t\tWHEN change_failure_rate <= .30 THEN \"21%-30%(medium)\"\n\t\t\t\tWHEN change_failure_rate > .30 THEN \"> 30%(low)\" \n\t\t\t\tELSE \"N/A. Please check if you have collected deployments/incidents.\"\n\t\t\t\tEND\n\t\tELSE 'Invalid Benchmarks'\n\tEND AS change_failure_rate\nFROM \n\t_change_failure_rate, _is_collected_data",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"sql": {
"columns": [
{
"parameters": [],
"type": "function"
}
],
"groupBy": [
{
"property": {
"type": "string"
},
"type": "groupBy"
}
],
"limit": 50
},
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Figure 7 - Change Failure Rate",
"type": "stat"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "auto",
"cellOptions": {
"mode": "basic",
"type": "color-background"
},
"filterable": true,
"inspect": false
},
"mappings": [
{
"options": {
"DEPLOYMENT": {
"color": "green",
"index": 0
},
"INCIDENT": {
"color": "red",
"index": 1
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 13,
"w": 8,
"x": 0,
"y": 108
},
"id": 58,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "with _deployments as(\n select distinct \n d.cicd_deployment_id as deployment_id,\n d.result,\n d.environment,\n d.finished_date,\n d.cicd_scope_id,\n pm.project_name\n from \n cicd_deployment_commits d\n join project_mapping pm on d.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\n where \n -- only result needs to specified, not envioronment\n d.result = 'SUCCESS'\n -- choose your project_name\n and pm.project_name in ($project)\n),\n\n_incidents as(\n select distinct \n i.id as issue_id,\n i.type,\n i.created_date,\n pm.project_name\n from \n issues i\n join board_issues bi on i.id = bi.issue_id\n join project_mapping pm on bi.board_id = pm.row_id \n where \n i.type = 'INCIDENT'\n -- choose your project_name\n and pm.project_name in ($project)\n)\n\nselect deployment_id as id, 'DEPLOYMENT' as type, finished_date as time from _deployments\nunion\nselect issue_id as id, 'INCIDENT' as type, created_date as time from _incidents\norder by time",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 3. The sequence of DEPLOYMENTS and INCIDENTS",
"type": "table"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "auto",
"cellOptions": {
"mode": "basic",
"type": "color-background"
},
"filterable": true,
"inspect": false
},
"mappings": [
{
"options": {
"FALSE": {
"color": "green",
"index": 1
},
"TRUE": {
"color": "red",
"index": 0
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 13,
"w": 8,
"x": 8,
"y": 108
},
"id": 59,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"editorMode": "code",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "select \n -- in CFR we use deployment_commit_id as the deployment_id in a specific repo\n cdc.cicd_deployment_id as deployment_id,\n cdc.finished_date,\n pim.id as incident_id,\n if (pim.id is not null, 'TRUE', 'FALSE') as has_failure\nfrom \n cicd_deployment_commits cdc\n left join project_issue_metrics pim on cdc.cicd_deployment_id = pim.deployment_id\n left join project_mapping pm on cdc.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\nwhere \n pm.project_name in ($project)\n and $__timeFilter(cdc.finished_date)\norder by 2 desc\n ",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"sql": {
"columns": [
{
"parameters": [],
"type": "function"
}
],
"groupBy": [
{
"property": {
"type": "string"
},
"type": "groupBy"
}
],
"limit": 50
},
"table": "_devlake_tasks",
"timeColumn": "created_at",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Step 4. Check if the DEPLOYMENT and INCIDENT mapping results are consistent with them in step 3 and figure 7&8",
"type": "table"
},
{
"datasource": "mysql",
"description": "",
"fieldConfig": {
"defaults": {
"color": {
"mode": "palette-classic"
},
"custom": {
"axisCenteredZero": false,
"axisColorMode": "text",
"axisLabel": "",
"axisPlacement": "auto",
"axisSoftMin": 0,
"fillOpacity": 80,
"gradientMode": "none",
"hideFrom": {
"legend": false,
"tooltip": false,
"viz": false
},
"lineWidth": 1,
"scaleDistribution": {
"type": "linear"
},
"thresholdsStyle": {
"mode": "off"
}
},
"mappings": [],
"max": 1,
"min": 0,
"thresholds": {
"mode": "percentage",
"steps": [
{
"color": "green",
"value": null
}
]
},
"unit": "percentunit"
},
"overrides": [
{
"matcher": {
"id": "byName",
"options": "change_failure_rate"
},
"properties": [
{
"id": "color",
"value": {
"fixedColor": "blue",
"mode": "fixed"
}
}
]
}
]
},
"gridPos": {
"h": 10,
"w": 8,
"x": 16,
"y": 111
},
"id": 48,
"links": [],
"options": {
"barRadius": 0,
"barWidth": 0.6,
"fullHighlight": false,
"groupWidth": 0.7,
"legend": {
"calcs": [],
"displayMode": "list",
"placement": "bottom",
"showLegend": true
},
"orientation": "auto",
"showValue": "auto",
"stacking": "none",
"text": {
"valueSize": 12
},
"tooltip": {
"mode": "single",
"sort": "none"
},
"xTickLabelRotation": 0,
"xTickLabelSpacing": 0
},
"pluginVersion": "8.0.6",
"targets": [
{
"datasource": "mysql",
"format": "table",
"group": [],
"hide": false,
"metricColumn": "none",
"rawQuery": true,
"rawSql": "-- Metric 4: change failure rate per month\nwith _deployments as (\n-- When deploying multiple commits in one pipeline, GitLab and BitBucket may generate more than one deployment. However, DevLake consider these deployments as ONE production deployment and use the last one's finished_date as the finished date.\n\tSELECT\n\t\tcdc.cicd_deployment_id as deployment_id,\n\t\tmax(cdc.finished_date) as deployment_finished_date\n\tFROM \n\t\tcicd_deployment_commits cdc\n\t\tJOIN project_mapping pm on cdc.cicd_scope_id = pm.row_id and pm.`table` = 'cicd_scopes'\n\tWHERE\n\t\tpm.project_name in ($project)\n\t\tand cdc.result = 'SUCCESS'\n\t\tand cdc.environment = 'PRODUCTION'\n\tGROUP BY 1\n\tHAVING $__timeFilter(max(cdc.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\nSELECT \n\tcm.month,\n\tcfr.change_failure_rate\nFROM \n\tcalendar_months cm\n\tLEFT JOIN _change_failure_rate_for_each_month cfr on cm.month = cfr.month\n\tWHERE $__timeFilter(cm.month_timestamp)",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"table": "ae_projects",
"timeColumn": "ae_create_time",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Figure 8 - Change Failure Rate",
"type": "barchart"
}
],
"refresh": "",
"schemaVersion": 38,
"style": "dark",
"tags": [
"Engineering Leads Dashboard",
"Highlights"
],
"templating": {
"list": [
{
"current": {
"selected": false,
"text": "All",
"value": "$__all"
},
"datasource": "mysql",
"definition": "select distinct name from projects",
"hide": 0,
"includeAll": true,
"label": "Project",
"multi": true,
"name": "project",
"options": [],
"query": "select distinct name from projects",
"refresh": 1,
"regex": "",
"skipUrlSync": false,
"sort": 0,
"type": "query"
},
{
"current": {
"selected": false,
"text": "https://github.com/apache/incubator-devlake/pull/5799",
"value": "github:GithubPullRequest:1:1460714136"
},
"datasource": "mysql",
"definition": "select concat(Url, '--', id) from pull_requests",
"hide": 0,
"includeAll": false,
"label": "Pull Request Url",
"multi": false,
"name": "pr_id",
"options": [],
"query": "select concat(Url, '--', id) from pull_requests",
"refresh": 1,
"regex": "/^(?<text>.*)--(?<value>.*)$/",
"skipUrlSync": false,
"sort": 0,
"type": "query"
},
{
"current": {
"selected": false,
"text": "2023 report",
"value": "2023 report"
},
"datasource": "mysql",
"definition": "select benchmarks from dora_benchmarks",
"hide": 0,
"includeAll": false,
"label": "Benchmarks",
"multi": false,
"name": "benchmarks",
"options": [],
"query": "select benchmarks from dora_benchmarks",
"refresh": 1,
"regex": "",
"skipUrlSync": false,
"sort": 0,
"type": "query"
}
]
},
"time": {
"from": "now-6M",
"to": "now"
},
"timepicker": {},
"timezone": "",
"title": "DORA Validation",
"uid": "KGkUnV-Vz",
"version": 2,
"weekStart": ""
}