diff --git a/queries/changes.sql b/queries/changes.sql index 711e7328..4b535bda 100644 --- a/queries/changes.sql +++ b/queries/changes.sql @@ -1,10 +1,23 @@ -# Changes Table -SELECT -source, -event_type, -JSON_EXTRACT_SCALAR(commit, '$.id') change_id, -TIMESTAMP_TRUNC(TIMESTAMP(JSON_EXTRACT_SCALAR(commit, '$.timestamp')),second) as time_created, -FROM four_keys.events_raw e, -UNNEST(JSON_EXTRACT_ARRAY(e.metadata, '$.commits')) as commit -WHERE event_type = "push" -GROUP BY 1,2,3,4 \ No newline at end of file +-- Changes View: The `change_id` field is a Git commit's ID +SELECT + source, + event_type, + CASE + WHEN source LIKE "github%" THEN JSON_EXTRACT_SCALAR(metadata, '$.repository.full_name') + END + AS service, + JSON_EXTRACT_SCALAR(commit, '$.id') AS change_id, + TIMESTAMP_TRUNC(TIMESTAMP(JSON_EXTRACT_SCALAR(commit, '$.timestamp')),second) AS time_created +FROM + four_keys.events_raw e, + -- Create a row for each element in the array of `commits` from the `metadata` field. + -- The other fields in the row are repeated for each `commit`. + UNNEST(JSON_EXTRACT_ARRAY(e.metadata, '$.commits')) AS commit +WHERE + event_type = "push" +GROUP BY + 1, + 2, + 3, + 4, + 5 diff --git a/queries/deployments.sql b/queries/deployments.sql index 3fabdb04..a00d2bc5 100644 --- a/queries/deployments.sql +++ b/queries/deployments.sql @@ -1,102 +1,79 @@ -# Deployments Table - -WITH deploys_cloudbuild_github_gitlab AS (# Cloud Build, Github, Gitlab pipelines - SELECT - source, - id as deploy_id, - time_created, - CASE WHEN source = "cloud_build" then JSON_EXTRACT_SCALAR(metadata, '$.substitutions.COMMIT_SHA') - WHEN source like "github%" then JSON_EXTRACT_SCALAR(metadata, '$.deployment.sha') - WHEN source like "gitlab%" then COALESCE( - # Data structure from GitLab Pipelines - JSON_EXTRACT_SCALAR(metadata, '$.commit.id'), - # Data structure from GitLab Deployments - # REGEX to get the commit sha from the URL - REGEXP_EXTRACT( - JSON_EXTRACT_SCALAR(metadata, '$.commit_url'), r".*commit\/(.*)") - ) - WHEN source = "argocd" then JSON_EXTRACT_SCALAR(metadata, '$.commit_sha') end as main_commit, - CASE WHEN source LIKE "github%" THEN ARRAY( - SELECT JSON_EXTRACT_SCALAR(string_element, '$') - FROM UNNEST(JSON_EXTRACT_ARRAY(metadata, '$.deployment.additional_sha')) AS string_element) - ELSE ARRAY[] end as additional_commits - FROM four_keys.events_raw - WHERE ( - # Cloud Build Deployments - (source = "cloud_build" AND JSON_EXTRACT_SCALAR(metadata, '$.status') = "SUCCESS") - # GitHub Deployments - OR (source LIKE "github%" and event_type = "deployment_status" and JSON_EXTRACT_SCALAR(metadata, '$.deployment_status.state') = "success") - # GitLab Pipelines - OR (source LIKE "gitlab%" AND event_type = "pipeline" AND JSON_EXTRACT_SCALAR(metadata, '$.object_attributes.status') = "success") - # GitLab Deployments - OR (source LIKE "gitlab%" AND event_type = "deployment" AND JSON_EXTRACT_SCALAR(metadata, '$.status') = "success") - # ArgoCD Deployments - OR (source = "argocd" AND JSON_EXTRACT_SCALAR(metadata, '$.status') = "SUCCESS") - ) - ), - deploys_tekton AS (# Tekton Pipelines - SELECT - source, - id as deploy_id, - time_created, - IF(JSON_EXTRACT_SCALAR(param, '$.name') = "gitrevision", JSON_EXTRACT_SCALAR(param, '$.value'), Null) as main_commit, - ARRAY[] AS additional_commits - FROM ( - SELECT - id, - TIMESTAMP_TRUNC(time_created, second) as time_created, - source, - four_keys.json2array(JSON_EXTRACT(metadata, '$.data.pipelineRun.spec.params')) params - FROM four_keys.events_raw - WHERE event_type = "dev.tekton.event.pipelinerun.successful.v1" - AND metadata like "%gitrevision%") e, e.params as param - ), - deploys_circleci AS (# CircleCI pipelines - SELECT +-- Deployments View: For GitHub `deploy_id` is the ID of the Deployment Status. +WITH + deploys AS ( -- Cloud Build, GitHub, ArgoCD + SELECT source, + CASE + WHEN source LIKE "github%" THEN JSON_EXTRACT_SCALAR(metadata, '$.repository.full_name') + END + AS service, id AS deploy_id, time_created, - JSON_EXTRACT_SCALAR(metadata, '$.pipeline.vcs.revision') AS main_commit, - ARRAY[] AS additional_commits - FROM four_keys.events_raw - WHERE (source = "circleci" AND event_type = "workflow-completed" AND JSON_EXTRACT_SCALAR(metadata, '$.workflow.name') LIKE "%deploy%" AND JSON_EXTRACT_SCALAR(metadata, '$.workflow.status') = "success") - ), - deploys AS ( - SELECT * FROM - deploys_cloudbuild_github_gitlab - UNION ALL - SELECT * FROM deploys_tekton - UNION ALL - SELECT * FROM deploys_circleci - ), - changes_raw AS ( - SELECT + CASE + WHEN source = "cloud_build" THEN JSON_EXTRACT_SCALAR(metadata, '$.substitutions.COMMIT_SHA') + WHEN source LIKE "github%" THEN JSON_EXTRACT_SCALAR(metadata, '$.deployment.sha') + WHEN source = "argocd" THEN JSON_EXTRACT_SCALAR(metadata, '$.commit_sha') + END + AS main_commit, + CASE + WHEN source LIKE "github%" THEN ARRAY( SELECT JSON_EXTRACT_SCALAR(string_element, '$') FROM UNNEST(JSON_EXTRACT_ARRAY(metadata, '$.deployment.additional_sha')) AS string_element) + ELSE + ARRAY[] + END + AS additional_commits + FROM + four_keys.events_raw + WHERE + ( + -- Cloud Build Deployments + (source = "cloud_build" AND JSON_EXTRACT_SCALAR(metadata, '$.status') = "SUCCESS") + -- GitHub Deployments + OR (source LIKE "github%" AND event_type = "deployment_status" AND JSON_EXTRACT_SCALAR(metadata, '$.deployment_status.state') = "success") + -- ArgoCD Deployments + OR (source = "argocd" AND JSON_EXTRACT_SCALAR(metadata, '$.status') = "SUCCESS") + ) + ), + changes_raw AS ( + SELECT id, - metadata as change_metadata - FROM four_keys.events_raw - ), - deployment_changes as ( - SELECT + metadata AS change_metadata, + CASE + WHEN source LIKE "github%" THEN JSON_EXTRACT_SCALAR(metadata, '$.repository.full_name') + END + AS service + FROM + four_keys.events_raw + ), + deployment_changes AS ( + SELECT source, + deploys.service, deploy_id, deploys.time_created time_created, change_metadata, - four_keys.json2array(JSON_EXTRACT(change_metadata, '$.commits')) as array_commits, + four_keys.json2array(JSON_EXTRACT(change_metadata, '$.commits')) AS array_commits, main_commit - FROM deploys - JOIN - changes_raw on ( - changes_raw.id = deploys.main_commit - or changes_raw.id in unnest(deploys.additional_commits) - ) - ) - - SELECT - source, - deploy_id, - time_created, - main_commit, - ARRAY_AGG(DISTINCT JSON_EXTRACT_SCALAR(array_commits, '$.id')) changes, - FROM deployment_changes - CROSS JOIN deployment_changes.array_commits - GROUP BY 1,2,3,4; + FROM + deploys + JOIN + changes_raw + ON + ( changes_raw.service = deploys.service ) AND ( changes_raw.id = deploys.main_commit OR changes_raw.id IN UNNEST(deploys.additional_commits) ) + ) +SELECT + source, + service, + deploy_id, + time_created, + main_commit, + ARRAY_AGG(DISTINCT JSON_EXTRACT_SCALAR(array_commits, '$.id')) AS changes, +FROM + deployment_changes +CROSS JOIN + deployment_changes.array_commits +GROUP BY + 1, + 2, + 3, + 4, + 5; diff --git a/queries/incidents.sql b/queries/incidents.sql index bd80619e..11f470be 100644 --- a/queries/incidents.sql +++ b/queries/incidents.sql @@ -1,36 +1,60 @@ -# Incidents Table +-- Incidents View SELECT -source, -incident_id, -MIN(IF(root.time_created < issue.time_created, root.time_created, issue.time_created)) as time_created, -MAX(time_resolved) as time_resolved, -ARRAY_AGG(root_cause IGNORE NULLS) changes, -FROM -( -SELECT -source, -CASE WHEN source LIKE "github%" THEN JSON_EXTRACT_SCALAR(metadata, '$.issue.number') - WHEN source LIKE "gitlab%" AND event_type = "note" THEN JSON_EXTRACT_SCALAR(metadata, '$.object_attributes.noteable_id') - WHEN source LIKE "gitlab%" AND event_type = "issue" THEN JSON_EXTRACT_SCALAR(metadata, '$.object_attributes.id') - WHEN source LIKE "pagerduty%" THEN JSON_EXTRACT_SCALAR(metadata, '$.event.data.id') - END AS incident_id, -CASE WHEN source LIKE "github%" THEN TIMESTAMP(JSON_EXTRACT_SCALAR(metadata, '$.issue.created_at')) - WHEN source LIKE "gitlab%" THEN four_keys.multiFormatParseTimestamp(JSON_EXTRACT_SCALAR(metadata, '$.object_attributes.created_at')) - WHEN source LIKE "pagerduty%" THEN TIMESTAMP(JSON_EXTRACT_SCALAR(metadata, '$.event.occurred_at')) - END AS time_created, -CASE WHEN source LIKE "github%" THEN TIMESTAMP(JSON_EXTRACT_SCALAR(metadata, '$.issue.closed_at')) - WHEN source LIKE "gitlab%" THEN four_keys.multiFormatParseTimestamp(JSON_EXTRACT_SCALAR(metadata, '$.object_attributes.closed_at')) - WHEN source LIKE "pagerduty%" THEN TIMESTAMP(JSON_EXTRACT_SCALAR(metadata, '$.event.occurred_at')) - END AS time_resolved, -REGEXP_EXTRACT(metadata, r"root cause: ([[:alnum:]]*)") as root_cause, -CASE WHEN source LIKE "github%" THEN REGEXP_CONTAINS(JSON_EXTRACT(metadata, '$.issue.labels'), '"name":"Incident"') - WHEN source LIKE "gitlab%" THEN REGEXP_CONTAINS(JSON_EXTRACT(metadata, '$.object_attributes.labels'), '"title":"Incident"') - WHEN source LIKE "pagerduty%" THEN TRUE # All Pager Duty events are incident-related - END AS bug, -FROM four_keys.events_raw -WHERE event_type LIKE "issue%" OR event_type LIKE "incident%" OR (event_type = "note" and JSON_EXTRACT_SCALAR(metadata, '$.object_attributes.noteable_type') = 'Issue') -) issue -LEFT JOIN (SELECT time_created, changes FROM four_keys.deployments d, d.changes) root on root.changes = root_cause -GROUP BY 1,2 -HAVING max(bug) is True -; + source, + service, + incident_id, + MIN(IF(root.time_created < issue.time_created, root.time_created, issue.time_created)) AS time_created, + MAX(time_resolved) AS time_resolved, + ARRAY_AGG(root_cause IGNORE NULLS) AS changes, +FROM ( + SELECT + source, + CASE + WHEN source LIKE "github%" THEN JSON_EXTRACT_SCALAR(metadata, '$.repository.full_name') + WHEN source LIKE "pagerduty%" THEN JSON_EXTRACT_SCALAR(metadata, '$.event.data.service.summary') + END + AS service, + CASE + WHEN source LIKE "github%" THEN JSON_EXTRACT_SCALAR(metadata, '$.issue.number') + WHEN source LIKE "pagerduty%" THEN JSON_EXTRACT_SCALAR(metadata, '$.event.data.id') + END + AS incident_id, + CASE + WHEN source LIKE "github%" THEN TIMESTAMP(JSON_EXTRACT_SCALAR(metadata, '$.issue.created_at')) + WHEN source LIKE "pagerduty%" THEN TIMESTAMP(JSON_EXTRACT_SCALAR(metadata, '$.event.occurred_at')) + END + AS time_created, + CASE + WHEN source LIKE "github%" THEN TIMESTAMP(JSON_EXTRACT_SCALAR(metadata, '$.issue.closed_at')) + WHEN source LIKE "pagerduty%" THEN TIMESTAMP(JSON_EXTRACT_SCALAR(metadata, '$.event.occurred_at')) + END + AS time_resolved, + REGEXP_EXTRACT(metadata, r"root cause: ([[:alnum:]]*)") AS root_cause, + CASE + WHEN source LIKE "github%" THEN REGEXP_CONTAINS(JSON_EXTRACT(metadata, '$.issue.labels'), '"name":"Incident"') + WHEN source LIKE "pagerduty%" THEN TRUE # All Pager Duty events are incident-related + END + AS bug, + FROM + four_keys.events_raw + WHERE + event_type LIKE "issue%" + OR event_type LIKE "incident%" + OR (event_type = "note" AND JSON_EXTRACT_SCALAR(metadata, '$.object_attributes.noteable_type') = 'Issue') +) AS issue +LEFT JOIN ( + SELECT + time_created, + changes + FROM + four_keys.deployments d, + d.changes +) AS root +ON + root.changes = root_cause +GROUP BY + 1, + 2, + 3 +HAVING + MAX(bug) IS TRUE ;