1 | -- $Id: tmdb-r22-testboxes-3-teststatus-4-testboxinschedgroups-1.pgsql 76553 2019-01-01 01:45:53Z vboxsync $
|
---|
2 | --- @file
|
---|
3 | -- VBox Test Manager Database - Turns idSchedGroup column in TestBoxes
|
---|
4 | -- into an N:M relationship with a priority via the new table
|
---|
5 | -- TestBoxesInSchedGroups. Adds an internal scheduling table index to
|
---|
6 | -- TestBoxStatuses to implement testboxes switching between groups.
|
---|
7 | --
|
---|
8 |
|
---|
9 | --
|
---|
10 | -- Copyright (C) 2013-2019 Oracle Corporation
|
---|
11 | --
|
---|
12 | -- This file is part of VirtualBox Open Source Edition (OSE), as
|
---|
13 | -- available from http://www.virtualbox.org. This file is free software;
|
---|
14 | -- you can redistribute it and/or modify it under the terms of the GNU
|
---|
15 | -- General Public License (GPL) as published by the Free Software
|
---|
16 | -- Foundation, in version 2 as it comes in the "COPYING" file of the
|
---|
17 | -- VirtualBox OSE distribution. VirtualBox OSE is distributed in the
|
---|
18 | -- hope that it will be useful, but WITHOUT ANY WARRANTY of any kind.
|
---|
19 | --
|
---|
20 | -- The contents of this file may alternatively be used under the terms
|
---|
21 | -- of the Common Development and Distribution License Version 1.0
|
---|
22 | -- (CDDL) only, as it comes in the "COPYING.CDDL" file of the
|
---|
23 | -- VirtualBox OSE distribution, in which case the provisions of the
|
---|
24 | -- CDDL are applicable instead of those of the GPL.
|
---|
25 | --
|
---|
26 | -- You may elect to license modified versions of this file under the
|
---|
27 | -- terms and conditions of either the GPL or the CDDL or both.
|
---|
28 | --
|
---|
29 |
|
---|
30 | --
|
---|
31 | -- Cleanup after failed runs.
|
---|
32 | --
|
---|
33 | DROP TABLE IF EXISTS OldTestBoxes;
|
---|
34 |
|
---|
35 | --
|
---|
36 | -- Die on error from now on.
|
---|
37 | --
|
---|
38 | \set ON_ERROR_STOP 1
|
---|
39 | \set AUTOCOMMIT 0
|
---|
40 |
|
---|
41 |
|
---|
42 | -- Total grid lock.
|
---|
43 | LOCK TABLE TestBoxStatuses IN ACCESS EXCLUSIVE MODE;
|
---|
44 | LOCK TABLE TestSets IN ACCESS EXCLUSIVE MODE;
|
---|
45 | LOCK TABLE TestBoxes IN ACCESS EXCLUSIVE MODE;
|
---|
46 | LOCK TABLE SchedGroups IN ACCESS EXCLUSIVE MODE;
|
---|
47 | LOCK TABLE SchedGroupMembers IN ACCESS EXCLUSIVE MODE;
|
---|
48 |
|
---|
49 | \d+ TestBoxes;
|
---|
50 |
|
---|
51 | --
|
---|
52 | -- We'll only be doing simple alterations so, no need to drop constraints
|
---|
53 | -- and stuff like we usually do first.
|
---|
54 | --
|
---|
55 |
|
---|
56 | --
|
---|
57 | -- Create the new table and populate it.
|
---|
58 | --
|
---|
59 |
|
---|
60 | CREATE TABLE TestBoxesInSchedGroups (
|
---|
61 | --- TestBox ID.
|
---|
62 | -- Non-unique foreign key: TestBoxes(idTestBox).
|
---|
63 | idTestBox INTEGER NOT NULL,
|
---|
64 | --- Scheduling ID.
|
---|
65 | -- Non-unique foreign key: SchedGroups(idSchedGroup).
|
---|
66 | idSchedGroup INTEGER NOT NULL,
|
---|
67 | --- When this row starts taking effect (inclusive).
|
---|
68 | tsEffective TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp NOT NULL,
|
---|
69 | --- When this row stops being tsEffective (exclusive).
|
---|
70 | tsExpire TIMESTAMP WITH TIME ZONE DEFAULT TIMESTAMP WITH TIME ZONE 'infinity' NOT NULL,
|
---|
71 | --- The user id of the one who created/modified this entry.
|
---|
72 | -- Non-unique foreign key: Users(uid)
|
---|
73 | uidAuthor INTEGER NOT NULL,
|
---|
74 |
|
---|
75 | --- The scheduling priority of the scheduling group for the test box.
|
---|
76 | -- Higher number causes the scheduling group to be serviced more frequently.
|
---|
77 | -- @sa TestGroupMembers.iSchedPriority, SchedGroups.iSchedPriority
|
---|
78 | iSchedPriority INTEGER DEFAULT 16 CHECK (iSchedPriority >= 0 AND iSchedPriority < 32) NOT NULL,
|
---|
79 |
|
---|
80 | PRIMARY KEY (idTestBox, idSchedGroup, tsExpire)
|
---|
81 | );
|
---|
82 |
|
---|
83 | GRANT ALL PRIVILEGES ON TABLE TestBoxesInSchedGroups TO testmanager;
|
---|
84 |
|
---|
85 | CREATE OR REPLACE FUNCTION TestBoxesInSchedGroups_ConvertedOneBox(a_idTestBox INTEGER)
|
---|
86 | RETURNS VOID AS $$
|
---|
87 | DECLARE
|
---|
88 | v_Row RECORD;
|
---|
89 | v_idSchedGroup INTEGER;
|
---|
90 | v_uidAuthor INTEGER;
|
---|
91 | v_tsEffective TIMESTAMP WITH TIME ZONE;
|
---|
92 | v_tsExpire TIMESTAMP WITH TIME ZONE;
|
---|
93 | BEGIN
|
---|
94 | FOR v_Row IN
|
---|
95 | SELECT idTestBox,
|
---|
96 | idSchedGroup,
|
---|
97 | tsEffective,
|
---|
98 | tsExpire,
|
---|
99 | uidAuthor
|
---|
100 | FROM TestBoxes
|
---|
101 | WHERE idTestBox = a_idTestBox
|
---|
102 | ORDER BY tsEffective, tsExpire
|
---|
103 | LOOP
|
---|
104 | IF v_idSchedGroup IS NOT NULL THEN
|
---|
105 | IF (v_idSchedGroup != v_Row.idSchedGroup) OR (v_Row.tsEffective <> v_tsExpire) THEN
|
---|
106 | INSERT INTO TestBoxesInSchedGroups (idTestBox, idSchedGroup, tsEffective, tsExpire, uidAuthor)
|
---|
107 | VALUES (a_idTestBox, v_idSchedGroup, v_tsEffective, v_tsExpire, v_uidAuthor);
|
---|
108 | v_idSchedGroup := NULL;
|
---|
109 | END IF;
|
---|
110 | END IF;
|
---|
111 |
|
---|
112 | IF v_idSchedGroup IS NULL THEN
|
---|
113 | v_idSchedGroup := v_Row.idSchedGroup;
|
---|
114 | v_tsEffective := v_Row.tsEffective;
|
---|
115 | END IF;
|
---|
116 | IF v_Row.uidAuthor IS NOT NULL THEN
|
---|
117 | v_uidAuthor := v_Row.uidAuthor;
|
---|
118 | END IF;
|
---|
119 | v_tsExpire := v_Row.tsExpire;
|
---|
120 | END LOOP;
|
---|
121 |
|
---|
122 | IF v_idSchedGroup != -1 THEN
|
---|
123 | INSERT INTO TestBoxesInSchedGroups (idTestBox, idSchedGroup, tsEffective, tsExpire, uidAuthor)
|
---|
124 | VALUES (a_idTestBox, v_idSchedGroup, v_tsEffective, v_tsExpire, v_uidAuthor);
|
---|
125 | END IF;
|
---|
126 | END;
|
---|
127 | $$ LANGUAGE plpgsql;
|
---|
128 |
|
---|
129 | SELECT TestBoxesInSchedGroups_ConvertedOneBox(TestBoxIDs.idTestBox)
|
---|
130 | FROM ( SELECT DISTINCT idTestBox FROM TestBoxes ) AS TestBoxIDs;
|
---|
131 |
|
---|
132 | DROP FUNCTION TestBoxesInSchedGroups_ConvertedOneBox(INTEGER);
|
---|
133 |
|
---|
134 | --
|
---|
135 | -- Do the other two modifications.
|
---|
136 | --
|
---|
137 | ALTER TABLE TestBoxStatuses ADD COLUMN iWorkItem INTEGER DEFAULT 0 NOT NULL;
|
---|
138 |
|
---|
139 | DROP VIEW TestBoxesWithStrings;
|
---|
140 | ALTER TABLE TestBoxes DROP COLUMN idSchedGroup;
|
---|
141 | CREATE VIEW TestBoxesWithStrings AS
|
---|
142 | SELECT TestBoxes.*,
|
---|
143 | Str1.sValue AS sDescription,
|
---|
144 | Str2.sValue AS sComment,
|
---|
145 | Str3.sValue AS sOs,
|
---|
146 | Str4.sValue AS sOsVersion,
|
---|
147 | Str5.sValue AS sCpuVendor,
|
---|
148 | Str6.sValue AS sCpuArch,
|
---|
149 | Str7.sValue AS sCpuName,
|
---|
150 | Str8.sValue AS sReport
|
---|
151 | FROM TestBoxes
|
---|
152 | LEFT OUTER JOIN TestBoxStrTab Str1 ON idStrDescription = Str1.idStr
|
---|
153 | LEFT OUTER JOIN TestBoxStrTab Str2 ON idStrComment = Str2.idStr
|
---|
154 | LEFT OUTER JOIN TestBoxStrTab Str3 ON idStrOs = Str3.idStr
|
---|
155 | LEFT OUTER JOIN TestBoxStrTab Str4 ON idStrOsVersion = Str4.idStr
|
---|
156 | LEFT OUTER JOIN TestBoxStrTab Str5 ON idStrCpuVendor = Str5.idStr
|
---|
157 | LEFT OUTER JOIN TestBoxStrTab Str6 ON idStrCpuArch = Str6.idStr
|
---|
158 | LEFT OUTER JOIN TestBoxStrTab Str7 ON idStrCpuName = Str7.idStr
|
---|
159 | LEFT OUTER JOIN TestBoxStrTab Str8 ON idStrReport = Str8.idStr;
|
---|
160 |
|
---|
161 | GRANT ALL PRIVILEGES ON TABLE TestBoxesWithStrings TO testmanager;
|
---|
162 |
|
---|
163 | \prompt "Update python files while everything is locked. Hurry!" dummy
|
---|
164 |
|
---|
165 | COMMIT;
|
---|
166 |
|
---|
167 | \d TestBoxesInSchedGroups;
|
---|
168 | \d TestBoxStatuses;
|
---|
169 | \d TestBoxes;
|
---|
170 | ANALYZE VERBOSE TestBoxesInSchedGroups;
|
---|
171 |
|
---|