|
|
@@ -180,6 +180,109 @@ export class MariaDBDatabase implements DataProvider, HealthCheckDataProvider {
|
|
|
return result.map(r => ({ time: new Date(r.Timegroup), avg: r.avg, peak: r.peak, max: r.max }));
|
|
|
}
|
|
|
|
|
|
+ public async reduceServerData(serverID: number, type: ServerDataType, sectionMs: number, to: Date, from?: Date) {
|
|
|
+ const select_max = type !== 'cpu';
|
|
|
+ const select_types = select_max ? [type, type, type] : [type, type];
|
|
|
+ const select_daterange = from ? [from, to] : [to];
|
|
|
+ const result: any[] = await this.db.query(
|
|
|
+ `
|
|
|
+ SELECT
|
|
|
+ CEIL(UNIX_TIMESTAMP(\`Timestamp\`) * 1000 / ?) * ? as 'Timegroup',
|
|
|
+ MIN(\`ServerDataEntry\`.\`ID\`) as 'entry_min_id',
|
|
|
+ MAX(\`ServerDataEntry\`.\`ID\`) as 'entry_max_id',
|
|
|
+
|
|
|
+ AVG(\`VALUE_AVG\`.\`Value\`) as 'avg',
|
|
|
+ MIN(\`VALUE_AVG\`.\`ID\`) as 'value_avg_min_id',
|
|
|
+ MAX(\`VALUE_AVG\`.\`ID\`) as 'value_avg_max_id',
|
|
|
+
|
|
|
+ MAX(\`VALUE_PEAK\`.\`Value\`) as 'peak',
|
|
|
+ MIN(\`VALUE_PEAK\`.\`ID\`) as 'value_peak_min_id',
|
|
|
+ MAX(\`VALUE_PEAK\`.\`ID\`) as 'value_peak_max_id'${
|
|
|
+ select_max
|
|
|
+ ? `,
|
|
|
+ MAX(\`VALUE_MAX\`.\`Value\`) as 'max',
|
|
|
+ MIN(\`VALUE_MAX\`.\`ID\`) as 'value_max_min_id',
|
|
|
+ MAX(\`VALUE_MAX\`.\`ID\`) as 'value_max_max_id'`
|
|
|
+ : ''
|
|
|
+ }
|
|
|
+ FROM \`ServerDataEntry\`
|
|
|
+ JOIN \`ServerDataValue\` AS \`VALUE_AVG\` ON \`ServerDataEntry\`.\`ID\` = \`VALUE_AVG\`.\`EntryID\` AND \`VALUE_AVG\`.\`Type\` = ? AND \`VALUE_AVG\`.\`Key\` = 'avg'
|
|
|
+ JOIN \`ServerDataValue\` AS \`VALUE_PEAK\` ON \`ServerDataEntry\`.\`ID\` = \`VALUE_PEAK\`.\`EntryID\` AND \`VALUE_PEAK\`.\`Type\` = ? AND \`VALUE_PEAK\`.\`Key\` = 'peak'
|
|
|
+ ${
|
|
|
+ select_max
|
|
|
+ ? "JOIN `ServerDataValue` AS `VALUE_MAX` ON `ServerDataEntry`.`ID` = `VALUE_MAX`.`EntryID` AND `VALUE_MAX`.`Type` = ? AND `VALUE_MAX`.`Key` = 'max'"
|
|
|
+ : ''
|
|
|
+ }
|
|
|
+ WHERE \`ServerDataEntry\`.\`ServerID\` = ?
|
|
|
+ AND \`ServerDataEntry\`.\`Timestamp\` ${from ? `BETWEEN ? AND ?` : `< ?`}
|
|
|
+ GROUP BY \`Timegroup\`
|
|
|
+ ORDER BY \`Timegroup\`;`,
|
|
|
+ [sectionMs, sectionMs, ...select_types, serverID, ...select_daterange]
|
|
|
+ );
|
|
|
+
|
|
|
+ for (const row of result) {
|
|
|
+ // PARENT ENTRIES
|
|
|
+ const queries = [
|
|
|
+ // Avoid ER_DUP_ENTRY on UQ(ServerID, Timestamp):
|
|
|
+ 'DELETE FROM `ServerDataEntry` WHERE `ID` != ? AND `ServerID` = ? AND `Timestamp` = ?;',
|
|
|
+ 'UPDATE `ServerDataEntry` SET `Timestamp` = ? WHERE `ID` = ?;'
|
|
|
+ ];
|
|
|
+ const params = [...[row.entry_max_id, serverID, new Date(row.Timegroup)], ...[new Date(row.Timegroup), row.entry_max_id]];
|
|
|
+
|
|
|
+ // AVG VALUES
|
|
|
+ queries.push('UPDATE `ServerDataValue` SET `Value` = ? WHERE `ID` = ?;');
|
|
|
+ params.push(row.avg, row.value_avg_max_id);
|
|
|
+ if (row.value_avg_max_id - 1 - row.value_avg_min_id >= 0) {
|
|
|
+ queries.push('DELETE FROM `ServerDataValue` WHERE `ID` >= ? AND `ID` <= ? AND `Type` = ? AND `Key` = ?;');
|
|
|
+ params.push(row.value_avg_min_id, row.value_avg_max_id - 1, type, 'avg');
|
|
|
+ }
|
|
|
+
|
|
|
+ // PEAK VALUES
|
|
|
+ queries.push('UPDATE `ServerDataValue` SET `Value` = ? WHERE `ID` = ?;');
|
|
|
+ params.push(row.peak, row.value_peak_max_id);
|
|
|
+ if (row.value_peak_max_id - 1 - row.value_peak_min_id >= 0) {
|
|
|
+ queries.push('DELETE FROM `ServerDataValue` WHERE `ID` >= ? AND `ID` <= ? AND `Type` = ? AND `Key` = ?;');
|
|
|
+ params.push(row.value_peak_min_id, row.value_peak_max_id - 1, type, 'avg');
|
|
|
+ }
|
|
|
+
|
|
|
+ if (select_max) {
|
|
|
+ // MAX VALUES (?)
|
|
|
+ queries.push('UPDATE `ServerDataValue` SET `Value` = ? WHERE `ID` = ?;');
|
|
|
+ params.push(row.max, row.value_max_max_id);
|
|
|
+ if (row.value_max_max_id - 1 - row.value_max_min_id >= 0) {
|
|
|
+ queries.push('DELETE FROM `ServerDataValue` WHERE `ID` >= ? AND `ID` <= ? AND `Type` = ? AND `Key` = ?;');
|
|
|
+ params.push(row.value_max_min_id, row.value_max_max_id - 1, type, 'avg');
|
|
|
+ }
|
|
|
+ }
|
|
|
+
|
|
|
+ // DELETE PARENT ENTRIES (cascade-delete)
|
|
|
+ if (row.entry_max_id - 1 - row.entry_min_id >= 0) {
|
|
|
+ queries.push('DELETE FROM `ServerDataEntry` WHERE `ID` >= ? AND `ID` <= ?;');
|
|
|
+ params.push(row.entry_min_id, row.entry_max_id - 1);
|
|
|
+ }
|
|
|
+
|
|
|
+ await this.db.beginTransaction();
|
|
|
+ try {
|
|
|
+ Logger.debug(
|
|
|
+ '[MARIADB] Reducing Server Data:',
|
|
|
+ JSON.stringify({
|
|
|
+ server: serverID,
|
|
|
+ type,
|
|
|
+ time: new Date(row.Timegroup),
|
|
|
+ avg: row.avg,
|
|
|
+ peak: row.peak,
|
|
|
+ max: row.max
|
|
|
+ })
|
|
|
+ );
|
|
|
+ await this.db.query(queries.join('\n'), params);
|
|
|
+ await this.db.commit();
|
|
|
+ } catch (error) {
|
|
|
+ Logger.error('[MARIADB] Reducing Server Data failed:', new String(error).toString());
|
|
|
+ await this.db.rollback();
|
|
|
+ }
|
|
|
+ }
|
|
|
+ }
|
|
|
+
|
|
|
public async queryServerStats(serverID: number, type: ServerDataType, from: Date, to: Date): Promise<ReducedValuesPerc> {
|
|
|
const select_max = type !== 'cpu';
|
|
|
const select_types = select_max ? [type, type, type] : [type, type];
|
|
|
@@ -627,6 +730,43 @@ export class MariaDBDatabase implements DataProvider, HealthCheckDataProvider {
|
|
|
return Object.keys(errors).length ? errors : null;
|
|
|
}
|
|
|
|
|
|
+ public cleanupData() {
|
|
|
+ process.nextTick(async () => {
|
|
|
+ await this.cleanupHealthCheckData();
|
|
|
+ await this.cleanupServerData();
|
|
|
+ });
|
|
|
+ }
|
|
|
+
|
|
|
+ private async cleanupHealthCheckData() {}
|
|
|
+
|
|
|
+ private async cleanupServerData() {
|
|
|
+ const nowMinus3M = moment().subtract(3, 'months').toDate();
|
|
|
+ const nowMinus1M = moment().subtract(1, 'month').toDate();
|
|
|
+ const nowMinus2W = moment().subtract(2, 'weeks').toDate();
|
|
|
+
|
|
|
+ const servers = await this.getAllServerConfigs();
|
|
|
+ for (const server of servers) {
|
|
|
+ const dataTypes = await this.getServerDataTypes(server.id);
|
|
|
+
|
|
|
+ for (const dataType of dataTypes) {
|
|
|
+ const loopTypes = dataType.type === 'hdd' ? (dataType.subtypes ?? []).map(s => `hdd:${s.type}`) : [dataType.type];
|
|
|
+ for (const type of loopTypes) {
|
|
|
+ // Reduce Data older than 3Mo to reduced data points like if requested in a 3Mo UI chart
|
|
|
+ let sectionMs = Math.floor(((365.2422 / 12) * 3 * 24 * 60 * 60) / 100) * 1000;
|
|
|
+ await this.reduceServerData(server.id, type, sectionMs, nowMinus3M);
|
|
|
+
|
|
|
+ // Reduce Data older than 1Mo to reduced data points like if requested in a 1Mo UI chart
|
|
|
+ sectionMs = Math.floor(((365.2422 / 12) * 1 * 24 * 60 * 60) / 100) * 1000;
|
|
|
+ await this.reduceServerData(server.id, type, sectionMs, nowMinus1M, nowMinus3M);
|
|
|
+
|
|
|
+ // Reduce Data older than 2We to reduced data points like if requested in a 2We UI chart
|
|
|
+ sectionMs = Math.floor((14 * 24 * 60 * 60) / 100) * 1000;
|
|
|
+ await this.reduceServerData(server.id, type, sectionMs, nowMinus2W, nowMinus1M);
|
|
|
+ }
|
|
|
+ }
|
|
|
+ }
|
|
|
+ }
|
|
|
+
|
|
|
public async close(): Promise<void> {
|
|
|
await this.db.close();
|
|
|
}
|