blob: f50d124f8ec0eea4a48cbea6cc6fad230fe0dcc8 [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": 41,
"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 explore [DORA](/grafana/d/qNo8_0M4z/dora?orgId=1) and find more details.",
"mode": "markdown"
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": {
"type": "datasource",
"uid": "grafana"
},
"queryType": "randomWalk",
"refId": "A"
}
],
"title": "Dashboard Introduction",
"type": "text"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "auto",
"cellOptions": {
"mode": "gradient",
"type": "color-background"
},
"filterable": true,
"inspect": false
},
"mappings": [
{
"options": {
"FALSE": {
"color": "red",
"index": 1
},
"TRUE": {
"color": "green",
"index": 0
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 16,
"w": 17,
"x": 0,
"y": 2
},
"id": 89,
"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": "-- Metric 3: 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 pim.id as incident_id,\n i.created_date,\n\t\ti.resolution_date,\n\t\tif (pim.id is not null, 'TRUE', 'FALSE') as is_related\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\tORDER BY 2\n)\n\nselect\n*\nfrom _failure_caused_by_deployments",
"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 4. Deployments and Incidents Details",
"type": "table"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 9,
"w": 7,
"x": 17,
"y": 2
},
"id": 44,
"links": [],
"options": {
"orientation": "auto",
"reduceOptions": {
"calcs": [
"lastNotNull"
],
"fields": "/.*/",
"values": false
},
"showThresholdLabels": false,
"showThresholdMarkers": true
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"editorMode": "code",
"format": "table",
"hide": false,
"rawQuery": true,
"rawSql": "-- ***** 2023 report ***** --\n-- Metric 4: Failed deployment recovery time\nwith _deployments as (\n SELECT\n cdc.cicd_deployment_id as deployment_id,\n max(cdc.finished_date) as deployment_finished_date\n FROM \n cicd_deployment_commits cdc\n 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 and cdc.result = 'SUCCESS'\n and cdc.environment = 'PRODUCTION'\n GROUP BY 1\n HAVING $__timeFilter(max(cdc.finished_date))\n)\n\nSELECT \n COUNT(deployment_id)\nFROM _deployments",
"refId": "D",
"sql": {
"columns": [
{
"parameters": [],
"type": "function"
}
],
"groupBy": [
{
"property": {
"type": "string"
},
"type": "groupBy"
}
],
"limit": 50
}
}
],
"title": "4.2 Deployment Count",
"type": "gauge"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 7,
"w": 7,
"x": 17,
"y": 11
},
"id": 88,
"links": [],
"options": {
"orientation": "auto",
"reduceOptions": {
"calcs": [
"lastNotNull"
],
"fields": "/.*/",
"values": false
},
"showThresholdLabels": false,
"showThresholdMarkers": true
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"editorMode": "code",
"format": "table",
"hide": false,
"rawQuery": true,
"rawSql": "-- ***** 2023 report ***** --\n-- Metric 4: Failed deployment recovery time\nwith _deployments as (\n SELECT\n cdc.cicd_deployment_id as deployment_id,\n max(cdc.finished_date) as deployment_finished_date\n FROM \n cicd_deployment_commits cdc\n 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 and cdc.result = 'SUCCESS'\n and cdc.environment = 'PRODUCTION'\n GROUP BY 1\n HAVING $__timeFilter(max(cdc.finished_date))\n),\n\n_incidents_for_deployments as (\n SELECT\n i.id as incident_id,\n i.created_date as incident_create_date,\n i.resolution_date as incident_resolution_date,\n fd.deployment_id as caused_by_deployment,\n fd.deployment_finished_date,\n date_format(fd.deployment_finished_date,'%y/%m') as deployment_finished_month\n FROM\n issues i\n left join project_issue_metrics pim on i.id = pim.id\n join _deployments fd on pim.deployment_id = fd.deployment_id\n WHERE\n i.type = 'INCIDENT'\n and $__timeFilter(i.resolution_date)\n),\n\n-- ***** 2021 report ***** --\n-- Metric 4: 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 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\nSELECT\n COUNT(incident_id) AS total_count\nFROM\n _incidents_for_deployments\n\n\n\n",
"refId": "D",
"sql": {
"columns": [
{
"parameters": [],
"type": "function"
}
],
"groupBy": [
{
"property": {
"type": "string"
},
"type": "groupBy"
}
],
"limit": 50
}
}
],
"title": "4.3 Incident Count",
"type": "gauge"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "rgba(255, 255, 255, 1)",
"mode": "fixed"
},
"custom": {
"align": "auto",
"cellOptions": {
"mode": "gradient",
"type": "color-background"
},
"filterable": true,
"inspect": false
},
"mappings": [
{
"options": {
"FALSE": {
"color": "red",
"index": 1
},
"TRUE": {
"color": "green",
"index": 0
}
},
"type": "value"
}
],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 12,
"w": 17,
"x": 0,
"y": 18
},
"id": 80,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": false,
"fields": "",
"reducer": [
"sum"
],
"show": false
},
"frameIndex": 1,
"showHeader": true,
"sortBy": []
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"editorMode": "code",
"format": "table",
"group": [],
"metricColumn": "none",
"queryType": "randomWalk",
"rawQuery": true,
"rawSql": "-- ***** 2023 report ***** --\n-- Metric 4: Failed deployment recovery time\nwith _deployments as (\n SELECT\n cdc.cicd_deployment_id as deployment_id,\n max(cdc.finished_date) as deployment_finished_date\n FROM \n cicd_deployment_commits cdc\n 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 and cdc.result = 'SUCCESS'\n and cdc.environment = 'PRODUCTION'\n GROUP BY 1\n HAVING $__timeFilter(max(cdc.finished_date))\n),\n\n_incidents_for_deployments as (\n SELECT\n\t\tfd.deployment_id as \"deployment_id\",\n fd.deployment_finished_date,\n date_format(fd.deployment_finished_date,'%y/%m') as deployment_finished_month,\n i.id as incident_id,\n i.created_date as incident_create_date,\n i.resolution_date as incident_resolution_date,\n\t\tTIMESTAMPDIFF(HOUR, fd.deployment_finished_date, i.resolution_date) as \"failed_deployment_recovery_time\"\n FROM\n issues i\n left join project_issue_metrics pim on i.id = pim.id\n join _deployments fd on pim.deployment_id = fd.deployment_id\n WHERE\n i.type = 'INCIDENT'\n and $__timeFilter(i.resolution_date)\n),\n\n\n-- ***** 2021 report ***** --\n-- Metric 4: 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 as \"incident_id\",\n i.resolution_date,\n i.created_date,\n\t cast(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 and i.type = 'INCIDENT'\n and $__timeFilter(i.created_date)\n)\n\nselect \n * \nFROM \n _incidents_for_deployments",
"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": "4.1 Failed deployment recovery time details(2023 dora report)",
"type": "table"
},
{
"datasource": "mysql",
"fieldConfig": {
"defaults": {
"color": {
"mode": "thresholds"
},
"mappings": [],
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "green",
"value": null
}
]
}
},
"overrides": []
},
"gridPos": {
"h": 12,
"w": 7,
"x": 17,
"y": 18
},
"id": 87,
"links": [],
"options": {
"orientation": "auto",
"reduceOptions": {
"calcs": [
"lastNotNull"
],
"fields": "/.*/",
"values": false
},
"showThresholdLabels": false,
"showThresholdMarkers": true
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"editorMode": "code",
"format": "table",
"hide": false,
"rawQuery": true,
"rawSql": "-- ***** 2023 report ***** --\n-- Metric 4: Failed deployment recovery time\nwith _deployments as (\n SELECT\n cdc.cicd_deployment_id as deployment_id,\n max(cdc.finished_date) as deployment_finished_date\n FROM \n cicd_deployment_commits cdc\n 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 and cdc.result = 'SUCCESS'\n and cdc.environment = 'PRODUCTION'\n GROUP BY 1\n HAVING $__timeFilter(max(cdc.finished_date))\n),\n\n_incidents_for_deployments as (\n SELECT\n i.id as incident_id,\n i.created_date as incident_create_date,\n i.resolution_date as incident_resolution_date,\n fd.deployment_id as caused_by_deployment,\n fd.deployment_finished_date,\n date_format(fd.deployment_finished_date,'%y/%m') as deployment_finished_month\n FROM\n issues i\n left join project_issue_metrics pim on i.id = pim.id\n join _deployments fd on pim.deployment_id = fd.deployment_id\n WHERE\n i.type = 'INCIDENT'\n and $__timeFilter(i.resolution_date)\n),\n\n_recovery_time_ranks as (\n SELECT *, percent_rank() over(order by TIMESTAMPDIFF(MINUTE, deployment_finished_date, incident_resolution_date)) as ranks\n FROM _incidents_for_deployments\n),\n\n_median_recovery_time as (\n SELECT max(TIMESTAMPDIFF(MINUTE, deployment_finished_date, incident_resolution_date)) as median_recovery_time\n FROM _recovery_time_ranks\n WHERE ranks <= 0.5\n),\n\n-- ***** 2021 report ***** --\n-- Metric 4: 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 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 median_recovery_time/60 AS median_recovery_time_in_hours\nFROM \n _median_recovery_time\n",
"refId": "D",
"sql": {
"columns": [
{
"parameters": [],
"type": "function"
}
],
"groupBy": [
{
"property": {
"type": "string"
},
"type": "groupBy"
}
],
"limit": 50
}
}
],
"title": "4.4 Failed Deployment Recovery Time In Hour",
"type": "gauge"
}
],
"refresh": "",
"schemaVersion": 38,
"style": "dark",
"tags": [],
"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"
}
]
},
"time": {
"from": "now-6M",
"to": "now"
},
"timepicker": {},
"timezone": "",
"title": "DORA Details - Failed Deployment Recovery Time",
"uid": "Failed-deployment-recovery-time",
"version": 7,
"weekStart": ""
}