Commit 3d061b41 authored by David Schäfer's avatar David Schäfer
Browse files

consistent queries and constraints

parent b091033f
......@@ -43,10 +43,10 @@ func initRouter(db *db.DataBase) *mux.Router {
router.HandleFunc("/loggers/{loggerId:[0-9]+}/data/level2", getWrapper(l2data.GetLogger)).Methods("GET")
router.HandleFunc("/loggers/{loggerId:[0-9]+}/data/level2", postWrapper(l2data.PostLogger)).Methods("POST")
router.HandleFunc(
"/loggers/{loggerId:[0-9]+}/data/level1/{aggregate:(?:hourly|daily|monthly|yearly)}/{func:(?:sum|mean)}",
"/loggers/{loggerId:[0-9]+}/data/level1/{period:(?:hourly|daily|monthly|yearly)}/{func:(?:sum|mean)}",
getWrapper(l1data.GetLoggerAggregate)).Methods("GET")
router.HandleFunc(
"/loggers/{loggerId:[0-9]+}/data/level2/{aggregate:(?:hourly|daily|monthly|yearly)}/{func:(?:sum|mean)}",
"/loggers/{loggerId:[0-9]+}/data/level2/{period:(?:hourly|daily|monthly|yearly)}/{func:(?:sum|mean)}",
getWrapper(l2data.GetLoggerAggregate)).Methods("GET")
router.HandleFunc("/sensors", getWrapper(sensors.GetAll)).Methods("GET")
......@@ -57,10 +57,10 @@ func initRouter(db *db.DataBase) *mux.Router {
router.HandleFunc("/sensors/{sensorId:[0-9]+}/data/level2", getWrapper(l2data.GetSensor)).Methods("GET")
router.HandleFunc(
"/sensors/{sensorId:[0-9]+}/data/level1/{aggregate:(?:hourly|daily|monthly|yearly)}/{func:(?:sum|mean)}",
"/sensors/{sensorId:[0-9]+}/data/level1/{period:(?:hourly|daily|monthly|yearly)}/{func:(?:sum|mean)}",
getWrapper(l1data.GetSensorAggregate)).Methods("GET")
router.HandleFunc(
"/sensors/{sensorId:[0-9]+}/data/level2/{aggregate:(?:hourly|daily|monthly|yearly)}/{func:(?:sum|mean)}",
"/sensors/{sensorId:[0-9]+}/data/level2/{period:(?:hourly|daily|monthly|yearly)}/{func:(?:sum|mean)}",
getWrapper(l2data.GetSensorAggregate)).Methods("GET")
return router
......
-- l1data.sql
SELECT
TO_CHAR(r.TIMESTAMP_MEASUREMENT, 'YYYY-MM-DD HH24:MI:SS') AS TIMESTAMP_MEASUREMENT
, v.VALUE AS VALUE_MEASUREMENT
, l.LOGGER_ID
, s.SENSOR_ID
, s.LABEL AS SENSOR_LABEL
, s.NAME AS SENSOR_NAME
TO_CHAR(r.timestamp_measurement, 'YYYY-MM-DD HH24:MI:SS') AS timestamp_measurement
, v.value AS value_measurement
, l.logger_id
, s.sensor_id
, s.label AS sensor_label
, s.name AS sensor_name
FROM LOGGER.LOGGER l
JOIN LOGGER.LEVEL1_RECORD r ON l.LOGGER_ID = r.LOGGER_ID
JOIN LOGGER.LEVEL1_VALUE v ON r.LEVEL1_RECORD_ID = v.LEVEL1_RECORD_ID
JOIN LOGGER.SENSOR s ON v.SENSOR_ID = s.SENSOR_ID
WHERE l.DATENPROJEKT_ID = :1
AND l.DELETED = 0
AND s.DELETED = 0
JOIN LOGGER.LEVEL1_RECORD r ON l.logger_id = r.logger_id
JOIN LOGGER.LEVEL1_VALUE v ON r.level1_record_id = v.level1_record_id
JOIN LOGGER.SENSOR s ON v.sensor_id = s.sensor_id
WHERE l.datenprojekt_id = :1
AND %s = :2
AND TIMESTAMP_MEASUREMENT >= LOGGER.DMP_DATE.PARSE(:3)
AND TIMESTAMP_MEASUREMENT < LOGGER.DMP_DATE.PARSE(:4)
ORDER BY r.TIMESTAMP_MEASUREMENT, s.SENSOR_ID
AND r.timestamp_measurement >= LOGGER.DMP_DATE.PARSE(:3)
AND r.timestamp_measurement <= LOGGER.DMP_DATE.PARSE(:4)
AND l.deleted = 0
AND s.deleted = 0
AND s.updated = 0
AND s.virtual_sensor = 0
ORDER BY r.timestamp_measurement, s.sensor_id
OFFSET :5 ROWS FETCH NEXT :6 ROWS ONLY
WITH tmp AS (
SELECT
TO_CHAR(TRUNC(TIMESTAMP_MEASUREMENT, '%s'), 'YYYY-MM-DD HH24:MI:SS') AS TIMESTAMP_MEASUREMENT
, CASE WHEN REGEXP_LIKE(v.VALUE, '^[\+-]?\d+(\.\d+)?$') THEN TO_NUMBER(v.VALUE) ELSE NULL END AS VALUE_MEASUREMENT
, l.LOGGER_ID
, s.SENSOR_ID
, s.LABEL AS SENSOR_LABEL
, s.NAME AS SENSOR_NAME
TO_CHAR(TRUNC(r.timestamp_measurement, '%s'), 'YYYY-MM-DD HH24:MI:SS') AS timestamp_measurement
, CASE WHEN REGEXP_LIKE(v.value, '^[\+-]?\d+(\.\d+)?$') THEN TO_NUMBER(v.VALUE) ELSE NULL END AS value_measurement
, l.logger_id
, s.sensor_id
, s.label AS sensor_label
, s.name AS sensor_name
FROM LOGGER.LOGGER l
JOIN LOGGER.LEVEL1_RECORD r ON l.LOGGER_ID = r.LOGGER_ID
JOIN LOGGER.LEVEL1_VALUE v ON r.LEVEL1_RECORD_ID = v.LEVEL1_RECORD_ID
JOIN LOGGER.SENSOR s ON v.SENSOR_ID = s.SENSOR_ID
WHERE l.DATENPROJEKT_ID = :1
JOIN LOGGER.LEVEL1_RECORD r ON l.logger_id = r.logger_id
JOIN LOGGER.LEVEL1_VALUE v ON r.level1_record_id = v.level1_record_id
JOIN LOGGER.SENSOR s ON v.sensor_id = s.sensor_id
WHERE l.datenprojekt_id = :1
AND %s = :2
AND TIMESTAMP_MEASUREMENT >= LOGGER.DMP_DATE.PARSE(:3)
AND TIMESTAMP_MEASUREMENT < LOGGER.DMP_DATE.PARSE(:4)
AND r.timestamp_measurement >= LOGGER.DMP_DATE.PARSE(:3)
AND r.timestamp_measurement <= LOGGER.DMP_DATE.PARSE(:4)
AND l.deleted = 0
AND s.deleted = 0
AND s.updated = 0
AND s.virtual_sensor = 0
) SELECT
TIMESTAMP_MEASUREMENT,
%s(VALUE_MEASUREMENT) AS VALUE_MEASUREMENT,
MAX(LOGGER_ID) AS LOGGER_ID,
SENSOR_ID,
MAX(SENSOR_NAME) AS SENSOR_NAME,
MAX(SENSOR_LABEL) AS SENSOR_LABEL
timestamp_measurement,
%s(value_measurement) AS value_measurement,
MAX(logger_id) AS logger_id,
sensor_id,
MAX(sensor_name) AS sensor_name,
MAX(sensor_label) AS sensor_label
FROM tmp
GROUP BY TIMESTAMP_MEASUREMENT, SENSOR_ID
ORDER BY TIMESTAMP_MEASUREMENT, LOGGER_ID, SENSOR_ID
GROUP BY timestamp_measurement, sensor_id
ORDER BY timestamp_measurement, logger_id, sensor_id
OFFSET :5 ROWS FETCH NEXT :6 ROWS ONLY
-- l2cache.sql
SELECT
TO_CHAR(d.TIMESTAMP, 'YYYY-MM-DD HH24:MI:SS') AS TIMESTAMP_MEASUREMENT
, d.VALUE AS VALUE_MEASUREMENT
, d.LOGGER_ID
, d.SENSOR_ID
, s.LABEL AS SENSOR_LABEL
, s.NAME AS SENSOR_NAME
, d.QUALITY_FLAG
, d.QUALITY_CAUSE
, d.QUALITY_COMMENT
TO_CHAR(d.timestamp, 'YYYY-MM-DD HH24:MI:SS') AS timestamp_measurement
, d.value AS value_measurement
, d.logger_id
, d.sensor_id
, s.label AS sensor_label
, s.name AS sensor_name
, d.quality_flag
, d.quality_cause
, d.quality_comment
FROM LOGGER.MV_LEVEL2A_DATA d
JOIN LOGGER.SENSOR s ON d.SENSOR_ID = s.SENSOR_ID
JOIN LOGGER.LOGGER l ON d.LOGGER_ID = l.LOGGER_ID
JOIN LOGGER.SENSOR s ON d.sensor_id = s.sensor_id
JOIN LOGGER.LOGGER l ON d.logger_id = l.logger_id
WHERE l.DATENPROJEKT_ID = :1
AND l.DELETED = 0
AND s.DELETED = 0
AND %s = :2
AND d.TIMESTAMP >= LOGGER.DMP_DATE.PARSE(:3)
AND d.TIMESTAMP < LOGGER.DMP_DATE.PARSE(:4)
ORDER BY TIMESTAMP, SENSOR_ID
AND d.timestamp >= LOGGER.DMP_DATE.PARSE(:3)
AND d.timestamp <= LOGGER.DMP_DATE.PARSE(:4)
AND l.deleted = 0
AND s.deleted = 0
AND s.updated = 0
AND s.virtual_sensor = 0
ORDER BY d.timestamp, s.sensor_id
OFFSET :5 ROWS FETCH NEXT :6 ROWS ONLY
-- l2data.sql
SELECT
TO_CHAR(r.TIMESTAMP_MEASUREMENT, 'YYYY-MM-DD HH24:MI:SS') AS TIMESTAMP_MEASUREMENT
, v.VALUE AS VALUE_MEASUREMENT
, l.LOGGER_ID
, s.SENSOR_ID
, s.LABEL AS SENSOR_LABEL
, s.NAME AS SENSOR_NAME
, f.QUALITY_FLAG
, f.QUALITY_CAUSE
, f.QUALITY_COMMENT
TO_CHAR(r.timestamp_measurement, 'YYYY-MM-DD HH24:MI:SS') AS timestamp_measurement
, v.value AS value_measurement
, l.logger_id
, s.sensor_id
, s.label AS sensor_label
, s.name AS sensor_name
, f.quality_flag
, f.quality_cause
, f.quality_comment
FROM LOGGER.LOGGER l
JOIN LOGGER.LEVEL1_RECORD r ON l.LOGGER_ID = r.LOGGER_ID
JOIN LOGGER.LEVEL1_VALUE v ON r.LEVEL1_RECORD_ID = v.LEVEL1_RECORD_ID
JOIN LOGGER.SENSOR s ON v.SENSOR_ID = s.SENSOR_ID
LEFT OUTER JOIN LOGGER.FLAG f on v.level1_value_id = f.level1_value_id
WHERE l.DATENPROJEKT_ID = :1
AND l.DELETED = 0
AND s.DELETED = 0
JOIN LOGGER.LEVEL1_RECORD r ON l.logger_id = r.logger_id
JOIN LOGGER.LEVEL1_VALUE v ON r.level1_record_id = v.level1_record_id
JOIN LOGGER.SENSOR s ON v.sensor_id = s.sensor_id
LEFT OUTER JOIN LOGGER.FLAG f on v.level1_value_id = f.level1_value_id
WHERE l.datenprojekt_id = :1
AND %s = :2
AND TIMESTAMP_MEASUREMENT >= LOGGER.DMP_DATE.PARSE(:3)
AND TIMESTAMP_MEASUREMENT < LOGGER.DMP_DATE.PARSE(:4)
ORDER BY TIMESTAMP_MEASUREMENT, SENSOR_ID
and r.timestamp_measurement >= LOGGER.DMP_DATE.PARSE(:3)
AND r.timestamp_measurement <= LOGGER.DMP_DATE.PARSE(:4)
AND l.deleted = 0
AND s.deleted = 0
AND s.updated = 0
AND s.virtual_sensor = 0
ORDER BY r.timestamp_measurement, s.sensor_id
OFFSET :5 ROWS FETCH NEXT :6 ROWS ONLY
-- l2data_aggregate.sql
WITH selected AS (
SELECT
TO_CHAR(TRUNC(TIMESTAMP_MEASUREMENT, '%s'), 'YYYY-MM-DD HH24:MI:SS') AS TIMESTAMP_MEASUREMENT
, CASE WHEN REGEXP_LIKE(v.VALUE, '^[\+-]?\d+(\.\d+)?$') THEN TO_NUMBER(v.VALUE) ELSE NULL END AS VALUE_MEASUREMENT
, l.LOGGER_ID
, s.SENSOR_ID
, s.LABEL AS SENSOR_LABEL
, s.NAME AS SENSOR_NAME
, f.QUALITY_FLAG
, f.QUALITY_CAUSE
, f.QUALITY_COMMENT
TO_CHAR(TRUNC(r.timestamp_measurement, '%s'), 'YYYY-MM-DD HH24:MI:SS') AS timestamp_measurement
, CASE WHEN REGEXP_LIKE(v.value, '^[\+-]?\d+(\.\d+)?$') THEN TO_NUMBER(v.value) ELSE NULL END AS value_measurement
, l.logger_id
, s.sensor_id
, s.label AS sensor_label
, s.name AS sensor_name
, f.quality_flag
, f.quality_cause
, f.quality_comment
FROM LOGGER.LOGGER l
JOIN LOGGER.LEVEL1_RECORD r ON l.LOGGER_ID = r.LOGGER_ID
JOIN LOGGER.LEVEL1_VALUE v ON r.LEVEL1_RECORD_ID = v.LEVEL1_RECORD_ID
JOIN LOGGER.SENSOR s ON v.SENSOR_ID = s.SENSOR_ID
LEFT OUTER JOIN LOGGER.FLAG f on v.level1_value_id = f.level1_value_id
WHERE l.DATENPROJEKT_ID = :1
JOIN LOGGER.LEVEL1_RECORD r ON l.logger_id = r.logger_id
JOIN LOGGER.LEVEL1_VALUE v ON r.level1_record_id = v.level1_record_id
JOIN LOGGER.SENSOR s ON v.sensor_id = s.sensor_id
LEFT OUTER JOIN LOGGER.FLAG f on v.level1_value_id = f.level1_value_id
WHERE l.datenprojekt_id = :1
AND %s = :2
AND TIMESTAMP_MEASUREMENT >= LOGGER.DMP_DATE.PARSE(:3)
AND TIMESTAMP_MEASUREMENT < LOGGER.DMP_DATE.PARSE(:4)
AND r.timestamp_measurement >= LOGGER.DMP_DATE.PARSE(:3)
AND r.timestamp_measurement <= LOGGER.DMP_DATE.PARSE(:4)
AND l.deleted = 0
AND s.deleted = 0
AND s.updated = 0
AND s.virtual_sensor = 0
) SELECT
TIMESTAMP_MEASUREMENT AS TIMESTAMP_MEASUREMENT,
MAX(LOGGER_ID) AS LOGGER_ID,
%s(CASE WHEN QUALITY_FLAG in ('BAD', 'DOUBTFUL') THEN NULL ELSE VALUE_MEASUREMENT END) AS VALUE_MEASUREMENT,
MAX(SENSOR_ID) AS SENSOR_ID,
MAX(SENSOR_NAME) AS SENSOR_NAME,
MAX(SENSOR_LABEL) AS SENSOR_LABEL,
timestamp_measurement AS timestamp_measurement,
MAX(logger_id) AS logger_id,
%s(CASE WHEN quality_flag in ('BAD', 'DOUBTFUL') THEN NULL ELSE value_measurement END) AS value_measurement,
MAX(sensor_id) AS sensor_id,
MAX(sensor_name) AS sensor_name,
MAX(sensor_label) AS sensor_label,
CASE
WHEN AVG(CASE WHEN QUALITY_FLAG = 'BAD' THEN 1 ELSE 0 END) > :5
WHEN AVG(CASE WHEN quality_flag = 'BAD' THEN 1 ELSE 0 END) > :5
THEN 'BAD'
WHEN AVG(CASE WHEN QUALITY_FLAG in ('BAD', 'DOUBTFUL') THEN 1 ELSE 0 END) > :6
WHEN AVG(CASE WHEN quality_flag in ('BAD', 'DOUBTFUL') THEN 1 ELSE 0 END) > :6
THEN 'DOUBTFUL'
ELSE 'OK'
END AS QUALITY_FLAG,
NULL AS QUALITY_CAUSE,
NULL AS QUALITY_COMMENT
END AS quality_flag,
NULL AS quality_cause,
NULL AS quality_comment
FROM selected
GROUP BY TIMESTAMP_MEASUREMENT, SENSOR_ID
ORDER BY TIMESTAMP_MEASUREMENT, SENSOR_ID
GROUP BY timestamp_measurement, sensor_id
ORDER BY timestamp_measurement, sensor_id
OFFSET :7 ROWS FETCH NEXT :8 ROWS ONLY
-- loggers.sql
SELECT
LOGGER_ID,
DEVICE_ID,
NAME AS LOGGER_NAME,
LABEL AS LOGGER_LABEL,
RESPONSIBLE_PERSON,
UNTERSUCHUNGSGEBIET_ID
logger_id,
device_id,
name AS logger_name,
label AS logger_label,
responsible_person,
untersuchungsgebiet_id
FROM
LOGGER.LOGGER l
WHERE DATENPROJEKT_ID = :1
AND l.DELETED = 0
AND DEVICE_ID IS NOT NULL
WHERE l.datenprojekt_id = :1
AND l.deleted = 0
AND device_id IS NOT NULL
%s
ORDER BY LOGGER_ID
ORDER BY l.logger_id
OFFSET :2 ROWS FETCH NEXT :3 ROWS ONLY
-- sensors.sql
SELECT
s.SENSOR_ID
, s.NAME AS SENSOR_NAME
, s.LABEL AS SENSOR_LABEL
, s.COMPARTMENT_NAME
, s.PHYSICAL_PROPERTY_NAME
, s.UPDATED
, s.UNIT_NAME
, s.SAMPLING_INTERVAL
, s.SAMPLING_ALTITUDE -- elevation of the sensor position
, c.LOGGER_ID
, o.HOEHE_NN -- elevation of the sampling location
, o.LAT
, o.LON
s.sensor_id
, s.name AS sensor_name
, s.label AS sensor_label
, s.compartment_name
, s.physical_property_name
, s.updated
, s.unit_name
, s.sampling_interval
, s.sampling_altitude -- elevation of the sensor position
, c.logger_id
, o.hoehe_nn -- elevation of the sampling location
, o.lat
, o.lon
FROM LOGGER.SENSOR s
JOIN LOGGER.SENSOR_CONFIGURATION c on s.SENSOR_CONFIGURATION_ID = c.SENSOR_CONFIGURATION_ID
JOIN LOGGER.LOGGER l on l.LOGGER_ID = c.LOGGER_ID
JOIN DATENMANAGEMENTPORTAL.ORT o on o.ORT_ID = s.ORT_ID
WHERE l.DATENPROJEKT_ID = :1
AND s.DELETED = 0
AND l.DELETED = 0
AND c.DELETED = 0
AND s.EVALUATE_SENSOR = 1
AND s.VIRTUAL_SENSOR = 0
AND s.UPDATED = 0
AND c.CONFIG_END IS NULL
JOIN LOGGER.SENSOR_CONFIGURATION c on s.sensor_configuration_id = c.sensor_configuration_id
JOIN LOGGER.LOGGER l on l.logger_id = c.logger_id
JOIN DATENMANAGEMENTPORTAL.ORT o on o.ort_id = s.ort_id
WHERE l.datenprojekt_id = :1
AND l.deleted = 0
AND s.deleted = 0
AND s.updated = 0
AND s.virtual_sensor = 0
AND s.evaluate_sensor = 1
AND c.deleted = 0
AND c.config_end IS NULL
%s
ORDER BY s.SENSOR_ID
ORDER BY s.sensor_id
OFFSET :2 ROWS FETCH NEXT :3 ROWS ONLY
......@@ -2,15 +2,16 @@ SELECT
s.name
, s.label
, s.position
, CASE WHEN s.SAMPLING_MEDIA_NAME = 'TIME' AND s.EVALUATE_SENSOR = 0 THEN 1 ELSE 0 END AS IS_TIME
, CASE WHEN s.sampling_media_name = 'TIME' AND s.evaluate_sensor = 0 THEN 1 ELSE 0 END AS is_time
FROM
logger.sensor s
JOIN logger.sensor_configuration c ON c.sensor_configuration_id = s.sensor_configuration_id
JOIN logger.logger l on l.logger_id = c.logger_id
WHERE l.DATENPROJEKT_ID = :1
AND c.logger_id = :2
AND c.deleted = 0
AND c.config_end is NULL
JOIN logger.logger l on l.logger_id = c.logger_id
WHERE l.datenprojekt_id = :1
AND l.logger_id = :2
AND l.deleted = 0
AND s.deleted = 0
AND s.updated = 0
AND s.virtual_sensor = 0
AND c.deleted = 0
AND c.config_end is NULL
-- value_ids.sql
SELECT
TO_CHAR(r.TIMESTAMP_MEASUREMENT, 'YYYY-MM-DD HH24:MI:SS') AS TIMESTAMP_MEASUREMENT
, s.SENSOR_ID
, v.LEVEL1_VALUE_ID AS VALUE_ID
TO_CHAR(r.timestamp_measurement, 'YYYY-MM-DD HH24:MI:SS') AS timestamp_measurement
, s.sensor_id
, v.level1_value_id AS value_id
FROM LOGGER.LOGGER l
JOIN LOGGER.LEVEL1_RECORD r ON l.LOGGER_ID = r.LOGGER_ID
JOIN LOGGER.LEVEL1_VALUE v ON r.LEVEL1_RECORD_ID = v.LEVEL1_RECORD_ID
JOIN LOGGER.SENSOR s ON v.SENSOR_ID = s.SENSOR_ID
JOIN LOGGER.LEVEL1_RECORD r ON l.LOGGER_ID = r.LOGGER_ID
JOIN LOGGER.LEVEL1_VALUE v ON r.LEVEL1_RECORD_ID = v.LEVEL1_RECORD_ID
JOIN LOGGER.SENSOR s ON v.SENSOR_ID = s.SENSOR_ID
JOIN LOGGER.SENSOR_CONFIGURATION c on c.SENSOR_CONFIGURATION_ID = s.SENSOR_CONFIGURATION_ID
WHERE l.DATENPROJEKT_ID = :1
AND l.DELETED = 0
AND s.DELETED = 0
AND c.DELETED = 0
WHERE l.datenprojekt_id = :1
AND l.logger_id = :2
AND timestamp_measurement >= LOGGER.DMP_DATE.PARSE(:3)
AND timestamp_measurement <= LOGGER.DMP_DATE.PARSE(:4)
AND l.deleted = 0
AND s.deleted = 0
AND s.updated = 0
AND s.virtual_sensor = 0
AND c.deleted = 0
AND c.config_end IS NULL
AND l.LOGGER_ID = :2
AND TIMESTAMP_MEASUREMENT >= LOGGER.DMP_DATE.PARSE(:3)
AND TIMESTAMP_MEASUREMENT <= LOGGER.DMP_DATE.PARSE(:4)
ORDER BY SENSOR_ID, TIMESTAMP_MEASUREMENT
ORDER BY s.sensor_id, r.timestamp_measurement
Markdown is supported
0% or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment