#33 reduce old server- & healthcheck data

Merged
tunefish merged 3 commits from hostbbq/feature/data-cleanup into hostbbq/master 1 year ago

+ 4 - 5
server.dockerfile

@@ -29,8 +29,7 @@ ARG HOME="/home/node"
 ARG APPDIR="${HOME}/monitoring"
 
 RUN apt update && \
-    apt install -y tzdata && \
-    apt install -y rsync
+    apt install -y tzdata
 
 # Change TimeZone
 ENV TZ=Europe/Berlin
@@ -39,13 +38,13 @@ RUN ln -snf /usr/share/zoneinfo/$TZ /etc/localtime && echo $TZ > /etc/timezone
 RUN mkdir ${APPDIR}
 WORKDIR ${APPDIR}
 
-COPY --from=build_helper --chown=node:node ${APPDIR}/server/dist/ ./dist
-COPY --from=build_helper --chown=node:node ${APPDIR}/server/public/ ./public
 COPY  --chown=node:node ./server/google-cloud/ ./google-cloud
 COPY  --chown=node:node ./server/package.json .
-
 RUN npm install --omit=dev
+
 COPY ./server/database.json .
+COPY --from=build_helper --chown=node:node ${APPDIR}/server/dist/ ./dist
+COPY --from=build_helper --chown=node:node ${APPDIR}/server/public/ ./public
 
 RUN mkdir data
 VOLUME ${APPDIR}/data

+ 2 - 0
server/src/ctrl/data-provider.interface.ts

@@ -23,4 +23,6 @@ export interface DataProvider {
   getHttpCheckConfigByID: (serverID: number, configID: number) => Promise<HttpCheckConfig | null>;
   insertHealthCheckData: (confID: number, time: Date, status: HttpCheckStatus, message: string) => Promise<HttpCheckData>;
   getLastErrors: (confID: number, threshold: number) => Promise<ServiceCheckData[]>;
+
+  cleanupData: () => void | Promise<void>;
 }

+ 106 - 0
server/src/ctrl/mariadb-database.class.ts

@@ -180,6 +180,82 @@ 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(intervalSecs: number, to: Date, from?: Date) {
+    const select_daterange = from ? [from, to] : [to];
+    const result: any[] = await this.db.query(
+      `
+      SELECT
+        MIN(\`ServerDataEntry\`.\`ID\`) AS 'minEntryID',
+        MAX(\`ServerDataEntry\`.\`ID\`) AS 'maxEntryID',
+        \`ServerDataEntry\`.\`ServerID\` AS 'serverID',
+        FROM_UNIXTIME(CEIL(UNIX_TIMESTAMP(\`ServerDataEntry\`.\`Timestamp\`) / ?) * ?) AS 'timegroup',
+        \`VALUE_AVG\`.\`Type\` AS 'type',
+        MAX(\`VALUE_AVG\`.\`ID\`) AS 'maxAvgID',
+        AVG(\`VALUE_AVG\`.\`Value\`) AS 'avg',
+        MAX(\`VALUE_PEAK\`.\`ID\`) AS 'maxPeakID',
+        MAX(\`VALUE_PEAK\`.\`Value\`) AS 'peak',
+        MAX(\`VALUE_MAX\`.\`ID\`) AS 'maxMaxID',
+        MAX(\`VALUE_MAX\`.\`Value\`) AS 'max'
+      FROM \`ServerDataEntry\`
+      LEFT OUTER JOIN \`ServerDataValue\` AS \`VALUE_AVG\` ON \`ServerDataEntry\`.\`ID\` = \`VALUE_AVG\`.\`EntryID\` AND \`VALUE_AVG\`.\`Key\` = 'avg'
+      LEFT OUTER JOIN \`ServerDataValue\` AS \`VALUE_PEAK\` ON \`ServerDataEntry\`.\`ID\` = \`VALUE_PEAK\`.\`EntryID\` AND \`VALUE_AVG\`.\`Type\` = \`VALUE_PEAK\`.\`Type\` AND \`VALUE_PEAK\`.\`Key\` = 'peak'
+      LEFT OUTER JOIN \`ServerDataValue\` AS \`VALUE_MAX\` ON \`ServerDataEntry\`.\`ID\` = \`VALUE_MAX\`.\`EntryID\` AND \`VALUE_PEAK\`.\`Type\` = \`VALUE_MAX\`.\`Type\` AND \`VALUE_MAX\`.\`Key\` = 'max'
+      WHERE ${from ? '`ServerDataEntry`.`Timestamp` BETWEEN ? AND ?' : '`ServerDataEntry`.`Timestamp` < ?'}
+      GROUP BY \`serverID\`, \`timegroup\`, \`type\`
+      ORDER BY \`serverID\`, \`timegroup\`, \`maxAvgID\`;`,
+      [intervalSecs, intervalSecs, ...select_daterange]
+    );
+
+    let lastRow: any | undefined = undefined;
+    let queries: string[] = [];
+    let params: any[] = [];
+    const execTransaction = async (row: any) => {
+      await this.db.beginTransaction();
+      try {
+        Logger.debug(
+          '[MARIADB] Reducing Server Data:',
+          JSON.stringify({
+            server: row.serverID,
+            time: row.timegroup
+          })
+        );
+        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();
+      }
+    };
+    for (const row of result) {
+      const { minEntryID, maxEntryID, serverID, timegroup } = row;
+
+      if (lastRow?.maxEntryID !== maxEntryID) {
+        if (queries.length) await execTransaction(row);
+
+        queries = [];
+        params = [];
+      }
+
+      if (!queries.length) {
+        // PARENT ENTRIES
+        queries.push(
+          'DELETE FROM `ServerDataEntry` WHERE `ID` != ? AND `ServerID` = ? AND `Timestamp` = ?;', // Avoid ER_DUP_ENTRY on UQ(ServerID, Timestamp):
+          'UPDATE `ServerDataEntry` SET `Timestamp` = ? WHERE ID = ?;'
+        );
+        params.push(maxEntryID, serverID, timegroup, timegroup, maxEntryID);
+        if (maxEntryID - 1 - minEntryID >= 0) {
+          queries.push('DELETE FROM `ServerDataEntry` WHERE ServerID = ? AND ID >= ? AND ID <= ?;');
+          params.push(serverID, minEntryID, maxEntryID - 1);
+        }
+      }
+      lastRow = row;
+    }
+
+    if (queries.length) {
+      await execTransaction(lastRow);
+    }
+  }
+
   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 +703,36 @@ 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() {
+    const nowMinus3M = moment().subtract(3, 'months').toDate();
+    await this.db.query('DELETE FROM `HealthCheckDataEntry` WHERE Timestamp < ?;', [nowMinus3M]);
+  }
+
+  private async cleanupServerData() {
+    const nowMinus3M = moment().subtract(3, 'months').toDate();
+    const nowMinus1M = moment().subtract(1, 'month').toDate();
+    const nowMinus2W = moment().subtract(2, 'weeks').toDate();
+
+    // Reduce Data older than 3Mo to reduced data points like if requested in a 3Mo UI chart
+    let intervalSeconds = Math.floor(((365.2422 / 12) * 3 * 24 * 60 * 60) / 100);
+    await this.reduceServerData(intervalSeconds, nowMinus3M);
+
+    // Reduce Data older than 1Mo to reduced data points like if requested in a 1Mo UI chart
+    intervalSeconds = Math.floor(((365.2422 / 12) * 1 * 24 * 60 * 60) / 100);
+    await this.reduceServerData(intervalSeconds, nowMinus1M, nowMinus3M);
+
+    // Reduce Data older than 2We to reduced data points like if requested in a 2We UI chart
+    intervalSeconds = Math.floor((14 * 24 * 60 * 60) / 100);
+    await this.reduceServerData(intervalSeconds, nowMinus2W, nowMinus1M);
+  }
+
   public async close(): Promise<void> {
     await this.db.close();
   }

+ 3 - 0
server/src/index.ts

@@ -33,6 +33,9 @@ let connectionPool: Pool;
   };
 
   Timer.instance.start();
+  Timer.instance.subscribe(7 * 24 * 60 * 60, db.cleanupData.bind(db));
+  db.cleanupData();
+
   new Webserver(Number(process.env.WEB_PORT ?? '80'), pool);
 })();