flucky/pkg/repository/sqlite3/ddl/6_table_measured_values.dow...

91 lines
3.5 KiB
SQL

-- All tables with the original data rows must be renamed, because it is not
-- possible to remove existing foreign keys. The tables will be recreated with
-- a new column measured_value_id which reference on the primary key of the
-- table measured values.
--
-- More about why it is not possible to delete a foreign key is described here:
-- https://stackoverflow.com/a/1884893/7652996
ALTER TABLE humidities
RENAME TO humidities_backup;
CREATE TABLE humidities (
id CHAR(36) NOT NULL,
value NUMERIC(10,3) NOT NULL,
date TIMESTAMP NOT NULL,
sensor_id CHAR(36) NOT NULL,
creation_date TIMESTAMP DEFAULT (datetime('now', 'localtime')) NOT NULL,
update_date TIMESTAMP,
CONSTRAINT pk_humidities PRIMARY KEY(id),
CONSTRAINT fk_humidities_sensor_id FOREIGN KEY(sensor_id) REFERENCES sensors(sensor_id) ON DELETE CASCADE ON UPDATE CASCADE
);
ALTER TABLE pressures
RENAME TO pressures_backup;
CREATE TABLE pressures (
id CHAR(36) NOT NULL,
value NUMERIC(10,3) NOT NULL,
date TIMESTAMP NOT NULL,
sensor_id CHAR(36) NOT NULL,
creation_date TIMESTAMP DEFAULT (datetime('now', 'localtime')) NOT NULL,
update_date TIMESTAMP,
CONSTRAINT pk_pressures PRIMARY KEY(id),
CONSTRAINT fk_pressures_sensor_id FOREIGN KEY(sensor_id) REFERENCES sensors(sensor_id) ON DELETE CASCADE ON UPDATE CASCADE
);
ALTER TABLE temperatures
RENAME TO temperatures_backup;
CREATE TABLE temperatures (
id CHAR(36) NOT NULL,
value NUMERIC(10,3) NOT NULL,
date TIMESTAMP NOT NULL,
sensor_id CHAR(36) NOT NULL,
creation_date TIMESTAMP DEFAULT (datetime('now', 'localtime')) NOT NULL,
update_date TIMESTAMP,
CONSTRAINT pk_temperatures PRIMARY KEY(id),
CONSTRAINT fk_temperatures_id FOREIGN KEY(sensor_id) REFERENCES sensors(sensor_id) ON DELETE CASCADE ON UPDATE CASCADE
);
-- Filling tables humidities, pressures and temperatures with the data from the
-- backup table.
INSERT INTO humidities
SELECT
h.id,
h.value,
h.date,
m.sensor_id,
h.creation_date,
h.update_date
FROM humidities_backup h
INNER JOIN measured_values m ON (m.id = h.measured_value_id);
INSERT INTO pressures
SELECT
p.id,
p.value,
p.date,
m.sensor_id,
p.creation_date,
p.update_date
FROM pressures_backup p
INNER JOIN measured_values m ON (m.id = p.measured_value_id);
INSERT INTO temperatures
SELECT
t.id,
t.value,
t.date,
m.sensor_id,
t.creation_date,
t.update_date
FROM temperatures_backup t
INNER JOIN measured_values m ON (m.id = t.measured_value_id);
-- The remaining tables, which were only necessary for the migration,
-- are now removed.
DROP TABLE humidities_backup;
DROP TABLE pressures_backup;
DROP TABLE temperatures_backup;
DROP TABLE measured_values;