diff --git a/queries/changes.sql b/queries/changes.sql index 4b535bda..f868375b 100644 --- a/queries/changes.sql +++ b/queries/changes.sql @@ -1,23 +1,39 @@ -- Changes View: The `change_id` field is a Git commit's ID +WITH + pushes AS ( + SELECT + source, + event_type, + CASE + WHEN source LIKE "github%" THEN JSON_EXTRACT_SCALAR(metadata, '$.repository.full_name') + END + AS metadata_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 + ) SELECT - source, - event_type, + pushes.*, + service_catalog.service, +FROM + pushes +LEFT JOIN + `four_keys.services` AS service_catalog +ON CASE - WHEN source LIKE "github%" THEN JSON_EXTRACT_SCALAR(metadata, '$.repository.full_name') + WHEN pushes.source = "pagerduty" THEN pushes.metadata_service = service_catalog.pagerduty_service + WHEN pushes.source = "github" THEN pushes.metadata_service = service_catalog.github_repository + ELSE FALSE 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 a00d2bc5..792f4b83 100644 --- a/queries/deployments.sql +++ b/queries/deployments.sql @@ -6,7 +6,7 @@ WITH CASE WHEN source LIKE "github%" THEN JSON_EXTRACT_SCALAR(metadata, '$.repository.full_name') END - AS service, + AS metadata_service, id AS deploy_id, time_created, CASE @@ -22,7 +22,7 @@ WITH END AS additional_commits FROM - four_keys.events_raw + `four_keys.events_raw` WHERE ( -- Cloud Build Deployments @@ -33,36 +33,71 @@ WITH OR (source = "argocd" AND JSON_EXTRACT_SCALAR(metadata, '$.status') = "SUCCESS") ) ), + deploys_with_service AS ( + SELECT + deploys.*, + service_catalog.service, + FROM + deploys + LEFT JOIN + `four_keys.services` AS service_catalog + ON + CASE + WHEN deploys.source = "pagerduty" THEN deploys.metadata_service = service_catalog.pagerduty_service + WHEN deploys.source = "github" THEN deploys.metadata_service = service_catalog.github_repository + ELSE FALSE + END + ), changes_raw AS ( SELECT + source, id, metadata AS change_metadata, CASE WHEN source LIKE "github%" THEN JSON_EXTRACT_SCALAR(metadata, '$.repository.full_name') END - AS service + AS metadata_service + FROM + `four_keys.events_raw` + ), + changes_raw_with_service AS ( + SELECT + changes_raw.*, + service_catalog.service, FROM - four_keys.events_raw + changes_raw + LEFT JOIN + `four_keys.services` AS service_catalog + ON + CASE + WHEN changes_raw.source = "pagerduty" THEN changes_raw.metadata_service = service_catalog.pagerduty_service + WHEN changes_raw.source = "github" THEN changes_raw.metadata_service = service_catalog.github_repository + ELSE FALSE + END ), deployment_changes AS ( SELECT - source, + deploys.source, deploys.service, + deploys.metadata_service as deploys_service, + changes_raw.metadata_service as changes_service, deploy_id, deploys.time_created time_created, change_metadata, four_keys.json2array(JSON_EXTRACT(change_metadata, '$.commits')) AS array_commits, main_commit FROM - deploys + deploys_with_service as deploys JOIN - changes_raw + changes_raw_with_service as 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, + deploys_service, + changes_service, deploy_id, time_created, main_commit, @@ -76,4 +111,6 @@ GROUP BY 2, 3, 4, - 5; + 5, + 6, + 7; diff --git a/queries/incidents.sql b/queries/incidents.sql index 11f470be..813907ec 100644 --- a/queries/incidents.sql +++ b/queries/incidents.sql @@ -1,7 +1,8 @@ -- Incidents View SELECT source, - service, + metadata_service, + service_catalog.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, @@ -13,7 +14,7 @@ FROM ( 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, + AS metadata_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') @@ -42,19 +43,29 @@ FROM ( OR event_type LIKE "incident%" OR (event_type = "note" AND JSON_EXTRACT_SCALAR(metadata, '$.object_attributes.noteable_type') = 'Issue') ) AS issue +LEFT JOIN + `four_keys.services` AS service_catalog +ON + CASE + WHEN issue.source = "pagerduty" THEN issue.metadata_service = service_catalog.pagerduty_service + WHEN issue.source = "github" THEN issue.metadata_service = service_catalog.github_repository + ELSE FALSE + END LEFT JOIN ( SELECT time_created, - changes + changes, + service FROM four_keys.deployments d, d.changes ) AS root ON - root.changes = root_cause + ( service_catalog.service = root.service AND root_cause = root.changes ) GROUP BY 1, 2, - 3 + 3, + 4 HAVING MAX(bug) IS TRUE ;