blob: b300eafc2913ad01e3390f03af7f4af217e96c8e [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": 39,
"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",
"description": "Lead time for changes = median(PR deployed date - PR's first commit's authored date)",
"fieldConfig": {
"defaults": {
"color": {
"fixedColor": "green",
"mode": "thresholds"
},
"custom": {
"align": "auto",
"cellOptions": {
"type": "auto"
},
"filterable": true,
"inspect": false
},
"mappings": [],
"noValue": "0",
"thresholds": {
"mode": "absolute",
"steps": [
{
"color": "purple",
"value": null
},
{
"color": "green",
"value": 24
},
{
"color": "orange",
"value": 168
},
{
"color": "red",
"value": 720
}
]
}
},
"overrides": [
{
"matcher": {
"id": "byName",
"options": "change_lead_time_in_hours"
},
"properties": [
{
"id": "custom.cellOptions",
"value": {
"type": "color-text"
}
}
]
}
]
},
"gridPos": {
"h": 11,
"w": 24,
"x": 0,
"y": 2
},
"id": 70,
"links": [],
"options": {
"cellHeight": "sm",
"footer": {
"countRows": true,
"fields": "",
"reducer": [
"count"
],
"show": true
},
"showHeader": true,
"sortBy": [
{
"desc": true,
"displayName": "change_lead_time_in_hours"
}
]
},
"pluginVersion": "9.5.15",
"targets": [
{
"datasource": "mysql",
"editorMode": "code",
"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\tpr.id,\n\t\tpr.title,\n\t\tpr.url,\n\t\tpr.created_date,\n\t\tppm.first_commit_sha,\n\t\tprc.commit_authored_date,\n\t\tcdc.cicd_deployment_id,\n\t\tcdc.name, \n\t\tcdc.finished_date,\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\t\tjoin pull_request_commits prc on prc.commit_sha = ppm.first_commit_sha\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\nSELECT \n id as \"PR id\",\n\t-- title as \"PR title\",\n\turl as \"PR url\",\n created_date as \"PR created_date\",\n\tfirst_commit_sha as \"First commit sha\",\n\tcommit_authored_date as \"First commit authored date\",\n\tcicd_deployment_id as \"Deployment id\",\n\t-- name as \"Deployment name\", \n\tfinished_date as \"Deployment finished_date\", \n pr_cycle_time/60 as change_lead_time_in_hours\nFROM _pr_stats\n",
"refId": "A",
"select": [
[
{
"params": [
"id"
],
"type": "column"
}
]
],
"sql": {
"columns": [
{
"parameters": [],
"type": "function"
}
],
"groupBy": [
{
"property": {
"type": "string"
},
"type": "groupBy"
}
],
"limit": 50
},
"table": "ae_projects",
"timeColumn": "ae_create_time",
"timeColumnType": "timestamp",
"where": [
{
"name": "$__timeFilter",
"params": [],
"type": "macro"
}
]
}
],
"title": "Figure 2 - PR Details",
"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": 7,
"w": 24,
"x": 0,
"y": 13
},
"id": 40,
"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": "select \n count(distinct pr.id) as 'All PRs'\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 ",
"refId": "D",
"sql": {
"columns": [
{
"parameters": [],
"type": "function"
}
],
"groupBy": [
{
"property": {
"type": "string"
},
"type": "groupBy"
}
],
"limit": 50
}
},
{
"datasource": "mysql",
"editorMode": "code",
"format": "table",
"hide": false,
"rawQuery": true,
"rawSql": "select \n count(distinct pr.id) as 'Merged PRs'\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": "B",
"sql": {
"columns": [
{
"parameters": [],
"type": "function"
}
],
"groupBy": [
{
"property": {
"type": "string"
},
"type": "groupBy"
}
],
"limit": 50
}
},
{
"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\t-- median_change_lead_time/24 as 'median_change_lead_time_in_hours',\n\tCOUNT(distinct id) as \"PRs associated with deployments\"\nFROM _median_change_lead_time, _pr_stats\n-- group by 1",
"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": "2.1 - Number of PRs in different statuses",
"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"
},
{
"current": {
"selected": false,
"text": "2023",
"value": "2023"
},
"datasource": "mysql",
"definition": "select dora_report from dora_benchmarks",
"hide": 0,
"includeAll": false,
"label": "DORA Report",
"multi": false,
"name": "dora_report",
"options": [],
"query": "select dora_report from dora_benchmarks",
"refresh": 1,
"regex": "",
"skipUrlSync": false,
"sort": 0,
"type": "query"
},
{
"current": {
"selected": false,
"text": "Failed Deployment Recovery Time",
"value": "Failed Deployment Recovery Time"
},
"datasource": "mysql",
"definition": "SELECT \n CASE \n WHEN dora_report = '2023' THEN \"Failed Deployment Recovery Time\"\n WHEN dora_report = '2021' THEN \"Median Time to Restore Service\"\n ELSE NULL \n END AS title_value\nFROM dora_benchmarks\nWHERE dora_report = '${dora_report:raw}'",
"hide": 2,
"includeAll": false,
"label": "TitleValue",
"multi": false,
"name": "title_value",
"options": [],
"query": "SELECT \n CASE \n WHEN dora_report = '2023' THEN \"Failed Deployment Recovery Time\"\n WHEN dora_report = '2021' THEN \"Median Time to Restore Service\"\n ELSE NULL \n END AS title_value\nFROM dora_benchmarks\nWHERE dora_report = '${dora_report:raw}'",
"refresh": 1,
"regex": "",
"skipUrlSync": false,
"sort": 0,
"type": "query"
}
]
},
"time": {
"from": "now-6M",
"to": "now"
},
"timepicker": {},
"timezone": "",
"title": "DORA Details - Lead Time for Changes",
"uid": "Lead-time-for-changes",
"version": 8,
"weekStart": ""
}