blob: cf237d68ef73453189586b57bb03547d2d2a7e85 [file] [log] [blame]
mbligh5456c2b2008-02-15 18:42:55 +00001import os
2
3required_tables = ('machines', 'jobs', 'patches', 'tests', 'test_attributes',
4 'iteration_result')
5
6def migrate_up(manager):
7 assert not manager.check_migrate_table_exists()
8 manager.execute("SHOW TABLES")
9 tables = [row[0] for row in manager.cursor.fetchall()]
10 db_initialized = True
11 for table in required_tables:
12 if table not in tables:
13 db_initialized = False
14 break
15 if not db_initialized:
16 response = raw_input(
17 'Your tko database does not appear to be initialized. Do '
18 'you want to recreate it (this will result in loss of any '
19 'existing data) (yes/No)? ')
20 if response != 'yes':
21 raise Exception('User has chosen to abort migration')
22
23 manager.execute_script(CREATE_DB_SQL)
24
25 manager.create_migrate_table()
26
27
28CREATE_DB_SQL = """\
29-- drop all views (since they depend on some or all of the following tables)
30DROP VIEW IF EXISTS test_view;
31DROP VIEW IF EXISTS perf_view;
32
33DROP TABLE IF EXISTS brrd_sync;
34DROP TABLE IF EXISTS iteration_result;
35DROP TABLE IF EXISTS test_attributes;
36DROP TABLE IF EXISTS tests;
37DROP TABLE IF EXISTS patches;
38DROP TABLE IF EXISTS jobs;
39DROP TABLE IF EXISTS machines;
40DROP TABLE IF EXISTS kernels;
41DROP TABLE IF EXISTS status;
42
43-- status key
44CREATE TABLE status (
45status_idx int(10) unsigned NOT NULL auto_increment PRIMARY KEY , -- numerical status
46word VARCHAR(10) -- status word
47) TYPE=InnoDB;
48
49-- kernel versions
50CREATE TABLE kernels (
51kernel_idx int(10) unsigned NOT NULL auto_increment PRIMARY KEY,
52kernel_hash VARCHAR(35), -- Hash of base + all patches
53base VARCHAR(30), -- Base version without patches
54printable VARCHAR(100) -- Full version with patches
55) TYPE=InnoDB;
56
57-- machines/hosts table
58CREATE TABLE machines (
59machine_idx int(10) unsigned NOT NULL auto_increment PRIMARY KEY,
60hostname VARCHAR(100) unique KEY, -- hostname
61machine_group VARCHAR(80), -- group name
62owner VARCHAR(80) -- owner name
63) TYPE=InnoDB;
64
65-- main jobs table
66CREATE TABLE jobs (
67job_idx int(10) unsigned NOT NULL auto_increment PRIMARY KEY, -- index number
68tag VARCHAR(100) unique KEY, -- job key
69label VARCHAR(100), -- job label assigned by user
70KEY (label),
71username VARCHAR(80), -- user name
72KEY (username),
73machine_idx INT(10) unsigned NOT NULL, -- reference to machine table
74KEY (machine_idx),
75FOREIGN KEY (machine_idx) REFERENCES machines(machine_idx) ON DELETE CASCADE
76) TYPE=InnoDB;
77
78-- One entry per patch used, anywhere
79CREATE TABLE patches (
80kernel_idx INT(10) unsigned NOT NULL, -- index number
81name VARCHAR(80), -- short name
82url VARCHAR(300), -- full URL
83hash VARCHAR(35),
84KEY (kernel_idx),
85FOREIGN KEY (kernel_idx) REFERENCES kernels(kernel_idx) ON DELETE CASCADE
86) TYPE=InnoDB;
87
88-- test functional results
89CREATE TABLE tests (
90test_idx int(10) unsigned NOT NULL auto_increment PRIMARY KEY, -- index number
91job_idx INTEGER, -- ref to job table
92test VARCHAR(30), -- name of test
93subdir VARCHAR(60), -- subdirectory name
94kernel_idx INT(10) unsigned NOT NULL, -- kernel test was AGAINST
95KEY (kernel_idx),
96FOREIGN KEY (kernel_idx) REFERENCES kernels(kernel_idx) ON DELETE CASCADE,
97status int(10) unsigned NOT NULL, -- test status
98KEY (status),
99FOREIGN KEY (status) REFERENCES status(status_idx) ON DELETE CASCADE,
100reason VARCHAR(100), -- reason for test status
101machine_idx INT(10) unsigned NOT NULL, -- reference to machine table
102KEY (machine_idx),
103FOREIGN KEY (machine_idx) REFERENCES machines(machine_idx) ON DELETE CASCADE,
104invalid BOOL NOT NULL
105) TYPE=InnoDB;
106
107-- test attributes (key value pairs at a test level)
108CREATE TABLE test_attributes (
109test_idx int(10) unsigned NOT NULL, -- ref to test table
110FOREIGN KEY (test_idx) REFERENCES tests(test_idx) ON DELETE CASCADE,
111attribute VARCHAR(30), -- attribute name (e.g. 'version')
112value VARCHAR(100), -- attribute value
113KEY `test_idx` (`test_idx`)
114) TYPE=InnoDB;
115
116-- test performance results
117CREATE TABLE iteration_result(
118test_idx int(10) unsigned NOT NULL, -- ref to test table
119FOREIGN KEY (test_idx) REFERENCES tests(test_idx) ON DELETE CASCADE,
120iteration INTEGER, -- integer
121attribute VARCHAR(30), -- attribute name (e.g. 'throughput')
122value FLOAT, -- attribute value (eg 700.1)
123KEY `test_idx` (`test_idx`)
124) TYPE=InnoDB;
125
126-- BRRD syncronization
127CREATE TABLE brrd_sync (
128test_idx int(10) unsigned NOT NULL, -- ref to test table
129FOREIGN KEY (test_idx) REFERENCES tests(test_idx) ON DELETE CASCADE
130) TYPE=InnoDB;
131
132-- test_view (to make life easier for people trying to mine data)
133CREATE VIEW test_view AS
134SELECT tests.test_idx,
135 tests.job_idx,
136 tests.test,
137 tests.subdir,
138 tests.kernel_idx,
139 tests.status,
140 tests.reason,
141 tests.machine_idx,
142 jobs.tag AS job_tag,
143 jobs.label AS job_label,
144 jobs.username AS job_username,
145 machines.hostname AS machine_hostname,
146 machines.machine_group,
147 machines.owner AS machine_owner,
148 kernels.kernel_hash,
149 kernels.base AS kernel_base,
150 kernels.printable AS kernel_printable,
151 status.word AS status_word
152FROM tests
153INNER JOIN jobs ON jobs.job_idx = tests.job_idx
154INNER JOIN machines ON machines.machine_idx = jobs.machine_idx
155INNER JOIN kernels ON kernels.kernel_idx = tests.kernel_idx
156INNER JOIN status ON status.status_idx = tests.status;
157
158-- perf_view (to make life easier for people trying to mine performance data)
159CREATE VIEW perf_view AS
160SELECT tests.test_idx,
161 tests.job_idx,
162 tests.test,
163 tests.subdir,
164 tests.kernel_idx,
165 tests.status,
166 tests.reason,
167 tests.machine_idx,
168 jobs.tag AS job_tag,
169 jobs.label AS job_label,
170 jobs.username AS job_username,
171 machines.hostname AS machine_hostname,
172 machines.machine_group,
173 machines.owner AS machine_owner,
174 kernels.kernel_hash,
175 kernels.base AS kernel_base,
176 kernels.printable AS kernel_printable,
177 status.word AS status_word,
178 iteration_result.iteration,
179 iteration_result.attribute AS iteration_key,
180 iteration_result.value AS iteration_value
181FROM tests
182INNER JOIN jobs ON jobs.job_idx = tests.job_idx
183INNER JOIN machines ON machines.machine_idx = jobs.machine_idx
184INNER JOIN kernels ON kernels.kernel_idx = tests.kernel_idx
185INNER JOIN status ON status.status_idx = tests.status
186INNER JOIN iteration_result ON iteration_result.test_idx = tests.kernel_idx;
187
188INSERT INTO status (word)
189VALUES ('NOSTATUS'), ('ERROR'), ('ABORT'), ('FAIL'), ('WARN'), ('GOOD'), ('ALERT');
190"""