VirtualBox

source: vbox/trunk/src/VBox/ValidationKit/testmanager/db/TestManagerDatabaseInit.pgsql

Last change on this file was 106061, checked in by vboxsync, 8 weeks ago

Copyright year updates by scm.

  • Property svn:eol-style set to native
  • Property svn:keywords set to Author Date Id Revision
File size: 83.5 KB
Line 
1-- $Id: TestManagerDatabaseInit.pgsql 106061 2024-09-16 14:03:52Z vboxsync $
2--- @file
3-- VBox Test Manager Database Creation script.
4--
5
6--
7-- Copyright (C) 2012-2024 Oracle and/or its affiliates.
8--
9-- This file is part of VirtualBox base platform packages, as
10-- available from https://www.virtualbox.org.
11--
12-- This program is free software; you can redistribute it and/or
13-- modify it under the terms of the GNU General Public License
14-- as published by the Free Software Foundation, in version 3 of the
15-- License.
16--
17-- This program is distributed in the hope that it will be useful, but
18-- WITHOUT ANY WARRANTY; without even the implied warranty of
19-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the GNU
20-- General Public License for more details.
21--
22-- You should have received a copy of the GNU General Public License
23-- along with this program; if not, see <https://www.gnu.org/licenses>.
24--
25-- The contents of this file may alternatively be used under the terms
26-- of the Common Development and Distribution License Version 1.0
27-- (CDDL), a copy of it is provided in the "COPYING.CDDL" file included
28-- in the VirtualBox distribution, in which case the provisions of the
29-- CDDL are applicable instead of those of the GPL.
30--
31-- You may elect to license modified versions of this file under the
32-- terms and conditions of either the GPL or the CDDL or both.
33--
34-- SPDX-License-Identifier: GPL-3.0-only OR CDDL-1.0
35--
36
37--
38-- Declaimer:
39--
40-- The guys working on this design are not database experts, web
41-- programming experts or similar, rather we are low level guys
42-- who's main job is x86 & AMD64 virtualization. So, please don't
43-- be too hard on us. :-)
44--
45--
46
47
48-- D R O P D A T A B A S E t e s t m a n a g e r - - you do this now.
49\set ON_ERROR_STOP 1
50CREATE DATABASE testmanager;
51\connect testmanager;
52
53
54-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
55--
56-- S y s t e m
57--
58-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
59
60---
61-- Log table for a few important events.
62--
63-- Currently, two events are planned to be logged:
64-- - Sign on of an unknown testbox, including the IP and System UUID.
65-- This will be restricted to one entry per 24h or something like that:
66-- SELECT COUNT(*)
67-- FROM SystemLog
68-- WHERE tsCreated >= (current_timestamp - interval '24 hours')
69-- AND sEvent = 'TBoxUnkn'
70-- AND sLogText = :sNewLogText;
71-- - When cleaning up an abandoned testcase (scenario #9), log which
72-- testbox abandoned which testset.
73--
74-- The Web UI will have some way of displaying the log.
75--
76-- A batch job should regularly clean out old log messages, like for instance
77-- > 64 days.
78--
79CREATE TABLE SystemLog (
80 --- When this was logged.
81 tsCreated TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
82 --- The event type.
83 -- This is a 8 character string identifier so that we don't need to change
84 -- some enum type everytime we introduce a new event type.
85 sEvent CHAR(8) NOT NULL,
86 --- The log text.
87 sLogText text NOT NULL,
88
89 PRIMARY KEY (tsCreated, sEvent)
90);
91
92
93-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
94--
95-- C o n f i g u r a t i o n
96--
97-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
98
99--- @table Users
100-- Test manager users.
101--
102-- This is mainly for doing simple access checks before permitting access to
103-- the test manager. This needs to be coordinated with
104-- apache/ldap/Oracle-Single-Sign-On.
105--
106-- The main purpose, though, is for tracing who changed the test config and
107-- analysis data.
108--
109-- @remarks This table stores history. Never update or delete anything. The
110-- equivalent of deleting is done by setting the 'tsExpire' field to
111-- current_timestamp.
112--
113CREATE SEQUENCE UserIdSeq
114 START 1
115 INCREMENT BY 1
116 NO MAXVALUE
117 NO MINVALUE
118 CACHE 1;
119CREATE TABLE Users (
120 --- The user id.
121 uid INTEGER DEFAULT NEXTVAL('UserIdSeq') NOT NULL,
122 --- When this row starts taking effect (inclusive).
123 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
124 --- When this row stops being tsEffective (exclusive).
125 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
126 --- The user id of the one who created/modified this entry.
127 -- Non-unique foreign key: Users(uid)
128 uidAuthor INTEGER DEFAULT NULL,
129 --- User name.
130 sUsername text NOT NULL,
131 --- The email address of the user.
132 sEmail text NOT NULL,
133 --- The full name.
134 sFullName text NOT NULL,
135 --- The login name used by apache.
136 sLoginName text NOT NULL,
137 --- Read access only.
138 fReadOnly BOOLEAN NOT NULL DEFAULT FALSE,
139
140 PRIMARY KEY (uid, tsExpire)
141);
142CREATE INDEX UsersLoginNameIdx ON Users (sLoginName, tsExpire DESC);
143
144
145--- @table GlobalResources
146-- Global resource configuration.
147--
148-- For example an iSCSI target.
149--
150-- @remarks This table stores history. Never update or delete anything. The
151-- equivalent of deleting is done by setting the 'tsExpire' field to
152-- current_timestamp.
153--
154CREATE SEQUENCE GlobalResourceIdSeq
155 START 1
156 INCREMENT BY 1
157 NO MAXVALUE
158 NO MINVALUE
159 CACHE 1;
160CREATE TABLE GlobalResources (
161 --- The global resource ID.
162 -- This stays the same thru updates.
163 idGlobalRsrc INTEGER DEFAULT NEXTVAL('GlobalResourceIdSeq') NOT NULL,
164 --- When this row starts taking effect (inclusive).
165 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
166 --- When this row stops being tsEffective (exclusive).
167 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
168 --- The user id of the one who created/modified this entry.
169 -- Non-unique foreign key: Users(uid)
170 uidAuthor INTEGER NOT NULL,
171 --- The name of the resource.
172 sName text NOT NULL,
173 --- Optional resource description.
174 sDescription text,
175 --- Indicates whether this resource is currently enabled (online).
176 fEnabled boolean DEFAULT FALSE NOT NULL,
177
178 PRIMARY KEY (idGlobalRsrc, tsExpire)
179);
180
181
182--- @table BuildSources
183-- Build sources.
184--
185-- This is used by a scheduling group to select builds and the default
186-- Validation Kit from the Builds table.
187--
188-- @remarks This table stores history. Never update or delete anything. The
189-- equivalent of deleting is done by setting the 'tsExpire' field to
190-- current_timestamp.
191--
192-- @todo Any better way of representing this so we could more easily
193-- join/whatever when searching for builds?
194--
195CREATE SEQUENCE BuildSourceIdSeq
196 START 1
197 INCREMENT BY 1
198 NO MAXVALUE
199 NO MINVALUE
200 CACHE 1;
201CREATE TABLE BuildSources (
202 --- The build source identifier.
203 -- This stays constant over time.
204 idBuildSrc INTEGER DEFAULT NEXTVAL('BuildSourceIdSeq') NOT NULL,
205 --- When this row starts taking effect (inclusive).
206 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
207 --- When this row stops being tsEffective (exclusive).
208 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
209 --- The user id of the one who created/modified this entry.
210 -- Non-unique foreign key: Users(uid)
211 uidAuthor INTEGER NOT NULL,
212
213 --- The name of the build source.
214 sName TEXT NOT NULL,
215 --- Description.
216 sDescription TEXT DEFAULT NULL,
217
218 --- Which product.
219 -- ASSUME that it is okay to limit a build source to a single product.
220 sProduct text NOT NULL,
221 --- Which branch.
222 -- ASSUME that it is okay to limit a build source to a branch.
223 sBranch text NOT NULL,
224
225 --- Build types to include, all matches if NULL.
226 -- @todo Weighting the types would be nice in a later version.
227 asTypes text ARRAY DEFAULT NULL,
228 --- Array of the 'sOs.sCpuArch' to match, all matches if NULL.
229 -- See KBUILD_OSES in kBuild for a list of standard target OSes, and
230 -- KBUILD_ARCHES for a list of standard architectures.
231 --
232 -- @remarks See marks on 'os-agnostic' and 'noarch' in BuildCategories.
233 asOsArches text ARRAY DEFAULT NULL,
234
235 --- The first subversion tree revision to match, no lower limit if NULL.
236 iFirstRevision INTEGER DEFAULT NULL,
237 --- The last subversion tree revision to match, no upper limit if NULL.
238 iLastRevision INTEGER DEFAULT NULL,
239
240 --- The maximum age of the builds in seconds, unlimited if NULL.
241 cSecMaxAge INTEGER DEFAULT NULL,
242
243 PRIMARY KEY (idBuildSrc, tsExpire)
244);
245
246
247--- @table TestCases
248-- Test case configuration.
249--
250-- @remarks This table stores history. Never update or delete anything. The
251-- equivalent of deleting is done by setting the 'tsExpire' field to
252-- current_timestamp.
253--
254CREATE SEQUENCE TestCaseIdSeq
255 START 1
256 INCREMENT BY 1
257 NO MAXVALUE
258 NO MINVALUE
259 CACHE 1;
260CREATE SEQUENCE TestCaseGenIdSeq
261 START 1
262 INCREMENT BY 1
263 NO MAXVALUE
264 NO MINVALUE
265 CACHE 1;
266CREATE TABLE TestCases (
267 --- The fixed test case ID.
268 -- This is assigned when the test case is created and will never change.
269 idTestCase INTEGER DEFAULT NEXTVAL('TestCaseIdSeq') NOT NULL,
270 --- When this row starts taking effect (inclusive).
271 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
272 --- When this row stops being tsEffective (exclusive).
273 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
274 --- The user id of the one who created/modified this entry.
275 -- Non-unique foreign key: Users(uid)
276 uidAuthor INTEGER NOT NULL,
277 --- Generation ID for this row, a truly unique identifier.
278 -- This is primarily for referencing by TestSets.
279 idGenTestCase INTEGER UNIQUE DEFAULT NEXTVAL('TestCaseGenIdSeq') NOT NULL,
280
281 --- The name of the test case.
282 sName TEXT NOT NULL,
283 --- Optional test case description.
284 sDescription TEXT DEFAULT NULL,
285 --- Indicates whether this test case is currently enabled.
286 fEnabled BOOLEAN DEFAULT FALSE NOT NULL,
287 --- Default test case timeout given in seconds.
288 cSecTimeout INTEGER NOT NULL CHECK (cSecTimeout > 0),
289 --- Default TestBox requirement expression (python boolean expression).
290 -- All the scheduler properties are available for use with the same names
291 -- as in that table.
292 -- If NULL everything matches.
293 sTestBoxReqExpr TEXT DEFAULT NULL,
294 --- Default build requirement expression (python boolean expression).
295 -- The following build properties are available: sProduct, sBranch,
296 -- sType, asOsArches, sVersion, iRevision, uidAuthor and idBuild.
297 -- If NULL everything matches.
298 sBuildReqExpr TEXT DEFAULT NULL,
299
300 --- The base command.
301 -- String suitable for executing in bourne shell with space as separator
302 -- (IFS). References to @BUILD_BINARIES@ will be replaced WITH the content
303 -- of the Builds(sBinaries) field.
304 sBaseCmd TEXT NOT NULL,
305
306 --- Comma separated list of test suite zips (or tars) that the testbox will
307 -- need to download and expand prior to testing.
308 -- If NULL the current test suite of the scheduling group will be used (the
309 -- scheduling group will have an optional test suite build queue associated
310 -- with it). The current test suite can also be referenced by
311 -- @VALIDATIONKIT_ZIP@ in case more downloads are required. Files may also be
312 -- uploaded to the test manager download area, in which case the
313 -- @DOWNLOAD_BASE_URL@ prefix can be used to refer to this area.
314 sTestSuiteZips TEXT DEFAULT NULL,
315
316 -- Comment regarding a change or something.
317 sComment TEXT DEFAULT NULL,
318
319 PRIMARY KEY (idTestCase, tsExpire)
320);
321
322
323--- @table TestCaseArgs
324-- Test case argument list variations.
325--
326-- For example, we have a test case that does a set of tests on a virtual
327-- machine. To get better code/feature coverage of this testcase we wish to
328-- run it with different guest hardware configuration. The test case may do
329-- the same stuff, but the guest OS as well as the VMM may react differently to
330-- the hardware configurations and uncover issues in the VMM, device emulation
331-- or other places.
332--
333-- Typical hardware variations are:
334-- - guest memory size (RAM),
335-- - guest video memory size (VRAM),
336-- - virtual CPUs / cores / threads,
337-- - virtual chipset
338-- - virtual network interface card (NIC)
339-- - USB 1.1, USB 2.0, no USB
340--
341-- The TM web UI will help the user create a reasonable set of permutations
342-- of these parameters, the user specifies a maximum and the TM uses certain
343-- rules together with random selection to generate the desired number. The
344-- UI will also help suggest fitting testbox requirements according to the
345-- RAM/VRAM sizes and the virtual CPU counts. The user may then make
346-- adjustments to the suggestions before commit them.
347--
348-- Alternatively, the user may also enter all the permutations without any
349-- help from the UI.
350--
351-- Note! All test cases has at least one entry in this table, even if it is
352-- empty, because testbox requirements are specified thru this.
353--
354-- Querying the valid parameter lists for a testase this way:
355-- SELECT * ... WHERE idTestCase = TestCases.idTestCase
356-- AND tsExpire > <when>
357-- AND tsEffective <= <when>;
358--
359-- Querying the valid parameter list for the latest generation can be
360-- simplified by just checking tsExpire date:
361-- SELECT * ... WHERE idTestCase = TestCases.idTestCase
362-- AND tsExpire == TIMESTAMP WITH TIME ZONE 'infinity';
363--
364-- @remarks This table stores history. Never update or delete anything. The
365-- equivalent of deleting is done by setting the 'tsExpire' field to
366-- current_timestamp.
367--
368CREATE SEQUENCE TestCaseArgsIdSeq
369 START 1
370 INCREMENT BY 1
371 NO MAXVALUE
372 NO MINVALUE
373 CACHE 1;
374CREATE SEQUENCE TestCaseArgsGenIdSeq
375 START 1
376 INCREMENT BY 1
377 NO MAXVALUE
378 NO MINVALUE
379 CACHE 1;
380CREATE TABLE TestCaseArgs (
381 --- The test case ID.
382 -- Non-unique foreign key: TestCases(idTestCase).
383 idTestCase INTEGER NOT NULL,
384 --- The testcase argument variation ID (fixed).
385 -- This is primarily for TestGroupMembers.aidTestCaseArgs.
386 idTestCaseArgs INTEGER DEFAULT NEXTVAL('TestCaseArgsIdSeq') NOT NULL,
387 --- When this row starts taking effect (inclusive).
388 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
389 --- When this row stops being tsEffective (exclusive).
390 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
391 --- The user id of the one who created/modified this entry.
392 -- Non-unique foreign key: Users(uid)
393 uidAuthor INTEGER NOT NULL,
394 --- Generation ID for this row.
395 -- This is primarily for efficient referencing by TestSets and SchedQueues.
396 idGenTestCaseArgs INTEGER UNIQUE DEFAULT NEXTVAL('TestCaseArgsGenIdSeq') NOT NULL,
397
398 --- The additional arguments.
399 -- String suitable for bourne shell style argument parsing with space as
400 -- separator (IFS). References to @BUILD_BINARIES@ will be replaced with
401 -- the content of the Builds(sBinaries) field.
402 sArgs TEXT NOT NULL,
403 --- Optional test case timeout given in seconds.
404 -- If NULL, the TestCases.cSecTimeout field is used instead.
405 cSecTimeout INTEGER DEFAULT NULL CHECK (cSecTimeout IS NULL OR cSecTimeout > 0),
406 --- Additional TestBox requirement expression (python boolean expression).
407 -- All the scheduler properties are available for use with the same names
408 -- as in that table. This is checked after first checking the requirements
409 -- in the TestCases.sTestBoxReqExpr field.
410 sTestBoxReqExpr TEXT DEFAULT NULL,
411 --- Additional build requirement expression (python boolean expression).
412 -- The following build properties are available: sProduct, sBranch,
413 -- sType, asOsArches, sVersion, iRevision, uidAuthor and idBuild. This is
414 -- checked after first checking the requirements in the
415 -- TestCases.sBuildReqExpr field.
416 sBuildReqExpr TEXT DEFAULT NULL,
417 --- Number of testboxes required (gang scheduling).
418 cGangMembers SMALLINT DEFAULT 1 NOT NULL CHECK (cGangMembers > 0 AND cGangMembers < 1024),
419 --- Optional variation sub-name.
420 sSubName TEXT DEFAULT NULL,
421
422 --- The arguments are part of the primary key for several reasons.
423 -- No duplicate argument lists (makes no sense - if you want to prioritize
424 -- argument lists, we add that explicitly). This may hopefully enable us
425 -- to more easily check coverage later on, even when the test case is
426 -- reconfigured with more/less permutations.
427 PRIMARY KEY (idTestCase, tsExpire, sArgs)
428);
429CREATE INDEX TestCaseArgsLookupIdx ON TestCaseArgs (idTestCase, tsExpire DESC, tsEffective ASC);
430
431
432--- @table TestCaseDeps
433-- Test case dependencies (N:M)
434--
435-- This effect build selection. The build must have passed all runs of the
436-- given prerequisite testcase (idTestCasePreReq) and executed at a minimum one
437-- argument list variation.
438--
439-- This should also affect scheduling order, if possible at least one
440-- prerequisite testcase variation should be place before the specific testcase
441-- in the scheduling queue.
442--
443-- @remarks This table stores history. Never update or delete anything. The
444-- equivalent of deleting is done by setting the 'tsExpire' field to
445-- current_timestamp. To select the currently valid entries use
446-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
447--
448CREATE TABLE TestCaseDeps (
449 --- The test case that depends on someone.
450 -- Non-unique foreign key: TestCases(idTestCase).
451 idTestCase INTEGER NOT NULL,
452 --- The prerequisite test case ID.
453 -- Non-unique foreign key: TestCases(idTestCase).
454 idTestCasePreReq INTEGER NOT NULL,
455 --- When this row starts taking effect (inclusive).
456 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
457 --- When this row stops being tsEffective (exclusive).
458 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
459 --- The user id of the one who created/modified this entry.
460 -- Non-unique foreign key: Users(uid)
461 uidAuthor INTEGER NOT NULL,
462
463 PRIMARY KEY (idTestCase, idTestCasePreReq, tsExpire)
464);
465
466
467--- @table TestCaseGlobalRsrcDeps
468-- Test case dependencies on global resources (N:M)
469--
470-- @remarks This table stores history. Never update or delete anything. The
471-- equivalent of deleting is done by setting the 'tsExpire' field to
472-- current_timestamp. To select the currently valid entries use
473-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
474--
475CREATE TABLE TestCaseGlobalRsrcDeps (
476 --- The test case that depends on someone.
477 -- Non-unique foreign key: TestCases(idTestCase).
478 idTestCase INTEGER NOT NULL,
479 --- The prerequisite resource ID.
480 -- Non-unique foreign key: GlobalResources(idGlobalRsrc).
481 idGlobalRsrc INTEGER NOT NULL,
482 --- When this row starts taking effect (inclusive).
483 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
484 --- When this row stops being tsEffective (exclusive).
485 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
486 --- The user id of the one who created/modified this entry.
487 -- Non-unique foreign key: Users(uid)
488 uidAuthor INTEGER NOT NULL,
489
490 PRIMARY KEY (idTestCase, idGlobalRsrc, tsExpire)
491);
492
493
494--- @table TestGroups
495-- Test Group - A collection of test cases.
496--
497-- This is for simplifying test configuration by working with a few groups
498-- instead of a herd of individual testcases. It may also be used for creating
499-- test suites for certain areas (like guest additions) or tasks (like
500-- performance measurements).
501--
502-- A test case can be member of any number of test groups.
503--
504-- @remarks This table stores history. Never update or delete anything. The
505-- equivalent of deleting is done by setting the 'tsExpire' field to
506-- current_timestamp. To select the currently valid entries use
507-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
508--
509CREATE SEQUENCE TestGroupIdSeq
510 START 1
511 INCREMENT BY 1
512 NO MAXVALUE
513 NO MINVALUE
514 CACHE 1;
515CREATE TABLE TestGroups (
516 --- The fixed scheduling group ID.
517 -- This is assigned when the group is created and will never change.
518 idTestGroup INTEGER DEFAULT NEXTVAL('TestGroupIdSeq') NOT NULL,
519 --- When this row starts taking effect (inclusive).
520 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
521 --- When this row stops being tsEffective (exclusive).
522 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
523 --- The user id of the one who created/modified this entry.
524 -- Non-unique foreign key: Users(uid)
525 uidAuthor INTEGER NOT NULL,
526
527 --- The name of the scheduling group.
528 sName TEXT NOT NULL,
529 --- Optional group description.
530 sDescription TEXT,
531 -- Comment regarding a change or something.
532 sComment TEXT DEFAULT NULL,
533
534 PRIMARY KEY (idTestGroup, tsExpire)
535);
536CREATE INDEX TestGroups_id_index ON TestGroups (idTestGroup, tsExpire DESC, tsEffective ASC);
537
538
539--- @table TestGroupMembers
540-- The N:M relationship between test case configurations and test groups.
541--
542-- @remarks This table stores history. Never update or delete anything. The
543-- equivalent of deleting is done by setting the 'tsExpire' field to
544-- current_timestamp. To select the currently valid entries use
545-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
546--
547CREATE TABLE TestGroupMembers (
548 --- The group ID.
549 -- Non-unique foreign key: TestGroups(idTestGroup).
550 idTestGroup INTEGER NOT NULL,
551 --- The test case ID.
552 -- Non-unique foreign key: TestCases(idTestCase).
553 idTestCase INTEGER NOT NULL,
554 --- When this row starts taking effect (inclusive).
555 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
556 --- When this row stops being tsEffective (exclusive).
557 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
558 --- The user id of the one who created/modified this entry.
559 -- Non-unique foreign key: Users(uid)
560 uidAuthor INTEGER NOT NULL,
561
562 --- Test case scheduling priority.
563 -- Higher number causes the test case to be run more frequently.
564 -- @sa SchedGroupMembers.iSchedPriority, TestBoxesInSchedGroups.iSchedPriority
565 -- @todo Not sure we want to keep this...
566 iSchedPriority INTEGER DEFAULT 16 CHECK (iSchedPriority >= 0 AND iSchedPriority < 32) NOT NULL,
567
568 --- Limit the memberships to the given argument variations.
569 -- Non-unique foreign key: TestCaseArgs(idTestCase, idTestCaseArgs).
570 aidTestCaseArgs INTEGER ARRAY DEFAULT NULL,
571
572 PRIMARY KEY (idTestGroup, idTestCase, tsExpire)
573);
574
575
576--- @table SchedGroups
577-- Scheduling group (aka. testbox partitioning) configuration.
578--
579-- A testbox is associated with exactly one scheduling group. This association
580-- can be changed, of course. If we (want to) retire a group which still has
581-- testboxes associated with it, these will be moved to the 'default' group.
582--
583-- The TM web UI will make sure that a testbox is always in a group and that
584-- the default group cannot be deleted.
585--
586-- A scheduling group combines several things:
587-- - A selection of builds to test (via idBuildSrc).
588-- - A collection of test groups to test with (via SchedGroupMembers).
589-- - A set of testboxes to test on (via TestBoxes.idSchedGroup).
590--
591-- In additions there is an optional source of fresh test suite builds (think
592-- VBoxTestSuite) as well as scheduling options.
593--
594-- @remarks This table stores history. Never update or delete anything. The
595-- equivalent of deleting is done by setting the 'tsExpire' field to
596-- current_timestamp. To select the currently valid entries use
597-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
598--
599CREATE TYPE Scheduler_T AS ENUM (
600 'bestEffortContinousItegration',
601 'reserved'
602);
603CREATE SEQUENCE SchedGroupIdSeq
604 START 2
605 INCREMENT BY 1
606 NO MAXVALUE
607 NO MINVALUE
608 CACHE 1;
609CREATE TABLE SchedGroups (
610 --- The fixed scheduling group ID.
611 -- This is assigned when the group is created and will never change.
612 idSchedGroup INTEGER DEFAULT NEXTVAL('SchedGroupIdSeq') NOT NULL,
613 --- When this row starts taking effect (inclusive).
614 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
615 --- When this row stops being tsEffective (exclusive).
616 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
617 --- The user id of the one who created/modified this entry.
618 -- Non-unique foreign key: Users(uid)
619 -- @note This is NULL for the default group.
620 uidAuthor INTEGER DEFAULT NULL,
621
622 --- The name of the scheduling group.
623 sName TEXT NOT NULL,
624 --- Optional group description.
625 sDescription TEXT,
626 --- Indicates whether this group is currently enabled.
627 fEnabled boolean NOT NULL,
628 --- The scheduler to use.
629 -- This is for when we later desire different scheduling that the best
630 -- effort stuff provided by the initial implementation.
631 enmScheduler Scheduler_T DEFAULT 'bestEffortContinousItegration'::Scheduler_T NOT NULL,
632 --- The build source.
633 -- Non-unique foreign key: BuildSources(idBuildSrc)
634 idBuildSrc INTEGER DEFAULT NULL,
635 --- The Validation Kit build source (@VALIDATIONKIT_ZIP@).
636 -- Non-unique foreign key: BuildSources(idBuildSrc)
637 idBuildSrcTestSuite INTEGER DEFAULT NULL,
638 -- Comment regarding a change or something.
639 sComment TEXT DEFAULT NULL,
640
641 PRIMARY KEY (idSchedGroup, tsExpire)
642);
643
644-- Special default group.
645INSERT INTO SchedGroups (idSchedGroup, tsEffective, tsExpire, sName, sDescription, fEnabled)
646 VALUES (1, TIMESTAMP WITH TIME ZONE 'epoch', TIMESTAMP WITH TIME ZONE 'infinity', 'default', 'default group', FALSE);
647
648
649--- @table SchedGroupMembers
650-- N:M relationship between scheduling groups and test groups.
651--
652-- Several scheduling parameters are associated with this relationship.
653--
654-- The test group dependency (idTestGroupPreReq) can be used in the same way as
655-- TestCaseDeps.idTestCasePreReq, only here on test group level. This means it
656-- affects the build selection. The builds needs to have passed all test runs
657-- the prerequisite test group and done at least one argument variation of each
658-- test case in it.
659--
660-- @remarks This table stores history. Never update or delete anything. The
661-- equivalent of deleting is done by setting the 'tsExpire' field to
662-- current_timestamp. To select the currently valid entries use
663-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
664--
665CREATE TABLE SchedGroupMembers (
666 --- Scheduling ID.
667 -- Non-unique foreign key: SchedGroups(idSchedGroup).
668 idSchedGroup INTEGER NOT NULL,
669 --- Testgroup ID.
670 -- Non-unique foreign key: TestGroups(idTestGroup).
671 idTestGroup INTEGER NOT NULL,
672 --- When this row starts taking effect (inclusive).
673 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
674 --- When this row stops being tsEffective (exclusive).
675 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
676 --- The user id of the one who created/modified this entry.
677 -- Non-unique foreign key: Users(uid)
678 uidAuthor INTEGER NOT NULL,
679
680 --- The scheduling priority of the test group.
681 -- Higher number causes the test case to be run more frequently.
682 -- @sa TestGroupMembers.iSchedPriority, TestBoxesInSchedGroups.iSchedPriority
683 iSchedPriority INTEGER DEFAULT 16 CHECK (iSchedPriority >= 0 AND iSchedPriority < 32) NOT NULL,
684 --- When during the week this group is allowed to start running, NULL means
685 -- there are no constraints.
686 -- Each bit in the bitstring represents one hour, with bit 0 indicating the
687 -- midnight hour on a monday.
688 bmHourlySchedule bit(168) DEFAULT NULL,
689 --- Optional test group dependency.
690 -- Non-unique foreign key: TestGroups(idTestGroup).
691 -- This is for requiring that a build has been subject to smoke tests
692 -- before bothering to subject it to longer tests.
693 -- @todo Not entirely sure this should be here, but I'm not so keen on yet
694 -- another table as the only use case is smoketests.
695 idTestGroupPreReq INTEGER DEFAULT NULL,
696
697 PRIMARY KEY (idSchedGroup, idTestGroup, tsExpire)
698);
699
700
701--- @table TestBoxStrTab
702-- String table for the test boxes.
703--
704-- This is a string cache for all string members in TestBoxes except the name.
705-- The rational is to avoid duplicating large strings like sReport when the
706-- testbox reports a new cMbScratch value or the box when the test sheriff
707-- sends a reboot command or similar.
708--
709-- At the time this table was introduced, we had 400558 TestBoxes rows, where
710-- the SUM(LENGTH(sReport)) was 993MB. There were really just 1066 distinct
711-- sReport values, with a total length of 0x3 MB.
712--
713-- Nothing is ever deleted from this table.
714--
715-- @note Should use a stored procedure to query/insert a string.
716--
717--
718-- TestBox stats prior to conversion:
719-- SELECT COUNT(*) FROM TestBoxes: 400558 rows
720-- SELECT pg_total_relation_size('TestBoxes'): 740794368 bytes (706 MB)
721-- Average row cost: 740794368 / 400558 = 1849 bytes/row
722--
723-- After conversion:
724-- SELECT COUNT(*) FROM TestBoxes: 400558 rows
725-- SELECT pg_total_relation_size('TestBoxes'): 144375808 bytes (138 MB)
726-- SELECT COUNT(idStr) FROM TestBoxStrTab: 1292 rows
727-- SELECT pg_total_relation_size('TestBoxStrTab'): 5709824 bytes (5.5 MB)
728-- (144375808 + 5709824) / 740794368 = 20 %
729-- Average row cost boxes: 144375808 / 400558 = 360 bytes/row
730-- Average row cost strings: 5709824 / 1292 = 4420 bytes/row
731--
732CREATE SEQUENCE TestBoxStrTabIdSeq
733 START 1
734 INCREMENT BY 1
735 NO MAXVALUE
736 NO MINVALUE
737 CACHE 1;
738CREATE TABLE TestBoxStrTab (
739 --- The ID of this string.
740 idStr INTEGER PRIMARY KEY DEFAULT NEXTVAL('TestBoxStrTabIdSeq'),
741 --- The string value.
742 sValue text NOT NULL,
743 --- Creation time stamp.
744 tsCreated TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL
745);
746-- Note! Must use hash index as the sReport strings are too long for regular indexing.
747CREATE INDEX TestBoxStrTabNameIdx ON TestBoxStrTab USING hash (sValue);
748
749--- Empty string with ID 0.
750INSERT INTO TestBoxStrTab (idStr, sValue) VALUES (0, '');
751
752
753--- @type TestBoxCmd_T
754-- Testbox commands.
755CREATE TYPE TestBoxCmd_T AS ENUM (
756 'none',
757 'abort',
758 'reboot', --< This implies abort. Status changes when reaching 'idle'.
759 'upgrade', --< This is only handled when asking for work.
760 'upgrade-and-reboot', --< Ditto.
761 'special' --< Similar to upgrade, reserved for the future.
762);
763
764
765--- @type LomKind_T
766-- The kind of lights out management on a testbox.
767CREATE TYPE LomKind_T AS ENUM (
768 'none',
769 'ilom',
770 'elom',
771 'apple-xserve-lom'
772);
773
774
775--- @table TestBoxes
776-- Testbox configurations.
777--
778-- The testboxes are identified by IP and the system UUID if available. Should
779-- the IP change, the testbox will be refused at sign on and the testbox
780-- sheriff will have to update it's IP.
781--
782-- @todo Implement the UUID stuff. Get it from DMI, UEFI or whereever.
783-- Mismatching needs to be logged somewhere...
784--
785-- To query the currently valid configuration:
786-- SELECT ... WHERE id = idTestBox AND tsExpire = TIMESTAMP WITH TIME ZONE 'infinity';
787--
788-- @remarks This table stores history. Never update or delete anything. The
789-- equivalent of deleting is done by setting the 'tsExpire' field to
790-- current_timestamp. To select the currently valid entries use
791-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
792--
793CREATE SEQUENCE TestBoxIdSeq
794 START 1
795 INCREMENT BY 1
796 NO MAXVALUE
797 NO MINVALUE
798 CACHE 1;
799CREATE SEQUENCE TestBoxGenIdSeq
800 START 1
801 INCREMENT BY 1
802 NO MAXVALUE
803 NO MINVALUE
804 CACHE 1;
805CREATE TABLE TestBoxes (
806 --- The fixed testbox ID.
807 -- This is assigned when the testbox is created and will never change.
808 idTestBox INTEGER DEFAULT NEXTVAL('TestBoxIdSeq') NOT NULL,
809 --- When this row starts taking effect (inclusive).
810 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
811 --- When this row stops being tsEffective (exclusive).
812 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
813 --- The user id of the one who created/modified this entry.
814 -- When modified automatically by the testbox, NULL is used.
815 -- Non-unique foreign key: Users(uid)
816 uidAuthor INTEGER DEFAULT NULL,
817 --- Generation ID for this row.
818 -- This is primarily for referencing by TestSets.
819 idGenTestBox INTEGER UNIQUE DEFAULT NEXTVAL('TestBoxGenIdSeq') NOT NULL,
820
821 --- The testbox IP.
822 -- This is from the webserver point of view and automatically updated on
823 -- SIGNON. The test setup doesn't permit for IP addresses to change while
824 -- the testbox is operational, because this will break gang tests.
825 ip inet NOT NULL,
826 --- The system or firmware UUID.
827 -- This uniquely identifies the testbox when talking to the server. After
828 -- SIGNON though, the testbox will also provide idTestBox and ip to
829 -- establish its identity beyond doubt.
830 uuidSystem uuid NOT NULL,
831 --- The testbox name.
832 -- Usually similar to the DNS name.
833 sName text NOT NULL,
834 --- Optional testbox description.
835 -- Intended for describing the box as well as making other relevant notes.
836 idStrDescription INTEGER REFERENCES TestBoxStrTab(idStr) DEFAULT NULL,
837
838 --- Indicates whether this testbox is enabled.
839 -- A testbox gets disabled when we're doing maintenance, debugging a issue
840 -- that happens only on that testbox, or some similar stuff. This is an
841 -- alternative to deleting the testbox.
842 fEnabled BOOLEAN DEFAULT NULL,
843
844 --- The kind of lights-out-management.
845 enmLomKind LomKind_T DEFAULT 'none'::LomKind_T NOT NULL,
846 --- The IP adress of the lights-out-management.
847 -- This can be NULL if enmLomKind is 'none', otherwise it must contain a valid address.
848 ipLom inet DEFAULT NULL,
849
850 --- Timeout scale factor, given as a percent.
851 -- This is a crude adjustment of the test case timeout for slower hardware.
852 pctScaleTimeout smallint DEFAULT 100 NOT NULL CHECK (pctScaleTimeout > 10 AND pctScaleTimeout < 20000),
853
854 --- Change comment or similar.
855 idStrComment INTEGER REFERENCES TestBoxStrTab(idStr) DEFAULT NULL,
856
857 --- @name Scheduling properties (reported by testbox script).
858 -- @{
859 --- Same abbrieviations as kBuild, see KBUILD_OSES.
860 idStrOs INTEGER REFERENCES TestBoxStrTab(idStr) DEFAULT NULL,
861 --- Informational, no fixed format.
862 idStrOsVersion INTEGER REFERENCES TestBoxStrTab(idStr) DEFAULT NULL,
863 --- Same as CPUID reports (GenuineIntel, AuthenticAMD, CentaurHauls, ...).
864 idStrCpuVendor INTEGER REFERENCES TestBoxStrTab(idStr) DEFAULT NULL,
865 --- Same as kBuild - x86, amd64, ... See KBUILD_ARCHES.
866 idStrCpuArch INTEGER REFERENCES TestBoxStrTab(idStr) DEFAULT NULL,
867 --- The CPU name if available.
868 idStrCpuName INTEGER REFERENCES TestBoxStrTab(idStr) DEFAULT NULL,
869 --- Number identifying the CPU family/model/stepping/whatever.
870 -- For x86 and AMD64 type CPUs, this will on the following format:
871 -- (EffFamily << 24) | (EffModel << 8) | Stepping.
872 lCpuRevision bigint DEFAULT NULL,
873 --- Number of CPUs, CPU cores and CPU threads.
874 cCpus smallint DEFAULT NULL CHECK (cCpus IS NULL OR cCpus > 0),
875 --- Set if capable of hardware virtualization.
876 fCpuHwVirt boolean DEFAULT NULL,
877 --- Set if capable of nested paging.
878 fCpuNestedPaging boolean DEFAULT NULL,
879 --- Set if CPU capable of 64-bit (VBox) guests.
880 fCpu64BitGuest boolean DEFAULT NULL,
881 --- Set if chipset with usable IOMMU (VT-d / AMD-Vi).
882 fChipsetIoMmu boolean DEFAULT NULL,
883 --- Set if the test box does raw-mode tests.
884 fRawMode boolean DEFAULT NULL,
885 -- Set if the test box does native API (NEM) tests.
886 fNativeApi boolean DEFAULT NULL,
887 --- The (approximate) memory size in megabytes (rounded down to nearest 4 MB).
888 cMbMemory bigint DEFAULT NULL CHECK (cMbMemory IS NULL OR cMbMemory > 0),
889 --- The amount of scratch space in megabytes (rounded down to nearest 64 MB).
890 cMbScratch bigint DEFAULT NULL CHECK (cMbScratch IS NULL OR cMbScratch >= 0),
891 --- Free form hardware and software report field.
892 idStrReport INTEGER REFERENCES TestBoxStrTab(idStr) DEFAULT NULL,
893 --- @}
894
895 --- The testbox script revision number, serves the purpose of a version number.
896 -- Probably good to have when scheduling upgrades as well for status purposes.
897 iTestBoxScriptRev INTEGER DEFAULT 0 NOT NULL,
898 --- The python sys.hexversion (layed out as of 2.7).
899 -- Good to know which python versions we need to support.
900 iPythonHexVersion INTEGER DEFAULT NULL,
901
902 --- Pending command.
903 -- @note We put it here instead of in TestBoxStatuses to get history.
904 enmPendingCmd TestBoxCmd_T DEFAULT 'none'::TestBoxCmd_T NOT NULL,
905
906 PRIMARY KEY (idTestBox, tsExpire),
907
908 --- Nested paging requires hardware virtualization.
909 CHECK (fCpuNestedPaging IS NULL OR (fCpuNestedPaging <> TRUE OR fCpuHwVirt = TRUE))
910);
911CREATE UNIQUE INDEX TestBoxesUuidIdx ON TestBoxes (uuidSystem, tsExpire DESC);
912CREATE INDEX TestBoxesExpireEffectiveIdx ON TestBoxes (tsExpire DESC, tsEffective ASC);
913
914
915--
916-- Create a view for TestBoxes where the strings are resolved.
917--
918CREATE VIEW TestBoxesWithStrings AS
919 SELECT TestBoxes.*,
920 Str1.sValue AS sDescription,
921 Str2.sValue AS sComment,
922 Str3.sValue AS sOs,
923 Str4.sValue AS sOsVersion,
924 Str5.sValue AS sCpuVendor,
925 Str6.sValue AS sCpuArch,
926 Str7.sValue AS sCpuName,
927 Str8.sValue AS sReport
928 FROM TestBoxes
929 LEFT OUTER JOIN TestBoxStrTab Str1 ON idStrDescription = Str1.idStr
930 LEFT OUTER JOIN TestBoxStrTab Str2 ON idStrComment = Str2.idStr
931 LEFT OUTER JOIN TestBoxStrTab Str3 ON idStrOs = Str3.idStr
932 LEFT OUTER JOIN TestBoxStrTab Str4 ON idStrOsVersion = Str4.idStr
933 LEFT OUTER JOIN TestBoxStrTab Str5 ON idStrCpuVendor = Str5.idStr
934 LEFT OUTER JOIN TestBoxStrTab Str6 ON idStrCpuArch = Str6.idStr
935 LEFT OUTER JOIN TestBoxStrTab Str7 ON idStrCpuName = Str7.idStr
936 LEFT OUTER JOIN TestBoxStrTab Str8 ON idStrReport = Str8.idStr;
937
938
939--- @table TestBoxesInSchedGroups
940-- N:M relationship between test boxes and scheduling groups.
941--
942-- We associate a priority with this relationship.
943--
944-- @remarks This table stores history. Never update or delete anything. The
945-- equivalent of deleting is done by setting the 'tsExpire' field to
946-- current_timestamp. To select the currently valid entries use
947-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
948--
949CREATE TABLE TestBoxesInSchedGroups (
950 --- TestBox ID.
951 -- Non-unique foreign key: TestBoxes(idTestBox).
952 idTestBox INTEGER NOT NULL,
953 --- Scheduling ID.
954 -- Non-unique foreign key: SchedGroups(idSchedGroup).
955 idSchedGroup INTEGER NOT NULL,
956 --- When this row starts taking effect (inclusive).
957 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
958 --- When this row stops being tsEffective (exclusive).
959 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
960 --- The user id of the one who created/modified this entry.
961 -- Non-unique foreign key: Users(uid)
962 uidAuthor INTEGER NOT NULL,
963
964 --- The scheduling priority of the scheduling group for the test box.
965 -- Higher number causes the scheduling group to be serviced more frequently.
966 -- @sa TestGroupMembers.iSchedPriority, SchedGroups.iSchedPriority
967 iSchedPriority INTEGER DEFAULT 16 CHECK (iSchedPriority >= 0 AND iSchedPriority < 32) NOT NULL,
968
969 PRIMARY KEY (idTestBox, idSchedGroup, tsExpire)
970);
971
972
973-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
974--
975-- F a i l u r e T r a c k i n g
976--
977-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
978
979
980--- @table FailureCategories
981-- Failure categories.
982--
983-- This is for organizing the failure reasons.
984--
985-- @remarks This table stores history. Never update or delete anything. The
986-- equivalent of deleting is done by setting the 'tsExpire' field to
987-- current_timestamp. To select the currently valid entries use
988-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
989--
990CREATE SEQUENCE FailureCategoryIdSeq
991 START 1
992 INCREMENT BY 1
993 NO MAXVALUE
994 NO MINVALUE
995 CACHE 1;
996CREATE TABLE FailureCategories (
997 --- The identifier of this failure category (once assigned, it will never change).
998 idFailureCategory INTEGER DEFAULT NEXTVAL('FailureCategoryIdSeq') NOT NULL,
999 --- When this row starts taking effect (inclusive).
1000 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
1001 --- When this row stops being tsEffective (exclusive).
1002 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
1003 --- The user id of the one who created/modified this entry.
1004 -- Non-unique foreign key: Users(uid)
1005 uidAuthor INTEGER NOT NULL,
1006 --- The short category description.
1007 -- For combo boxes and other selection lists.
1008 sShort text NOT NULL,
1009 --- Full description
1010 -- For cursor-over-poppups for instance.
1011 sFull text NOT NULL,
1012
1013 PRIMARY KEY (idFailureCategory, tsExpire)
1014);
1015
1016
1017--- @table FailureReasons
1018-- Failure reasons.
1019--
1020-- When analysing a test failure, the testbox sheriff will try assign a fitting
1021-- reason for the failure. This table is here to help the sheriff in his/hers
1022-- job as well as developers looking checking if their changes affected the
1023-- test results in any way.
1024--
1025-- @remarks This table stores history. Never update or delete anything. The
1026-- equivalent of deleting is done by setting the 'tsExpire' field to
1027-- current_timestamp. To select the currently valid entries use
1028-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
1029--
1030CREATE SEQUENCE FailureReasonIdSeq
1031 START 1
1032 INCREMENT BY 1
1033 NO MAXVALUE
1034 NO MINVALUE
1035 CACHE 1;
1036CREATE TABLE FailureReasons (
1037 --- The identifier of this failure reason (once assigned, it will never change).
1038 idFailureReason INTEGER DEFAULT NEXTVAL('FailureReasonIdSeq') NOT NULL,
1039 --- When this row starts taking effect (inclusive).
1040 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
1041 --- When this row stops being tsEffective (exclusive).
1042 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
1043 --- The user id of the one who created/modified this entry.
1044 -- Non-unique foreign key: Users(uid)
1045 uidAuthor INTEGER NOT NULL,
1046
1047 --- The failure category this reason belongs to.
1048 -- Non-unique foreign key: FailureCategories(idFailureCategory)
1049 idFailureCategory INTEGER NOT NULL,
1050 --- The short failure description.
1051 -- For combo boxes and other selection lists.
1052 sShort text NOT NULL,
1053 --- Full failure description.
1054 sFull text NOT NULL,
1055 --- Ticket number in the primary bugtracker.
1056 iTicket INTEGER DEFAULT NULL,
1057 --- Other URLs to reports or discussions of the observed symptoms.
1058 asUrls text ARRAY DEFAULT NULL,
1059
1060 PRIMARY KEY (idFailureReason, tsExpire)
1061);
1062CREATE INDEX FailureReasonsCategoryIdx ON FailureReasons (idFailureCategory, idFailureReason);
1063
1064
1065
1066--- @table TestResultFailures
1067-- This is for tracking/discussing test result failures.
1068--
1069-- The rational for putting this is a separate table is that we need history on
1070-- this while TestResults does not.
1071--
1072-- @remarks This table stores history. Never update or delete anything. The
1073-- equivalent of deleting is done by setting the 'tsExpire' field to
1074-- current_timestamp. To select the currently valid entries use
1075-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
1076--
1077CREATE TABLE TestResultFailures (
1078 --- The test result we're disucssing.
1079 -- @note The foreign key is declared after TestResults (further down).
1080 idTestResult INTEGER NOT NULL,
1081 --- When this row starts taking effect (inclusive).
1082 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
1083 --- When this row stops being tsEffective (exclusive).
1084 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
1085 --- The user id of the one who created/modified this entry.
1086 -- Non-unique foreign key: Users(uid)
1087 uidAuthor INTEGER NOT NULL,
1088 --- The testsest this result is a part of.
1089 -- This is mainly an aid for bypassing the enormous TestResults table.
1090 -- Note! This is a foreign key, but we have to add it after TestSets has
1091 -- been created, see further down.
1092 idTestSet INTEGER NOT NULL,
1093
1094 --- The suggested failure reason.
1095 -- Non-unique foreign key: FailureReasons(idFailureReason)
1096 idFailureReason INTEGER NOT NULL,
1097 --- Optional comment.
1098 sComment text DEFAULT NULL,
1099
1100 PRIMARY KEY (idTestResult, tsExpire)
1101);
1102CREATE INDEX TestResultFailureIdx ON TestResultFailures (idTestSet, tsExpire DESC, tsEffective ASC);
1103CREATE INDEX TestResultFailureIdx2 ON TestResultFailures (idTestResult, tsExpire DESC, tsEffective ASC);
1104CREATE INDEX TestResultFailureIdx3 ON TestResultFailures (idFailureReason, idTestResult, tsExpire DESC, tsEffective ASC);
1105
1106
1107
1108
1109-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
1110--
1111-- T e s t I n p u t
1112--
1113-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
1114
1115
1116--- @table BuildBlacklist
1117-- Table used to blacklist sets of builds.
1118--
1119-- The best usage example is a VMM developer realizing that a change causes the
1120-- host to panic, hang, or otherwise misbehave. To prevent the testbox sheriff
1121-- from repeatedly having to reboot testboxes, the builds gets blacklisted
1122-- until there is a working build again. This may mean adding an open ended
1123-- blacklist spec and then updating it with the final revision number once the
1124-- fix has been committed.
1125--
1126-- @remarks This table stores history. Never update or delete anything. The
1127-- equivalent of deleting is done by setting the 'tsExpire' field to
1128-- current_timestamp. To select the currently valid entries use
1129-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
1130--
1131-- @todo Would be nice if we could replace the text strings below with a set of
1132-- BuildCategories, or sore it in any other way which would enable us to
1133-- do a negative join with build category... The way it is specified
1134-- now, it looks like we have to open a cursor of prospecitve builds and
1135-- filter then thru this table one by one.
1136--
1137-- Any better representation is welcome, but this is low prioirty for
1138-- now, as it's relatively easy to change this later one.
1139--
1140CREATE SEQUENCE BuildBlacklistIdSeq
1141 START 1
1142 INCREMENT BY 1
1143 NO MAXVALUE
1144 NO MINVALUE
1145 CACHE 1;
1146CREATE TABLE BuildBlacklist (
1147 --- The blacklist entry id.
1148 -- This stays constant over time.
1149 idBlacklisting INTEGER DEFAULT NEXTVAL('BuildBlacklistIdSeq') NOT NULL,
1150 --- When this row starts taking effect (inclusive).
1151 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
1152 --- When this row stops being tsEffective (exclusive).
1153 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
1154 --- The user id of the one who created/modified this entry.
1155 -- Non-unique foreign key: Users(uid)
1156 uidAuthor INTEGER NOT NULL,
1157
1158 --- The reason for the blacklisting.
1159 -- Non-unique foreign key: FailureReasons(idFailureReason)
1160 idFailureReason INTEGER NOT NULL,
1161
1162 --- Which product.
1163 -- ASSUME that it is okay to limit a blacklisting to a single product.
1164 sProduct text NOT NULL,
1165 --- Which branch.
1166 -- ASSUME that it is okay to limit a blacklisting to a branch.
1167 sBranch text NOT NULL,
1168
1169 --- Build types to include, all matches if NULL.
1170 asTypes text ARRAY DEFAULT NULL,
1171 --- Array of the 'sOs.sCpuArch' to match, all matches if NULL.
1172 -- See KBUILD_OSES in kBuild for a list of standard target OSes, and
1173 -- KBUILD_ARCHES for a list of standard architectures.
1174 --
1175 -- @remarks See marks on 'os-agnostic' and 'noarch' in BuildCategories.
1176 asOsArches text ARRAY DEFAULT NULL,
1177
1178 --- The first subversion tree revision to blacklist.
1179 iFirstRevision INTEGER NOT NULL,
1180 --- The last subversion tree revision to blacklist, no upper limit if NULL.
1181 iLastRevision INTEGER NOT NULL,
1182
1183 PRIMARY KEY (idBlacklisting, tsExpire)
1184);
1185CREATE INDEX BuildBlacklistIdx ON BuildBlacklist (iLastRevision DESC, iFirstRevision ASC, sProduct, sBranch,
1186 tsExpire DESC, tsEffective ASC);
1187
1188--- @table BuildCategories
1189-- Build categories.
1190--
1191-- The purpose of this table is saving space in the Builds table and hopefully
1192-- speed things up when selecting builds as well (compared to selecting on 4
1193-- text fields in the much larger Builds table).
1194--
1195-- Insert only table, no update, no delete. History is not needed.
1196--
1197CREATE SEQUENCE BuildCategoryIdSeq
1198 START 1
1199 INCREMENT BY 1
1200 NO MAXVALUE
1201 NO MINVALUE
1202 CACHE 1;
1203CREATE TABLE BuildCategories (
1204 --- The build type identifier.
1205 idBuildCategory INTEGER PRIMARY KEY DEFAULT NEXTVAL('BuildCategoryIdSeq') NOT NULL,
1206 --- Product.
1207 -- The product name. For instance 'VBox' or 'VBoxTestSuite'.
1208 sProduct TEXT NOT NULL,
1209 --- The version control repository name.
1210 sRepository TEXT NOT NULL,
1211 --- The branch name (in the version control system).
1212 sBranch TEXT NOT NULL,
1213 --- The build type.
1214 -- See KBUILD_BLD_TYPES in kBuild for a list of standard build types.
1215 sType TEXT NOT NULL,
1216 --- Array of the 'sOs.sCpuArch' supported by the build.
1217 -- See KBUILD_OSES in kBuild for a list of standard target OSes, and
1218 -- KBUILD_ARCHES for a list of standard architectures.
1219 --
1220 -- @remarks 'os-agnostic' is used if the build doesn't really target any
1221 -- specific OS or if it targets all applicable OSes.
1222 -- 'noarch' is used if the build is architecture independent or if
1223 -- all applicable architectures are handled.
1224 -- Thus, 'os-agnostic.noarch' will run on all build boxes.
1225 --
1226 -- @note The array shall be sorted ascendingly to prevent unnecessary duplicates!
1227 --
1228 asOsArches TEXT ARRAY NOT NULL,
1229
1230 UNIQUE (sProduct, sRepository, sBranch, sType, asOsArches)
1231);
1232
1233
1234--- @table Builds
1235-- The builds table contains builds from the tinderboxes and oaccasionally from
1236-- developers.
1237--
1238-- The tinderbox side could be fed by a batch job enumerating the build output
1239-- directories every so often, looking for new builds. Or we could query them
1240-- from the tinderbox database. Yet another alternative is making the
1241-- tinderbox server or client side software inform us about all new builds.
1242--
1243-- The developer builds are entered manually thru the TM web UI. They are used
1244-- for subjecting new code to some larger scale testing before commiting,
1245-- enabling, or merging a private branch.
1246--
1247-- The builds are being selected from this table by the via the build source
1248-- specification that SchedGroups.idBuildSrc and
1249-- SchedGroups.idBuildSrcTestSuite links to.
1250--
1251-- @remarks This table stores history. Never update or delete anything. The
1252-- equivalent of deleting is done by setting the 'tsExpire' field to
1253-- current_timestamp. To select the currently valid entries use
1254-- tsExpire = TIMESTAMP WITH TIME ZONE 'infinity'.
1255--
1256CREATE SEQUENCE BuildIdSeq
1257 START 1
1258 INCREMENT BY 1
1259 NO MAXVALUE
1260 NO MINVALUE
1261 CACHE 1;
1262CREATE TABLE Builds (
1263 --- The build identifier.
1264 -- This remains unchanged
1265 idBuild INTEGER DEFAULT NEXTVAL('BuildIdSeq') NOT NULL,
1266 --- When this build was created or entered into the database.
1267 -- This remains unchanged
1268 tsCreated TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
1269 --- When this row starts taking effect (inclusive).
1270 tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
1271 --- When this row stops being tsEffective (exclusive).
1272 tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
1273 --- The user id of the one who created/modified this entry.
1274 -- Non-unique foreign key: Users(uid)
1275 -- @note This is NULL if added by a batch job / tinderbox.
1276 uidAuthor INTEGER DEFAULT NULL,
1277 --- The build category.
1278 idBuildCategory INTEGER REFERENCES BuildCategories(idBuildCategory) NOT NULL,
1279 --- The subversion tree revision of the build.
1280 iRevision INTEGER NOT NULL,
1281 --- The product version number (suitable for RTStrVersionCompare).
1282 sVersion TEXT NOT NULL,
1283 --- The link to the tinderbox log of this build.
1284 sLogUrl TEXT,
1285 --- Comma separated list of binaries.
1286 -- The binaries have paths relative to the TESTBOX_PATH_BUILDS or full URLs.
1287 sBinaries TEXT NOT NULL,
1288 --- Set when the binaries gets deleted by the build quota script.
1289 fBinariesDeleted BOOLEAN DEFAULT FALSE NOT NULL,
1290
1291 UNIQUE (idBuild, tsExpire)
1292);
1293CREATE INDEX BuildsLookupIdx ON Builds (idBuildCategory, iRevision);
1294
1295
1296--- @table VcsRevisions
1297-- This table is for translating build revisions into commit details.
1298--
1299-- For graphs and test results, it would be useful to translate revisions into
1300-- dates and maybe provide commit message and the committer.
1301--
1302-- Data is entered exclusively thru one or more batch jobs, so no internal
1303-- authorship needed. Also, since we're mirroring data from external sources
1304-- here, the batch job is allowed to update/replace existing records.
1305--
1306-- @todo We we could collect more info from the version control systems, if we
1307-- believe it's useful and can be presented in a reasonable manner.
1308-- Getting a list of affected files would be simple (requires
1309-- a separate table with a M:1 relationship to this table), or try
1310-- associate a commit to a branch.
1311--
1312CREATE TABLE VcsRevisions (
1313 --- The version control tree name.
1314 sRepository TEXT NOT NULL,
1315 --- The version control tree revision number.
1316 iRevision INTEGER NOT NULL,
1317 --- When the revision was created (committed).
1318 tsCreated TIMESTAMP WITH TIME ZONE NOT NULL,
1319 --- The name of the committer.
1320 -- @note Not to be confused with uidAuthor and test manager users.
1321 sAuthor TEXT,
1322 --- The commit message.
1323 sMessage TEXT,
1324
1325 UNIQUE (sRepository, iRevision)
1326);
1327CREATE INDEX VcsRevisionsByDate ON VcsRevisions (tsCreated DESC);
1328
1329
1330--- @table VcsBugReferences
1331-- This is for relating commits to a bug and vice versa.
1332--
1333-- This feature isn't so much for the test manager as a cheap way of extending
1334-- bug trackers without VCS integration. We just need to parse the commit
1335-- messages when inserting them into the VcsRevisions table.
1336--
1337-- Same input, updating and history considerations as VcsRevisions.
1338--
1339CREATE TABLE VcsBugReferences (
1340 --- The version control tree name.
1341 sRepository TEXT NOT NULL,
1342 --- The version control tree revision number.
1343 iRevision INTEGER NOT NULL,
1344 --- The bug tracker identifier - see g_kdBugTrackers in config.py.
1345 sBugTracker CHAR(4) NOT NULL,
1346 --- The bug number in the bug tracker.
1347 lBugNo BIGINT NOT NULL,
1348
1349 UNIQUE (sRepository, iRevision, sBugTracker, lBugNo)
1350);
1351CREATE INDEX VcsBugReferencesLookupIdx ON VcsBugReferences (sBugTracker, lBugNo);
1352
1353
1354
1355
1356-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
1357--
1358-- T e s t R e s u l t s
1359--
1360-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
1361
1362
1363--- @table TestResultStrTab
1364-- String table for the test results.
1365--
1366-- This is a string cache for value names, test names and possible more, that
1367-- is frequently repated in the test results record for each test run. The
1368-- purpose is not only to save space, but to make datamining queries faster by
1369-- giving them integer fields to work on instead of text fields. There may
1370-- possibly be some benefits on INSERT as well as there are only integer
1371-- indexes.
1372--
1373-- Nothing is ever deleted from this table.
1374--
1375-- @note Should use a stored procedure to query/insert a string.
1376--
1377CREATE SEQUENCE TestResultStrTabIdSeq
1378 START 1
1379 INCREMENT BY 1
1380 NO MAXVALUE
1381 NO MINVALUE
1382 CACHE 1;
1383CREATE TABLE TestResultStrTab (
1384 --- The ID of this string.
1385 idStr INTEGER PRIMARY KEY DEFAULT NEXTVAL('TestResultStrTabIdSeq'),
1386 --- The string value.
1387 sValue text NOT NULL,
1388 --- Creation time stamp.
1389 tsCreated TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL
1390);
1391CREATE UNIQUE INDEX TestResultStrTabNameIdx ON TestResultStrTab (sValue);
1392
1393--- Empty string with ID 0.
1394INSERT INTO TestResultStrTab (idStr, sValue) VALUES (0, '');
1395
1396
1397--- @type TestStatus_T
1398-- The status of a test (set / result).
1399--
1400CREATE TYPE TestStatus_T AS ENUM (
1401 -- Initial status:
1402 'running',
1403 -- Final statuses:
1404 'success',
1405 -- Final status: Test didn't fail as such, it was something else.
1406 'skipped',
1407 'bad-testbox',
1408 'aborted',
1409 -- Final status: Test failed.
1410 'failure',
1411 'timed-out',
1412 'rebooted'
1413);
1414
1415
1416--- @table TestResults
1417-- Test results - a recursive bundle of joy!
1418--
1419-- A test case will be created when the testdriver calls reporter.testStart and
1420-- concluded with reporter.testDone. The testdriver (or it subordinates) can
1421-- use these methods to create nested test results. For IPRT based test cases,
1422-- RTTestCreate, RTTestInitAndCreate and RTTestSub will both create new test
1423-- result records, where as RTTestSubDone, RTTestSummaryAndDestroy and
1424-- RTTestDestroy will conclude records.
1425--
1426-- By concluding is meant updating the status. When the test driver reports
1427-- success, we check it against reported results. (paranoia strikes again!)
1428--
1429-- Nothing is ever deleted from this table.
1430--
1431-- @note As seen below, several other tables associate data with a
1432-- test result, and the top most test result is referenced by the
1433-- test set.
1434--
1435CREATE SEQUENCE TestResultIdSeq
1436 START 1
1437 INCREMENT BY 1
1438 NO MAXVALUE
1439 NO MINVALUE
1440 CACHE 1;
1441CREATE TABLE TestResults (
1442 --- The ID of this test result.
1443 idTestResult INTEGER PRIMARY KEY DEFAULT NEXTVAL('TestResultIdSeq'),
1444 --- The parent test result.
1445 -- This is NULL for the top test result.
1446 idTestResultParent INTEGER REFERENCES TestResults(idTestResult),
1447 --- The test set this result is a part of.
1448 -- Note! This is a foreign key, but we have to add it after TestSets has
1449 -- been created, see further down.
1450 idTestSet INTEGER NOT NULL,
1451 --- Creation time stamp. This may also be the timestamp of when the test started.
1452 tsCreated TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
1453 --- The elapsed time for this test.
1454 -- This is either reported by the directly (with some sanity checking) or
1455 -- calculated (current_timestamp - created_ts).
1456 -- @todo maybe use a nanosecond field here, check with what
1457 tsElapsed interval DEFAULT NULL,
1458 --- The test name.
1459 idStrName INTEGER REFERENCES TestResultStrTab(idStr) NOT NULL,
1460 --- The error count.
1461 cErrors INTEGER DEFAULT 0 NOT NULL,
1462 --- The test status.
1463 enmStatus TestStatus_T DEFAULT 'running'::TestStatus_T NOT NULL,
1464 --- Nesting depth.
1465 iNestingDepth smallint NOT NULL CHECK (iNestingDepth >= 0 AND iNestingDepth < 16),
1466 -- Make sure errors and status match up.
1467 CONSTRAINT CheckStatusMatchesErrors
1468 CHECK ( (cErrors > 0 AND enmStatus IN ('running'::TestStatus_T,
1469 'failure'::TestStatus_T, 'timed-out'::TestStatus_T, 'rebooted'::TestStatus_T ))
1470 OR (cErrors = 0 AND enmStatus IN ('running'::TestStatus_T, 'success'::TestStatus_T,
1471 'skipped'::TestStatus_T, 'aborted'::TestStatus_T, 'bad-testbox'::TestStatus_T))
1472 ),
1473 -- The following is for the TestResultFailures foreign key.
1474 -- Note! This was added with the name TestResults_idTestResult_idTestSet_key in the tmdb-r16 update script.
1475 UNIQUE (idTestResult, idTestSet)
1476);
1477
1478CREATE INDEX TestResultsSetIdx ON TestResults (idTestSet, idStrName, idTestResult);
1479CREATE INDEX TestResultsParentIdx ON TestResults (idTestResultParent);
1480-- The TestResultsNameIdx and TestResultsNameIdx2 are for speeding up the result graph & reporting code.
1481CREATE INDEX TestResultsNameIdx ON TestResults (idStrName, tsCreated DESC);
1482CREATE INDEX TestResultsNameIdx2 ON TestResults (idTestResult, idStrName);
1483
1484ALTER TABLE TestResultFailures ADD CONSTRAINT TestResultFailures_idTestResult_idTestSet_fkey
1485 FOREIGN KEY (idTestResult, idTestSet) REFERENCES TestResults(idTestResult, idTestSet) MATCH FULL;
1486
1487
1488--- @table TestResultValues
1489-- Test result values.
1490--
1491-- A testdriver or subordinate may report a test value via
1492-- reporter.testValue(), while IPRT based test will use RTTestValue and
1493-- associates.
1494--
1495-- This is an insert only table, no deletes, no updates.
1496--
1497CREATE SEQUENCE TestResultValueIdSeq
1498 START 1
1499 INCREMENT BY 1
1500 NO MAXVALUE
1501 NO MINVALUE
1502 CACHE 1;
1503CREATE TABLE TestResultValues (
1504 --- The ID of this value.
1505 idTestResultValue INTEGER PRIMARY KEY DEFAULT NEXTVAL('TestResultValueIdSeq'),
1506 --- The test result it was reported within.
1507 idTestResult INTEGER REFERENCES TestResults(idTestResult) NOT NULL,
1508 --- The test set this value is a part of (for avoiding joining thru TestResults).
1509 -- Note! This is a foreign key, but we have to add it after TestSets has
1510 -- been created, see further down.
1511 idTestSet INTEGER NOT NULL,
1512 --- Creation time stamp.
1513 tsCreated TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
1514 --- The name.
1515 idStrName INTEGER REFERENCES TestResultStrTab(idStr) NOT NULL,
1516 --- The value.
1517 lValue bigint NOT NULL,
1518 --- The unit.
1519 -- @todo This is currently not defined properly. Will fix/correlate this
1520 -- with the other places we use unit (IPRT/testdriver/VMMDev).
1521 iUnit smallint NOT NULL CHECK (iUnit >= 0 AND iUnit < 1024)
1522);
1523
1524CREATE INDEX TestResultValuesIdx ON TestResultValues(idTestResult);
1525-- The TestResultValuesGraphIdx is for speeding up the result graph & reporting code.
1526CREATE INDEX TestResultValuesGraphIdx ON TestResultValues(idStrName, tsCreated);
1527-- The TestResultValuesLogIdx is for speeding up the log viewer.
1528CREATE INDEX TestResultValuesLogIdx ON TestResultValues(idTestSet, tsCreated);
1529
1530
1531--- @table TestResultFiles
1532-- Test result files.
1533--
1534-- A testdriver or subordinate may report a file by using
1535-- reporter.addFile() or reporter.addLogFile().
1536--
1537-- The files stored here as well as the primary log file will be processed by a
1538-- batch job and compressed if considered compressable. Thus, TM will look for
1539-- files with a .gz/.bz2 suffix first and then without a suffix.
1540--
1541-- This is an insert only table, no deletes, no updates.
1542--
1543CREATE SEQUENCE TestResultFileId
1544 START 1
1545 INCREMENT BY 1
1546 NO MAXVALUE
1547 NO MINVALUE
1548 CACHE 1;
1549CREATE TABLE TestResultFiles (
1550 --- The ID of this file.
1551 idTestResultFile INTEGER PRIMARY KEY DEFAULT NEXTVAL('TestResultFileId'),
1552 --- The test result it was reported within.
1553 idTestResult INTEGER REFERENCES TestResults(idTestResult) NOT NULL,
1554 --- The test set this file is a part of (for avoiding joining thru TestResults).
1555 -- Note! This is a foreign key, but we have to add it after TestSets has
1556 -- been created, see further down.
1557 idTestSet INTEGER NOT NULL,
1558 --- Creation time stamp.
1559 tsCreated TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
1560 --- The filename relative to TestSets(sBaseFilename) + '-'.
1561 -- The set of valid filename characters should be very limited so that no
1562 -- file system issues can occure either on the TM side or the user when
1563 -- loading the files. Tests trying to use other characters will fail.
1564 -- Valid character regular expession: '^[a-zA-Z0-9_-(){}#@+,.=]*$'
1565 idStrFile INTEGER REFERENCES TestResultStrTab(idStr) NOT NULL,
1566 --- The description.
1567 idStrDescription INTEGER REFERENCES TestResultStrTab(idStr) NOT NULL,
1568 --- The kind of file.
1569 -- For instance: 'log/release/vm',
1570 -- 'screenshot/failure',
1571 -- 'screencapture/failure',
1572 -- 'xmllog/somestuff'
1573 idStrKind INTEGER REFERENCES TestResultStrTab(idStr) NOT NULL,
1574 --- The mime type for the file.
1575 -- For instance: 'text/plain',
1576 -- 'image/png',
1577 -- 'video/webm',
1578 -- 'text/xml'
1579 idStrMime INTEGER REFERENCES TestResultStrTab(idStr) NOT NULL
1580);
1581
1582CREATE INDEX TestResultFilesIdx ON TestResultFiles(idTestResult);
1583CREATE INDEX TestResultFilesIdx2 ON TestResultFiles(idTestSet, tsCreated DESC);
1584
1585
1586--- @table TestResultMsgs
1587-- Test result message.
1588--
1589-- A testdriver or subordinate may report a message via the sDetails parameter
1590-- of the reporter.testFailure() method, while IPRT test cases will use
1591-- RTTestFailed, RTTestPrintf and their friends. For RTTestPrintf, we will
1592-- ignore the more verbose message levels since these can also be found in one
1593-- of the logs.
1594--
1595-- This is an insert only table, no deletes, no updates.
1596--
1597CREATE TYPE TestResultMsgLevel_T AS ENUM (
1598 'failure',
1599 'info'
1600);
1601CREATE SEQUENCE TestResultMsgIdSeq
1602 START 1
1603 INCREMENT BY 1
1604 NO MAXVALUE
1605 NO MINVALUE
1606 CACHE 1;
1607CREATE TABLE TestResultMsgs (
1608 --- The ID of this file.
1609 idTestResultMsg INTEGER PRIMARY KEY DEFAULT NEXTVAL('TestResultMsgIdSeq'),
1610 --- The test result it was reported within.
1611 idTestResult INTEGER REFERENCES TestResults(idTestResult) NOT NULL,
1612 --- The test set this file is a part of (for avoiding joining thru TestResults).
1613 -- Note! This is a foreign key, but we have to add it after TestSets has
1614 -- been created, see further down.
1615 idTestSet INTEGER NOT NULL,
1616 --- Creation time stamp.
1617 tsCreated TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
1618 --- The message string.
1619 idStrMsg INTEGER REFERENCES TestResultStrTab(idStr) NOT NULL,
1620 --- The message level.
1621 enmLevel TestResultMsgLevel_T NOT NULL
1622);
1623
1624CREATE INDEX TestResultMsgsIdx ON TestResultMsgs(idTestResult);
1625CREATE INDEX TestResultMsgsIdx2 ON TestResultMsgs(idTestSet, tsCreated DESC);
1626
1627
1628--- @table TestSets
1629-- Test sets / Test case runs.
1630--
1631-- This is where we collect data about test runs.
1632--
1633-- @todo Not entirely sure where the 'test set' term came from. Consider
1634-- finding something more appropriate.
1635--
1636CREATE SEQUENCE TestSetIdSeq
1637 START 1
1638 INCREMENT BY 1
1639 NO MAXVALUE
1640 NO MINVALUE
1641 CACHE 1;
1642CREATE TABLE TestSets (
1643 --- The ID of this test set.
1644 idTestSet INTEGER PRIMARY KEY DEFAULT NEXTVAL('TestSetIdSeq') NOT NULL,
1645
1646 --- The test config timestamp, used when reading test config.
1647 tsConfig TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
1648 --- When this test set was scheduled.
1649 -- idGenTestBox is valid at this point.
1650 tsCreated TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
1651 --- When this test completed, i.e. testing stopped. This should only be set once.
1652 tsDone TIMESTAMP WITH TIME ZONE DEFAULT NULL,
1653 --- The current status.
1654 enmStatus TestStatus_T DEFAULT 'running'::TestStatus_T NOT NULL,
1655
1656 --- The build we're testing.
1657 -- Non-unique foreign key: Builds(idBuild)
1658 idBuild INTEGER NOT NULL,
1659 --- The build category of idBuild when the test started.
1660 -- This is for speeding up graph data collection, i.e. avoid idBuild
1661 -- the WHERE part of the selection.
1662 idBuildCategory INTEGER REFERENCES BuildCategories(idBuildCategory) NOT NULL,
1663 --- The test suite build we're using to do the testing.
1664 -- This is NULL if the test suite zip wasn't referred or if a test suite
1665 -- build source wasn't configured.
1666 -- Non-unique foreign key: Builds(idBuild)
1667 idBuildTestSuite INTEGER DEFAULT NULL,
1668
1669 --- The exact testbox configuration.
1670 idGenTestBox INTEGER REFERENCES TestBoxes(idGenTestBox) NOT NULL,
1671 --- The testbox ID for joining with (valid: tsStarted).
1672 -- Non-unique foreign key: TestBoxes(idTestBox)
1673 idTestBox INTEGER NOT NULL,
1674 --- The scheduling group ID the test was scheduled thru (valid: tsStarted).
1675 -- Non-unique foreign key: SchedGroups(idSchedGroup)
1676 idSchedGroup INTEGER NOT NULL,
1677
1678 --- The testgroup (valid: tsConfig).
1679 -- Non-unique foreign key: TestBoxes(idTestGroup)
1680 -- Note! This also gives the member ship entry, since a testcase can only
1681 -- have one membership per test group.
1682 idTestGroup INTEGER NOT NULL,
1683
1684 --- The exact test case config we executed in this test run.
1685 idGenTestCase INTEGER REFERENCES TestCases(idGenTestCase) NOT NULL,
1686 --- The test case ID for joining with (valid: tsConfig).
1687 -- Non-unique foreign key: TestBoxes(idTestCase)
1688 idTestCase INTEGER NOT NULL,
1689
1690 --- The arguments (and requirements++) we executed this test case with.
1691 idGenTestCaseArgs INTEGER REFERENCES TestCaseArgs(idGenTestCaseArgs) NOT NULL,
1692 --- The argument variation ID (valid: tsConfig).
1693 -- Non-unique foreign key: TestCaseArgs(idTestCaseArgs)
1694 idTestCaseArgs INTEGER NOT NULL,
1695
1696 --- The root of the test result tree.
1697 -- @note This will only be NULL early in the transaction setting up the testset.
1698 -- @note If the test reports more than one top level test result, we'll
1699 -- fail the whole test run and let the test developer fix it.
1700 idTestResult INTEGER REFERENCES TestResults(idTestResult) DEFAULT NULL,
1701
1702 --- The base filename used for storing files related to this test set.
1703 -- This is a path relative to wherever TM is dumping log files. In order
1704 -- to not become a file system test case, we will try not to put too many
1705 -- hundred thousand files in a directory. A simple first approach would
1706 -- be to just use the current date (tsCreated) like this:
1707 -- TM_FILE_DIR/year/month/day/TestSets.idTestSet
1708 --
1709 -- The primary log file for the test is this name suffixed by '.log'.
1710 --
1711 -- The files in the testresultfile table gets their full names like this:
1712 -- TM_FILE_DIR/sBaseFilename-testresultfile.id-TestResultStrTab(testresultfile.idStrFilename)
1713 --
1714 -- @remarks We store this explicitly in case we change the directly layout
1715 -- at some later point.
1716 sBaseFilename text UNIQUE NOT NULL,
1717
1718 --- The gang member number number, 0 is the leader.
1719 iGangMemberNo SMALLINT DEFAULT 0 NOT NULL CHECK (iGangMemberNo >= 0 AND iGangMemberNo < 1024),
1720 --- The test set of the gang leader, NULL if no gang involved.
1721 -- @note This is set by the gang leader as well, so that we can find all
1722 -- gang members by WHERE idTestSetGangLeader = :id.
1723 idTestSetGangLeader INTEGER REFERENCES TestSets(idTestSet) DEFAULT NULL
1724
1725);
1726CREATE INDEX TestSetsGangIdx ON TestSets (idTestSetGangLeader);
1727CREATE INDEX TestSetsBoxIdx ON TestSets (idTestBox, idTestResult);
1728CREATE INDEX TestSetsBuildIdx ON TestSets (idBuild, idTestResult);
1729CREATE INDEX TestSetsTestCaseIdx ON TestSets (idTestCase, idTestResult);
1730CREATE INDEX TestSetsTestVarIdx ON TestSets (idTestCaseArgs, idTestResult);
1731--- The TestSetsDoneCreatedBuildCatIdx is for testbox results, graph options and such.
1732CREATE INDEX TestSetsDoneCreatedBuildCatIdx ON TestSets (tsDone DESC NULLS FIRST, tsCreated ASC, idBuildCategory);
1733--- For graphs.
1734CREATE INDEX TestSetsGraphBoxIdx ON TestSets (idTestBox, tsCreated DESC, tsDone ASC NULLS LAST, idBuildCategory, idTestCase);
1735
1736ALTER TABLE TestResults ADD FOREIGN KEY (idTestSet) REFERENCES TestSets(idTestSet) MATCH FULL;
1737ALTER TABLE TestResultValues ADD FOREIGN KEY (idTestSet) REFERENCES TestSets(idTestSet) MATCH FULL;
1738ALTER TABLE TestResultFiles ADD FOREIGN KEY (idTestSet) REFERENCES TestSets(idTestSet) MATCH FULL;
1739ALTER TABLE TestResultMsgs ADD FOREIGN KEY (idTestSet) REFERENCES TestSets(idTestSet) MATCH FULL;
1740ALTER TABLE TestResultFailures ADD FOREIGN KEY (idTestSet) REFERENCES TestSets(idTestSet) MATCH FULL;
1741
1742
1743
1744
1745-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
1746--
1747-- T e s t M a n g e r P e r s i s t e n t S t o r a g e
1748--
1749-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- --
1750
1751--- @type TestBoxState_T
1752-- TestBox state.
1753--
1754-- @todo Consider drawing a state diagram for this.
1755--
1756CREATE TYPE TestBoxState_T AS ENUM (
1757 --- Nothing to do.
1758 -- Prev: testing, gang-cleanup, rebooting, upgrading,
1759 -- upgrading-and-rebooting, doing-special-cmd.
1760 -- Next: testing, gang-gathering, rebooting, upgrading,
1761 -- upgrading-and-rebooting, doing-special-cmd.
1762 'idle',
1763 --- Executing a test.
1764 -- Prev: idle
1765 -- Next: idle
1766 'testing',
1767
1768 -- Gang scheduling statuses:
1769 --- The gathering of a gang.
1770 -- Prev: idle
1771 -- Next: gang-gathering-timedout, gang-testing
1772 'gang-gathering',
1773 --- The gathering timed out, the testbox needs to cleanup and move on.
1774 -- Prev: gang-gathering
1775 -- Next: idle
1776 -- This is set on all gathered members by the testbox who triggers the
1777 -- timeout.
1778 'gang-gathering-timedout',
1779 --- The gang scheduling equivalent of 'testing'.
1780 -- Prev: gang-gathering
1781 -- Next: gang-cleanup
1782 'gang-testing',
1783 --- Waiting for the other gang members to stop testing so that cleanups
1784 -- can be performed and members safely rescheduled.
1785 -- Prev: gang-testing
1786 -- Next: idle
1787 --
1788 -- There are two resource clean up issues being targeted here:
1789 -- 1. Global resources will be allocated by the leader when he enters the
1790 -- 'gang-gathering' state. If the leader quits and frees the resource
1791 -- while someone is still using it, bad things will happen. Imagine a
1792 -- global resource without any access checks and relies exclusivly on
1793 -- the TM doing its job.
1794 -- 2. TestBox resource accessed by other gang members may also be used in
1795 -- other tests. Should a gang member leave early and embark on a
1796 -- testcase using the same resources, bad things will happen. Example:
1797 -- Live migration. One partner leaves early because it detected some
1798 -- fatal failure, the other one is still trying to connect to him.
1799 -- The testbox is scheduled again on the same live migration testcase,
1800 -- only with different arguments (VM config), it will try migrate using
1801 -- the same TCP ports. Confusion ensues.
1802 --
1803 -- To figure out whether to remain in this status because someone is
1804 -- still testing:
1805 -- SELECT COUNT(*) FROM TestBoxStatuses, TestSets
1806 -- WHERE TestSets.idTestSetGangLeader = :idGangLeader
1807 -- AND TestSets.idTestBox = TestBoxStatuses.idTestBox
1808 -- AND TestSets.idTestSet = TestBoxStatuses.idTestSet
1809 -- AND TestBoxStatuses.enmState = 'gang-testing'::TestBoxState_T;
1810 'gang-cleanup',
1811
1812 -- Command related statuses (all command status changes comes from 'idle'
1813 -- and goes back to 'idle'):
1814 'rebooting',
1815 'upgrading',
1816 'upgrading-and-rebooting',
1817 'doing-special-cmd'
1818);
1819
1820--- @table TestBoxStatuses
1821-- Testbox status table.
1822--
1823-- History is not planned on this table.
1824--
1825CREATE TABLE TestBoxStatuses (
1826 --- The testbox.
1827 idTestBox INTEGER PRIMARY KEY NOT NULL,
1828 --- The testbox generation ID.
1829 idGenTestBox INTEGER REFERENCES TestBoxes(idGenTestBox) NOT NULL,
1830 --- When this status was last updated.
1831 -- This is updated everytime the testbox talks to the test manager, thus it
1832 -- can easily be used to find testboxes which has stopped responding.
1833 --
1834 -- This is used for timeout calculation during gang-gathering, so in that
1835 -- scenario it won't be updated until the gang is gathered or we time out.
1836 tsUpdated TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
1837 --- The current state.
1838 enmState TestBoxState_T DEFAULT 'idle'::TestBoxState_T NOT NULL,
1839 --- Reference to the test set
1840 idTestSet INTEGER REFERENCES TestSets(idTestSet),
1841 --- Interal work item number.
1842 -- This is used to pick and prioritize between multiple scheduling groups.
1843 iWorkItem INTEGER DEFAULT 0 NOT NULL
1844);
1845
1846
1847--- @table GlobalResourceStatuses
1848-- Global resource status, tracks which test set resources are allocated by.
1849--
1850-- History is not planned on this table.
1851--
1852CREATE TABLE GlobalResourceStatuses (
1853 --- The resource ID.
1854 -- Non-unique foreign key: GlobalResources(idGlobalRsrc).
1855 idGlobalRsrc INTEGER PRIMARY KEY NOT NULL,
1856 --- The resource owner.
1857 -- @note This is going thru testboxstatus to be able to use the testbox ID
1858 -- as a foreign key.
1859 idTestBox INTEGER REFERENCES TestBoxStatuses(idTestBox) NOT NULL,
1860 --- When the allocation took place.
1861 tsAllocated TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL
1862);
1863
1864
1865--- @table SchedQueues
1866-- Scheduler queue.
1867--
1868-- The queues are currently associated with a scheduling group, it could
1869-- alternative be changed to hook on to a testbox instead. It depends on what
1870-- kind of scheduling method we prefer. The former method aims at test case
1871-- thruput, making sacrifices in the hardware distribution area. The latter is
1872-- more like the old buildbox style testing, making sure that each test case is
1873-- executed on each testbox.
1874--
1875-- When there are configuration changes, TM will regenerate the scheduling
1876-- queue for the affected scheduling groups. We do not concern ourselves with
1877-- trying to continue at the approximately same queue position, we simply take
1878-- it from the top.
1879--
1880-- When a testbox ask for work, we will open a cursor on the queue and take the
1881-- first test in the queue that can be executed on that testbox. The test will
1882-- be moved to the end of the queue (getting a new item_id).
1883--
1884-- If a test is manually changed to the head of the queue, the item will get a
1885-- item_id which is 1 lower than the head of the queue. Unless someone does
1886-- this a couple of billion times, we shouldn't have any trouble running out of
1887-- number space. :-)
1888--
1889-- Manually moving a test to the end of the queue is easy, just get a new
1890-- 'item_id'.
1891--
1892-- History is not planned on this table.
1893--
1894CREATE SEQUENCE SchedQueueItemIdSeq
1895 START 1
1896 INCREMENT BY 1
1897 NO MAXVALUE
1898 NO MINVALUE
1899 CACHE 1;
1900CREATE TABLE SchedQueues (
1901 --- The scheduling queue (one queue per scheduling group).
1902 -- Non-unique foreign key: SchedGroups(idSchedGroup)
1903 idSchedGroup INTEGER NOT NULL,
1904 --- The scheduler queue entry ID.
1905 -- Lower numbers means early queue position.
1906 idItem INTEGER DEFAULT NEXTVAL('SchedQueueItemIdSeq') NOT NULL,
1907 --- The queue offset.
1908 -- This is used for repositining the queue when recreating it. It can also
1909 -- be used to figure out how jumbled the queue gets after real life has had
1910 -- it's effect on it.
1911 offQueue INTEGER NOT NULL,
1912 --- The test case argument variation to execute.
1913 idGenTestCaseArgs INTEGER REFERENCES TestCaseArgs(idGenTestCaseArgs) NOT NULL,
1914 --- The relevant testgroup.
1915 -- Non-unique foreign key: TestGroups(idTestGroup).
1916 idTestGroup INTEGER NOT NULL,
1917 --- Aggregated test group dependencies (NULL if none).
1918 -- Non-unique foreign key: TestGroups(idTestGroup).
1919 -- See also comments on SchedGroupMembers.idTestGroupPreReq.
1920 aidTestGroupPreReqs INTEGER ARRAY DEFAULT NULL,
1921 --- The scheduling time constraints (see SchedGroupMembers.bmHourlySchedule).
1922 bmHourlySchedule bit(168) DEFAULT NULL,
1923 --- When the queue entry was created and for which config is valid.
1924 -- This is the timestamp that should be used when reading config info.
1925 tsConfig TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
1926 --- When this status was last scheduled.
1927 -- This is set to current_timestamp when moving the entry to the end of the
1928 -- queue. It's initial value is unix-epoch. Not entirely sure if it's
1929 -- useful beyond introspection and non-unique foreign key hacking.
1930 tsLastScheduled TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'epoch' NOT NULL,
1931
1932 --- This is used in gang scheduling.
1933 idTestSetGangLeader INTEGER REFERENCES TestSets(idTestSet) DEFAULT NULL UNIQUE,
1934 --- The number of gang members still missing.
1935 --
1936 -- This saves calculating the number of missing members via selects like:
1937 -- SELECT COUNT(*) FROM TestSets WHERE idTestSetGangLeader = :idGang;
1938 -- and
1939 -- SELECT cGangMembers FROM TestCaseArgs WHERE idGenTestCaseArgs = :idTest;
1940 -- to figure out whether to remain in 'gather-gang'::TestBoxState_T.
1941 --
1942 cMissingGangMembers smallint DEFAULT 1 NOT NULL,
1943
1944 --- @todo
1945 --- The number of times this has been considered for scheduling.
1946 -- cConsidered SMALLINT DEFAULT 0 NOT NULL,
1947
1948 PRIMARY KEY (idSchedGroup, idItem)
1949);
1950CREATE INDEX SchedQueuesItemIdx ON SchedQueues(idItem);
1951CREATE INDEX SchedQueuesSchedGroupIdx ON SchedQueues(idSchedGroup);
1952
Note: See TracBrowser for help on using the repository browser.

© 2024 Oracle Support Privacy / Do Not Sell My Info Terms of Use Trademark Policy Automated Access Etiquette