add a log entry limit to the object page (Mantis#769)
[racktables] / wwwroot / inc / upgrade.php
1 <?php
2
3 # This file is a part of RackTables, a datacenter and server room management
4 # framework. See accompanying file "COPYING" for the full copyright and
5 # licensing information.
6
7 $relnotes = array
8 (
9 '0.20.0' => <<<'ENDOFTEXT'
10 WARNING: This release have too many internal changes, some of them were waiting more than a year
11 to be released. So this release is considered "BETA" and is recommended only to curiuos users,
12 who agree to sacrifice the stability to the progress.
13
14 Racks and Rows are now stored in the database as Objects. The RackObject table
15 was renamed to Object. SQL views were created to ease the migration of custom
16 reports and scripts.
17
18 New plugins engine instead of local.php file. To make your own code stored in local.php work,
19 you must move the local.php file into the plugins/ directory. The name of this file does not
20 matter any more. You also can store multiple files in that dir, separate your plugins by features,
21 share them and try the plugins from other people just placing them into plugins/ dir, no more merging.
22 $path_to_local_php variable has no special meaning any more.
23 $racktables_confdir variable is now used only to search for secret.php file.
24 $racktables_plugins_dir is a new overridable special variable pointing to plugins/ directory.
25
26 Beginning with this version it is possible to delete IP prefixes, VLANs, Virtual services
27 and RS pools from within theirs properties tab. So please inspect your permissions rules
28 to assure there are no undesired allows for deletion of these objects. To ensure this, you could
29 try this code in the beginning of permissions script:
30
31 allow {userid_1} and {$op_del}
32 deny {$op_del} and ({$tab_edit} or {$tab_properties})
33
34 Hardware gateways engine was rewritten in this version of RackTables. This means that
35 the file gateways/deviceconfig/switch.secrets.php is not used any more. To get information
36 about configuring connection properties and credentials in a new way please visit
37 http://wiki.racktables.org/index.php/Gateways
38
39 This also means that recently added features based on old API (D-Link switches and Linux
40 gateway support contributed by Ilya Evseev) are not working any more and waiting to be
41 forward-ported to new gateways API. Sorry for that.
42
43 Two new config variables appeared in this version:
44 - SEARCH_DOMAINS. Comma-separated list of DNS domains that are considered "base" for your
45 network. If RackTables search engine finds multiple objects based on your search input, but
46 there is only one that has FQDN consisting of your input and one of these search domains, you will
47 be redirected to this object and other results will be discarded. Such behavior was unconditional
48 since 0.19.3, which caused many objections from users. So welcome this config var.
49 - QUICK_LINK_PAGES. Comma-separated list of RackTables pages to display links to them on top.
50 Each user could have his own list.
51
52 Also some of config variables have changed their default values in this version.
53 This means that upgrade script will change their values if you have them in previous default state.
54 This could be inconvenient, but it is the most effective way to encourage users to use new features.
55 If this behavior is not what you want, simply revert these variables' values:
56 - SHOW_LAST_TAB no => yes
57 - IPV4_TREE_SHOW_USAGE yes =>no (networks' usage is still available by click)
58 - IPV4LB_LISTSRC {$typeid_4} => false
59 - FILTER_DEFAULT_ANDOR or => and (this implicitly enables the feature of dynamic tree shrinking)
60 - FILTER_SUGGEST_EXTRA no => yes (yes, we have extra logical filters!)
61 - IPV4_TREE_RTR_AS_CELL yes => no (display routers as simple text, not cell)
62
63 Also please note that variable IPV4_TREE_RTR_AS_CELL now has third special value
64 besides 'yes' and 'no': 'none'. Use 'none' value if you are experiencing low performance
65 on IP tree page. It will completely disable IP ranges scan for used/spare IPs and the
66 speed of IP tree will increase radically. The price is you will not see the routers in
67 IP tree at all.
68
69 ENDOFTEXT
70 ,
71
72 '0.20.1' => <<<'ENDOFTEXT'
73 The 0.20.0 release includes a bug that breaks IP networks' capacity displaying on 32-bit architecture machines. To fix this, this release makes use of PHP's BC Math module. It is a new reqiurement. Most PHP distributions have this module already enabled, but if yours does not - you need yo recompile PHP.
74
75 Security context of 'ipaddress' page now includes tags from the network containing an IP address. This means that you should audit your permission rules to check there is no unintended allows of changing IPs based on network's tagset. Example:
76 allow {client network} and {New York}
77 This rule now not only allows any operation on NY client networks, but also any operation with IP addresses included in those networks. To fix this, you should change the rule this way:
78 allow {client network} and {New York} and not {$page_ipaddress}
79
80 ENDOFTEXT
81 ,
82
83 '0.20.4' => <<<'ENDOFTEXT'
84 Please note that some dictionary items of Cisco Catalyst 2960 series switches
85 were renamed to meet official Cisco classification:
86 2960-48TT => 2960-48TT-L
87 2960-24TC => 2960-24TC-L
88 2960-24TT => 2960-24TT-L
89 2960-8TC => 2960-8TC-L
90 2960G-48TC => 2960G-48TC-L
91 2960G-24TC => 2960G-24TC-L
92 2960G-8TC => 2960G-8TC-L
93 C2960-24 => C2960-24-S
94 C2960G-24PC => C2960-24PC-L
95
96 The DATETIME_FORMAT configuration option used in setting date and time output
97 format now uses a different [1] syntax. During upgrade the option is reset to
98 the default value, which is now %Y-%m-%d (YYYY-MM-DD) per ISO 8601.
99
100 This release intoduces two new configuration options:
101 REVERSED_RACKS_LISTSRC and NEAREST_RACKS_CHECKBOX.
102
103 [1] http://php.net/manual/en/function.strftime.php
104 ENDOFTEXT
105 ,
106
107 '0.20.5' => <<<'ENDOFTEXT'
108 This release introduces the VS groups feature. VS groups is a new way to store
109 and display virtual services configuration. There is a new "ipvs" (VS group)
110 realm. All previously existing VS configuration remains functional and user
111 is free to convert it to the new format, which displays it in a more natural way
112 and allows to generate virtual_server_group keepalived configs. To convert a
113 virtual service to the new format, it is necessary to manually create a VS group
114 object and assign IP addresses to it. The VS group will display a "Migrate" tab
115 to convert the old-style VS objects, which can be removed after a successful
116 conversion.
117
118 The old-style VS configuration becomes DEPRECATED. Its support will be removed
119 in a future major release. So it is strongly recommended to convert it to the
120 new format.
121 ENDOFTEXT
122 ,
123
124 '0.20.6' => <<<'ENDOFTEXT'
125 New MGMT_PROTOS configuration option replaces the TELNET_OBJS_LISTSRC,
126 SSH_OBJS_LISTSRC and RDP_OBJS_LISTSRC options (converting existing settings as
127 necessary). MGMT_PROTOS allows to specify any management protocol for a
128 particular device list using a RackCode filter. The default value
129 ("ssh: {$typeid_4}, telnet: {$typeid_8}") produces "ssh://server.fqdn" for
130 servers and "telnet://switch.fqdn" for network switches.
131 ENDOFTEXT
132 ,
133
134 '0.20.7' => <<<'ENDOFTEXT'
135 From now on the minimum (oldest) release of PHP that can run RackTables is
136 5.2.10. In particular, to continue running RackTables on CentOS 5 it is
137 necessary to replace its php* RPM packages with respective php53* packages
138 before the upgrade (except the JSON package, which PHP 5.3 provides internally).
139
140 Database triggers are used for some data consistency measures. The database
141 user account must have the 'TRIGGER' privilege, which was introduced in
142 MySQL 5.1.7.
143
144 The IPV4OBJ_LISTSRC configuration option is reset to an expression that enables
145 the IP addressing feature for all object types except those listed.
146
147 Tags could now be assigned on the Edit/Properties tab using a text input with
148 auto-completion. Type a star '*' to view full tag tree in auto-complete menu.
149 It is worth to add the following line to the permissions script if the
150 old-fashioned 'Tags' tab is not needed any more:
151 deny {$tab_tags} # this hides 'Tags' tab
152
153 This release converts collation of all DB fields to the utf8_unicode_ci. This
154 procedure may take some time, and could fail if there are rows that differ only
155 by letter case. If this happen, you'll see the failed SQL query in upgrade report
156 with the "Duplicate entry" error message. Feel free to continue using your
157 installation. If desired so, you could eliminate the case-duplicating rows
158 and re-apply the failed query.
159 ENDOFTEXT
160 ,
161 '0.20.11' => <<<'ENDOFTEXT'
162 New IPV4_TREE_SHOW_UNALLOCATED configuration option introduced to disable
163 dsplaying unallocated networks in IPv4 space tree. Setting it also disables
164 the "knight" feature.
165 ENDOFTEXT
166 ,
167 '0.21.0' => <<<'ENDOFTEXT'
168 From now on the minimum (oldest) release of PHP that can run RackTables is
169 5.5.0.
170
171 This release introduces a new plugin architecture. If you experience issues
172 after the upgrade, try disabling plugins.
173 Refer to <a href="http://wiki.racktables.org/index.php/Plugins">the wiki</a> for more information.
174 ENDOFTEXT
175 ,
176 '0.21.2' => <<<'ENDOFTEXT'
177 "Shared router" allocation type introduced, useful for documenting VRRP-protected addresses.
178
179 This version drops support for the $localreports global variable, which is
180 trivial to replace in a local plugin if necessary.
181
182 The "addJS()" function is now deprecated in favour of "addJSText()", "addJSInternal()",
183 and "addJSExternal()" functions. The "addJS()" function will likely be removed in 0.22.0.
184
185 The "addCSS()" function is now deprecated in favour of "addCSSText()", "addCSSInternal()",
186 and "addCSSExternal()" functions. The "addCSS()" function will likely be removed in 0.22.0.
187
188 For more information on the "addJS()" and "addCSS()" changes see the README.md
189 ENDOFTEXT
190 ,
191 );
192
193 // This function currently implements a convention that to upgrade any release R1
194 // to a release R2 (such that R2 > R1) it takes to apply the sequence of batches
195 // (R1, R2] to database R1.
196 // Returning an empty array means that no upgrade is necessary.
197 // Returning NULL indicates an error.
198 function getDBUpgradePath ($v1, $v2)
199 {
200 $versionhistory = array
201 (
202 '0.20.0',
203 '0.20.1',
204 '0.20.2',
205 '0.20.3',
206 '0.20.4',
207 '0.20.5',
208 '0.20.6',
209 '0.20.7',
210 '0.20.8',
211 '0.20.9',
212 '0.20.10',
213 '0.20.11',
214 '0.20.12',
215 '0.20.13',
216 '0.20.14',
217 '0.21.0',
218 '0.21.1',
219 '0.21.2',
220 '0.21.3',
221 );
222 if (! in_array ($v1, $versionhistory) || ! in_array ($v2, $versionhistory))
223 return NULL;
224 $skip = TRUE;
225 $path = NULL;
226 // foreach() below cannot handle this specific case
227 if ($v1 == $v2)
228 return array();
229 // Now collect all versions > $v1 and <= $v2
230 foreach ($versionhistory as $v)
231 {
232 if ($skip && $v == $v1)
233 {
234 $skip = FALSE;
235 $path = array();
236 continue;
237 }
238 if ($skip)
239 continue;
240 $path[] = $v;
241 if ($v == $v2)
242 break;
243 }
244 return $path;
245 }
246
247 // Upgrade batches are named exactly as the release where they first appear.
248 // That is simple, but seems sufficient for beginning.
249 function getUpgradeBatch ($batchid)
250 {
251 $query = array();
252 global $dbver, $dbxlink;
253 switch ($batchid)
254 {
255 case '0.20.0':
256 $query[] = "
257 CREATE TABLE `PortLog` (
258 `id` int(10) unsigned NOT NULL AUTO_INCREMENT,
259 `port_id` int(10) unsigned NOT NULL,
260 `date` datetime NOT NULL,
261 `user` varchar(64) NOT NULL,
262 `message` text NOT NULL,
263 PRIMARY KEY (`id`),
264 KEY `port_id-date` (`port_id`,`date`),
265 CONSTRAINT `PortLog_ibfk_1` FOREIGN KEY (`port_id`) REFERENCES `Port` (`id`) ON DELETE CASCADE
266 ) ENGINE=InnoDB;
267 ";
268 $query[] = "
269 CREATE TABLE `IPv4Log` (
270 `id` int(10) NOT NULL AUTO_INCREMENT,
271 `ip` int(10) unsigned NOT NULL,
272 `date` datetime NOT NULL,
273 `user` varchar(64) NOT NULL,
274 `message` text NOT NULL,
275 PRIMARY KEY (`id`),
276 KEY `ip-date` (`ip`,`date`)
277 ) ENGINE=InnoDB;
278 ";
279 $query[] = "
280 CREATE TABLE `IPv6Log` (
281 `id` int(10) NOT NULL AUTO_INCREMENT,
282 `ip` binary(16) NOT NULL,
283 `date` datetime NOT NULL,
284 `user` varchar(64) NOT NULL,
285 `message` text NOT NULL,
286 PRIMARY KEY (`id`),
287 KEY `ip-date` (`ip`,`date`)
288 ) ENGINE=InnoDB;
289 ";
290 $query[] = "ALTER TABLE `FileLink` MODIFY COLUMN `entity_type` ENUM('ipv4net','ipv4rspool','ipv4vs','ipv6net','location','object','rack','user') NOT NULL DEFAULT 'object'";
291 $query[] = "ALTER TABLE `TagStorage` MODIFY COLUMN `entity_realm` ENUM('file','ipv4net','ipv4rspool','ipv4vs','ipv6net','location','object','rack','user','vst') NOT NULL default 'object'";
292 $query[] = "ALTER TABLE `TagStorage` ADD COLUMN `user` char(64) DEFAULT NULL, ADD COLUMN `date` datetime DEFAULT NULL";
293
294 // Rename object tables and keys, 'name' no longer needs to be unique
295 $dbxlink->query ('ALTER TABLE `RackObject` RENAME TO `Object`');
296 $dbxlink->query ('ALTER TABLE `RackObjectHistory` RENAME TO `ObjectHistory`');
297 $dbxlink->query ('ALTER TABLE `Object` DROP KEY `name`');
298 $query[] = 'ALTER TABLE `Object` DROP KEY `RackObject_asset_no`';
299 $query[] = 'ALTER TABLE `Object` ADD UNIQUE KEY `asset_no` (`asset_no`)';
300 $query[] = 'ALTER TABLE `Object` ADD KEY `type_id` (`objtype_id`,`id`)';
301 $query[] = 'ALTER TABLE `ObjectHistory` DROP FOREIGN KEY `RackObjectHistory-FK-object_id`';
302 $query[] = 'ALTER TABLE `ObjectHistory` ADD CONSTRAINT `ObjectHistory-FK-object_id` FOREIGN KEY (`id`) REFERENCES `Object` (`id`) ON DELETE CASCADE';
303 $query[] = 'ALTER TABLE `RackSpace` DROP FOREIGN KEY `RackSpace-FK-rack_id`';
304
305 // Rack height is now an attribute
306 $query[] = "INSERT INTO `Attribute` (`id`,`type`,`name`) VALUES (27,'uint','Height, units')";
307 $query[] = 'INSERT INTO `AttributeMap` (`objtype_id`,`attr_id`,`chapter_id`) VALUES (1560,27,NULL)';
308
309 // Racks are now sorted using an attribute
310 $query[] = "INSERT INTO `Attribute` (`id`,`type`,`name`) VALUES (29,'uint','Sort order')";
311 $query[] = 'INSERT INTO `AttributeMap` (`objtype_id`,`attr_id`,`chapter_id`) VALUES (1560,29,NULL)';
312
313 // Relate 'contact person' with locations
314 $query[] = 'INSERT INTO `AttributeMap` (`objtype_id`,`attr_id`,`chapter_id`) VALUES (1562,14,NULL)';
315
316 // Allow relationships between racks/rows/locations
317 $query[] = "ALTER TABLE `EntityLink` MODIFY COLUMN `parent_entity_type` ENUM('ipv4net','ipv4rspool','ipv4vs','ipv6net','location','object','rack','row','user') NOT NULL";
318 $query[] = "ALTER TABLE `EntityLink` MODIFY COLUMN `child_entity_type` ENUM('file','location','object','rack','row') NOT NULL";
319
320 // Turn rows into objects
321 $result = $dbxlink->query ('SELECT id, name FROM RackRow');
322 $rows = $result->fetchAll (PDO::FETCH_ASSOC);
323 unset ($result);
324 foreach ($rows as $row)
325 {
326 $prepared = $dbxlink->prepare ('INSERT INTO `Object` (`name`,`objtype_id`) VALUES (?,?)');
327 $prepared->execute (array($row['name'], 1561));
328 $row_id = $dbxlink->lastInsertID();
329 // Turn all racks in this row into objects
330 $result = $dbxlink->query ("SELECT id, name, height, comment FROM Rack WHERE row_id=${row['id']} ORDER BY name");
331 $racks = $result->fetchAll (PDO::FETCH_ASSOC);
332 unset ($result);
333 $sort_order = 1;
334 foreach ($racks as $rack)
335 {
336 // Add the rack as an object, set the height and sort order as attributes, link the rack to the row,
337 // update rackspace, tags and files to reflect new rack_id, move history
338 $prepared = $dbxlink->prepare ('INSERT INTO `Object` (`name`,`objtype_id`,`comment`) VALUES (?,?,?)');
339 $prepared->execute (array($rack['name'], 1560, $rack['comment']));
340 $rack_id = $dbxlink->lastInsertID();
341 $query[] = "INSERT INTO `AttributeValue` (`object_id`,`object_tid`,`attr_id`,`uint_value`) VALUES (${rack_id},1560,27,${rack['height']})";
342 $query[] = "INSERT INTO `AttributeValue` (`object_id`,`object_tid`,`attr_id`,`uint_value`) VALUES (${rack_id},1560,29,${sort_order})";
343 $query[] = "INSERT INTO `EntityLink` (`parent_entity_type`,`parent_entity_id`,`child_entity_type`,`child_entity_id`) VALUES ('row',${row_id},'rack',${rack_id})";
344 $query[] = "UPDATE `RackSpace` SET `rack_id`=${rack_id} WHERE `rack_id`=${rack['id']}";
345 $query[] = "UPDATE `Atom` SET `rack_id`=${rack_id} WHERE `rack_id`=${rack['id']}";
346 $query[] = "UPDATE `TagStorage` SET `entity_id`=${rack_id} WHERE `entity_realm`='rack' AND `entity_id`=${rack['id']}";
347 $query[] = "UPDATE `FileLink` SET `entity_id`=${rack_id} WHERE `entity_type`='rack' AND `entity_id`=${rack['id']}";
348 $query[] = "INSERT INTO `ObjectHistory` (`id`,`name`,`objtype_id`,`comment`,`ctime`,`user_name`) SELECT ${rack_id},`name`,1560,`comment`,`ctime`,`user_name` FROM `RackHistory` WHERE `id`=${rack['id']}";
349 $sort_order++;
350 }
351 }
352 $query[] = 'ALTER TABLE `RackSpace` ADD CONSTRAINT `RackSpace-FK-rack_id` FOREIGN KEY (`rack_id`) REFERENCES `Object` (`id`)';
353 $query[] = 'DROP TABLE `Rack`';
354 $query[] = 'DROP TABLE `RackRow`';
355 $query[] = 'DROP TABLE `RackHistory`';
356 $query[] = "
357 CREATE TABLE `RackThumbnail` (
358 `rack_id` int(10) unsigned NOT NULL,
359 `thumb_data` blob,
360 UNIQUE KEY `rack_id` (`rack_id`),
361 CONSTRAINT `RackThumbnail-FK-rack_id` FOREIGN KEY (`rack_id`) REFERENCES `Object` (`id`) ON DELETE CASCADE
362 ) ENGINE=InnoDB
363 ";
364 $query[] = "
365 CREATE VIEW `Location` AS SELECT O.id, O.name, O.has_problems, O.comment, P.id AS parent_id, P.name AS parent_name
366 FROM `Object` O
367 LEFT JOIN (
368 `Object` P INNER JOIN `EntityLink` EL
369 ON EL.parent_entity_id = P.id AND P.objtype_id = 1562 AND EL.parent_entity_type = 'location' AND EL.child_entity_type = 'location'
370 ) ON EL.child_entity_id = O.id
371 WHERE O.objtype_id = 1562
372 ";
373 $query[] = "
374 CREATE VIEW `Row` AS SELECT O.id, O.name, L.id AS location_id, L.name AS location_name
375 FROM `Object` O
376 LEFT JOIN `EntityLink` EL ON O.id = EL.child_entity_id AND EL.parent_entity_type = 'location' AND EL.child_entity_type = 'row'
377 LEFT JOIN `Object` L ON EL.parent_entity_id = L.id AND L.objtype_id = 1562
378 WHERE O.objtype_id = 1561
379 ";
380 $query[] = "
381 CREATE VIEW `Rack` AS SELECT O.id, O.name AS name, O.asset_no, O.has_problems, O.comment,
382 AV_H.uint_value AS height,
383 AV_S.uint_value AS sort_order,
384 RT.thumb_data,
385 R.id AS row_id,
386 R.name AS row_name
387 FROM `Object` O
388 LEFT JOIN `AttributeValue` AV_H ON O.id = AV_H.object_id AND AV_H.attr_id = 27
389 LEFT JOIN `AttributeValue` AV_S ON O.id = AV_S.object_id AND AV_S.attr_id = 29
390 LEFT JOIN `RackThumbnail` RT ON O.id = RT.rack_id
391 LEFT JOIN `EntityLink` EL ON O.id = EL.child_entity_id AND EL.parent_entity_type = 'row' AND EL.child_entity_type = 'rack'
392 INNER JOIN `Object` R ON R.id = EL.parent_entity_id
393 WHERE O.objtype_id = 1560
394 ";
395 $query[] = "
396 CREATE VIEW `RackObject` AS SELECT id, name, label, objtype_id, asset_no, has_problems, comment FROM `Object`
397 WHERE `objtype_id` NOT IN (1560, 1561, 1562)
398 ";
399 $query[] = "UPDATE `Chapter` SET `name` = 'ObjectType' WHERE `id` = 1";
400 $query[] = "DELETE FROM RackSpace WHERE object_id IS NULL AND state = 'T'";
401
402 $query[] = "INSERT INTO `Config` (varname, varvalue, vartype, emptyok, is_hidden, is_userdefined, description) VALUES ('SYNC_802Q_LISTSRC','','string','yes','no','no','List of VLAN switches sync is enabled on')";
403 $query[] = "UPDATE `Config` SET is_userdefined='yes' WHERE varname='PROXIMITY_RANGE'";
404 $query[] = "INSERT INTO `Config` (varname, varvalue, vartype, emptyok, is_hidden, is_userdefined, description) VALUES ('QUICK_LINK_PAGES','depot,ipv4space,rackspace','string','yes','no','yes','List of pages to dislay in quick links')";
405 $query[] = "ALTER TABLE `IPv4LB` MODIFY `prio` varchar(255) DEFAULT NULL";
406
407 $query[] = "ALTER TABLE `IPv4Address` ADD COLUMN `comment` char(255) NOT NULL default '' AFTER `name`";
408 $query[] = "ALTER TABLE `IPv6Address` ADD COLUMN `comment` char(255) NOT NULL default '' AFTER `name`";
409
410 // change IP address format of IPv4VS and IPv4RS tables
411 convertSLBTablesToBinIPs();
412
413 // do not allow NULL allocation type
414 $query[] = "ALTER TABLE `IPv4Allocation` MODIFY `type` enum('regular','shared','virtual','router') NOT NULL DEFAULT 'regular'";
415 $query[] = "ALTER TABLE `IPv6Allocation` MODIFY `type` enum('regular','shared','virtual','router') NOT NULL DEFAULT 'regular'";
416
417 $query[] = "INSERT INTO `Config` (varname, varvalue, vartype, emptyok, is_hidden, is_userdefined, description) VALUES ('SEARCH_DOMAINS','','string','yes','no','yes','DNS domain list (comma-separated) to search in FQDN attributes')";
418
419 // update some config variables that changed their defaults in this verison
420 replaceConfigVarValue ('SHOW_LAST_TAB', 'yes');
421 replaceConfigVarValue ('IPV4_TREE_SHOW_USAGE','no');
422 replaceConfigVarValue ('IPV4LB_LISTSRC', 'false', '{$typeid_4}');
423 replaceConfigVarValue ('FILTER_DEFAULT_ANDOR', 'and');
424 replaceConfigVarValue ('FILTER_SUGGEST_EXTRA', 'yes');
425 replaceConfigVarValue ('IPV4_TREE_RTR_AS_CELL', 'no');
426 replaceConfigVarValue ('SSH_OBJS_LISTSRC', 'false', 'none');
427 replaceConfigVarValue ('TELNET_OBJS_LISTSRC', 'false', 'none');
428
429 $query[] = "UPDATE Config SET varvalue = '0.20.0' WHERE varname = 'DB_VERSION'";
430 break;
431 case '0.20.1':
432 // some HW types were moved from the 'Network switch' chapter to the 'Network chassis' chapter
433 // change the type of affected objects to 'Network chassis'
434 $query[] = "UPDATE `Object` SET objtype_id = 1503 WHERE id IN (SELECT object_id FROM `AttributeValue` WHERE attr_id = 2 and uint_value IN (888,889,890,891))";
435
436 // new 'management interface' object type
437 $query[] = "INSERT INTO `Chapter` (`id`,`sticky`,`name`) VALUES (38,'no','management interface type')";
438 $query[] = "INSERT INTO `Attribute` (`id`,`type`,`name`) VALUES (30,'dict','Mgmt type')";
439 $query[] = "INSERT INTO `AttributeMap` (`objtype_id`,`attr_id`,`chapter_id`) VALUES (1787,3,NULL),(1787,14,NULL),(1787,30,38)";
440 $query[] = "UPDATE `Config` SET varvalue = CONCAT(varvalue, ' or {\$typeid_1787}') WHERE varname = 'IPV4OBJ_LISTSRC'";
441
442 $query[] = "INSERT INTO Config VALUES ('8021Q_EXTSYNC_LISTSRC','false','string','yes','no','no','List source: objects with extended 802.1Q sync')";
443
444 // constraints to prevent orphan records
445 $query[] = "DELETE A FROM `Atom` A LEFT JOIN `Molecule` M ON A.molecule_id = M.id LEFT JOIN `Object` O ON A.rack_id = O.id WHERE M.id IS NULL OR O.id IS NULL";
446 $query[] = "DELETE FROM `MountOperation` WHERE old_molecule_id NOT IN (SELECT id FROM `Molecule`) OR new_molecule_id NOT IN (SELECT id FROM `Molecule`)";
447 $query[] = "ALTER TABLE `Atom` ADD CONSTRAINT `Atom-FK-molecule_id` FOREIGN KEY (`molecule_id`) REFERENCES `Molecule` (`id`) ON DELETE CASCADE";
448 $query[] = "ALTER TABLE `Atom` ADD CONSTRAINT `Atom-FK-rack_id` FOREIGN KEY (`rack_id`) REFERENCES `Object` (`id`) ON DELETE CASCADE";
449 $query[] = "ALTER TABLE `MountOperation` ADD CONSTRAINT `MountOperation-FK-old_molecule_id` FOREIGN KEY (`old_molecule_id`) REFERENCES `Molecule` (`id`) ON DELETE CASCADE";
450 $query[] = "ALTER TABLE `MountOperation` ADD CONSTRAINT `MountOperation-FK-new_molecule_id` FOREIGN KEY (`new_molecule_id`) REFERENCES `Molecule` (`id`) ON DELETE CASCADE";
451 # multiple Cacti servers
452 $query[] = "
453 CREATE TABLE `CactiServer` (
454 `id` int(10) unsigned NOT NULL auto_increment,
455 `base_url` char(255) DEFAULT NULL,
456 `username` char(64) DEFAULT NULL,
457 `password` char(64) DEFAULT NULL,
458 PRIMARY KEY (`id`)
459 ) ENGINE=InnoDB
460 ";
461 $query[] = "ALTER TABLE CactiGraph ADD COLUMN server_id int(10) unsigned NOT NULL AFTER object_id";
462
463 $result = $dbxlink->query ('SELECT COUNT(*) AS cnt FROM CactiGraph');
464 $row = $result->fetch (PDO::FETCH_ASSOC);
465 unset ($result);
466
467 $result = $dbxlink->query ("SELECT varvalue FROM Config WHERE varname = 'CACTI_URL'");
468 $cacti_url_row = $result->fetch (PDO::FETCH_ASSOC);
469 unset ($result);
470
471 if ($row['cnt'] != 0 || is_array ($cacti_url_row) && $cacti_url_row['varvalue'] != '')
472 {
473 $query[] = "INSERT INTO CactiServer (id) VALUES (1)";
474 $query[] = "UPDATE CactiServer SET base_url = (SELECT varvalue FROM Config WHERE varname = 'CACTI_URL') WHERE id = 1";
475 $query[] = "UPDATE CactiServer SET username = (SELECT varvalue FROM Config WHERE varname = 'CACTI_USERNAME') WHERE id = 1";
476 $query[] = "UPDATE CactiServer SET password = (SELECT varvalue FROM Config WHERE varname = 'CACTI_USERPASS') WHERE id = 1";
477 $query[] = "UPDATE CactiGraph SET server_id = 1";
478 }
479 $query[] = "ALTER TABLE CactiGraph DROP PRIMARY KEY";
480 $query[] = "ALTER TABLE CactiGraph ADD PRIMARY KEY (server_id, graph_id)";
481 $query[] = "ALTER TABLE CactiGraph ADD KEY (graph_id)";
482 $query[] = "ALTER TABLE CactiGraph ADD CONSTRAINT `CactiGraph-FK-server_id` FOREIGN KEY (server_id) REFERENCES CactiServer (id)";
483 $query[] = "DELETE FROM Config WHERE varname IN('CACTI_URL', 'CACTI_USERNAME', 'CACTI_USERPASS')";
484 $query[] = "UPDATE Config SET varvalue = '0.20.1' WHERE varname = 'DB_VERSION'";
485 break;
486 case '0.20.2':
487 $query[] = "ALTER TABLE TagStorage ADD COLUMN tag_is_assignable ENUM('yes', 'no') NOT NULL default 'yes' AFTER tag_id";
488 $query[] = "ALTER TABLE TagStorage ADD KEY `tag_id-tag_is_assignable` (tag_id, tag_is_assignable)";
489 $query[] = "ALTER TABLE TagTree ADD COLUMN is_assignable ENUM('yes', 'no') NOT NULL default 'yes' AFTER parent_id";
490 $query[] = "ALTER TABLE TagTree ADD KEY `id-is_assignable` (id, is_assignable)";
491 $query[] = "ALTER TABLE TagStorage DROP FOREIGN KEY `TagStorage-FK-tag_id`";
492 $query[] = "ALTER TABLE TagStorage ADD CONSTRAINT `TagStorage-FK-TagTree` FOREIGN KEY (tag_id, tag_is_assignable) REFERENCES TagTree (id, is_assignable)";
493 $query[] = "UPDATE UserAccount SET user_realname = NULL WHERE user_realname = ''";
494 $query[] = "UPDATE Object SET comment = NULL WHERE comment = ''";
495 $query[] = "
496 CREATE TABLE `MuninServer` (
497 `id` int(10) unsigned NOT NULL auto_increment,
498 `base_url` char(255) DEFAULT NULL,
499 PRIMARY KEY (`id`)
500 ) ENGINE=InnoDB
501 ";
502 $query[] = "
503 CREATE TABLE `MuninGraph` (
504 `object_id` int(10) unsigned NOT NULL,
505 `server_id` int(10) unsigned NOT NULL,
506 `graph` char(255) NOT NULL,
507 `caption` char(255) DEFAULT NULL,
508 PRIMARY KEY (`object_id`,`server_id`,`graph`),
509 KEY `server_id` (`server_id`),
510 KEY `graph` (`graph`),
511 CONSTRAINT `MuninGraph-FK-server_id` FOREIGN KEY (`server_id`) REFERENCES `MuninServer` (`id`),
512 CONSTRAINT `MuninGraph-FK-object_id` FOREIGN KEY (`object_id`) REFERENCES `Object` (`id`) ON DELETE CASCADE
513 ) ENGINE=InnoDB
514 ";
515 $query[] = "INSERT INTO `Config` (varname, varvalue, vartype, emptyok, is_hidden, is_userdefined, description) VALUES ('MUNIN_LISTSRC','false','string','yes','no','no','List of object with Munin graphs')";
516 $query[] = "INSERT INTO `Config` (varname, varvalue, vartype, emptyok, is_hidden, is_userdefined, description) VALUES ('8021Q_MULTILINK_LISTSRC','false','string','yes','no','no','List source: IPv4/IPv6 networks allowing multiple VLANs from same domain')";
517 $query[] = "ALTER TABLE VLANIPv4 ADD UNIQUE `network-domain-vlan` (ipv4net_id, domain_id, vlan_id)";
518 $query[] = "ALTER TABLE VLANIPv4 DROP KEY `network-domain`";
519 $query[] = "ALTER TABLE VLANIPv6 ADD UNIQUE `network-domain-vlan` (ipv6net_id, domain_id, vlan_id)";
520 $query[] = "ALTER TABLE VLANIPv6 DROP KEY `network-domain`";
521 $query[] = "UPDATE Config SET varvalue = '0.20.2' WHERE varname = 'DB_VERSION'";
522 break;
523 case '0.20.3':
524 $query[] = "UPDATE Config SET varvalue = '0.20.3' WHERE varname = 'DB_VERSION'";
525 break;
526 case '0.20.4':
527 $query[] = "ALTER TABLE `FileLink` MODIFY COLUMN `entity_type` ENUM('ipv4net','ipv4rspool','ipv4vs','ipv6net','location','object','rack','row','user') NOT NULL DEFAULT 'object'";
528 $query[] = "ALTER TABLE `RackSpace` MODIFY COLUMN `state` ENUM('A','U','T') NOT NULL default 'A'";
529 $query[] = "INSERT INTO `Config` (varname, varvalue, vartype, emptyok, is_hidden, is_userdefined, description) VALUES ('REVERSED_RACKS_LISTSRC', 'false', 'string', 'yes', 'no', 'no', 'List of racks with reversed (top to bottom) units order')";
530 $query[] = "UPDATE `Config` SET varvalue = CONCAT(varvalue, ' or {\$typeid_965}') WHERE varname = 'IPV4OBJ_LISTSRC'";
531 $query[] = "UPDATE AttributeValue INNER JOIN AttributeMap USING (attr_id) SET AttributeValue.uint_value = 1572 WHERE chapter_id = 12 AND uint_value = 162";
532 $query[] = "UPDATE AttributeValue INNER JOIN AttributeMap USING (attr_id) SET AttributeValue.uint_value = 1710 WHERE chapter_id = 12 AND uint_value = 163";
533 $query[] = "UPDATE Config SET varvalue = '%Y-%m-%d', description='PHP strftime() format to use for date output' WHERE varname = 'DATETIME_FORMAT'";
534 $query[] = "INSERT INTO `Config` (varname, varvalue, vartype, emptyok, is_hidden, is_userdefined, description) VALUES ('NEAREST_RACKS_CHECKBOX', 'yes', 'string', 'yes', 'no', 'yes', 'Enable nearest racks in port list filter by default')";
535 $query[] = "UPDATE Config SET varvalue = '0.20.4' WHERE varname = 'DB_VERSION'";
536 break;
537 case '0.20.5':
538 $query[] = "
539 CREATE OR REPLACE VIEW `Rack` AS SELECT O.id, O.name AS name, O.asset_no, O.has_problems, O.comment,
540 AV_H.uint_value AS height,
541 AV_S.uint_value AS sort_order,
542 RT.thumb_data,
543 R.id AS row_id,
544 R.name AS row_name,
545 L.id AS location_id,
546 L.name AS location_name
547 FROM `Object` O
548 LEFT JOIN `AttributeValue` AV_H ON O.id = AV_H.object_id AND AV_H.attr_id = 27
549 LEFT JOIN `AttributeValue` AV_S ON O.id = AV_S.object_id AND AV_S.attr_id = 29
550 LEFT JOIN `RackThumbnail` RT ON O.id = RT.rack_id
551 LEFT JOIN `EntityLink` RL ON O.id = RL.child_entity_id AND RL.parent_entity_type = 'row' AND RL.child_entity_type = 'rack'
552 INNER JOIN `Object` R ON R.id = RL.parent_entity_id
553 LEFT JOIN `EntityLink` LL ON R.id = LL.child_entity_id AND LL.parent_entity_type = 'location' AND LL.child_entity_type = 'row'
554 LEFT JOIN `Object` L ON L.id = LL.parent_entity_id
555 WHERE O.objtype_id = 1560
556 ";
557
558 // prevent some AttributeMap entries from being deleted
559 $query[] = "ALTER TABLE AttributeMap ADD COLUMN sticky enum('yes','no') default 'no'";
560 $query[] = "UPDATE AttributeMap SET sticky = 'yes' WHERE objtype_id = 4 AND attr_id IN (26,28)"; // Server -> Hypervisor, Slot number
561 $query[] = "UPDATE AttributeMap SET sticky = 'yes' WHERE objtype_id = 8 AND attr_id IN (1,2,4,28)"; // Network switch -> OEM S/N 1, HW type, SW type, Slot number
562 $query[] = "UPDATE AttributeMap SET sticky = 'yes' WHERE objtype_id = 798 AND attr_id = 28"; // Network security -> Slot number
563 $query[] = "UPDATE AttributeMap SET sticky = 'yes' WHERE objtype_id = 1055 AND attr_id = 28"; // FC switch -> Slot number
564 $query[] = "UPDATE AttributeMap SET sticky = 'yes' WHERE objtype_id = 1560 AND attr_id IN (27,29)"; // Rack -> Height, Sort order
565 $query[] = "UPDATE AttributeMap SET sticky = 'yes' WHERE objtype_id = 1787 AND attr_id = 30"; // Management interface -> Mgmt type
566
567 $query[] = "INSERT INTO `Config` (varname, varvalue, vartype, emptyok, is_hidden, is_userdefined, description) VALUES ('RDP_OBJS_LISTSRC','false','string','yes','no','yes','Rackcode filter for RDP-managed objects')";
568
569 // SLB v2 tables
570 $query[] = "
571 CREATE TABLE `VS` (
572 `id` int(10) unsigned NOT NULL AUTO_INCREMENT,
573 `name` char(255) DEFAULT NULL,
574 `vsconfig` text,
575 `rsconfig` text,
576 PRIMARY KEY (`id`)
577 ) ENGINE=InnoDB
578 ";
579 $query[] = "
580 CREATE TABLE `VSIPs` (
581 `vs_id` int(10) unsigned NOT NULL,
582 `vip` varbinary(16) NOT NULL,
583 `vsconfig` text,
584 `rsconfig` text,
585 PRIMARY KEY (`vs_id`,`vip`),
586 KEY `vip` (`vip`),
587 CONSTRAINT `VSIPs-vs_id` FOREIGN KEY (`vs_id`) REFERENCES `VS` (`id`) ON DELETE CASCADE
588 ) ENGINE=InnoDB
589 ";
590 $query[] = "
591 CREATE TABLE `VSPorts` (
592 `vs_id` int(10) unsigned NOT NULL,
593 `proto` enum('TCP','UDP','MARK') NOT NULL,
594 `vport` int(10) unsigned NOT NULL,
595 `vsconfig` text,
596 `rsconfig` text,
597 PRIMARY KEY (`vs_id`,`proto`,`vport`),
598 KEY `proto-vport` (`proto`,`vport`),
599 CONSTRAINT `VS-vs_id` FOREIGN KEY (`vs_id`) REFERENCES `VS` (`id`) ON DELETE CASCADE
600 ) ENGINE=InnoDB
601 ";
602 $query[] = "
603 CREATE TABLE `VSEnabledIPs` (
604 `object_id` int(10) unsigned NOT NULL,
605 `vs_id` int(10) unsigned NOT NULL,
606 `vip` varbinary(16) NOT NULL,
607 `rspool_id` int(10) unsigned NOT NULL,
608 `prio` varchar(255) DEFAULT NULL,
609 `vsconfig` text,
610 `rsconfig` text,
611 PRIMARY KEY (`object_id`,`vs_id`,`vip`,`rspool_id`),
612 KEY `vip` (`vip`),
613 KEY `VSEnabledIPs-FK-vs_id-vip` (`vs_id`,`vip`),
614 KEY `VSEnabledIPs-FK-rspool_id` (`rspool_id`),
615 CONSTRAINT `VSEnabledIPs-FK-rspool_id` FOREIGN KEY (`rspool_id`) REFERENCES `IPv4RSPool` (`id`) ON DELETE CASCADE,
616 CONSTRAINT `VSEnabledIPs-FK-vs_id-vip` FOREIGN KEY (`vs_id`, `vip`) REFERENCES `VSIPs` (`vs_id`, `vip`) ON DELETE CASCADE
617 ) ENGINE=InnoDB
618 ";
619 $query[] = "
620 CREATE TABLE `VSEnabledPorts` (
621 `object_id` int(10) unsigned NOT NULL,
622 `vs_id` int(10) unsigned NOT NULL,
623 `proto` enum('TCP','UDP','MARK') NOT NULL,
624 `vport` int(10) unsigned NOT NULL,
625 `rspool_id` int(10) unsigned NOT NULL,
626 `vsconfig` text,
627 `rsconfig` text,
628 PRIMARY KEY (`object_id`,`vs_id`,`proto`,`vport`,`rspool_id`),
629 KEY `VSEnabledPorts-FK-vs_id-proto-vport` (`vs_id`,`proto`,`vport`),
630 KEY `VSEnabledPorts-FK-rspool_id` (`rspool_id`),
631 CONSTRAINT `VSEnabledPorts-FK-object_id` FOREIGN KEY (`object_id`) REFERENCES `Object` (`id`) ON DELETE CASCADE,
632 CONSTRAINT `VSEnabledPorts-FK-rspool_id` FOREIGN KEY (`rspool_id`) REFERENCES `IPv4RSPool` (`id`) ON DELETE CASCADE,
633 CONSTRAINT `VSEnabledPorts-FK-vs_id-proto-vport` FOREIGN KEY (`vs_id`, `proto`, `vport`) REFERENCES `VSPorts` (`vs_id`, `proto`, `vport`) ON DELETE CASCADE
634 ) ENGINE=InnoDB
635 ";
636 $query[] = "ALTER TABLE `EntityLink` MODIFY COLUMN `parent_entity_type` ENUM('ipv4net','ipv4rspool','ipv4vs','ipv6net','location','object','rack','row','user') NOT NULL";
637 $query[] = "ALTER TABLE `FileLink` MODIFY COLUMN `entity_type` ENUM('ipv4net','ipv4rspool','ipv4vs','ipv6net','location','object','rack','row','user') NOT NULL DEFAULT 'object'";
638 $query[] = "ALTER TABLE `TagStorage` MODIFY COLUMN `entity_realm` ENUM('file','ipv4net','ipv4rspool','ipv4vs','ipvs','ipv6net','location','object','rack','user','vst') NOT NULL DEFAULT 'object'";
639 $query[] = "ALTER TABLE `UserConfig` DROP FOREIGN KEY `UserConfig-FK-user`";
640 $query[] = "UPDATE Config SET varvalue = '0.20.5' WHERE varname = 'DB_VERSION'";
641 break;
642 case '0.20.6':
643 // one HW type was moved from the 'Network switch' chapter to the 'Network chassis' chapter
644 // change the type of affected objects to 'Network chassis'
645 $query[] = "UPDATE `Object` SET objtype_id = 1503 WHERE id IN (SELECT object_id FROM `AttributeValue` WHERE attr_id = 2 and uint_value = 935)";
646
647 // convert values of old 'TELNET_OBJS_LISTSRC' 'SSH_OBJS_LISTSRC', 'RDP_OBJS_LISTSRC' variables into 'MGMT_PROTOS'
648 $query[] = "INSERT INTO `Config` (varname, varvalue, vartype, emptyok, is_hidden, is_userdefined, description) VALUES ('MGMT_PROTOS','ssh: {\$typeid_4}; telnet: {\$typeid_8}','string','yes','no','yes','Mapping of management protocol to devices')";
649 if ('' !== $mgmt_converted_var = convertMgmtConfigVars())
650 $query[] = "UPDATE `Config` SET varvalue = '" . mysql_escape_string ($mgmt_converted_var) . "' WHERE varname = 'MGMT_PROTOS'"; // TODO: call of deprecated function
651 $query[] = "DELETE `Config`,`UserConfig` FROM `Config` LEFT JOIN `UserConfig` USING (`varname`) WHERE `Config`.`varname` IN ('TELNET_OBJS_LISTSRC', 'SSH_OBJS_LISTSRC', 'RDP_OBJS_LISTSRC')";
652
653 $query[] = "ALTER TABLE `VSEnabledIPs` ADD CONSTRAINT `VSEnabledIPs-FK-object_id` FOREIGN KEY (`object_id`) REFERENCES `Object` (`id`) ON DELETE CASCADE";
654
655 $query[] = "DELETE FROM Config WHERE varname = 'PORTS_PER_ROW'";
656 $query[] = "UPDATE Config SET varvalue = '0.20.6' WHERE varname = 'DB_VERSION'";
657 break;
658 case '0.20.7':
659 if (! isInnoDBSupported ())
660 {
661 showUpgradeError ('Cannot upgrade because triggers are not supported by your MySQL server.', __FUNCTION__);
662 die;
663 }
664
665 // for the UNIQUE key to work, portb needs to be > porta
666 $result = $dbxlink->query ('SELECT porta, portb FROM `Link` WHERE porta > portb');
667 $links = $result->fetchAll (PDO::FETCH_ASSOC);
668 unset ($result);
669 foreach ($links as $link)
670 $query[] = "UPDATE `Link` SET `porta`=${link['portb']}, `portb`=${link['porta']} WHERE `porta`=${link['porta']} AND `portb`=${link['portb']}";
671
672 // add triggers
673 $query[] = "
674 CREATE TRIGGER `EntityLink-before-insert` BEFORE INSERT ON `EntityLink` FOR EACH ROW
675 EntityLinkTrigger:BEGIN
676 DECLARE parent_objtype, child_objtype, count INTEGER;
677
678 # forbid linking an entity to itself
679 IF NEW.parent_entity_type = NEW.child_entity_type AND NEW.parent_entity_id = NEW.child_entity_id THEN
680 SET NEW.parent_entity_id = NULL;
681 LEAVE EntityLinkTrigger;
682 END IF;
683
684 # in some scenarios, only one parent is allowed
685 CASE CONCAT(NEW.parent_entity_type, '.', NEW.child_entity_type)
686 WHEN 'location.location' THEN
687 SELECT COUNT(*) INTO count FROM EntityLink WHERE parent_entity_type = 'location' AND child_entity_type = 'location' AND child_entity_id = NEW.child_entity_id;
688 WHEN 'location.row' THEN
689 SELECT COUNT(*) INTO count FROM EntityLink WHERE parent_entity_type = 'location' AND child_entity_type = 'row' AND child_entity_id = NEW.child_entity_id;
690 WHEN 'row.rack' THEN
691 SELECT COUNT(*) INTO count FROM EntityLink WHERE parent_entity_type = 'row' AND child_entity_type = 'rack' AND child_entity_id = NEW.child_entity_id;
692 ELSE
693 # some other scenario, assume it is valid
694 SET count = 0;
695 END CASE;
696 IF count > 0 THEN
697 SET NEW.parent_entity_id = NULL;
698 LEAVE EntityLinkTrigger;
699 END IF;
700
701 IF NEW.parent_entity_type = 'object' AND NEW.child_entity_type = 'object' THEN
702 # lock objects to prevent concurrent link establishment
703 SELECT objtype_id INTO parent_objtype FROM Object WHERE id = NEW.parent_entity_id FOR UPDATE;
704 SELECT objtype_id INTO child_objtype FROM Object WHERE id = NEW.child_entity_id FOR UPDATE;
705
706 # only permit the link if object types are compatibile
707 SELECT COUNT(*) INTO count FROM ObjectParentCompat WHERE parent_objtype_id = parent_objtype AND child_objtype_id = child_objtype;
708 IF count = 0 THEN
709 SET NEW.parent_entity_id = NULL;
710 END IF;
711 END IF;
712 END;
713 ";
714 $query[] = "
715 CREATE TRIGGER `EntityLink-before-update` BEFORE UPDATE ON `EntityLink` FOR EACH ROW
716 EntityLinkTrigger:BEGIN
717 DECLARE parent_objtype, child_objtype, count INTEGER;
718
719 # forbid linking an entity to itself
720 IF NEW.parent_entity_type = NEW.child_entity_type AND NEW.parent_entity_id = NEW.child_entity_id THEN
721 SET NEW.parent_entity_id = NULL;
722 LEAVE EntityLinkTrigger;
723 END IF;
724
725 # in some scenarios, only one parent is allowed
726 CASE CONCAT(NEW.parent_entity_type, '.', NEW.child_entity_type)
727 WHEN 'location.location' THEN
728 SELECT COUNT(*) INTO count FROM EntityLink WHERE parent_entity_type = 'location' AND child_entity_type = 'location' AND child_entity_id = NEW.child_entity_id AND id != NEW.id;
729 WHEN 'location.row' THEN
730 SELECT COUNT(*) INTO count FROM EntityLink WHERE parent_entity_type = 'location' AND child_entity_type = 'row' AND child_entity_id = NEW.child_entity_id AND id != NEW.id;
731 WHEN 'row.rack' THEN
732 SELECT COUNT(*) INTO count FROM EntityLink WHERE parent_entity_type = 'row' AND child_entity_type = 'rack' AND child_entity_id = NEW.child_entity_id AND id != NEW.id;
733 ELSE
734 # some other scenario, assume it is valid
735 SET count = 0;
736 END CASE;
737 IF count > 0 THEN
738 SET NEW.parent_entity_id = NULL;
739 LEAVE EntityLinkTrigger;
740 END IF;
741
742 IF NEW.parent_entity_type = 'object' AND NEW.child_entity_type = 'object' THEN
743 # lock objects to prevent concurrent link establishment
744 SELECT objtype_id INTO parent_objtype FROM Object WHERE id = NEW.parent_entity_id FOR UPDATE;
745 SELECT objtype_id INTO child_objtype FROM Object WHERE id = NEW.child_entity_id FOR UPDATE;
746
747 # only permit the link if object types are compatibile
748 SELECT COUNT(*) INTO count FROM ObjectParentCompat WHERE parent_objtype_id = parent_objtype AND child_objtype_id = child_objtype;
749 IF count = 0 THEN
750 SET NEW.parent_entity_id = NULL;
751 END IF;
752 END IF;
753 END;
754 ";
755 $link_trigger_body = <<<'ENDOFTRIGGER'
756 LinkTrigger:BEGIN
757 DECLARE tmp, porta_type, portb_type, count INTEGER;
758
759 IF NEW.porta = NEW.portb THEN
760 # forbid connecting a port to itself
761 SET NEW.porta = NULL;
762 LEAVE LinkTrigger;
763 ELSEIF NEW.porta > NEW.portb THEN
764 # force porta < portb
765 SET tmp = NEW.porta;
766 SET NEW.porta = NEW.portb;
767 SET NEW.portb = tmp;
768 END IF;
769
770 # lock ports to prevent concurrent link establishment
771 SELECT type INTO porta_type FROM Port WHERE id = NEW.porta FOR UPDATE;
772 SELECT type INTO portb_type FROM Port WHERE id = NEW.portb FOR UPDATE;
773
774 # only permit the link if ports are compatibile
775 SELECT COUNT(*) INTO count FROM PortCompat WHERE (type1 = porta_type AND type2 = portb_type) OR (type1 = portb_type AND type2 = porta_type);
776 IF count = 0 THEN
777 SET NEW.porta = NULL;
778 END IF;
779 END;
780 ENDOFTRIGGER;
781 $query[] = "CREATE TRIGGER `Link-before-insert` BEFORE INSERT ON `Link` FOR EACH ROW $link_trigger_body";
782 $query[] = "CREATE TRIGGER `Link-before-update` BEFORE UPDATE ON `Link` FOR EACH ROW $link_trigger_body";
783
784 // enable IP addressing for all object types unless specifically excluded
785 $query[] = "UPDATE `Config` SET varvalue = 'not ({\$typeid_3} or {\$typeid_9} or {\$typeid_10} or {\$typeid_11})' WHERE varname = 'IPV4OBJ_LISTSRC'";
786
787 $query[] = "ALTER TABLE `EntityLink` MODIFY COLUMN `parent_entity_type` ENUM('location','object','rack','row') NOT NULL";
788 $query[] = "ALTER TABLE `EntityLink` MODIFY COLUMN `child_entity_type` ENUM('location','object','rack','row') NOT NULL";
789
790 $query[] = "UPDATE Config SET description = 'List source: objects for that asset tag should be set' WHERE varname = 'ASSETWARN_LISTSRC'";
791 $query[] = "UPDATE Config SET description = 'List source: objects for that common name should be set' WHERE varname = 'NAMEWARN_LISTSRC'";
792 $query[] = "ALTER TABLE `IPv4NAT` MODIFY COLUMN `proto` ENUM('TCP','UDP','ALL')";
793
794 // add new 'point2point' alloc type
795 $query[] = "ALTER TABLE `IPv4Allocation` MODIFY `type` enum('regular','shared','virtual','router','point2point') NOT NULL DEFAULT 'regular'";
796 $query[] = "ALTER TABLE `IPv6Allocation` MODIFY `type` enum('regular','shared','virtual','router','point2point') NOT NULL DEFAULT 'regular'";
797
798 // update to use utf8_unicode_ci collation
799 // http://bugs.racktables.org/view.php?id=837
800 $query[] = "ALTER DATABASE DEFAULT CHARACTER SET UTF8 COLLATE utf8_unicode_ci";
801
802 $query[] = "SET @OLD_FOREIGN_KEY_CHECKS=@@FOREIGN_KEY_CHECKS, FOREIGN_KEY_CHECKS=0";
803 $query[] = "ALTER TABLE `Atom` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
804 $query[] = "ALTER TABLE `Attribute` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
805 $query[] = "ALTER TABLE `AttributeMap` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
806 $query[] = "ALTER TABLE `AttributeValue` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
807 $query[] = "ALTER TABLE `CachedPAV` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
808 $query[] = "ALTER TABLE `CachedPNV` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
809 $query[] = "ALTER TABLE `CachedPVM` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
810 $query[] = "ALTER TABLE `CactiGraph` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
811 $query[] = "ALTER TABLE `CactiServer` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
812 $query[] = "ALTER TABLE `Chapter` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
813 $query[] = "ALTER TABLE `Config` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
814 $query[] = "ALTER TABLE `Dictionary` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
815 $query[] = "ALTER TABLE `EntityLink` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
816 $query[] = "ALTER TABLE `File` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
817 $query[] = "ALTER TABLE `FileLink` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
818 $query[] = "ALTER TABLE `IPv4Address` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
819 $query[] = "ALTER TABLE `IPv4Allocation` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
820 $query[] = "ALTER TABLE `IPv4LB` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
821 $query[] = "ALTER TABLE `IPv4Log` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
822 $query[] = "ALTER TABLE `IPv6Log` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
823 $query[] = "ALTER TABLE `IPv4NAT` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
824 $query[] = "ALTER TABLE `IPv4Network` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
825 $query[] = "ALTER TABLE `IPv4RS` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
826 $query[] = "ALTER TABLE `IPv4RSPool` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
827 $query[] = "ALTER TABLE `IPv4VS` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
828 $query[] = "ALTER TABLE `IPv6Address` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
829 $query[] = "ALTER TABLE `IPv6Allocation` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
830 $query[] = "ALTER TABLE `IPv6Network` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
831 $query[] = "ALTER TABLE `LDAPCache` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
832 $query[] = "ALTER TABLE `Link` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
833 $query[] = "ALTER TABLE `Molecule` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
834 $query[] = "ALTER TABLE `MountOperation` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
835 $query[] = "ALTER TABLE `MuninGraph` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
836 $query[] = "ALTER TABLE `MuninServer` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
837 $query[] = "ALTER TABLE `ObjectLog` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
838 $query[] = "ALTER TABLE `ObjectParentCompat` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
839 $query[] = "ALTER TABLE `Port` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
840 $query[] = "ALTER TABLE `PortAllowedVLAN` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
841 $query[] = "ALTER TABLE `PortCompat` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
842 $query[] = "ALTER TABLE `PortInnerInterface` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
843 $query[] = "ALTER TABLE `PortInterfaceCompat` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
844 $query[] = "ALTER TABLE `PortLog` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
845 $query[] = "ALTER TABLE `PortNativeVLAN` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
846 $query[] = "ALTER TABLE `PortVLANMode` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
847 $query[] = "ALTER TABLE `Object` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
848 $query[] = "ALTER TABLE `ObjectHistory` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
849 $query[] = "ALTER TABLE `RackSpace` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
850 $query[] = "ALTER TABLE `RackThumbnail` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
851 $query[] = "ALTER TABLE `Script` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
852 $query[] = "ALTER TABLE `TagStorage` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
853 $query[] = "ALTER TABLE `TagTree` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
854 $query[] = "ALTER TABLE `UserAccount` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
855 $query[] = "ALTER TABLE `UserConfig` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
856 $query[] = "ALTER TABLE `VLANDescription` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
857 $query[] = "ALTER TABLE `VLANDomain` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
858 $query[] = "ALTER TABLE `VLANIPv4` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
859 $query[] = "ALTER TABLE `VLANIPv6` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
860 $query[] = "ALTER TABLE `VLANSTRule` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
861 $query[] = "ALTER TABLE `VLANSwitch` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
862 $query[] = "ALTER TABLE `VLANSwitchTemplate` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
863 $query[] = "ALTER TABLE `VLANValidID` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
864 $query[] = "ALTER TABLE `VS` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
865 $query[] = "ALTER TABLE `VSIPs` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
866 $query[] = "ALTER TABLE `VSPorts` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
867 $query[] = "ALTER TABLE `VSEnabledIPs` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
868 $query[] = "ALTER TABLE `VSEnabledPorts` CONVERT TO CHARACTER SET utf8 COLLATE utf8_unicode_ci";
869 $query[] = "SET FOREIGN_KEY_CHECKS=@OLD_FOREIGN_KEY_CHECKS";
870
871 $query[] = "UPDATE Config SET varvalue = '0.20.7' WHERE varname = 'DB_VERSION'";
872 break;
873 case '0.20.8':
874 $query[] = "ALTER TABLE `VLANSTRule` CHANGE COLUMN `wrt_vlans` `wrt_vlans` text";
875
876 $query[] = "
877 CREATE TABLE `PortOuterInterface` (
878 `id` int(10) unsigned NOT NULL auto_increment,
879 `oif_name` char(48) NOT NULL,
880 PRIMARY KEY (`id`),
881 UNIQUE KEY `oif_name` (`oif_name`)
882 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci
883 ";
884 // if upgrading from certain older releases, inject some data to satisfy foreign keys
885 if (version_compare ($dbver, '0.19.2', '<'))
886 $query[] = "INSERT INTO Dictionary (chapter_id,dict_key,dict_value) VALUES (2,1399,'DC')";
887 if (version_compare ($dbver, '0.19.5', '<'))
888 $query[] = "INSERT INTO Dictionary (chapter_id,dict_key,dict_value) VALUES (2,1469,'virtual port')";
889 if (version_compare ($dbver, '0.19.7', '<'))
890 $query[] = "INSERT INTO Dictionary (chapter_id,dict_key,dict_value) VALUES (2,1588,'empty QSFP+')";
891 if (version_compare ($dbver, '0.19.8', '<'))
892 $query[] = "INSERT INTO Dictionary (chapter_id,dict_key,dict_value) VALUES
893 (2,1424,'1000Base-CX'),
894 (2,1425,'10GBase-ER-DWDM40-61.42 (ITU 20)'),
895 (2,1426,'10GBase-ER-DWDM40-60.61 (ITU 21)'),
896 (2,1427,'10GBase-ER-DWDM40-59.79 (ITU 22)'),
897 (2,1428,'10GBase-ER-DWDM40-58.98 (ITU 23)'),
898 (2,1429,'10GBase-ER-DWDM40-58.17 (ITU 24)'),
899 (2,1430,'10GBase-ER-DWDM40-57.36 (ITU 25)'),
900 (2,1431,'10GBase-ER-DWDM40-56.55 (ITU 26)'),
901 (2,1432,'10GBase-ER-DWDM40-55.75 (ITU 27)'),
902 (2,1433,'10GBase-ER-DWDM40-54.94 (ITU 28)'),
903 (2,1434,'10GBase-ER-DWDM40-54.13 (ITU 29)'),
904 (2,1435,'10GBase-ER-DWDM40-53.33 (ITU 30)'),
905 (2,1436,'10GBase-ER-DWDM40-52.52 (ITU 31)'),
906 (2,1437,'10GBase-ER-DWDM40-51.72 (ITU 32)'),
907 (2,1438,'10GBase-ER-DWDM40-50.92 (ITU 33)'),
908 (2,1439,'10GBase-ER-DWDM40-50.12 (ITU 34)'),
909 (2,1440,'10GBase-ER-DWDM40-49.32 (ITU 35)'),
910 (2,1441,'10GBase-ER-DWDM40-48.51 (ITU 36)'),
911 (2,1442,'10GBase-ER-DWDM40-47.72 (ITU 37)'),
912 (2,1443,'10GBase-ER-DWDM40-46.92 (ITU 38)'),
913 (2,1444,'10GBase-ER-DWDM40-46.12 (ITU 39)'),
914 (2,1445,'10GBase-ER-DWDM40-45.32 (ITU 40)'),
915 (2,1446,'10GBase-ER-DWDM40-44.53 (ITU 41)'),
916 (2,1447,'10GBase-ER-DWDM40-43.73 (ITU 42)'),
917 (2,1448,'10GBase-ER-DWDM40-42.94 (ITU 43)'),
918 (2,1449,'10GBase-ER-DWDM40-42.14 (ITU 44)'),
919 (2,1450,'10GBase-ER-DWDM40-41.35 (ITU 45)'),
920 (2,1451,'10GBase-ER-DWDM40-40.56 (ITU 46)'),
921 (2,1452,'10GBase-ER-DWDM40-39.77 (ITU 47)'),
922 (2,1453,'10GBase-ER-DWDM40-38.98 (ITU 48)'),
923 (2,1454,'10GBase-ER-DWDM40-38.19 (ITU 49)'),
924 (2,1455,'10GBase-ER-DWDM40-37.40 (ITU 50)'),
925 (2,1456,'10GBase-ER-DWDM40-36.61 (ITU 51)'),
926 (2,1457,'10GBase-ER-DWDM40-35.82 (ITU 52)'),
927 (2,1458,'10GBase-ER-DWDM40-35.04 (ITU 53)'),
928 (2,1459,'10GBase-ER-DWDM40-34.25 (ITU 54)'),
929 (2,1460,'10GBase-ER-DWDM40-33.47 (ITU 55)'),
930 (2,1461,'10GBase-ER-DWDM40-32.68 (ITU 56)'),
931 (2,1462,'10GBase-ER-DWDM40-31.90 (ITU 57)'),
932 (2,1463,'10GBase-ER-DWDM40-31.12 (ITU 58)'),
933 (2,1464,'10GBase-ER-DWDM40-30.33 (ITU 59)'),
934 (2,1465,'10GBase-ER-DWDM40-29.55 (ITU 60)'),
935 (2,1466,'10GBase-ER-DWDM40-28.77 (ITU 61)')";
936 if (version_compare ($dbver, '0.19.10', '<'))
937 $query[] = "INSERT INTO Dictionary (chapter_id,dict_key,dict_value) VALUES (2,1603,'1000Base-T (HP c-Class)')";
938 if (version_compare ($dbver, '0.19.11', '<'))
939 $query[] = "INSERT INTO Dictionary (chapter_id,dict_key,dict_value) VALUES (2,1642,'10GBase-T')";
940 if (version_compare ($dbver, '0.19.12', '<'))
941 $query[] = "INSERT INTO Dictionary (chapter_id,dict_key,dict_value) VALUES
942 (2,1661,'40GBase-KR4'),
943 (2,1663,'40GBase-SR4'),
944 (2,1664,'40GBase-LR4'),
945 (2,1668,'empty CFP'),
946 (2,1669,'100GBase-SR10'),
947 (2,1670,'100GBase-LR4'),
948 (2,1671,'100GBase-ER4')";
949 $query[] = "INSERT INTO PortOuterInterface SELECT dict_key, dict_value FROM Dictionary WHERE chapter_id = 2";
950 // Previously listed 10GBase-Kx actually means two standards: 10GBase-KX4
951 // and 10GBase-KR. Make respective changes and make primary key auto
952 // increment start at 2000.
953 $query[] = "UPDATE PortOuterInterface SET oif_name = '10GBase-KX4' WHERE id = 41";
954 $query[] = "INSERT INTO PortOuterInterface (id, oif_name) VALUES (1999, '10GBase-KR')";
955 $query[] = "INSERT INTO PortCompat (type1, type2) VALUES (1999, 1999)";
956 $query[] = "DELETE FROM Dictionary WHERE chapter_id = 2";
957 $query[] = "DELETE FROM Chapter WHERE id = 2";
958 $query[] = "ALTER TABLE PortInterfaceCompat ADD CONSTRAINT `PortInterfaceCompat-FK-oif_id` FOREIGN KEY (oif_id) REFERENCES PortOuterInterface (id)";
959 $query[] = "ALTER TABLE PortCompat ADD CONSTRAINT `PortCompat-FK-oif_id1` FOREIGN KEY (type1) REFERENCES PortOuterInterface (id)";
960 $query[] = "ALTER TABLE PortCompat ADD CONSTRAINT `PortCompat-FK-oif_id2` FOREIGN KEY (type2) REFERENCES PortOuterInterface (id)";
961 // Add more 40G and 100G standards.
962 $query[] = "INSERT INTO PortOuterInterface (id, oif_name) VALUES
963 (1660,'40GBase-FR'),
964 (1662,'40GBase-ER4'),
965 (1672,'100GBase-SR4'),
966 (1673,'100GBase-KR4'),
967 (1674,'100GBase-KP4')";
968 $query[] = "INSERT INTO PortInterfaceCompat (iif_id, oif_id) VALUES
969 (10,1660),
970 (10,1662),
971 (11,1672),
972 (11,1673),
973 (11,1674)";
974 $query[] = "INSERT INTO PortCompat (type1, type2) VALUES
975 (1660,1660),
976 (1662,1662),
977 (1672,1672),
978 (1673,1673),
979 (1674,1674)";
980 // Refine 1G OIF list: fix spelling and add a new standard.
981 $query[] = "UPDATE PortOuterInterface SET oif_name = '1000Base-LX10' WHERE id = 1205";
982 $query[] = "INSERT INTO PortOuterInterface (id, oif_name) VALUES (42, '1000Base-EX')";
983 $query[] = "INSERT INTO PortCompat (type1, type2) VALUES (42, 42)";
984 $query[] = "INSERT INTO PortInterfaceCompat (iif_id, oif_id) VALUES (3, 42), (4,42)";
985 // patch cables
986 $query[] = "
987 CREATE TABLE `PatchCableConnector` (
988 `id` int(10) unsigned NOT NULL AUTO_INCREMENT,
989 `origin` enum('default','custom') NOT NULL DEFAULT 'custom',
990 `connector` char(32) NOT NULL,
991 PRIMARY KEY (`id`),
992 UNIQUE KEY `connector_per_origin` (`connector`,`origin`)
993 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci";
994 $query[] = "
995 CREATE TABLE `PatchCableType` (
996 `id` int(10) unsigned NOT NULL AUTO_INCREMENT,
997 `origin` enum('default','custom') NOT NULL DEFAULT 'custom',
998 `pctype` char(64) NOT NULL,
999 PRIMARY KEY (`id`),
1000 UNIQUE KEY `pctype_per_origin` (`pctype`,`origin`)
1001 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci";
1002 $query[] = "
1003 CREATE TABLE `PatchCableConnectorCompat` (
1004 `pctype_id` int(10) unsigned NOT NULL,
1005 `connector_id` int(10) unsigned NOT NULL,
1006 PRIMARY KEY (`pctype_id`,`connector_id`),
1007 KEY `connector_id` (`connector_id`),
1008 CONSTRAINT `PatchCableConnectorCompat-FK-connector_id` FOREIGN KEY (`connector_id`) REFERENCES `PatchCableConnector` (`id`),
1009 CONSTRAINT `PatchCableConnectorCompat-FK-pctype_id` FOREIGN KEY (`pctype_id`) REFERENCES `PatchCableType` (`id`)
1010 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci";
1011 $query[] = "
1012 CREATE TABLE `PatchCableHeap` (
1013 `id` int(10) unsigned NOT NULL AUTO_INCREMENT,
1014 `pctype_id` int(10) unsigned NOT NULL,
1015 `end1_conn_id` int(10) unsigned NOT NULL,
1016 `end2_conn_id` int(10) unsigned NOT NULL,
1017 `amount` smallint(5) unsigned NOT NULL DEFAULT '0',
1018 `length` decimal(5,2) unsigned NOT NULL DEFAULT '1.00',
1019 `description` char(255) DEFAULT NULL,
1020 PRIMARY KEY (`id`),
1021 KEY `compat1` (`pctype_id`,`end1_conn_id`),
1022 KEY `compat2` (`pctype_id`,`end2_conn_id`),
1023 CONSTRAINT `PatchCableHeap-FK-compat1` FOREIGN KEY (`pctype_id`, `end1_conn_id`) REFERENCES `PatchCableConnectorCompat` (`pctype_id`, `connector_id`),
1024 CONSTRAINT `PatchCableHeap-FK-compat2` FOREIGN KEY (`pctype_id`, `end2_conn_id`) REFERENCES `PatchCableConnectorCompat` (`pctype_id`, `connector_id`)
1025 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci";
1026 $query[] = "
1027 CREATE TABLE `PatchCableHeapLog` (
1028 `id` int(10) unsigned NOT NULL AUTO_INCREMENT,
1029 `heap_id` int(10) unsigned NOT NULL,
1030 `date` datetime NOT NULL,
1031 `user` char(64) NOT NULL,
1032 `message` char(255) NOT NULL,
1033 PRIMARY KEY (`id`),
1034 KEY `heap_id-date` (`heap_id`,`date`),
1035 CONSTRAINT `PatchCableHeapLog-FK-heap_id` FOREIGN KEY (`heap_id`) REFERENCES `PatchCableHeap` (`id`) ON DELETE CASCADE
1036 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci";
1037 $query[] = "
1038 CREATE TABLE `PatchCableOIFCompat` (
1039 `pctype_id` int(10) unsigned NOT NULL,
1040 `oif_id` int(10) unsigned NOT NULL,
1041 PRIMARY KEY (`pctype_id`,`oif_id`),
1042 KEY `oif_id` (`oif_id`),
1043 CONSTRAINT `PatchCableOIFCompat-FK-oif_id` FOREIGN KEY (`oif_id`) REFERENCES `PortOuterInterface` (`id`),
1044 CONSTRAINT `PatchCableOIFCompat-FK-pctype_id` FOREIGN KEY (`pctype_id`) REFERENCES `PatchCableType` (`id`)
1045 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci";
1046 $query[] = "INSERT INTO PatchCableConnector (id, origin, connector) VALUES
1047 (1,'default','FC/PC'),(2,'default','FC/APC'),
1048 (3,'default','LC/PC'),(4,'default','LC/APC'),
1049 (5,'default','MPO-12/PC'),(6,'default','MPO-12/APC'),
1050 (7,'default','MPO-24/PC'),(8,'default','MPO-24/APC'),
1051 (9,'default','SC/PC'),(10,'default','SC/APC'),
1052 (11,'default','ST/PC'),(12,'default','ST/APC'),
1053 (13,'default','T568/8P8C/RJ45'),
1054 (14,'default','SFP-1000'),
1055 (15,'default','SFP+'),
1056 (999,'default','CX4/SFF-8470')";
1057 $query[] = "INSERT INTO PatchCableType (id, origin, pctype) VALUES
1058 (1,'default','duplex OM1'),
1059 (2,'default','duplex OM2'),
1060 (3,'default','duplex OM3'),
1061 (4,'default','duplex OM4'),
1062 (5,'default','duplex OS1'),
1063 (6,'default','duplex OS2'),
1064 (7,'default','simplex OM1'),
1065 (8,'default','simplex OM2'),
1066 (9,'default','simplex OM3'),
1067 (10,'default','simplex OM4'),
1068 (11,'default','simplex OS1'),
1069 (12,'default','simplex OS2'),
1070 (13,'default','Cat.5 TP'),
1071 (14,'default','Cat.6 TP'),
1072 (15,'default','Cat.6a TP'),
1073 (16,'default','Cat.7 TP'),
1074 (17,'default','Cat.7a TP'),
1075 (18,'default','12-fiber OM3'),
1076 (19,'default','12-fiber OM4'),
1077 (20,'default','10Gb/s CX4 coax'),
1078 (21,'default','24-fiber OM3'),
1079 (22,'default','24-fiber OM4'),
1080 (23,'default','1Gb/s 50cm shielded'),
1081 (24,'default','10Gb/s 24AWG twinax'),
1082 (25,'default','10Gb/s 26AWG twinax'),
1083 (26,'default','10Gb/s 28AWG twinax'),
1084 (27,'default','10Gb/s 30AWG twinax'),
1085 (999,'default','Cat.3 TP')";
1086 $query[] = "INSERT INTO PatchCableOIFCompat (pctype_id, oif_id) VALUES
1087 (13,18),(14,18),(15,18),(16,18),(17,18),(999,18), -- 10Base-T: Cat.3+ TP
1088 (11,1198),(12,1198),(11,1199),(12,1199), -- 100Base-BX10: 1xSMF
1089 (5,1197),(6,1197), -- 100Base-LX10: 2xSMF
1090 (5,1200),(6,1200), -- 100Base-EX: 2xSMF
1091 (5,1201),(6,1201), -- 100Base-ZX: 2xSMF
1092 (1,1195),(2,1195),(3,1195),(4,1195), -- 100Base-FX: 2xMMF
1093 (1,1196),(2,1196),(3,1196),(4,1196), -- 100Base-SX: 2xMMF
1094 (13,19),(14,19),(15,19),(16,19),(17,19), -- 100Base-TX: Cat.5+ TP
1095 (11,1206),(12,1206),(11,1207),(12,1207), -- 1000Base-BX10: 1xSMF
1096 (5,1204),(6,1204), -- 1000Base-LX: 2xSMF
1097 (5,1205),(6,1205), -- 1000Base-LX10: 2xSMF
1098 (1,1202),(2,1202),(3,1202),(4,1202), -- 1000Base-SX: 2xMMF
1099 (1,1203),(2,1203),(3,1203),(4,1203), -- 1000Base-SX+: 2xMMF
1100 (13,24),(14,24),(15,24),(16,24),(17,24), -- 1000Base-T: Cat.5+ TP
1101 (5,34),(6,34), -- 1000Base-ZX: 2xSMF
1102 (23,1077), -- 1000Base direct attach: shielded
1103 (1,30),(2,30),(3,30),(4,30), -- 10GBase-SR: 2xMMF
1104 (5,36),(6,36), -- 10GBase-LR: 2xSMF
1105 (5,35),(6,35), -- 10GBase-ER: 2xSMF
1106 (5,38),(6,38), -- 10GBase-ZR: 2xSMF
1107 (1,39),(2,39),(3,39),(4,39),(5,39),(6,39), -- 10GBase-LX4: 2xMMF/2xSMF
1108 (1,37),(2,37),(3,37),(4,37), -- 10GBase-LRM: 2xMMF
1109 (14,1642),(15,1642),(16,1642),(17,1642), -- 10GBase-T: Cat.6+ TP
1110 (20,40), -- 10GBase-CX4: coax
1111 (24,1084),(25,1084),(26,1084),(27,1084), -- 10GBase direct attach: twinax
1112 (18,1663),(19,1663), -- 40GBase-SR4: 8xMMF
1113 (5,1664),(6,1664), -- 40GBase-LR4: 2xSMF
1114 (5,1662),(6,1662), -- 40GBase-ER4: 2xSMF
1115 (5,1660),(6,1660), -- 40GBase-FR: 2xSMF
1116 (21,1669),(22,1669), -- 100GBase-SR10: 20xMMF
1117 (18,1672),(19,1672), -- 100GBase-SR4: 8xMMF
1118 (5,1670),(6,1670), -- 100GBase-LR4: 2xSMF
1119 (5,1671),(6,1671) -- 100GBase-ER4: 2xSMF";
1120 $query[] = "INSERT INTO PatchCableConnectorCompat (pctype_id, connector_id) VALUES
1121 (1,1),(2,1),(3,1),(4,1),(5,1),(6,1),(7,1),(8,1),(9,1),(10,1),(11,1),(12,1), -- FC/PC
1122 (1,2),(2,2),(3,2),(4,2),(5,2),(6,2),(7,2),(8,2),(9,2),(10,2),(11,2),(12,2), -- FC/APC
1123 (1,3),(2,3),(3,3),(4,3),(5,3),(6,3),(7,3),(8,3),(9,3),(10,3),(11,3),(12,3), -- LC/PC
1124 (1,4),(2,4),(3,4),(4,4),(5,4),(6,4),(7,4),(8,4),(9,4),(10,4),(11,4),(12,4), -- LC/APC
1125 (1,9),(2,9),(3,9),(4,9),(5,9),(6,9),(7,9),(8,9),(9,9),(10,9),(11,9),(12,9), -- SC/PC
1126 (1,10),(2,10),(3,10),(4,10),(5,10),(6,10),(7,10),(8,10),(9,10),(10,10),(11,10),(12,10), -- SC/APC
1127 (1,11),(2,11),(3,11),(4,11),(5,11),(6,11),(7,11),(8,11),(9,11),(10,11),(11,11),(12,11), -- ST/PC
1128 (1,12),(2,12),(3,12),(4,12),(5,12),(6,12),(7,12),(8,12),(9,12),(10,12),(11,12),(12,12), -- ST/APC
1129 (13,13),(14,13),(15,13),(16,13),(17,13),(999,13), -- T568
1130 (18,5),(19,5), -- MPO-12/PC
1131 (18,6),(19,6), -- MPO-12/APC
1132 (20,999), -- CX4
1133 (21,7),(22,7), -- MPO-24/PC
1134 (21,8),(22,8), -- MPO-24/APC
1135 (23,14), -- SFP-1000
1136 (24,15),(25,15),(26,15),(27,15) -- SFP+";
1137 // add rules for Cisco UCS objects
1138 $query[] = "INSERT INTO `ObjectParentCompat` (`parent_objtype_id`, `child_objtype_id`) VALUES (1787,8),(1787,1502)";
1139 $query[] = "UPDATE Config SET varvalue = '0.20.8' WHERE varname = 'DB_VERSION'";
1140 break;
1141 case '0.20.9':
1142 $query[] = "ALTER TABLE CactiGraph ADD KEY (server_id)";
1143 $query[] = "ALTER TABLE CactiGraph DROP PRIMARY KEY";
1144 $query[] = "ALTER TABLE CactiGraph ADD PRIMARY KEY (object_id, server_id, graph_id)";
1145 $query[] = "ALTER TABLE CactiGraph DROP KEY `object_id`";
1146 $query[] = "UPDATE Config SET description = 'List of pages to display in quick links' WHERE varname = 'QUICK_LINK_PAGES'";
1147 $query[] = "INSERT INTO `Config` (varname, varvalue, vartype, emptyok, is_hidden, is_userdefined, description) VALUES ('CACTI_RRA_ID','1','uint','no','no','yes','RRA ID for Cacti graphs displayed in RackTables')";
1148 $query[] = "INSERT INTO `Config` (`varname`,`varvalue`,`vartype`,`emptyok`,`is_hidden`,`is_userdefined`,`description`)
1149 VALUES ('SHOW_OBJECTTYPE', 'no', 'string', 'no', 'no', 'yes', 'Show object type column on depot page.')";
1150
1151 $query[] = "INSERT INTO PortInnerInterface (id, iif_name) VALUES (12, 'CFP2'),(13,'CPAK')";
1152 $query[] = "INSERT INTO PortOuterInterface (id, oif_name) VALUES (1589, 'empty CFP2'),(1590,'empty CPAK')";
1153 $query[] = "INSERT INTO PortInterfaceCompat (iif_id, oif_id) VALUES
1154 (12,1589),(12,1669),(12,1670),(12,1671),(12,1672),(12,1673),(12,1674),
1155 (13,1590),(13,1669),(13,1670),(13,1671),(13,1672),(13,1673),(13,1674)";
1156 $query[] = "INSERT INTO PortCompat (type1, type2) VALUES (1588,1589),(1588,1590),(1589,1589),(1589,1590),(1590,1590)";
1157 $query[] = "UPDATE Config SET varvalue = CONCAT(varvalue, '; 12=1589; 13=1590') WHERE varname = 'DEFAULT_PORT_OIF_IDS'";
1158 $query[] = extendPortCompatQuery();
1159
1160 $query[] = "UPDATE Config SET varvalue = '0.20.9' WHERE varname = 'DB_VERSION'";
1161 break;
1162 case '0.20.10':
1163 $query[] = "UPDATE Config SET varvalue = '0.20.10' WHERE varname = 'DB_VERSION'";
1164 break;
1165 case '0.20.11':
1166 $query[] = "ALTER TABLE VLANDomain ADD COLUMN `group_id` int(10) UNSIGNED DEFAULT NULL AFTER `id`, " .
1167 "ADD CONSTRAINT `VLANDomain-FK-group_id` FOREIGN KEY (`group_id`) REFERENCES `VLANDomain` (`id`) ON DELETE SET NULL";
1168
1169 // new 100GBase port types
1170 $query[] = "INSERT INTO `PortInnerInterface` (`id`, `iif_name`) VALUES (14,'CXP')";
1171 $query[] = "INSERT INTO `PortOuterInterface` (`id`, `oif_name`) VALUES
1172 (1591,'empty CXP'),
1173 (1675,'100GBase-LR10'),
1174 (1676,'100GBase-ER10'),
1175 (1677,'100GBase-CR4'),
1176 (1678,'100GBase-CR10')";
1177 $query[] = "INSERT INTO `PatchCableOIFCompat` (`pctype_id`, `oif_id`) VALUES
1178 (5,1675),(6,1675), -- 100GBase-LR10: 2xSMF
1179 (5,1676),(6,1676) -- 100GBase-ER10: 2xSMF";
1180 $query[] = "INSERT INTO `PortInterfaceCompat` (`iif_id`, `oif_id`) VALUES
1181 (11,1675),(11,1676),
1182 (12,1675),(12,1676),
1183 (13,1675),(13,1676),
1184 (14,1591),(14,1677),(14,1678)";
1185 $query[] = "INSERT INTO `PortCompat` (`type1`, `type2`) VALUES
1186 (1591,1591),
1187 (1675,1675),
1188 (1676,1676),
1189 (1677,1677),
1190 (1678,1678)";
1191 $query[] = "UPDATE Config SET varvalue = CONCAT(varvalue, '; 14=1591') WHERE varname = 'DEFAULT_PORT_OIF_IDS'";
1192
1193 // ABI_ver = 2, invalidate RackCode cache
1194 $query[] = "DELETE FROM Script WHERE script_name='RackCodeCache'";
1195
1196 $query[] = "INSERT INTO Config (varname, varvalue, is_hidden, is_userdefined, description) VALUES ('IPV4_TREE_SHOW_UNALLOCATED', 'yes', 'no', 'yes', 'Show unallocated networks in IPv4 tree'); ";
1197 $query[] = "UPDATE Config SET varvalue = '0.20.11' WHERE varname = 'DB_VERSION'";
1198
1199 break;
1200 case '0.20.12':
1201 // NO_ZERO_DATE
1202 $query[] = "ALTER TABLE LDAPCache MODIFY COLUMN last_retry timestamp NULL DEFAULT NULL";
1203 $query[] = "DELETE FROM LDAPCache";
1204
1205 $query[] = "INSERT INTO ObjectParentCompat (parent_objtype_id, child_objtype_id) VALUES (1787,4)";
1206
1207 $port_trigger_body = <<<'ENDOFTRIGGER'
1208 PortTrigger:BEGIN
1209 IF (NEW.`l2address` IS NOT NULL AND (SELECT COUNT(*) FROM `Port` WHERE `l2address` = NEW.`l2address` AND `object_id` != NEW.`object_id`) > 0) THEN
1210 CALL `Port-l2address-already-exists-on-another-object`;
1211 END IF;
1212 END;
1213 ENDOFTRIGGER;
1214 $query[] = "CREATE TRIGGER `Port-before-insert` BEFORE INSERT ON `Port` FOR EACH ROW $port_trigger_body";
1215 $query[] = "CREATE TRIGGER `Port-before-update` BEFORE UPDATE ON `Port` FOR EACH ROW $port_trigger_body";
1216
1217 $query[] = "ALTER TABLE UserConfig DROP FOREIGN KEY `UserConfig-FK-varname`";
1218 $query[] = "ALTER TABLE UserConfig ADD CONSTRAINT `UserConfig-FK-varname` FOREIGN KEY (`varname`) REFERENCES `Config` (`varname`) ON DELETE CASCADE ON UPDATE CASCADE";
1219 $query[] = "UPDATE Config SET varname = 'SYNC_8021Q_LISTSRC' WHERE varname = 'SYNC_802Q_LISTSRC'";
1220
1221 // new iif_type 'QSFP28'
1222 $query[] = "INSERT INTO `PortInnerInterface` (`id`, `iif_name`) VALUES (15,'QSFP28')";
1223 $query[] = "UPDATE Config SET varvalue = CONCAT(varvalue, '; 15=1588') WHERE varname = 'DEFAULT_PORT_OIF_IDS' AND 0 = INSTR(varvalue, '15=')";
1224 // rename 'empty QSFP+' to 'empty QSFP'
1225 $query[] = "UPDATE PortOuterInterface SET oif_name='empty QSFP' WHERE id=1588";
1226
1227 $query[] = "INSERT INTO PortOuterInterface (id, oif_name) VALUES
1228 (1088,'1000Base-BX40-D'),
1229 (1089,'1000Base-BX40-U'),
1230 (1090,'1000Base-BX80-D'),
1231 (1091,'1000Base-BX80-U')";
1232 $query[] = "INSERT INTO PortCompat (type1, type2) VALUES
1233 (1088,1089),
1234 (1089,1088),
1235 (1090,1091),
1236 (1091,1090)";
1237 $query[] = "INSERT INTO PortInterfaceCompat (iif_id, oif_id) VALUES
1238 (4,1088), (4,1089), (4,1090), (4,1091),
1239 (15,1588),(15,1660),(15,1662),(15,1663),(15,1664),(15,1670),(15,1671),(15,1672),(15,1673),(15,1674)";
1240 $query[] = "INSERT INTO PatchCableOIFCompat (pctype_id, oif_id) VALUES
1241 (11,1088), (12,1088), (11,1089), (12,1089),
1242 (11,1090), (12,1090), (11,1091), (12,1091)";
1243
1244 $query[] = "UPDATE Config SET varvalue = '0.20.12' WHERE varname = 'DB_VERSION'";
1245 break;
1246 case '0.20.13':
1247 $query[] = "DROP TRIGGER IF EXISTS `Port-before-insert`";
1248 $query[] = "DROP TRIGGER IF EXISTS `Port-before-update`";
1249 $query[] = "UPDATE Config SET varvalue = '0.20.13' WHERE varname = 'DB_VERSION'";
1250 break;
1251 case '0.20.14':
1252 $query[] = "UPDATE Object SET has_problems = 'no' WHERE objtype_id = 1561 AND has_problems = ''";
1253 $query[] = "UPDATE ObjectHistory SET ctime = ctime, has_problems = 'no' WHERE objtype_id = 1561 AND has_problems = ''";
1254 $query[] = "UPDATE Config SET varvalue = '0.20.14' WHERE varname = 'DB_VERSION'";
1255 break;
1256 case '0.21.0':
1257 $query[] = "UPDATE Port SET label = NULL WHERE label = ''";
1258 $query[] = "DELETE FROM RackThumbnail";
1259 $query[] = "ALTER TABLE TagTree ADD COLUMN color mediumint unsigned DEFAULT NULL AFTER tag";
1260
1261 $query[] = "
1262 CREATE TABLE `Plugin` (
1263 `name` char(255) NOT NULL,
1264 `longname` char(255) NOT NULL,
1265 `version` char(64) NOT NULL,
1266 `home_url` char(255) NOT NULL,
1267 `state` enum('disabled','enabled') NOT NULL default 'disabled',
1268 PRIMARY KEY (`name`)
1269 ) ENGINE=InnoDB DEFAULT CHARSET=utf8 COLLATE=utf8_unicode_ci";
1270
1271 // if the Cacti or Munin plugins are being used, mark them as enabled, otherwise uninstall them
1272 // from now on, upgrades will be handled by the plugins themselves
1273 $result = $dbxlink->query ('SELECT COUNT(*) FROM CactiServer');
1274 if ($result->fetchColumn() > 0)
1275 $query[] = "INSERT INTO Plugin VALUES ('cacti','Cacti','1.0','http://www.racktables.org/','enabled')";
1276 else
1277 {
1278 $query[] = "DELETE FROM Config WHERE varname IN ('CACTI_LISTSRC','CACTI_RRA_ID')";
1279 $query[] = "UPDATE Config SET varname = 'VLANNET_LISTSRC' WHERE varname = 'VLANIPV4NET_LISTSRC'";
1280 $query[] = "DROP TABLE `CactiGraph`";
1281 $query[] = "DROP TABLE `CactiServer`";
1282 }
1283 unset ($result);
1284 $result = $dbxlink->query ('SELECT COUNT(*) FROM MuninServer');
1285 if ($result->fetchColumn() > 0)
1286 $query[] = "INSERT INTO Plugin VALUES ('munin','Munin','1.0','http://www.racktables.org/','enabled')";
1287 else
1288 {
1289 $query[] = "DELETE FROM Config WHERE varname = 'MUNIN_LISTSRC'";
1290 $query[] = "DROP TABLE `MuninGraph`";
1291 $query[] = "DROP TABLE `MuninServer`";
1292 }
1293 unset ($result);
1294
1295 $query[] = "UPDATE Config SET description = 'PHP strftime() format for date+time' WHERE varname = 'DATETIME_FORMAT'";
1296 $query[] = "
1297 INSERT INTO `Config` (varname, varvalue, vartype, emptyok, is_hidden, is_userdefined, description) VALUES
1298 ('DATEONLY_FORMAT','%Y-%m-%d','string','no','no','yes','PHP strftime() format for dates')";
1299
1300 $query[] = "UPDATE Config SET varvalue = '0.21.0' WHERE varname = 'DB_VERSION'";
1301 break;
1302 case '0.21.1':
1303 // The query below was conditional in the 0.20.0 section, which was wrong.
1304 $query[] = "UPDATE Config SET varname = 'VLANNET_LISTSRC' WHERE varname = 'VLANIPV4NET_LISTSRC'";
1305 $query[] = "UPDATE Config SET description = 'List of VLAN-related IPv4/IPv6 networks' WHERE varname = 'VLANNET_LISTSRC'";
1306 $query[] = "ALTER TABLE ObjectHistory ADD COLUMN event_id int(10) unsigned NOT NULL AUTO_INCREMENT FIRST, ADD PRIMARY KEY (event_id)";
1307 $query[] = "DELETE FROM Atom WHERE molecule_id IS NULL OR rack_id IS NULL OR unit_no IS NULL OR atom IS NULL";
1308 // Modify the columns explicitly before the primary key addition does it implicitly.
1309 $query[] = "ALTER TABLE Atom MODIFY COLUMN molecule_id int(10) unsigned NOT NULL";
1310 $query[] = "ALTER TABLE Atom MODIFY COLUMN rack_id int(10) unsigned NOT NULL";
1311 $query[] = "ALTER TABLE Atom MODIFY COLUMN unit_no int(10) unsigned NOT NULL";
1312 $query[] = "ALTER TABLE Atom MODIFY COLUMN atom enum('front','interior','rear') NOT NULL";
1313 $query[] = "ALTER TABLE Atom ADD PRIMARY KEY (molecule_id, rack_id, unit_no, atom)";
1314 $query[] = "ALTER TABLE Atom DROP KEY `Atom-FK-molecule_id`";
1315 $query[] = "UPDATE Config SET varvalue = '0.21.1' WHERE varname = 'DB_VERSION'";
1316 break;
1317 case '0.21.2':
1318 $query[] = "ALTER TABLE MountOperation ADD UNIQUE KEY `old_molecule_id` (old_molecule_id)";
1319 $query[] = "ALTER TABLE MountOperation ADD UNIQUE KEY `new_molecule_id` (new_molecule_id)";
1320 $query[] = "ALTER TABLE MountOperation DROP KEY `MountOperation-FK-old_molecule_id`";
1321 $query[] = "ALTER TABLE MountOperation DROP KEY `MountOperation-FK-new_molecule_id`";
1322 $query[] = "ALTER TABLE IPv4Allocation MODIFY type ENUM('regular','shared','virtual','router','point2point','sharedrouter') NOT NULL DEFAULT 'regular'";
1323 $query[] = "ALTER TABLE IPv6Allocation MODIFY type ENUM('regular','shared','virtual','router','point2point','sharedrouter') NOT NULL DEFAULT 'regular'";
1324 $query[] = "INSERT INTO Chapter (`id`, `sticky`, `name`) VALUES (39,'no','UPS models')";
1325 $query[] = "INSERT INTO AttributeMap (`objtype_id`,`attr_id`,`chapter_id`) VALUES (12,2,39)"; // UPS (UPS models) -> HW type
1326 $query[] = "ALTER TABLE TagTree ADD COLUMN description char(255) DEFAULT NULL AFTER color";
1327
1328 // new iif_type SFP28
1329 $query[] = "INSERT INTO PortInnerInterface VALUES (16, 'SFP28')";
1330 $query[] = "INSERT INTO PortOuterInterface VALUES
1331 (1592, 'empty SFP28'),
1332 (1651, '25GBase-KR'),
1333 (1652, '25GBase-T'),
1334 (1653, '25GBase-CR'),
1335 (1654, '25GBase-SR'),
1336 (1655, '25GBase-LR'),
1337 (1656, '25Gbase-ER')";
1338 $query[] = "INSERT INTO PortInterfaceCompat VALUES
1339 (16,1592),(16,1651),(16,1653),(16,1654),(16,1655),(16,1656),
1340 (16,30),(16,35),(16,36),(16,37),(16,38),(16,39),(16,40)";
1341 $query[] = "INSERT INTO PortCompat VALUES
1342 (1592, 1592),
1343 (1592, 1084),
1344 (1084, 1592),
1345 (1651, 1651),
1346 (1652, 1652),
1347 (1653, 1653),
1348 (1654, 1654),
1349 (1655, 1655),
1350 (1656, 1656)";
1351 $query[] = "UPDATE Config SET varvalue = CONCAT(varvalue, '; 16=1592')
1352 WHERE varname = 'DEFAULT_PORT_OIF_IDS' AND 0 = INSTR(varvalue, '16=')";
1353 $query[] = "UPDATE Config SET varname = 'VIRTUAL_OBJ_CSV' WHERE varname = 'VIRTUAL_OBJ_LISTSRC'";
1354 $query[] = "UPDATE Config SET varvalue = '0.21.2' WHERE varname = 'DB_VERSION'";
1355 break;
1356 case '0.21.3':
1357 $query[] = "INSERT INTO Config VALUES ('OBJECTLOG_PREVIEW_ENTRIES','5','uint','no','no','yes','Object log preview maximum entries (0 disables the preview)')";
1358 $query[] = "UPDATE Config SET varvalue = '0.21.3' WHERE varname = 'DB_VERSION'";
1359 break;
1360 case 'dictionary':
1361 $query = reloadDictionary();
1362 break;
1363 default:
1364 return NULL;
1365 }
1366 return $query;
1367 }
1368
1369 function executeUpgradeBatch ($batchid)
1370 {
1371 global $dbxlink;
1372 $query = getUpgradeBatch($batchid);
1373 if ($query === NULL)
1374 {
1375 showError ("unknown batch '${batchid}'", __FUNCTION__);
1376 die;
1377 }
1378 $failures = array();
1379 echo "<tr><th>Executing batch '${batchid}'</th><td>";
1380 foreach ($query as $q)
1381 {
1382 try
1383 {
1384 $result = $dbxlink->query ($q);
1385 }
1386 catch (PDOException $e)
1387 {
1388 $errorInfo = $dbxlink->errorInfo();
1389 $failures[] = array ($q, $errorInfo[2]);
1390 }
1391 }
1392 if (!count ($failures))
1393 echo "<strong><font color=green>done</font></strong>";
1394 else
1395 {
1396 echo "<strong><font color=red>The following queries failed:</font></strong><br><pre>";
1397 foreach ($failures as $f)
1398 {
1399 list ($q, $i) = $f;
1400 echo "${q} -- ${i}\n";
1401 }
1402 echo "</pre>";
1403 }
1404 echo '</td></tr>';
1405 }
1406
1407 function authenticate_admin ($username, $password)
1408 {
1409 global $dbxlink;
1410 $prepared = $dbxlink->prepare ('SELECT COUNT(*) FROM UserAccount WHERE user_id=1 AND user_name=? AND user_password_hash=?');
1411 if (!$prepared->execute (array ($username, sha1 ($password))))
1412 die ('SQL query failed in ' . __FUNCTION__);
1413 $rows = $prepared->fetchAll (PDO::FETCH_NUM);
1414 return $rows[0][0] == 1;
1415 }
1416
1417 // Database version detector. Should behave corretly on any
1418 // working dataset a user might have.
1419 function getDatabaseVersion ()
1420 {
1421 global $dbxlink;
1422 $prepared = $dbxlink->prepare ('SELECT varvalue FROM Config WHERE varname = "DB_VERSION" and vartype = "string"');
1423 if (! $prepared->execute())
1424 {
1425 $errorInfo = $dbxlink->errorInfo();
1426 die (__FUNCTION__ . ': SQL query failed with error ' . $errorInfo[2]);
1427 }
1428 $rows = $prepared->fetchAll (PDO::FETCH_NUM);
1429 if (count ($rows) != 1 || $rows[0][0] == '')
1430 die (__FUNCTION__ . ': Cannot guess database version. Config table is present, but DB_VERSION is missing or invalid. Giving up.');
1431 $ret = $rows[0][0];
1432 return $ret;
1433 }
1434
1435 function showUpgradeError ($info = '', $location = 'N/A')
1436 {
1437 if (preg_match ('/\.php$/', $location))
1438 $location = basename ($location);
1439 elseif ($location != 'N/A')
1440 $location = $location . '()';
1441 echo "<div class=msg_error>An error has occured in [${location}]. ";
1442 if ($info == '')
1443 echo 'No additional information is available.';
1444 else
1445 echo "Additional information:<br><p>\n<pre>\n${info}\n</pre></p>";
1446 echo "Go back or try starting from <a href='index.php'>index page</a>.<br></div>\n";
1447 }
1448
1449 // changes the value of config variable. If $old_value_filter is set, value is changed only if current value equals to it.
1450 function replaceConfigVarValue ($varname, $new_value, $old_value_filter = NULL)
1451 {
1452 global $dbxlink;
1453 if (isset ($old_value_filter))
1454 {
1455 $result = $dbxlink->prepare ("SELECT varvalue FROM Config WHERE varname = ?");
1456 $result->execute (array ($varname));
1457 if ($row = $result->fetch (PDO::FETCH_ASSOC))
1458 if ($row['varvalue'] != $old_value_filter)
1459 return;
1460 unset ($result);
1461 }
1462 $result = $dbxlink->prepare ("UPDATE Config set varvalue = ? WHERE varname = ?");
1463 $result->execute (array ($new_value, $varname));
1464 }
1465
1466 function renderUpgraderHTML()
1467 {
1468 global $found_secret_file;
1469 if (! $found_secret_file)
1470 die ('<center>There is no working RackTables instance here, <a href="?module=installer">install</a>?</center>');
1471
1472 try
1473 {
1474 connectDB();
1475 }
1476 catch (RackTablesError $e)
1477 {
1478 die ("Database connection failed:\n\n" . $e->getMessage());
1479 }
1480
1481 if
1482 (
1483 ! isset ($_SERVER['PHP_AUTH_USER']) ||
1484 $_SERVER['PHP_AUTH_USER'] == '' ||
1485 ! isset ($_SERVER['PHP_AUTH_PW']) ||
1486 $_SERVER['PHP_AUTH_PW'] == '' ||
1487 !authenticate_admin ($_SERVER['PHP_AUTH_USER'], $_SERVER['PHP_AUTH_PW'])
1488 )
1489 {
1490 header ('WWW-Authenticate: Basic realm="RackTables upgrade"');
1491 header ('HTTP/1.0 401 Unauthorized');
1492 echo <<<'ENDOFTEXT'
1493 <h1>Trouble logging in?</h1>
1494 You are trying to authenticate for the RackTables upgrade screen. This means that
1495 you must authenticate with the username and password of the main RackTables
1496 administrator. There is only one such account in each installation, its default
1497 username is "admin". RackTables wiki provides more information on this topic.
1498 ENDOFTEXT;
1499 die;
1500 }
1501
1502 echo <<<'ENDOFTEXT'
1503 <!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd">
1504 <html xmlns="http://www.w3.org/1999/xhtml" xml:lang="en" lang="en">
1505 <head><title>RackTables upgrade script</title>
1506 <style type="text/css">
1507 .tdleft {
1508 text-align: left;
1509 }
1510
1511 .trok {
1512 background-color: #80FF80;
1513 }
1514
1515 .trwarning {
1516 background-color: #FFFF80;
1517 }
1518
1519 .trerror {
1520 background-color: #FF8080;
1521 }
1522 </style>
1523 </head>
1524 <body>
1525 <h1>Platform check status</h1>
1526 ENDOFTEXT;
1527
1528 if (! platform_is_ok (TRUE))
1529 {
1530 echo '<h1>Please resolve the failed (red) item(s) above.</h1>';
1531 die ('</body></html>');
1532 }
1533
1534 echo '<h1>Upgrade status</h1>';
1535 global $dbver;
1536 $dbver = getDatabaseVersion();
1537 echo '<table border=1 cellpadding=5>';
1538 echo "<tr><th>Current status</th><td>Data version: ${dbver}<br>Code version: " . CODE_VERSION . "</td></tr>\n";
1539
1540 $path = getDBUpgradePath ($dbver, CODE_VERSION);
1541 if ($path === NULL)
1542 {
1543 echo "<tr><th>Upgrade path</th><td><font color=red>not found</font></td></tr>\n";
1544 echo "<tr><th>Summary</th><td>Check README for more information. RackTables releases prior to 0.18.0 ";
1545 echo "must be upgraded to 0.18.0 first. RackTables releases prior to 0.20.0 must be upgraded to 0.20.0 first.</td></tr>\n";
1546 }
1547 else
1548 {
1549 if (!count ($path))
1550 echo "<tr><th>Summary</th><td>Come back later.</td></tr>\n";
1551 else
1552 {
1553 echo "<tr><th>Upgrade path</th><td>${dbver} &rarr; " . implode (' &rarr; ', $path) . "</td></tr>\n";
1554 global $relnotes;
1555 foreach ($path as $batchid)
1556 if (isset ($relnotes[$batchid]))
1557 echo "<tr><th>Release notes for ${batchid}</th><td><pre>" . $relnotes[$batchid] . "</pre></td></tr>\n";
1558 if (array_key_exists ('reallyreally', $_REQUEST))
1559 {
1560 foreach ($path as $batchid)
1561 executeUpgradeBatch ($batchid);
1562 executeUpgradeBatch ('dictionary');
1563 echo "<tr><th>Summary</th><td>Upgrade complete, it is Ok to ";
1564 echo "<a href='index.php'>enter</a> the system.</td></tr>\n";
1565 }
1566 else
1567 {
1568 echo '<form method=post action="index.php?module=upgrade"><tr><th>Wait!</th>';
1569 echo '<td><p>RackTables database upgrades sometimes go wrong because of assorted reasons. ';
1570 echo 'It is <strong>highly recommended</strong> to make a database backup before ';
1571 echo 'proceeding any further. <tt>mysqldump</tt> and <tt>PHPMyAdmin</tt> are convenient ';
1572 echo 'tools for doing this.</p>';
1573 echo '<p><label><input type=checkbox name=reallyreally>';
1574 echo 'I am ready to bear all risks of this upgrade. I am ready to roll it back in case of ';
1575 echo 'a failure.</label> <input type=submit value="Yes, I am."></p></td></tr></form>';
1576 }
1577 }
1578 }
1579 echo '</table>';
1580 echo '</body></html>';
1581 }
1582
1583 // returns SQL query to make PortCompat symmetric (insert missing reversed-order pairs).
1584 // It should be called each time after the PortCompat table pairs being added during upgrade.
1585 function extendPortCompatQuery()
1586 {
1587 return "INSERT INTO PortCompat SELECT pc1.type2, pc1.type1 FROM PortCompat pc1 LEFT JOIN PortCompat pc2 ON pc1.type1 = pc2.type2 AND pc1.type2 = pc2.type1 WHERE pc2.type1 IS NULL";
1588 }
1589
1590 function convertSLBTablesToBinIPs()
1591 {
1592 global $dbxlink;
1593
1594 $dbxlink->query ("DROP TABLE IF EXISTS `IPv4VS_new`, `IPv4RS_new`, `IPv4VS_old`, `IPv4RS_old`");
1595
1596 $dbxlink->query (<<<'END'
1597 CREATE TABLE `IPv4VS_new` (
1598 `id` int(10) unsigned NOT NULL auto_increment,
1599 `vip` varbinary(16) NOT NULL,
1600 `vport` smallint(5) unsigned default NULL,
1601 `proto` enum('TCP','UDP','MARK') NOT NULL default 'TCP',
1602 `name` char(255) default NULL,
1603 `vsconfig` text,
1604 `rsconfig` text,
1605 PRIMARY KEY (`id`),
1606 KEY `vip` (`vip`)
1607 ) ENGINE=InnoDB DEFAULT CHARSET=utf8
1608 END
1609 );
1610 $result = $dbxlink->query ("SELECT id, vip, vport, proto, name, vsconfig, rsconfig FROM IPv4VS");
1611 $rows = $result->fetchAll (PDO::FETCH_ASSOC);
1612 unset ($result);
1613 foreach ($rows as $row)
1614 {
1615 $row['vip'] = ip4_int2bin ($row['vip']);
1616 usePreparedInsertBlade ('IPv4VS_new', $row);
1617 }
1618
1619 $dbxlink->query (<<<'END'
1620 CREATE TABLE `IPv4RS_new` (
1621 `id` int(10) unsigned NOT NULL auto_increment,
1622 `inservice` enum('yes','no') NOT NULL default 'no',
1623 `rsip` varbinary(16) NOT NULL,
1624 `rsport` smallint(5) unsigned default NULL,
1625 `rspool_id` int(10) unsigned default NULL,
1626 `rsconfig` text,
1627 `comment` varchar(255) DEFAULT NULL,
1628 PRIMARY KEY (`id`),
1629 KEY `rsip` (`rsip`),
1630 UNIQUE KEY `pool-endpoint` (`rspool_id`,`rsip`,`rsport`),
1631 CONSTRAINT `IPRS-FK` FOREIGN KEY (`rspool_id`) REFERENCES `IPv4RSPool` (`id`) ON DELETE CASCADE
1632 ) ENGINE=InnoDB DEFAULT CHARSET=utf8
1633 END
1634 );
1635 $result = $dbxlink->query ("SELECT id, inservice, rsip, rsport, rspool_id, rsconfig FROM IPv4RS");
1636 $rows = $result->fetchAll (PDO::FETCH_ASSOC);
1637 unset ($result);
1638 foreach ($rows as $row)
1639 {
1640 $row['rsip'] = ip4_int2bin ($row['rsip']);
1641 usePreparedInsertBlade ('IPv4RS_new', $row);
1642 }
1643
1644 $dbxlink->query (<<<'END'
1645 RENAME TABLE
1646 `IPv4VS` TO `IPv4VS_old`,
1647 `IPv4VS_new` TO `IPv4VS`,
1648 `IPv4RS` TO `IPv4RS_old`,
1649 `IPv4RS_new` TO `IPv4RS`
1650 END
1651 );
1652 // re-create foreign key in IPv4LB
1653 $dbxlink->query ("ALTER TABLE `IPv4LB` DROP FOREIGN KEY `IPv4LB-FK-vs_id`");
1654 $dbxlink->query ("ALTER TABLE `IPv4LB` ADD CONSTRAINT `IPv4LB-FK-vs_id` FOREIGN KEY (`vs_id`) REFERENCES `IPv4VS` (`id`)");
1655
1656 $dbxlink->query ("DROP TABLE `IPv4VS_old`, `IPv4RS_old`");
1657
1658 // re-create foreign key in IPv4RS
1659 $dbxlink->query ("ALTER TABLE `IPv4RS` DROP FOREIGN KEY `IPRS-FK`");
1660 $dbxlink->query ("ALTER TABLE `IPv4RS` ADD CONSTRAINT `IPv4RS-FK` FOREIGN KEY (`rspool_id`) REFERENCES `IPv4RSPool` (`id`) ON DELETE CASCADE");
1661 }
1662
1663 // converts the values of old-style config vars TELNET_OBJS_LISTSRC, SSH_OBJS_LISTSRC, RDP_OBJS_LISTSRC
1664 // to the format of MGMT_PROTOS (comma-separated list of "proto: rackcode" pairs)
1665 function convertMgmtConfigVars()
1666 {
1667 global $dbxlink;
1668 $ret = array();
1669 foreach (array ('telnet' => 'TELNET_OBJS_LISTSRC', 'ssh' => 'SSH_OBJS_LISTSRC', 'rdp' => 'RDP_OBJS_LISTSRC') as $proto => $varname)
1670 {
1671 $result = $dbxlink->prepare ("SELECT varvalue FROM Config WHERE varname = ?");
1672 $result->execute (array ($varname));
1673 if ($row = $result->fetch (PDO::FETCH_ASSOC))
1674 if ($row['varvalue'] != 'false' && $row['varvalue'] != '')
1675 $ret[] = "$proto: " . $row['varvalue'];
1676 unset ($result);
1677 }
1678 return implode (',', $ret);
1679 }