fix: add measured values table - postgres

This commit is contained in:
Markus Pesch 2021-05-29 18:58:45 +02:00
parent a62bf175cb
commit 077988b503
Signed by: volker.raschek
GPG Key ID: 852BCC170D81A982
2 changed files with 225 additions and 0 deletions

View File

@ -0,0 +1,95 @@
-- Remove constraints to table measured_values
ALTER TABLE humidities
DROP CONSTRAINT fk_humidites_measured_value_id;
ALTER TABLE pressures
DROP CONSTRAINT fk_pressures_measured_value_id;
ALTER TABLE temperatures
DROP CONSTRAINT fk_temperatures_measured_value_id;
-- Rename measured_value_id to sensor_id
ALTER TABLE humidities
RENAME COLUMN measured_value_id TO sensor_id;
ALTER TABLE pressures
RENAME COLUMN measured_value_id TO sensor_id;
ALTER TABLE temperatures
RENAME COLUMN measured_value_id TO sensor_id;
-- Add new column measures_value_id with data from sensor_id
ALTER TABLE humidities
ADD COLUMN measured_value_id CHAR(36);
UPDATE humidities
SET measured_value_id=sensor_id;
ALTER TABLE pressures
ADD COLUMN measured_value_id CHAR(36);
UPDATE pressures
SET measured_value_id=sensor_id;
ALTER TABLE temperatures
ADD COLUMN measured_value_id CHAR(36);
UPDATE temperatures
SET measured_value_id=sensor_id;
-- Update sensor_id's
UPDATE humidities h
SET sensor_id = (
SELECT m.sensor_id
FROM measured_values m
WHERE m.id = h.measured_value_id
);
UPDATE pressures p
SET sensor_id = (
SELECT m.sensor_id
FROM measured_values m
WHERE m.id = p.measured_value_id
);
UPDATE temperatures t
SET sensor_id = (
SELECT m.sensor_id
FROM measured_values m
WHERE m.id = t.measured_value_id
);
-- Delete sensor_id columns
ALTER TABLE humidities
DROP COLUMN measured_value_id;
ALTER TABLE pressures
DROP COLUMN measured_value_id;
ALTER TABLE temperatures
DROP COLUMN measured_value_id;
-- Add foreign keys
ALTER TABLE humidities
ADD CONSTRAINT fk_humidites_sensor_id
FOREIGN KEY (sensor_id)
REFERENCES sensors(sensor_id)
ON DELETE CASCADE
ON UPDATE CASCADE;
ALTER TABLE pressures
ADD CONSTRAINT fk_pressures_sensor_id
FOREIGN KEY (sensor_id)
REFERENCES sensors(sensor_id)
ON DELETE CASCADE
ON UPDATE CASCADE;
ALTER TABLE temperatures
ADD CONSTRAINT fk_temperatures_sensor_id
FOREIGN KEY (sensor_id)
REFERENCES sensors(sensor_id)
ON DELETE CASCADE
ON UPDATE CASCADE;
-- drop measured values table
DROP TABLE measured_values CASCADE;

View File

@ -0,0 +1,130 @@
-- Create measures_values table.
-- This table represent a collection of different measured values, because it
-- can be possible, that a sensor returns multiple measured values. For example
-- the BME280 semsor returns humidity, pressure and temperature values.
CREATE TABLE measured_values (
id CHAR(36) NOT NULL,
sensor_id CHAR(36) NOT NULL,
creation_date TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
update_date TIMESTAMP WITH TIME ZONE,
CONSTRAINT pk_measured_value PRIMARY KEY(id),
CONSTRAINT pk_measured_value_sensor_id FOREIGN KEY(sensor_id) REFERENCES sensors(sensor_id) ON DELETE CASCADE ON UPDATE CASCADE
);
-- Remove constraints to table sensor
ALTER TABLE humidities
DROP CONSTRAINT fk_humidites_sensor_id;
ALTER TABLE pressures
DROP CONSTRAINT fk_pressures_sensor_id;
ALTER TABLE temperatures
DROP CONSTRAINT fk_temperatures_sensor_id;
-- Rename sensor_id to measured_value_id
ALTER TABLE humidities
RENAME COLUMN sensor_id TO measured_value_id;
ALTER TABLE pressures
RENAME COLUMN sensor_id TO measured_value_id;
ALTER TABLE temperatures
RENAME COLUMN sensor_id TO measured_value_id;
-- Add new column sensor_id with data from measures_value_id
ALTER TABLE humidities
ADD COLUMN sensor_id CHAR(36);
UPDATE humidities
SET sensor_id=measured_value_id;
ALTER TABLE pressures
ADD COLUMN sensor_id CHAR(36);
UPDATE pressures
SET sensor_id=measured_value_id;
ALTER TABLE temperatures
ADD COLUMN sensor_id CHAR(36);
UPDATE temperatures
SET sensor_id=measured_value_id;
DO $$
DECLARE
f record;
BEGIN
FOR f IN (
SELECT
md5(random()::text || clock_timestamp()::text)::uuid AS measured_value_id,
h.id AS humidity_id,
p.id AS pressure_id,
t.id AS temperature_id,
CASE WHEN h.sensor_id IS NOT NULL THEN h.sensor_id
WHEN p.sensor_id IS NOT NULL THEN p.sensor_id
WHEN t.sensor_id IS NOT NULL THEN t.sensor_id
ELSE NULL
END sensor_id
FROM pressures p
FULL OUTER JOIN temperatures t ON (t.date = p.date AND t.sensor_id = p.sensor_id)
FULL OUTER JOIN humidities h ON (h.date = p.date AND h.sensor_id = p.sensor_id)
) LOOP
-- MEASURED_VALUE
INSERT INTO measured_values(id, sensor_id, creation_date, update_date)
VALUES (f.measured_value_id, f.sensor_id, NOW(), NULL)
ON CONFLICT (
id
)
DO NOTHING;
-- HUMIDITY
UPDATE humidities
SET measured_value_id=f.measured_value_id
WHERE id=f.humidity_id;
-- PRESSURE
UPDATE pressures
SET measured_value_id=f.measured_value_id
WHERE id=f.pressure_id;
-- TEMPERATURES
UPDATE temperatures
SET measured_value_id=f.measured_value_id
WHERE id=f.temperature_id;
END LOOP;
END;
$$;
-- Delete sensor_id columns
ALTER TABLE humidities
DROP COLUMN sensor_id;
ALTER TABLE pressures
DROP COLUMN sensor_id;
ALTER TABLE temperatures
DROP COLUMN sensor_id;
-- Add foreign keys
ALTER TABLE humidities
ADD CONSTRAINT fk_humidites_measured_value_id
FOREIGN KEY (measured_value_id)
REFERENCES measured_values(id)
ON DELETE CASCADE
ON UPDATE CASCADE;
ALTER TABLE pressures
ADD CONSTRAINT fk_pressures_measured_value_id
FOREIGN KEY (measured_value_id)
REFERENCES measured_values(id)
ON DELETE CASCADE
ON UPDATE CASCADE;
ALTER TABLE temperatures
ADD CONSTRAINT fk_temperatures_measured_value_id
FOREIGN KEY (measured_value_id)
REFERENCES measured_values(id)
ON DELETE CASCADE
ON UPDATE CASCADE;