blob: 065e5c5c79b9b204fa8d8c627073cd0d35e3ca2d [file] [log] [blame]
mbligh5456c2b2008-02-15 18:42:55 +00001import os
2
3required_tables = ('machines', 'jobs', 'patches', 'tests', 'test_attributes',
jadmanski0afbb632008-06-06 21:10:57 +00004 'iteration_result')
mbligh5456c2b2008-02-15 18:42:55 +00005
6def migrate_up(manager):
jadmanski0afbb632008-06-06 21:10:57 +00007 manager.execute("SHOW TABLES")
8 tables = [row[0] for row in manager.cursor.fetchall()]
9 db_initialized = True
10 for table in required_tables:
11 if table not in tables:
12 db_initialized = False
13 break
14 if not db_initialized:
15 response = raw_input(
16 'Your tko database does not appear to be initialized. Do '
17 'you want to recreate it (this will result in loss of any '
18 'existing data) (yes/No)? ')
19 if response != 'yes':
20 raise Exception('User has chosen to abort migration')
mbligh5456c2b2008-02-15 18:42:55 +000021
jadmanski0afbb632008-06-06 21:10:57 +000022 manager.execute_script(CREATE_DB_SQL)
mbligh5456c2b2008-02-15 18:42:55 +000023
jadmanski0afbb632008-06-06 21:10:57 +000024 manager.create_migrate_table()
mbligh5456c2b2008-02-15 18:42:55 +000025
26
mblighaa383b72008-03-12 20:11:56 +000027def migrate_down(manager):
jadmanski0afbb632008-06-06 21:10:57 +000028 manager.execute_script(DROP_DB_SQL)
mblighaa383b72008-03-12 20:11:56 +000029
30
31DROP_DB_SQL = """\
mbligh5456c2b2008-02-15 18:42:55 +000032-- drop all views (since they depend on some or all of the following tables)
33DROP VIEW IF EXISTS test_view;
34DROP VIEW IF EXISTS perf_view;
35
36DROP TABLE IF EXISTS brrd_sync;
37DROP TABLE IF EXISTS iteration_result;
38DROP TABLE IF EXISTS test_attributes;
39DROP TABLE IF EXISTS tests;
40DROP TABLE IF EXISTS patches;
41DROP TABLE IF EXISTS jobs;
42DROP TABLE IF EXISTS machines;
43DROP TABLE IF EXISTS kernels;
44DROP TABLE IF EXISTS status;
mblighaa383b72008-03-12 20:11:56 +000045"""
mbligh5456c2b2008-02-15 18:42:55 +000046
mblighaa383b72008-03-12 20:11:56 +000047
48CREATE_DB_SQL = DROP_DB_SQL + """\
mbligh5456c2b2008-02-15 18:42:55 +000049-- status key
50CREATE TABLE status (
jadmanski0afbb632008-06-06 21:10:57 +000051status_idx int(10) unsigned NOT NULL auto_increment PRIMARY KEY , -- numerical status
52word VARCHAR(10) -- status word
mbligh5456c2b2008-02-15 18:42:55 +000053) TYPE=InnoDB;
54
55-- kernel versions
56CREATE TABLE kernels (
57kernel_idx int(10) unsigned NOT NULL auto_increment PRIMARY KEY,
jadmanski0afbb632008-06-06 21:10:57 +000058kernel_hash VARCHAR(35), -- Hash of base + all patches
59base VARCHAR(30), -- Base version without patches
60printable VARCHAR(100) -- Full version with patches
mbligh5456c2b2008-02-15 18:42:55 +000061) TYPE=InnoDB;
62
63-- machines/hosts table
64CREATE TABLE machines (
65machine_idx int(10) unsigned NOT NULL auto_increment PRIMARY KEY,
jadmanski0afbb632008-06-06 21:10:57 +000066hostname VARCHAR(100) unique KEY, -- hostname
67machine_group VARCHAR(80), -- group name
68owner VARCHAR(80) -- owner name
mbligh5456c2b2008-02-15 18:42:55 +000069) TYPE=InnoDB;
70
71-- main jobs table
72CREATE TABLE jobs (
jadmanski0afbb632008-06-06 21:10:57 +000073job_idx int(10) unsigned NOT NULL auto_increment PRIMARY KEY, -- index number
74tag VARCHAR(100) unique KEY, -- job key
mbligh5456c2b2008-02-15 18:42:55 +000075label VARCHAR(100), -- job label assigned by user
76KEY (label),
jadmanski0afbb632008-06-06 21:10:57 +000077username VARCHAR(80), -- user name
mbligh5456c2b2008-02-15 18:42:55 +000078KEY (username),
jadmanski0afbb632008-06-06 21:10:57 +000079machine_idx INT(10) unsigned NOT NULL, -- reference to machine table
mbligh5456c2b2008-02-15 18:42:55 +000080KEY (machine_idx),
81FOREIGN KEY (machine_idx) REFERENCES machines(machine_idx) ON DELETE CASCADE
82) TYPE=InnoDB;
83
84-- One entry per patch used, anywhere
85CREATE TABLE patches (
jadmanski0afbb632008-06-06 21:10:57 +000086kernel_idx INT(10) unsigned NOT NULL, -- index number
87name VARCHAR(80), -- short name
88url VARCHAR(300), -- full URL
mbligh5456c2b2008-02-15 18:42:55 +000089hash VARCHAR(35),
90KEY (kernel_idx),
91FOREIGN KEY (kernel_idx) REFERENCES kernels(kernel_idx) ON DELETE CASCADE
92) TYPE=InnoDB;
93
94-- test functional results
95CREATE TABLE tests (
jadmanski0afbb632008-06-06 21:10:57 +000096test_idx int(10) unsigned NOT NULL auto_increment PRIMARY KEY, -- index number
97job_idx INTEGER, -- ref to job table
98test VARCHAR(30), -- name of test
99subdir VARCHAR(60), -- subdirectory name
100kernel_idx INT(10) unsigned NOT NULL, -- kernel test was AGAINST
mbligh5456c2b2008-02-15 18:42:55 +0000101KEY (kernel_idx),
102FOREIGN KEY (kernel_idx) REFERENCES kernels(kernel_idx) ON DELETE CASCADE,
jadmanski0afbb632008-06-06 21:10:57 +0000103status int(10) unsigned NOT NULL, -- test status
mbligh5456c2b2008-02-15 18:42:55 +0000104KEY (status),
105FOREIGN KEY (status) REFERENCES status(status_idx) ON DELETE CASCADE,
jadmanski0afbb632008-06-06 21:10:57 +0000106reason VARCHAR(100), -- reason for test status
107machine_idx INT(10) unsigned NOT NULL, -- reference to machine table
mbligh5456c2b2008-02-15 18:42:55 +0000108KEY (machine_idx),
109FOREIGN KEY (machine_idx) REFERENCES machines(machine_idx) ON DELETE CASCADE,
110invalid BOOL NOT NULL
111) TYPE=InnoDB;
112
113-- test attributes (key value pairs at a test level)
114CREATE TABLE test_attributes (
jadmanski0afbb632008-06-06 21:10:57 +0000115test_idx int(10) unsigned NOT NULL, -- ref to test table
mbligh5456c2b2008-02-15 18:42:55 +0000116FOREIGN KEY (test_idx) REFERENCES tests(test_idx) ON DELETE CASCADE,
jadmanski0afbb632008-06-06 21:10:57 +0000117attribute VARCHAR(30), -- attribute name (e.g. 'version')
118value VARCHAR(100), -- attribute value
mbligh5456c2b2008-02-15 18:42:55 +0000119KEY `test_idx` (`test_idx`)
120) TYPE=InnoDB;
121
122-- test performance results
123CREATE TABLE iteration_result(
jadmanski0afbb632008-06-06 21:10:57 +0000124test_idx int(10) unsigned NOT NULL, -- ref to test table
mbligh5456c2b2008-02-15 18:42:55 +0000125FOREIGN KEY (test_idx) REFERENCES tests(test_idx) ON DELETE CASCADE,
jadmanski0afbb632008-06-06 21:10:57 +0000126iteration INTEGER, -- integer
127attribute VARCHAR(30), -- attribute name (e.g. 'throughput')
128value FLOAT, -- attribute value (eg 700.1)
mbligh5456c2b2008-02-15 18:42:55 +0000129KEY `test_idx` (`test_idx`)
130) TYPE=InnoDB;
131
132-- BRRD syncronization
133CREATE TABLE brrd_sync (
jadmanski0afbb632008-06-06 21:10:57 +0000134test_idx int(10) unsigned NOT NULL, -- ref to test table
mbligh5456c2b2008-02-15 18:42:55 +0000135FOREIGN KEY (test_idx) REFERENCES tests(test_idx) ON DELETE CASCADE
136) TYPE=InnoDB;
137
138-- test_view (to make life easier for people trying to mine data)
139CREATE VIEW test_view AS
jadmanski0afbb632008-06-06 21:10:57 +0000140SELECT tests.test_idx,
141 tests.job_idx,
142 tests.test,
143 tests.subdir,
144 tests.kernel_idx,
145 tests.status,
146 tests.reason,
147 tests.machine_idx,
148 jobs.tag AS job_tag,
149 jobs.label AS job_label,
150 jobs.username AS job_username,
151 machines.hostname AS machine_hostname,
152 machines.machine_group,
153 machines.owner AS machine_owner,
154 kernels.kernel_hash,
155 kernels.base AS kernel_base,
156 kernels.printable AS kernel_printable,
157 status.word AS status_word
mbligh5456c2b2008-02-15 18:42:55 +0000158FROM tests
159INNER JOIN jobs ON jobs.job_idx = tests.job_idx
160INNER JOIN machines ON machines.machine_idx = jobs.machine_idx
161INNER JOIN kernels ON kernels.kernel_idx = tests.kernel_idx
162INNER JOIN status ON status.status_idx = tests.status;
163
164-- perf_view (to make life easier for people trying to mine performance data)
165CREATE VIEW perf_view AS
jadmanski0afbb632008-06-06 21:10:57 +0000166SELECT tests.test_idx,
167 tests.job_idx,
168 tests.test,
169 tests.subdir,
170 tests.kernel_idx,
171 tests.status,
172 tests.reason,
173 tests.machine_idx,
174 jobs.tag AS job_tag,
175 jobs.label AS job_label,
176 jobs.username AS job_username,
177 machines.hostname AS machine_hostname,
178 machines.machine_group,
179 machines.owner AS machine_owner,
180 kernels.kernel_hash,
181 kernels.base AS kernel_base,
182 kernels.printable AS kernel_printable,
183 status.word AS status_word,
184 iteration_result.iteration,
185 iteration_result.attribute AS iteration_key,
186 iteration_result.value AS iteration_value
mbligh5456c2b2008-02-15 18:42:55 +0000187FROM tests
188INNER JOIN jobs ON jobs.job_idx = tests.job_idx
189INNER JOIN machines ON machines.machine_idx = jobs.machine_idx
190INNER JOIN kernels ON kernels.kernel_idx = tests.kernel_idx
191INNER JOIN status ON status.status_idx = tests.status
192INNER JOIN iteration_result ON iteration_result.test_idx = tests.kernel_idx;
193
194INSERT INTO status (word)
195VALUES ('NOSTATUS'), ('ERROR'), ('ABORT'), ('FAIL'), ('WARN'), ('GOOD'), ('ALERT');
196"""