summaryrefslogtreecommitdiffstats
path: root/modules-available/statistics/install.inc.php
blob: a9e8fb7b9254a2fe99749511c8830785e765497a (plain) (blame)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
<?php

// locationid trigger
$addTrigger = false;

$res = array();

// The main statistic table used for log entries

$res[] = tableCreate('statistic', "
  `logid` int(10) unsigned NOT NULL AUTO_INCREMENT,
  `dateline` int(10) unsigned NOT NULL,
  `typeid` varchar(30) NOT NULL,
  `clientip` varchar(40) NOT NULL,
  `machineuuid` char(36) CHARACTER SET ascii DEFAULT NULL,
  `username` varchar(30) NOT NULL,
  `data` varchar(255) NOT NULL,
  PRIMARY KEY (`logid`),
  KEY `dateline` (`dateline`),
  KEY `logtypeid` (`typeid`,`dateline`),
  KEY `clientip` (`clientip`,`dateline`),
  KEY `machineuuid` (`machineuuid`,`dateline`)
");

// Main table containing all known clients

$res[] = $machineCreate = tableCreate('machine', "
  `machineuuid` char(36) CHARACTER SET ascii NOT NULL,
  `fixedlocationid` int(11) DEFAULT NULL           COMMENT 'Manually set location (e.g. roomplanner)',
  `subnetlocationid` int(11) DEFAULT NULL          COMMENT 'Automatically determined location (e.g. from subnet match)',
  `locationid` int(11) DEFAULT NULL                COMMENT 'Will be automatically set to fixedlocationid if not null, subnetlocationid otherwise',
  `macaddr` char(17) CHARACTER SET ascii NOT NULL,
  `clientip` varchar(45) CHARACTER SET ascii NOT NULL,
  `firstseen` int(10) unsigned NOT NULL,
  `lastseen` int(10) unsigned NOT NULL,
  `logintime` int(10) unsigned NOT NULL,
  `position` varchar(200) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL,
  `lastboot` int(10) unsigned NOT NULL,
  `state` enum('OFFLINE', 'IDLE', 'OCCUPIED', 'STANDBY', 'IGNORED') NOT NULL DEFAULT 'OFFLINE',
  `realcores` smallint(5) unsigned NOT NULL,
  `mbram` int(10) unsigned NOT NULL,
  `kvmstate` enum('UNKNOWN','UNSUPPORTED','DISABLED','ENABLED') NOT NULL,
  `cpumodel` varchar(120) NOT NULL,
  `systemmodel` varchar(120) NOT NULL DEFAULT '',
  `id44mb` int(10) unsigned NOT NULL,
  `badsectors` int(10) unsigned NOT NULL,
  `data` mediumtext NOT NULL,
  `hostname` varchar(200) NOT NULL DEFAULT '',
  `currentsession` varchar(120) CHARACTER SET utf8 COLLATE utf8_unicode_ci DEFAULT NULL,
  `currentuser` varchar(50) CHARACTER SET utf8 COLLATE utf8_unicode_ci DEFAULT NULL,
  `notes` text,
  PRIMARY KEY (`machineuuid`),
  KEY `macaddr` (`macaddr`),
  KEY `clientip` (`clientip`),
  KEY `state` (`state`),
  KEY `realcores` (`realcores`),
  KEY `mbram` (`mbram`),
  KEY `kvmstate` (`kvmstate`),
  KEY `id44mb` (`id44mb`),
  KEY `locationid` (`locationid`),
  KEY `lastseen` (`lastseen`),
  KEY `cpumodel` (`cpumodel`),
  KEY `systemmodel` (`systemmodel`)
");

$res[] = $machineHwCreate = tableCreate('machine_x_hw', "
  `machinehwid` int(10) unsigned NOT NULL AUTO_INCREMENT,
  `hwid` int(10) unsigned NOT NULL,
  `machineuuid` char(36) CHARACTER SET ascii NOT NULL,
  `devpath` char(50) CHARACTER SET ascii NOT NULL,
  `disconnecttime` int(10) unsigned NOT NULL COMMENT 'time the device was not connected to the pc anymore for the first time, 0 if it is connected',
  PRIMARY KEY (`machinehwid`),
  UNIQUE KEY `hwid` (`hwid`,`machineuuid`,`devpath`),
  KEY `machineuuid` (`machineuuid`,`hwid`),
  KEY `disconnecttime` (`disconnecttime`)
 ");

$res[] = tableCreate('machine_x_hw_prop', "
  `machinehwid` int(10) unsigned NOT NULL,
  `prop` char(16) CHARACTER SET ascii NOT NULL,
  `value` varchar(500) NOT NULL,
  PRIMARY KEY (`machinehwid`,`prop`)
");

$res[] = tableCreate('statistic_hw', "
  `hwid` int(10) unsigned NOT NULL AUTO_INCREMENT,
  `hwtype` char(11) CHARACTER SET ascii NOT NULL,
  `hwname` varchar(200) NOT NULL,
  PRIMARY KEY (`hwid`),
  UNIQUE KEY `hwtype` (`hwtype`,`hwname`)
");

$res[] = tableCreate('statistic_hw_prop', "
  `hwid` int(10) unsigned NOT NULL,
  `prop` char(16) CHARACTER SET ascii NOT NULL,
  `value` varchar(500) NOT NULL,
  PRIMARY KEY (`hwid`,`prop`)
");

// PCI-ID cache

$res[] = tableCreate('pciid', "
	`category` enum('CLASS','VENDOR','DEVICE') NOT NULL,
	`id` varchar(10) CHARACTER SET ascii NOT NULL,
	`value` varchar(200) NOT NULL,
	`dateline` int(10) unsigned NOT NULL,
	PRIMARY KEY (`category`,`id`)
");

// need trigger?
if ($machineCreate === UPDATE_DONE) {
	$addTrigger = true;
}

//
// This was added/changed later -- keep update path
//

// 2015-12-21: Add machine uuid column to statistics table
if (!tableHasColumn('statistic', 'machineuuid')) {
	$ret = Database::exec('ALTER TABLE statistic'
		. ' ADD COLUMN `machineuuid` varchar(36) CHARACTER SET ascii DEFAULT NULL AFTER clientip,'
		. ' ADD INDEX `machineuuid` (`machineuuid`,`dateline`)');
	if ($ret === false) {
		finalResponse(UPDATE_FAILED, 'Adding machineuuid to statistic failed: ' . Database::lastError());
	}
	$res[] = UPDATE_DONE;
}

// Rename roomid to locationid
if (tableHasColumn('machine', 'roomid')) {
	$ret = Database::exec("ALTER TABLE `machine` CHANGE `roomid` `locationid` INT(11) DEFAULT NULL") !== false;
	$ret = Database::exec("ALTER TABLE `machine` DROP `roomid`") !== false || $ret;
	if ($ret === false) {
		finalResponse(UPDATE_FAILED, 'Renaming roomid to locationid in statistic failed: ' . Database::lastError());
	}
	$res[] = UPDATE_DONE;
}

// 2016-08-31: Add lectureid and user name
if (!tableHasColumn('machine', 'currentsession')) {
	$ret = Database::exec("ALTER TABLE `machine` ADD COLUMN `currentsession` varchar(120) CHARACTER SET utf8 COLLATE utf8_unicode_ci DEFAULT NULL AFTER hostname") !== false;
	if ($ret === false) {
		finalResponse(UPDATE_FAILED, 'Adding currentsession to machine failed: ' . Database::lastError());
	}
	$res[] = UPDATE_DONE;
}
if (!tableHasColumn('machine', 'currentuser')) {
	$ret = Database::exec("ALTER TABLE `machine` ADD COLUMN `currentuser` varchar(50) CHARACTER SET utf8 COLLATE utf8_unicode_ci DEFAULT NULL AFTER currentsession") !== false;
	if ($ret === false) {
		finalResponse(UPDATE_FAILED, 'Adding currentuser to machine failed: ' . Database::lastError());
	}
	$res[] = UPDATE_DONE;
}
// 2016-09-01: Fix position column size
$ret = Database::exec("ALTER TABLE `machine` CHANGE `position` `position` VARCHAR( 200 ) CHARACTER SET utf8 COLLATE utf8_unicode_ci NOT NULL");
if ($ret === false) {
	finalResponse(UPDATE_FAILED, 'Expanding position column failed: ' . Database::lastError());
}

// 2016-12-06:
// Add subnetlocationid - contains automatically determined location (by subnet)
if (!tableHasColumn('machine', 'subnetlocationid')) {
	$ret = Database::exec('ALTER TABLE machine'
		. ' ADD COLUMN `subnetlocationid` int(11) DEFAULT NULL AFTER `machineuuid`');
	if ($ret === false) {
		finalResponse(UPDATE_FAILED, 'Adding subnetlocationid to machine failed: ' . Database::lastError());
	}
	$res[] = UPDATE_DONE;
	$addTrigger = true;
}
// And fixedlocationid - manually set location, currently used by roomplanner
if (!tableHasColumn('machine', 'fixedlocationid')) {
	$ret = Database::exec('ALTER TABLE machine'
		. ' ADD COLUMN `fixedlocationid` int(11) DEFAULT NULL AFTER `machineuuid`');
	if ($ret === false) {
		finalResponse(UPDATE_FAILED, 'Adding fixedlocationid to machine failed: ' . Database::lastError());
	}
	// Now copy over the values from locationid, since this was used before
	Database::exec("UPDATE machine SET fixedlocationid = locationid");
	$res[] = UPDATE_DONE;
	$addTrigger = true;
}
// If any of these was added, create the trigger
if ($addTrigger) {
	$ret = Database::exec(" 
	CREATE TRIGGER set_automatic_locationid
		BEFORE UPDATE ON machine FOR EACH ROW
	BEGIN
		SET NEW.locationid = If(NEW.fixedlocationid IS NULL, NEW.subnetlocationid, NEW.fixedlocationid);
	END");
	if ($ret === false) {
		finalResponse(UPDATE_FAILED, 'Adding locationid trigger to machine failed: ' . Database::lastError());
	}
	// This might be an update - calculate all subnetlocationid values (if location module is installed yet)
	if (Module::isAvailable('locations')) {
		if (tableExists('subnet')) {
			AutoLocation::rebuildAll();
		}
	}
	$res[] = UPDATE_DONE;
}

$res[] = tableAddConstraint('machine_x_hw', 'hwid', 'statistic_hw', 'hwid', 'ON DELETE CASCADE');
$res[] = tableAddConstraint('machine_x_hw', 'machineuuid', 'machine', 'machineuuid', 'ON DELETE CASCADE ON UPDATE CASCADE');
$res[] = tableAddConstraint('machine_x_hw_prop', 'machinehwid', 'machine_x_hw', 'machinehwid', 'ON DELETE CASCADE');
$res[] = tableAddConstraint('statistic_hw_prop', 'hwid', 'statistic_hw', 'hwid', 'ON DELETE CASCADE');

// 2017-11-27: Add state column
if (!tableHasColumn('machine', 'state')) {
	$ret = Database::exec("ALTER TABLE `machine`
		ADD COLUMN `state` enum('OFFLINE', 'IDLE', 'OCCUPIED', 'STANDBY', 'IGNORED') NOT NULL DEFAULT 'OFFLINE' AFTER `lastboot`,
		ADD INDEX `state` (`state`)");
	if ($ret === false) {
		finalResponse(UPDATE_FAILED, 'Adding state column to machine table failed: ' . Database::lastError());
	}
	$res[] = UPDATE_DONE;
}

// 2019-01-25: Add memory/temp stats column
if (!tableHasColumn('machine', 'live_tmpsize')) {
	$ret = Database::exec("ALTER TABLE `machine`
		ADD COLUMN `live_tmpsize` int(10) UNSIGNED NOT NULL DEFAULT '0' AFTER `id44mb`,
		ADD COLUMN `live_tmpfree` int(10) UNSIGNED NOT NULL DEFAULT '0' AFTER `live_tmpsize`,
		ADD COLUMN `live_swapsize` int(10) UNSIGNED NOT NULL DEFAULT '0' AFTER `live_tmpfree`,
		ADD COLUMN `live_swapfree` int(10) UNSIGNED NOT NULL DEFAULT '0' AFTER `live_swapsize`,
		ADD COLUMN `live_memsize` int(10) UNSIGNED NOT NULL DEFAULT '0' AFTER `live_swapfree`,
		ADD COLUMN `live_memfree` int(10) UNSIGNED NOT NULL DEFAULT '0' AFTER `live_memsize`,
		ADD INDEX `live_tmpfree` (`live_tmpfree`),
		ADD INDEX `live_memfree` (`live_memfree`)");
	if ($ret === false) {
		finalResponse(UPDATE_FAILED, 'Adding state column to machine table failed: ' . Database::lastError());
	}
	$res[] = UPDATE_DONE;
}

// 2019-02-20: Convert bogus UUIDs
$res2 = Database::simpleQuery("SELECT machineuuid, macaddr FROM machine WHERE machineuuid LIKE '000000000000001-%'");
while ($row = $res2->fetch(PDO::FETCH_ASSOC)) {
	$new = strtoupper('baad1d00-9491-4716-b98b-' . preg_replace('/[^0-9a-f]/i', '', $row['macaddr']));
	error_log('Replacing ' . $row['machineuuid'] . ' with ' . $new);
	if (strlen($new) === 36) {
		if (Database::exec("UPDATE machine SET machineuuid = :new WHERE machineuuid = :old",
					['old' => $row['machineuuid'], 'new' => $new]) === false) {
			error_log('Result: ' . Database::lastError());
			Database::exec("DELETE FROM machine WHERE machineuuid = :old", ['old' => $row['machineuuid']]);
		}
	}
}

// Create response
responseFromArray($res);