diff --git a/terraform/services/insights/db-exports/ab2d-prod-benes-searched.sql b/terraform/services/insights/db-exports/ab2d-prod-benes-searched.sql new file mode 100644 index 00000000..a8e3007a --- /dev/null +++ b/terraform/services/insights/db-exports/ab2d-prod-benes-searched.sql @@ -0,0 +1,20 @@ +SELECT cron.schedule_in_database( + 's3_export_ab2d_prod_benes_searched', + '0 */6 * * *', + $$ + SELECT * + FROM aws_s3.query_export_to_s3 + ( + 'SELECT * FROM ab2d_prod_benes_searched', + aws_commons.create_s3_uri + ( + 'ab2d-prod-aurora-export-2025xxxxxxxxxxxxxxxxxxxxxx', + 'ab2d-prod-benes-searched.csv', + 'us-east-1' + ), + options := 'format csv, HEADER true', + kms_key => '' + ); + $$, + 'main' +); diff --git a/terraform/services/insights/db-exports/ab2d-prod-benes-weekly.sql b/terraform/services/insights/db-exports/ab2d-prod-benes-weekly.sql new file mode 100644 index 00000000..630f289d --- /dev/null +++ b/terraform/services/insights/db-exports/ab2d-prod-benes-weekly.sql @@ -0,0 +1,20 @@ +SELECT cron.schedule_in_database( + 's3_export_ab2d_prod_benes_weekly', + '0 */6 * * *', + $$ + SELECT * + FROM aws_s3.query_export_to_s3 + ( + 'SELECT * FROM ab2d_prod_benes_weekly', + aws_commons.create_s3_uri + ( + 'ab2d-prod-aurora-export-2025xxxxxxxxxxxxxxxxxxxxxx', + 'ab2d-prod-benes-weekly.csv', + 'us-east-1' + ), + options :='format csv, HEADER true', + kms_key => '' + ); + $$, + 'main' +); diff --git a/terraform/services/insights/db-exports/ab2d-prod-contracts-one-job-minimum.sql b/terraform/services/insights/db-exports/ab2d-prod-contracts-one-job-minimum.sql new file mode 100644 index 00000000..d22558d4 --- /dev/null +++ b/terraform/services/insights/db-exports/ab2d-prod-contracts-one-job-minimum.sql @@ -0,0 +1,20 @@ +SELECT cron.schedule_in_database( + 's3_export_ab2d_prod_contracts_one_job_minimum', + '0 */6 * * *', + $$ + SELECT * + FROM aws_s3.query_export_to_s3 + ( + 'SELECT * FROM ab2d_prod_contracts_one_job_minimum', + aws_commons.create_s3_uri + ( + 'ab2d-prod-aurora-export-2025xxxxxxxxxxxxxxxxxxxxxx', + 'ab2d-prod-contracts-one-job-minimum.csv', + 'us-east-1' + ), + options :='format csv, HEADER true', + kms_key => '' + ); + $$, + 'main' +); diff --git a/terraform/services/insights/db-exports/ab2d-prod-contracts-view.sql b/terraform/services/insights/db-exports/ab2d-prod-contracts-view.sql new file mode 100644 index 00000000..b9a1d2ac --- /dev/null +++ b/terraform/services/insights/db-exports/ab2d-prod-contracts-view.sql @@ -0,0 +1,20 @@ +SELECT cron.schedule_in_database( + 's3_export_ab2d_prod_contracts_view', + '0 */6 * * *', + $$ + SELECT * + FROM aws_s3.query_export_to_s3 + ( + 'SELECT * FROM ab2d_prod_contracts_view', + aws_commons.create_s3_uri + ( + 'ab2d-prod-aurora-export-2025xxxxxxxxxxxxxxxxxxxxxx', + 'ab2d-prod-contracts-view.csv', + 'us-east-1' + ), + options :='format csv, HEADER true', + kms_key => '' + ); + $$, + 'main' +); diff --git a/terraform/services/insights/db-exports/ab2d-prod-coverage-counts.sql b/terraform/services/insights/db-exports/ab2d-prod-coverage-counts.sql new file mode 100644 index 00000000..6cc6ff64 --- /dev/null +++ b/terraform/services/insights/db-exports/ab2d-prod-coverage-counts.sql @@ -0,0 +1,20 @@ +SELECT cron.schedule_in_database( + 's3_export_ab2d_prod_coverage_counts', + '0 */6 * * *', + $$ + SELECT * + FROM aws_s3.query_export_to_s3 + ( + 'SELECT * FROM ab2d_prod_coverage_counts', + aws_commons.create_s3_uri + ( + 'ab2d-prod-aurora-export-2025xxxxxxxxxxxxxxxxxxxxxx', + 'ab2d-prod-coverage-counts.csv', + 'us-east-1' + ), + options :='format csv, HEADER true', + kms_key => '' + ); + $$, + 'main' +); diff --git a/terraform/services/insights/db-exports/ab2d-prod-eob-search-summaries-1.sql b/terraform/services/insights/db-exports/ab2d-prod-eob-search-summaries-1.sql new file mode 100644 index 00000000..d2feb8c3 --- /dev/null +++ b/terraform/services/insights/db-exports/ab2d-prod-eob-search-summaries-1.sql @@ -0,0 +1,20 @@ +SELECT cron.schedule_in_database( + 's3_export_ab2d_prod_eob_search_summaries_1', + '0 */6 * * *', + $$ + SELECT * + FROM aws_s3.query_export_to_s3 + ( + 'SELECT * FROM ab2d_prod_eob_search_summaries_1', + aws_commons.create_s3_uri + ( + 'ab2d-prod-aurora-export-2025xxxxxxxxxxxxxxxxxxxxxx', + 'ab2d-prod-eob-search-summaries-1.csv', + 'us-east-1' + ), + options :='format csv, header true', + kms_key => '' + ); + $$, + 'main' +); diff --git a/terraform/services/insights/db-exports/ab2d-prod-eob-search-summaries-2.sql b/terraform/services/insights/db-exports/ab2d-prod-eob-search-summaries-2.sql new file mode 100644 index 00000000..4f2ae4c9 --- /dev/null +++ b/terraform/services/insights/db-exports/ab2d-prod-eob-search-summaries-2.sql @@ -0,0 +1,20 @@ +SELECT cron.schedule_in_database( + 's3_export_ab2d_prod_eob_search_summaries_2', + '0 */6 * * *', + $$ + SELECT * + FROM aws_s3.query_export_to_s3 + ( + 'SELECT * FROM ab2d_prod_eob_search_summaries_2', + aws_commons.create_s3_uri + ( + 'ab2d-prod-aurora-export-2025xxxxxxxxxxxxxxxxxxxxxx', + 'ab2d-prod-eob-search-summaries-2.csv', + 'us-east-1' + ), + options :='format csv, HEADER true', + kms_key => '' + ); + $$, + 'main' +); diff --git a/terraform/services/insights/db-exports/ab2d-prod-eob-search-summaries-event.sql b/terraform/services/insights/db-exports/ab2d-prod-eob-search-summaries-event.sql new file mode 100644 index 00000000..dbd3408f --- /dev/null +++ b/terraform/services/insights/db-exports/ab2d-prod-eob-search-summaries-event.sql @@ -0,0 +1,20 @@ +SELECT cron.schedule_in_database( + 's3_export_ab2d_prod_eob_search_summaries_event', + '0 */6 * * *', + $$ + SELECT * + FROM aws_s3.query_export_to_s3 + ( + 'SELECT * FROM ab2d_prod_eob_search_summaries_event', + aws_commons.create_s3_uri + ( + 'ab2d-prod-aurora-export-2025xxxxxxxxxxxxxxxxxxxxxx', + 'ab2d-prod-eob-search-summaries-event.csv', + 'us-east-1' + ), + options :='format csv, HEADER true', + kms_key => '' + ); + $$, + 'main' +); diff --git a/terraform/services/insights/db-exports/ab2d-prod-job-view.sql b/terraform/services/insights/db-exports/ab2d-prod-job-view.sql new file mode 100644 index 00000000..5a191d14 --- /dev/null +++ b/terraform/services/insights/db-exports/ab2d-prod-job-view.sql @@ -0,0 +1,20 @@ +SELECT cron.schedule_in_database( + 's3_export_ab2d_prod_job_view', + '0 */6 * * *', + $$ + SELECT * + FROM aws_s3.query_export_to_s3 + ( + 'SELECT * FROM ab2d_prod_job_view', + aws_commons.create_s3_uri + ( + 'ab2d-prod-aurora-export-2025xxxxxxxxxxxxxxxxxxxxxx', + 'ab2d-prod-job-view.csv', + 'us-east-1' + ), + options :='format csv, HEADER true', + kms_key => '' + ); + $$, + 'main' +); diff --git a/terraform/services/insights/db-exports/ab2d-prod-summary-statistics.sql b/terraform/services/insights/db-exports/ab2d-prod-summary-statistics.sql new file mode 100644 index 00000000..644240e4 --- /dev/null +++ b/terraform/services/insights/db-exports/ab2d-prod-summary-statistics.sql @@ -0,0 +1,20 @@ +SELECT cron.schedule_in_database( + 's3_export_ab2d_prod_summary_statistics', + '0 */6 * * *', + $$ + SELECT * + FROM aws_s3.query_export_to_s3 + ( + 'SELECT * FROM ab2d_prod_summary_statistics', + aws_commons.create_s3_uri + ( + 'ab2d-prod-aurora-export-2025xxxxxxxxxxxxxxxxxxxxxx', + 'ab2d-prod-summary-statistics.csv', + 'us-east-1' + ), + options :='format csv, HEADER true', + kms_key => '' + ); + $$, + 'main' +); diff --git a/terraform/services/insights/db-exports/ab2d-prod-uptime-all.sql b/terraform/services/insights/db-exports/ab2d-prod-uptime-all.sql new file mode 100644 index 00000000..d6256e31 --- /dev/null +++ b/terraform/services/insights/db-exports/ab2d-prod-uptime-all.sql @@ -0,0 +1,20 @@ +SELECT cron.schedule_in_database( + 's3_export_ab2d_prod_uptime_all', + '0 */6 * * *', + $$ + SELECT * + FROM aws_s3.query_export_to_s3 + ( + 'SELECT * FROM ab2d_prod_uptime_all', + aws_commons.create_s3_uri + ( + 'ab2d-prod-aurora-export-2025xxxxxxxxxxxxxxxxxxxxxx', + 'ab2d-prod-uptime-all.csv', + 'us-east-1' + ), + options :='format csv, HEADER true', + kms_key => '' + ); + $$, + 'main' +); diff --git a/terraform/services/insights/views/ab2d-prod-benes-searched.view.sql b/terraform/services/insights/views/ab2d-prod-benes-searched.view.sql new file mode 100644 index 00000000..ac3437ed --- /dev/null +++ b/terraform/services/insights/views/ab2d-prod-benes-searched.view.sql @@ -0,0 +1,53 @@ +CREATE VIEW ab2d_prod_benes_searched AS + SELECT + contract_number, + job_uuid, + benes_searched, + TO_CHAR(created_at, 'yyyy-MM-ddThh:mm:ss') created_at, + TO_CHAR(completed_at, 'yyyy-MM-ddThh:mm:ss') completed_at, + eobs_written, + time_to_complete, + data_start_time, + since, + fhir_version, + status, + contract_number AS "Contract Number", + job_uuid AS "Job ID", + benes_searched AS "# Bene Searched", + completed_at AS "Completed At", + eobs_written AS "# EoBs Written", + data_start_time AS "Data Start Date (Since Date)", + fhir_version AS "FHIR Version", + to_char(time_to_complete, 'HH24:MI:SS') AS "Seconds Run", + TO_CHAR(created_at, 'yyyy-MM-ddThh:mm:ss') "Job Start Time", + TO_CHAR(completed_at, 'yyyy-MM-ddThh:mm:ss') "Job Complete Time", + to_char(time_to_complete, 'HH24:MI:SS') AS sec_run, + TO_CHAR(created_at, 'yyyy-MM-ddThh:mm:ss') job_start_time, + TO_CHAR(completed_at, 'yyyy-MM-ddThh:mm:ss') job_complete_time + FROM ( + SELECT + s.contract_number, + j.job_uuid, + s.benes_searched, + j.created_at, + j.completed_at, + s.eobs_written, + j.completed_at - j.created_at as time_to_complete, + CASE + WHEN j.since is null + THEN + CASE + WHEN c.attested_on < '2020-01-01' + THEN '2020-01-01' + ELSE c.attested_on + END + ELSE j.since + END AS data_start_time, + j.since, + j.fhir_version, + j.status + FROM job j + LEFT JOIN event.event_bene_search s ON s.job_id = j.job_uuid + LEFT JOIN contract_view c ON c.contract_number = j.contract_number + WHERE j.started_by='PDP') t + ORDER BY "Job Start Time" DESC; diff --git a/terraform/services/insights/views/ab2d-prod-benes-weekly.view.sql b/terraform/services/insights/views/ab2d-prod-benes-weekly.view.sql new file mode 100644 index 00000000..7a6d206a --- /dev/null +++ b/terraform/services/insights/views/ab2d-prod-benes-weekly.view.sql @@ -0,0 +1,17 @@ +CREATE VIEW ab2d_prod_benes_weekly AS + SELECT + week_start, + week_end, + SUM(t.total_benes) AS total_benes + FROM ( + SELECT + jv.contract_number, + DATE_TRUNC('day', jv.week_start) AS week_start, + DATE_TRUNC('day', jv.week_end) AS week_end, + MAX(bs.benes_searched) AS total_benes + FROM ab2d.job_view AS jv + LEFT JOIN event.event_bene_search AS bs ON bs.job_id = jv.job_uuid + WHERE jv.status = 'SUCCESSFUL' + GROUP BY jv.contract_number, jv.week_start, jv.week_end) t + GROUP BY t.week_start, t.week_end + ORDER BY week_start DESC; diff --git a/terraform/services/insights/views/ab2d-prod-contracts-one-job-minimum.view.sql b/terraform/services/insights/views/ab2d-prod-contracts-one-job-minimum.view.sql new file mode 100644 index 00000000..d9230854 --- /dev/null +++ b/terraform/services/insights/views/ab2d-prod-contracts-one-job-minimum.view.sql @@ -0,0 +1,6 @@ +CREATE VIEW ab2d_prod_contracts_one_job_minimum AS + SELECT + COUNT(DISTINCT c.contract_number) AS "Contracts, at least 1 Job" + FROM ab2d.contract_view c + INNER JOIN ab2d.job_view j ON j.contract_number = c.contract_number + WHERE c.contract_number NOT LIKE 'Z%'; diff --git a/terraform/services/insights/views/ab2d-prod-contracts-view.view.sql b/terraform/services/insights/views/ab2d-prod-contracts-view.view.sql new file mode 100644 index 00000000..88521989 --- /dev/null +++ b/terraform/services/insights/views/ab2d-prod-contracts-view.view.sql @@ -0,0 +1,16 @@ +CREATE VIEW ab2d_prod_contracts_view AS + SELECT + contract_number, + contract_name, + TO_CHAR(attested_on, 'yyyy-MM-ddThh:mm:ss') attested_on, + TO_CHAR(created, 'yyyy-MM-ddThh:mm:ss') created, + TO_CHAR(modified, 'yyyy-MM-ddThh:mm:ss') modified, + hpms_parent_org_name, + hpms_org_marketing_name, + update_mode, + contract_type, + CASE + WHEN enabled='f' THEN 0 + WHEN enabled='t' THEN 1 + END AS enabled + FROM contract_view; diff --git a/terraform/services/insights/views/ab2d-prod-coverage-counts.view.sql b/terraform/services/insights/views/ab2d-prod-coverage-counts.view.sql new file mode 100644 index 00000000..3aa6920e --- /dev/null +++ b/terraform/services/insights/views/ab2d-prod-coverage-counts.view.sql @@ -0,0 +1,46 @@ +CREATE VIEW ab2d_prod_coverage_counts AS + SELECT + p.contract_number, + MAX( + CASE + WHEN p.service = 'AB2D' + THEN p.count + END + ) AS AB2D, + MAX( + CASE + WHEN p.service = 'HPMS' + THEN p.count + END + ) AS HPMS, + MAX( + CASE + WHEN p.service = 'BFD' + THEN p.count + END + ) AS BFD, + year, + month + FROM ( + SELECT DISTINCT ON ( + contract_number, + service, + year, + month + ) contract_number, + service, + create_at, + count, + year, + month + FROM lambda.coverage_counts + ORDER BY + contract_number, + service, + year, + month, + create_at desc) p + GROUP BY + contract_number, + year, + month; diff --git a/terraform/services/insights/views/ab2d-prod-eob-search-summaries-1.view.sql b/terraform/services/insights/views/ab2d-prod-eob-search-summaries-1.view.sql new file mode 100644 index 00000000..f6d6804d --- /dev/null +++ b/terraform/services/insights/views/ab2d-prod-eob-search-summaries-1.view.sql @@ -0,0 +1,38 @@ +CREATE VIEW ab2d_prod_eob_search_summaries_1 AS + SELECT + event.event_bene_search.id AS "id[event_bene_search]", + TO_CHAR(time_of_event, 'yyyy-MM-ddThh:mm:ss') time_of_event, + job_id, + event.event_bene_search.contract_number AS "contract_number[event_bene_search]", + benes_expected, + benes_searched, + num_opted_out, + benes_errored, + aws_id, + environment, + event.event_bene_search.organization AS "organization[event_bene_search]", + benes_queued, + eobs_fetched, + eobs_written, + eob_files, + benes_with_eobs, + job_view.id AS "id[job_view]", + job_uuid, + TO_CHAR(created_at, 'yyyy-MM-ddThh:mm:ss') created_at, + TO_CHAR(completed_at, 'yyyy-MM-ddThh:mm:ss') completed_at, + TO_CHAR(expires_at, 'yyyy-MM-ddThh:mm:ss') expires_at, + resource_types, + status, + request_url, + output_format, + since, + fhir_version, + year_week, + week_start, + week_end, + job_view.organization AS "organization[job_view]", + job_view.contract_number AS "contract_number[job_view]", + contract_name + FROM event.event_bene_search + RIGHT JOIN job_view + ON job_id = job_uuid; diff --git a/terraform/services/insights/views/ab2d-prod-eob-search-summaries-2.view.sql b/terraform/services/insights/views/ab2d-prod-eob-search-summaries-2.view.sql new file mode 100644 index 00000000..a8aa1153 --- /dev/null +++ b/terraform/services/insights/views/ab2d-prod-eob-search-summaries-2.view.sql @@ -0,0 +1,32 @@ +CREATE VIEW ab2d_prod_eob_search_summaries_2 AS + SELECT + job_uuid, + jv.contract_number, + jv.contract_name, + jv.organization, + TO_CHAR(created_at, 'yyyy-MM-ddThh:mm:ss') created_at, + TO_CHAR(completed_at, 'yyyy-MM-ddThh:mm:ss') completed_at, + TO_CHAR(expires_at, 'yyyy-MM-ddThh:mm:ss') expires_at, + resource_types, + status, + request_url, + output_format, + since, + fhir_version, + year_week, + week_start, + week_end, + benes_expected, + benes_searched, + num_opted_out, + benes_errored, + benes_queued, + eobs_fetched, + eobs_written, + eob_files, + EXTRACT(epoch FROM (completed_at - created_at)) / 60 AS job_time_minutes, + age(date_trunc('minute', completed_at), + date_trunc('minute', created_at))::TEXT AS job_time + FROM event.event_bene_search ebs + RIGHT JOIN job_view jv + ON ebs.job_id = jv.job_uuid; diff --git a/terraform/services/insights/views/ab2d-prod-eob-search-summaries-event.view.sql b/terraform/services/insights/views/ab2d-prod-eob-search-summaries-event.view.sql new file mode 100644 index 00000000..48d699f8 --- /dev/null +++ b/terraform/services/insights/views/ab2d-prod-eob-search-summaries-event.view.sql @@ -0,0 +1,15 @@ +CREATE VIEW ab2d_prod_eob_search_summaries_event AS + SELECT + jv.week_start, + jv.week_end, + jv.contract_number, + jv.job_uuid, + TO_CHAR(jv.created_at, 'yyyy-MM-ddThh:mm:ss') created_at, + TO_CHAR(jv.completed_at, 'yyyy-MM-ddThh:mm:ss') completed_at, + jv.since, + bs.benes_searched, + TO_CHAR(jv.completed_at - jv.created_at,'HH24:MI:SS') time_to_complete + FROM ab2d.job_view AS jv + LEFT JOIN event.event_bene_search AS bs + ON bs.job_id = jv.job_uuid + ORDER BY week_start DESC; diff --git a/terraform/services/insights/views/ab2d-prod-job-view.view.sql b/terraform/services/insights/views/ab2d-prod-job-view.view.sql new file mode 100644 index 00000000..36fa65c5 --- /dev/null +++ b/terraform/services/insights/views/ab2d-prod-job-view.view.sql @@ -0,0 +1,22 @@ +CREATE VIEW ab2d_prod_job_view AS + SELECT + id, + job_uuid, + TO_CHAR(created_at, 'yyyy-MM-ddThh:mm:ss') created_at, + TO_CHAR(completed_at, 'yyyy-MM-ddThh:mm:ss') completed_at, + TO_CHAR(expires_at, 'yyyy-MM-ddThh:mm:ss') expires_at, + resource_types, + status, + request_url, + output_format, + since, + TO_CHAR(until, 'yyyy-MM-ddThh:mm:ss') until, + fhir_version, + year_week, + week_start, + week_end, + organization, + contract_number, + contract_name, + contract_type + FROM job_view; diff --git a/terraform/services/insights/views/ab2d-prod-summary-statistics.view.sql b/terraform/services/insights/views/ab2d-prod-summary-statistics.view.sql new file mode 100644 index 00000000..bc86f991 --- /dev/null +++ b/terraform/services/insights/views/ab2d-prod-summary-statistics.view.sql @@ -0,0 +1,3 @@ +CREATE VIEW ab2d_prod_summary_statistics AS + SELECT * + FROM ab2d_statistics; diff --git a/terraform/services/insights/views/ab2d-prod-uptime-all.view.sql b/terraform/services/insights/views/ab2d-prod-uptime-all.view.sql new file mode 100644 index 00000000..6b9fcc18 --- /dev/null +++ b/terraform/services/insights/views/ab2d-prod-uptime-all.view.sql @@ -0,0 +1,150 @@ +CREATE VIEW ab2d_prod_uptime_all AS + WITH + ranked AS ( + SELECT + service, + state_type, + event_description, + time_of_event, + SUM( + CASE + WHEN prevDate IS NULL THEN 1 + WHEN EXTRACT(epoch FROM (time_of_event - prevDate)) >= 600 THEN 1 + ELSE 0 + END + ) OVER (ORDER BY time_of_event) AS Rnk + FROM ( + SELECT + service, + state_type, + event_description, + time_of_event, + LAG(time_of_event) OVER (ORDER BY time_of_event) AS prevDate + FROM event.event_metrics + ) q1 + ), + rankings AS ( + SELECT + service, + time_of_event, + state_type, + event_description, + DENSE_RANK() OVER (PARTITION BY service ORDER BY time_of_event) + - DENSE_RANK() OVER (PARTITION BY service, Rnk ORDER BY time_of_event) + AS sequence_grouping + FROM ranked + WHERE state_type = 'CONTINUE' + ORDER BY time_of_event ASC + ), + data AS ( + SELECT + service, + event_description, + MIN(time_of_event) AS start_date, + MAX(time_of_event)AS end_date, + MAX(time_of_event) - MIN(time_of_event) AS duration + FROM rankings + GROUP BY + service, + sequence_grouping, + event_description + UNION ALL + SELECT + service, + event_description, + start_date, + end_date, + end_date - start_date AS duration + FROM ( + SELECT + service, + event_description, + time_of_event as start_date, + ( + SELECT time_of_event + FROM event.event_metrics b + WHERE b.service = a.service + AND state_type = 'END' + AND b.time_of_event >= a.time_of_event + ORDER BY b.time_of_event + LIMIT 1 + ) AS end_date + FROM + event.event_metrics a + WHERE state_type = 'START' + GROUP BY + service, + state_type, + event_description, + time_of_event + ORDER BY a.time_of_event + ) strstp + ), + hours AS ( + SELECT + d.hour + FROM generate_series(now() - interval '30 day', now(), interval '1 hour') d(hour)), + MATCHES AS ( + SELECT + m.hour, + 'uptime' as uptime, + COUNT(*) AS ct, + event_description, + service FROM hours m + CROSS JOIN ( + SELECT DISTINCT start_date + FROM data + ) AS i + CROSS JOIN LATERAL ( + SELECT + service, + event_description + FROM + data a + WHERE a.start_date < m.hour + interval '1 hour' + AND (a.end_date >= m.hour OR a.end_date IS NULL) + ORDER BY a.end_date DESC + LIMIT 1 + ) a + GROUP BY + m.hour, + a.service, + event_description + ORDER BY + m.hour, + a.service, + event_description + ), + COMBINED AS ( + SELECT + m.hour, + uptime, + 0 AS up, + event_description + FROM matches m + UNION + SELECT + h.hour, + 'uptime' AS uptime, + 1 as up, + '' as event_description + FROM hours h + ORDER BY hour + ) + SELECT + hour, + uptime, + up, + event_description + FROM ( + SELECT + *, + LAG(up) OVER (PARTITION BY hour ORDER BY hour, up) AS prev_year + FROM combined + GROUP BY + hour, + uptime, + up, + event_description + ) comp + WHERE comp.prev_year IS NULL;