From 83884ed2ea4369d88b5a323333a6c78dbc471d24 Mon Sep 17 00:00:00 2001 From: Christopher Baines Date: Tue, 13 Oct 2020 19:31:43 +0100 Subject: Add a latest_build_status table This will avoid many queries trying to figure out what the latest build status is, which will hopefuly simplify queries as well as improving performance. --- sqitch/deploy/create_latest_build_status.sql | 27 +++++++++++++++++++++++++++ sqitch/revert/create_latest_build_status.sql | 7 +++++++ sqitch/sqitch.plan | 1 + sqitch/verify/create_latest_build_status.sql | 7 +++++++ 4 files changed, 42 insertions(+) create mode 100644 sqitch/deploy/create_latest_build_status.sql create mode 100644 sqitch/revert/create_latest_build_status.sql create mode 100644 sqitch/verify/create_latest_build_status.sql (limited to 'sqitch') diff --git a/sqitch/deploy/create_latest_build_status.sql b/sqitch/deploy/create_latest_build_status.sql new file mode 100644 index 0000000..982d729 --- /dev/null +++ b/sqitch/deploy/create_latest_build_status.sql @@ -0,0 +1,27 @@ +-- Deploy guix-data-service:create_latest_build_status to pg + +BEGIN; + +CREATE TABLE latest_build_status ( + build_id integer PRIMARY KEY NOT NULL REFERENCES builds(id), + "timestamp" timestamp without time zone DEFAULT clock_timestamp(), + status guix_data_service.buildstatus NOT NULL +); + +INSERT INTO latest_build_status +SELECT DISTINCT build_id, + first_value(timestamp) OVER rows_for_build AS timestamp, + first_value(status) OVER rows_for_build AS status +FROM build_status +WINDOW rows_for_build AS ( + PARTITION BY build_id + ORDER BY + timestamp DESC, + CASE WHEN status = 'scheduled' THEN -2 + WHEN status = 'started' THEN -1 + ELSE 0 + END DESC + RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING +); + +COMMIT; diff --git a/sqitch/revert/create_latest_build_status.sql b/sqitch/revert/create_latest_build_status.sql new file mode 100644 index 0000000..1afce28 --- /dev/null +++ b/sqitch/revert/create_latest_build_status.sql @@ -0,0 +1,7 @@ +-- Revert guix-data-service:create_latest_build_status from pg + +BEGIN; + +-- XXX Add DDLs here. + +COMMIT; diff --git a/sqitch/sqitch.plan b/sqitch/sqitch.plan index 6055c5a..f5b2c33 100644 --- a/sqitch/sqitch.plan +++ b/sqitch/sqitch.plan @@ -73,3 +73,4 @@ change_autovacuum_config 2020-10-01T21:24:46Z Christopher Baines # Change derivation source file nars constraint add_derivation_sources_derivation_source_file_id_index 2020-10-02T19:11:59Z Christopher Baines # Add derivation_sources.derivation_source_file_id index git_repositories_add_fetch_with_authentication_field 2020-10-07T17:31:20Z Christopher Baines # Add git_repositories.fetch_with_authentication +create_latest_build_status 2020-10-13T17:22:39Z Christopher Baines # Create the latest_build_status table diff --git a/sqitch/verify/create_latest_build_status.sql b/sqitch/verify/create_latest_build_status.sql new file mode 100644 index 0000000..a272972 --- /dev/null +++ b/sqitch/verify/create_latest_build_status.sql @@ -0,0 +1,7 @@ +-- Verify guix-data-service:create_latest_build_status on pg + +BEGIN; + +-- XXX Add verifications here. + +ROLLBACK; -- cgit v1.2.3