86 lines
2.7 KiB
SQL
86 lines
2.7 KiB
SQL
DELIMITER $$
|
|
|
|
|
|
DROP PROCEDURE IF EXISTS spSensorCalculate$$
|
|
|
|
|
|
CREATE DEFINER=`root`@`%` PROCEDURE `spSensorCalculate`()
|
|
NOT DETERMINISTIC
|
|
SQL SECURITY DEFINER
|
|
BEGIN
|
|
DECLARE dfrom DATETIME;
|
|
SET dfrom = NOW() - INTERVAL 14 DAY;
|
|
|
|
/* Stundenwerte erzeugen / aktualisieren (ohne CTE) */
|
|
INSERT INTO tblSensorDataStunde
|
|
(SensorID, Datum, StartValue, EndValue, ValueMIN, ValueMAX, ValueAVG)
|
|
SELECT
|
|
sd.SensorID,
|
|
DATE_FORMAT(sd.ValueDate, '%Y-%m-%d %H:00:00') AS Datum,
|
|
CASE s.Berechnung
|
|
WHEN 1 THEN MIN(sd.Value)
|
|
WHEN 2 THEN MAX(sd.Value)
|
|
END AS StartValue,
|
|
NULL AS EndValue,
|
|
MIN(sd.Value) AS ValueMIN,
|
|
MAX(sd.Value) AS ValueMAX,
|
|
AVG(sd.Value) AS ValueAVG
|
|
FROM tblSensoren s
|
|
JOIN tblSensorData sd ON s.ID = sd.SensorID
|
|
WHERE sd.Value IS NOT NULL
|
|
AND sd.ValueDate >= dfrom
|
|
AND s.Berechnung <> 0
|
|
GROUP BY sd.SensorID, DATE_FORMAT(sd.ValueDate, '%Y-%m-%d %H:00:00')
|
|
ON DUPLICATE KEY UPDATE
|
|
StartValue = VALUES(StartValue),
|
|
EndValue = NULL,
|
|
ValueMIN = VALUES(ValueMIN),
|
|
ValueMAX = VALUES(ValueMAX),
|
|
ValueAVG = VALUES(ValueAVG);
|
|
|
|
/* --- 1093-sicher: NextStart in TEMP-Tabelle berechnen --- */
|
|
DROP TEMPORARY TABLE IF EXISTS tmp_next;
|
|
|
|
/* Variante ohne Window-Funktionen (läuft auch auf älteren Versionen):
|
|
Wir sortieren pro Sensor DESC nach Datum, dann ist "prev_start" die nächste Stunde. */
|
|
CREATE TEMPORARY TABLE tmp_next
|
|
AS
|
|
SELECT SensorID, Datum, NextStart
|
|
FROM (
|
|
SELECT
|
|
x.SensorID,
|
|
x.Datum,
|
|
/* beim Abstieg ist die "vorherige" StartValue die nächste in der Zukunft */
|
|
CASE WHEN @cur_sid = x.SensorID THEN @prev_start ELSE NULL END AS NextStart,
|
|
/* Hilfszuweisungen für den nächsten Datensatz */
|
|
@prev_start := x.StartValue AS _set_prev,
|
|
@cur_sid := x.SensorID AS _set_sid
|
|
FROM (
|
|
SELECT SensorID, Datum, StartValue
|
|
FROM tblSensorDataStunde
|
|
WHERE Datum >= dfrom
|
|
ORDER BY SensorID, Datum DESC
|
|
) x
|
|
/* Variablen initialisieren */
|
|
JOIN (SELECT @cur_sid := NULL, @prev_start := NULL) vars
|
|
) z;
|
|
|
|
|
|
/* Jetzt gefahrlos updaten, weil wir aus tmp_next lesen, nicht aus der Zieltabelle */
|
|
UPDATE tblSensorDataStunde t
|
|
JOIN tmp_next n
|
|
ON n.SensorID = t.SensorID AND n.Datum = t.Datum
|
|
SET t.EndValue = n.NextStart
|
|
WHERE t.Datum >= dfrom
|
|
AND t.EndValue IS NULL
|
|
AND n.NextStart IS NOT NULL;
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS tmp_next;
|
|
|
|
END$$
|
|
|
|
DELIMITER ;
|
|
|
|
CALL spSensorCalculate;
|
|
|