2
0
Fork 0
mirror of git://git.savannah.gnu.org/guix/data-service.git synced 2023-12-14 03:23:03 +01:00

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.
This commit is contained in:
Christopher Baines 2020-10-13 19:31:43 +01:00
parent 941d1af556
commit 83884ed2ea
5 changed files with 90 additions and 1 deletions

View file

@ -18,6 +18,7 @@
(define-module (guix-data-service model build-status)
#:use-module (ice-9 match)
#:use-module (squee)
#:use-module (guix-data-service database)
#:use-module (guix-data-service model utils)
#:export (build-statuses
build-status-strings
@ -89,4 +90,50 @@ VALUES "
"
ON CONFLICT DO NOTHING"))
(exec-query conn query '()))
(define (delete-old-latest-status-entries conn)
(define query
(string-append
"
DELETE FROM latest_build_status
WHERE build_id IN ("
(string-join
(map number->string build-ids)
",")
")"))
(exec-query conn query))
(define (insert-new-latest-status-entries conn)
(define query
(string-append
"
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
WHERE build_id IN ("
(string-join
(map number->string build-ids)
",")
")
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
)"))
(exec-query conn query))
(with-postgresql-transaction
conn
(lambda (conn)
(exec-query conn query '())
(delete-old-latest-status-entries conn)
(insert-new-latest-status-entries conn))))

View file

@ -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;

View file

@ -0,0 +1,7 @@
-- Revert guix-data-service:create_latest_build_status from pg
BEGIN;
-- XXX Add DDLs here.
COMMIT;

View file

@ -73,3 +73,4 @@ change_autovacuum_config 2020-10-01T21:24:46Z Christopher Baines <mail@cbaines.n
change_derivation_source_file_nars_constraint 2020-10-02T17:12:58Z Christopher Baines <mail@cbaines.net> # Change derivation source file nars constraint
add_derivation_sources_derivation_source_file_id_index 2020-10-02T19:11:59Z Christopher Baines <mail@cbaines.net> # Add derivation_sources.derivation_source_file_id index
git_repositories_add_fetch_with_authentication_field 2020-10-07T17:31:20Z Christopher Baines <mail@cbaines.net> # Add git_repositories.fetch_with_authentication
create_latest_build_status 2020-10-13T17:22:39Z Christopher Baines <mail@cbaines.net> # Create the latest_build_status table

View file

@ -0,0 +1,7 @@
-- Verify guix-data-service:create_latest_build_status on pg
BEGIN;
-- XXX Add verifications here.
ROLLBACK;