Skip to content

Commit

Permalink
Merge pull request #13 from mozilla-services/update-incidents-view-fo…
Browse files Browse the repository at this point in the history
…r-google-form

Update incidents view for Google Form responses
  • Loading branch information
hackebrot authored May 29, 2024
2 parents 9bd66dc + 88f4eaa commit 442a88b
Showing 1 changed file with 66 additions and 38 deletions.
104 changes: 66 additions & 38 deletions queries/incidents.sql
Original file line number Diff line number Diff line change
@@ -1,4 +1,60 @@
-- Incidents View
WITH
github_pagerduty AS (
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 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')
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')
),
issue AS (
SELECT
*,
NULL as deployment_environment -- Remove this once we collect deployment_environment
FROM
github_pagerduty
UNION ALL
SELECT
source,
github_repo AS metadata_service,
incident_id,
time_created,
time_resolved,
root_cause,
TRUE as bug,
deployment_environment, -- This is expected to always be `production`
FROM
`four_keys.incidents_google_form`
)
SELECT
source,
metadata_service,
Expand All @@ -8,48 +64,15 @@ SELECT
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 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')
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
FROM
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
WHEN issue.source = "google_form" THEN issue.metadata_service = service_catalog.github_repository
ELSE FALSE
END
LEFT JOIN (
Expand All @@ -59,11 +82,16 @@ LEFT JOIN (
service,
environment
FROM
four_keys.deployments d,
`four_keys.deployments` AS d,
d.changes
) AS root
ON
( service_catalog.service = root.service AND root_cause = root.changes )
service_catalog.service = root.service
AND root_cause = root.changes
-- GitHub and PagerDuty incidents don't contain information about the environment.
-- Google Form incidents are always reported for the `production` environment.
-- The following ensures we don't correlate incidents with `staging` deployments.
AND issue.deployment_environment = root.environment
GROUP BY
1,
2,
Expand Down

0 comments on commit 442a88b

Please sign in to comment.