From 8b6a1c80451a579579c41f91059f67f6a5219488 Mon Sep 17 00:00:00 2001 From: Jan Eitzinger Date: Mon, 5 Jun 2023 15:58:07 +0200 Subject: [PATCH] Add migration for job table contraints --- .../migrations/sqlite3/01_init-schema.up.sql | 104 +++++++++--------- .../sqlite3/04_add-constraints.down.sql | 45 ++++++++ .../sqlite3/04_add-constraints.up.sql | 45 ++++++++ 3 files changed, 139 insertions(+), 55 deletions(-) create mode 100644 internal/repository/migrations/sqlite3/04_add-constraints.down.sql create mode 100644 internal/repository/migrations/sqlite3/04_add-constraints.up.sql diff --git a/internal/repository/migrations/sqlite3/01_init-schema.up.sql b/internal/repository/migrations/sqlite3/01_init-schema.up.sql index eab2d8d..7c5bce0 100644 --- a/internal/repository/migrations/sqlite3/01_init-schema.up.sql +++ b/internal/repository/migrations/sqlite3/01_init-schema.up.sql @@ -1,64 +1,58 @@ CREATE TABLE IF NOT EXISTS job ( - id INTEGER PRIMARY KEY, - job_id BIGINT NOT NULL, - cluster VARCHAR(255) NOT NULL, - subcluster VARCHAR(255) NOT NULL, - start_time BIGINT NOT NULL, -- Unix timestamp - - user VARCHAR(255) NOT NULL, - project VARCHAR(255) NOT NULL, - partition VARCHAR(255), - array_job_id BIGINT, - duration INT NOT NULL, - walltime INT NOT NULL, - job_state VARCHAR(255) NOT NULL - CHECK(job_state IN ('running', 'completed', 'failed', 'cancelled', - 'stopped', 'timeout', 'preempted', 'out_of_memory')), - meta_data TEXT, -- JSON - resources TEXT NOT NULL, -- JSON - - num_nodes INT NOT NULL, - num_hwthreads INT, - num_acc INT, - smt TINYINT NOT NULL DEFAULT 1 CHECK(smt IN (0, 1 )), - exclusive TINYINT NOT NULL DEFAULT 1 CHECK(exclusive IN (0, 1, 2)), - monitoring_status TINYINT NOT NULL DEFAULT 1 CHECK(monitoring_status IN (0, 1, 2, 3)), - - mem_used_max REAL NOT NULL DEFAULT 0.0, - flops_any_avg REAL NOT NULL DEFAULT 0.0, - mem_bw_avg REAL NOT NULL DEFAULT 0.0, - load_avg REAL NOT NULL DEFAULT 0.0, - net_bw_avg REAL NOT NULL DEFAULT 0.0, - net_data_vol_total REAL NOT NULL DEFAULT 0.0, - file_bw_avg REAL NOT NULL DEFAULT 0.0, - file_data_vol_total REAL NOT NULL DEFAULT 0.0, - UNIQUE (job_id, cluster, start_time) - ); +id INTEGER PRIMARY KEY, +job_id BIGINT NOT NULL, +cluster VARCHAR(255) NOT NULL, +subcluster VARCHAR(255) NOT NULL, +start_time BIGINT NOT NULL, -- Unix timestamp +user VARCHAR(255) NOT NULL, +project VARCHAR(255) NOT NULL, +partition VARCHAR(255), +array_job_id BIGINT, +duration INT NOT NULL, +walltime INT NOT NULL, +job_state VARCHAR(255) NOT NULL +CHECK(job_state IN ('running', 'completed', 'failed', 'canceled', 'stopped', 'timeout')), +meta_data TEXT, -- JSON +resources TEXT NOT NULL, -- JSON +num_nodes INT NOT NULL, +num_hwthreads INT, +num_acc INT, +smt TINYINT NOT NULL DEFAULT 1 CHECK(smt IN (0, 1 )), +exclusive TINYINT NOT NULL DEFAULT 1 CHECK(exclusive IN (0, 1, 2)), +monitoring_status TINYINT NOT NULL DEFAULT 1 CHECK(monitoring_status IN (0, 1, 2, 3)), +mem_used_max REAL NOT NULL DEFAULT 0.0, +flops_any_avg REAL NOT NULL DEFAULT 0.0, +mem_bw_avg REAL NOT NULL DEFAULT 0.0, +load_avg REAL NOT NULL DEFAULT 0.0, +net_bw_avg REAL NOT NULL DEFAULT 0.0, +net_data_vol_total REAL NOT NULL DEFAULT 0.0, +file_bw_avg REAL NOT NULL DEFAULT 0.0, +file_data_vol_total REAL NOT NULL DEFAULT 0.0; CREATE TABLE IF NOT EXISTS tag ( - id INTEGER PRIMARY KEY, - tag_type VARCHAR(255) NOT NULL, - tag_name VARCHAR(255) NOT NULL, - UNIQUE (tag_type, tag_name)); +id INTEGER PRIMARY KEY, +tag_type VARCHAR(255) NOT NULL, +tag_name VARCHAR(255) NOT NULL, +UNIQUE (tag_type, tag_name)); CREATE TABLE IF NOT EXISTS jobtag ( - job_id INTEGER, - tag_id INTEGER, - PRIMARY KEY (job_id, tag_id), - FOREIGN KEY (job_id) REFERENCES job (id) ON DELETE CASCADE, - FOREIGN KEY (tag_id) REFERENCES tag (id) ON DELETE CASCADE); +job_id INTEGER, +tag_id INTEGER, +PRIMARY KEY (job_id, tag_id), +FOREIGN KEY (job_id) REFERENCES job (id) ON DELETE CASCADE, +FOREIGN KEY (tag_id) REFERENCES tag (id) ON DELETE CASCADE); CREATE TABLE IF NOT EXISTS configuration ( - username varchar(255), - confkey varchar(255), - value varchar(255), - PRIMARY KEY (username, confkey), - FOREIGN KEY (username) REFERENCES user (username) ON DELETE CASCADE ON UPDATE NO ACTION); +username varchar(255), +confkey varchar(255), +value varchar(255), +PRIMARY KEY (username, confkey), +FOREIGN KEY (username) REFERENCES user (username) ON DELETE CASCADE ON UPDATE NO ACTION); CREATE TABLE IF NOT EXISTS user ( - username varchar(255) PRIMARY KEY NOT NULL, - password varchar(255) DEFAULT NULL, - ldap tinyint NOT NULL DEFAULT 0, /* col called "ldap" for historic reasons, fills the "AuthSource" */ - name varchar(255) DEFAULT NULL, - roles varchar(255) NOT NULL DEFAULT "[]", - email varchar(255) DEFAULT NULL); +username varchar(255) PRIMARY KEY NOT NULL, +password varchar(255) DEFAULT NULL, +ldap tinyint NOT NULL DEFAULT 0, /* col called "ldap" for historic reasons, fills the "AuthSource" */ +name varchar(255) DEFAULT NULL, +roles varchar(255) NOT NULL DEFAULT "[]", +email varchar(255) DEFAULT NULL); diff --git a/internal/repository/migrations/sqlite3/04_add-constraints.down.sql b/internal/repository/migrations/sqlite3/04_add-constraints.down.sql new file mode 100644 index 0000000..76540b2 --- /dev/null +++ b/internal/repository/migrations/sqlite3/04_add-constraints.down.sql @@ -0,0 +1,45 @@ +CREATE TABLE IF NOT EXISTS job_new ( +id INTEGER PRIMARY KEY, +job_id BIGINT NOT NULL, +cluster VARCHAR(255) NOT NULL, +subcluster VARCHAR(255) NOT NULL, +start_time BIGINT NOT NULL, -- Unix timestamp +user VARCHAR(255) NOT NULL, +project VARCHAR(255) NOT NULL, +partition VARCHAR(255), +array_job_id BIGINT, +duration INT NOT NULL, +walltime INT NOT NULL, +job_state VARCHAR(255) NOT NULL +CHECK(job_state IN ('running', 'completed', 'failed', 'canceled', 'stopped', 'timeout')), +meta_data TEXT, -- JSON +resources TEXT NOT NULL, -- JSON +num_nodes INT NOT NULL, +num_hwthreads INT, +num_acc INT, +smt TINYINT NOT NULL DEFAULT 1 CHECK(smt IN (0, 1 )), +exclusive TINYINT NOT NULL DEFAULT 1 CHECK(exclusive IN (0, 1, 2)), +monitoring_status TINYINT NOT NULL DEFAULT 1 CHECK(monitoring_status IN (0, 1, 2, 3)), +mem_used_max REAL NOT NULL DEFAULT 0.0, +flops_any_avg REAL NOT NULL DEFAULT 0.0, +mem_bw_avg REAL NOT NULL DEFAULT 0.0, +load_avg REAL NOT NULL DEFAULT 0.0, +net_bw_avg REAL NOT NULL DEFAULT 0.0, +net_data_vol_total REAL NOT NULL DEFAULT 0.0, +file_bw_avg REAL NOT NULL DEFAULT 0.0, +file_data_vol_total REAL NOT NULL DEFAULT 0.0; + + +INSERT INTO job_new SELECT * FROM job; +DROP TABLE job; +ALTER TABLE job_new RENAME TO job; +VACUUM; + +CREATE INDEX IF NOT EXISTS job_stats ON job (cluster,subcluster,user); +CREATE INDEX IF NOT EXISTS job_by_user ON job (user); +CREATE INDEX IF NOT EXISTS job_by_starttime ON job (start_time); +CREATE INDEX IF NOT EXISTS job_by_job_id ON job (job_id, cluster, start_time); +CREATE INDEX IF NOT EXISTS job_list ON job (cluster, job_state); +CREATE INDEX IF NOT EXISTS job_list_user ON job (user, cluster, job_state); +CREATE INDEX IF NOT EXISTS job_list_users ON job (user, job_state); +CREATE INDEX IF NOT EXISTS job_list_users_start ON job (start_time, user, job_state); diff --git a/internal/repository/migrations/sqlite3/04_add-constraints.up.sql b/internal/repository/migrations/sqlite3/04_add-constraints.up.sql new file mode 100644 index 0000000..5bfeb99 --- /dev/null +++ b/internal/repository/migrations/sqlite3/04_add-constraints.up.sql @@ -0,0 +1,45 @@ +CREATE TABLE IF NOT EXISTS job_new ( +id INTEGER PRIMARY KEY, +job_id BIGINT NOT NULL, +cluster VARCHAR(255) NOT NULL, +subcluster VARCHAR(255) NOT NULL, +start_time BIGINT NOT NULL, -- Unix timestamp +user VARCHAR(255) NOT NULL, +project VARCHAR(255) NOT NULL, +partition VARCHAR(255), +array_job_id BIGINT, +duration INT NOT NULL, +walltime INT NOT NULL, +job_state VARCHAR(255) NOT NULL +CHECK(job_state IN ('running', 'completed', 'failed', 'cancelled', 'stopped', 'timeout', 'preempted', 'out_of_memory')), +meta_data TEXT, -- JSON +resources TEXT NOT NULL, -- JSON +num_nodes INT NOT NULL, +num_hwthreads INT, +num_acc INT, +smt TINYINT NOT NULL DEFAULT 1 CHECK(smt IN (0, 1 )), +exclusive TINYINT NOT NULL DEFAULT 1 CHECK(exclusive IN (0, 1, 2)), +monitoring_status TINYINT NOT NULL DEFAULT 1 CHECK(monitoring_status IN (0, 1, 2, 3)), +mem_used_max REAL NOT NULL DEFAULT 0.0, +flops_any_avg REAL NOT NULL DEFAULT 0.0, +mem_bw_avg REAL NOT NULL DEFAULT 0.0, +load_avg REAL NOT NULL DEFAULT 0.0, +net_bw_avg REAL NOT NULL DEFAULT 0.0, +net_data_vol_total REAL NOT NULL DEFAULT 0.0, +file_bw_avg REAL NOT NULL DEFAULT 0.0, +file_data_vol_total REAL NOT NULL DEFAULT 0.0, +UNIQUE (job_id, cluster, start_time)); + +INSERT INTO job_new SELECT * FROM job; +DROP TABLE job; +ALTER TABLE job_new RENAME TO job; +VACUUM; + +CREATE INDEX IF NOT EXISTS job_stats ON job (cluster,subcluster,user); +CREATE INDEX IF NOT EXISTS job_by_user ON job (user); +CREATE INDEX IF NOT EXISTS job_by_starttime ON job (start_time); +CREATE INDEX IF NOT EXISTS job_by_job_id ON job (job_id, cluster, start_time); +CREATE INDEX IF NOT EXISTS job_list ON job (cluster, job_state); +CREATE INDEX IF NOT EXISTS job_list_user ON job (user, cluster, job_state); +CREATE INDEX IF NOT EXISTS job_list_users ON job (user, job_state); +CREATE INDEX IF NOT EXISTS job_list_users_start ON job (start_time, user, job_state);