fix: add measured values table - sqlite
This commit is contained in:
		
							
								
								
									
										90
									
								
								pkg/repository/sqlite3/ddl/6_table_measured_values.down.sql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										90
									
								
								pkg/repository/sqlite3/ddl/6_table_measured_values.down.sql
									
									
									
									
									
										Normal file
									
								
							@@ -0,0 +1,90 @@
 | 
				
			|||||||
 | 
					-- 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;
 | 
				
			||||||
							
								
								
									
										189
									
								
								pkg/repository/sqlite3/ddl/6_table_measured_values.up.sql
									
									
									
									
									
										Normal file
									
								
							
							
						
						
									
										189
									
								
								pkg/repository/sqlite3/ddl/6_table_measured_values.up.sql
									
									
									
									
									
										Normal file
									
								
							@@ -0,0 +1,189 @@
 | 
				
			|||||||
 | 
					-- 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
 | 
				
			||||||
 | 
					);
 | 
				
			||||||
 | 
					
 | 
				
			||||||
 | 
					-- 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,
 | 
				
			||||||
 | 
					  measured_value_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_measured_value_id FOREIGN KEY(measured_value_id) REFERENCES measured_values(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,
 | 
				
			||||||
 | 
					  measured_value_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_measured_value_id FOREIGN KEY(measured_value_id) REFERENCES measured_values(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,
 | 
				
			||||||
 | 
					  measured_value_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_measured_value_id FOREIGN KEY(measured_value_id) REFERENCES measured_values(id) ON DELETE CASCADE ON UPDATE CASCADE
 | 
				
			||||||
 | 
					);
 | 
				
			||||||
 | 
					
 | 
				
			||||||
 | 
					-- The following two views are necessary to create a FULL OUTER JOIN via the
 | 
				
			||||||
 | 
					-- tables humidities, pressures and temperatures, as this is not supported in
 | 
				
			||||||
 | 
					-- SQLite. More about this here:
 | 
				
			||||||
 | 
					--
 | 
				
			||||||
 | 
					-- https://stackoverflow.com/questions/12759087/full-outer-join-in-sqlite-on-4-tables
 | 
				
			||||||
 | 
					CREATE VIEW humidities_pressures AS
 | 
				
			||||||
 | 
					SELECT
 | 
				
			||||||
 | 
					  h.id AS humidity_id,
 | 
				
			||||||
 | 
					  h.value AS humidity_value,
 | 
				
			||||||
 | 
					  h.date AS humidity_date,
 | 
				
			||||||
 | 
					  h.sensor_id AS humidity_sensor_id,
 | 
				
			||||||
 | 
					  h.creation_date AS humidity_creation_date,
 | 
				
			||||||
 | 
					  h.update_date AS humidity_update_date,
 | 
				
			||||||
 | 
					  p.id AS pressure_id,
 | 
				
			||||||
 | 
					  p.value AS pressure_value,
 | 
				
			||||||
 | 
					  p.date AS pressure_date,
 | 
				
			||||||
 | 
					  p.sensor_id AS pressure_sensor_id,
 | 
				
			||||||
 | 
					  p.creation_date AS pressure_creation_date,
 | 
				
			||||||
 | 
					  p.update_date AS pressure_update_date
 | 
				
			||||||
 | 
					FROM humidities_backup h
 | 
				
			||||||
 | 
					  LEFT JOIN pressures_backup p ON (h.date = p.date AND h.sensor_id = p.sensor_id)
 | 
				
			||||||
 | 
					UNION ALL
 | 
				
			||||||
 | 
					SELECT
 | 
				
			||||||
 | 
					  h.id AS humidity_id,
 | 
				
			||||||
 | 
					  h.value AS humidity_value,
 | 
				
			||||||
 | 
					  h.date AS humidity_date,
 | 
				
			||||||
 | 
					  h.sensor_id AS humidity_sensor_id,
 | 
				
			||||||
 | 
					  h.creation_date AS humidity_creation_date,
 | 
				
			||||||
 | 
					  h.update_date AS humidity_update_date,
 | 
				
			||||||
 | 
					  p.id AS pressure_id,
 | 
				
			||||||
 | 
					  p.value AS pressure_value,
 | 
				
			||||||
 | 
					  p.date AS pressure_date,
 | 
				
			||||||
 | 
					  p.sensor_id AS pressure_sensor_id,
 | 
				
			||||||
 | 
					  p.creation_date AS pressure_creation_date,
 | 
				
			||||||
 | 
					  p.update_date AS pressure_update_date
 | 
				
			||||||
 | 
					FROM pressures_backup p
 | 
				
			||||||
 | 
					  LEFT JOIN humidities_backup h ON (p.date = h.date AND p.sensor_id = h.sensor_id)
 | 
				
			||||||
 | 
					WHERE h.date IS NULL
 | 
				
			||||||
 | 
					AND h.sensor_id IS NULL;
 | 
				
			||||||
 | 
					
 | 
				
			||||||
 | 
					CREATE VIEW joined_values AS
 | 
				
			||||||
 | 
					SELECT
 | 
				
			||||||
 | 
					  hp.*,
 | 
				
			||||||
 | 
					  t.id AS temperature_id,
 | 
				
			||||||
 | 
					  t.value AS temperature_value,
 | 
				
			||||||
 | 
					  t.date AS temperature_date,
 | 
				
			||||||
 | 
					  t.sensor_id AS temperature_sensor_id,
 | 
				
			||||||
 | 
					  t.creation_date AS temperature_creation_date,
 | 
				
			||||||
 | 
					  t.update_date AS temperature_update_date
 | 
				
			||||||
 | 
					FROM temperatures_backup t
 | 
				
			||||||
 | 
					  LEFT JOIN humidities_pressures hp ON (t.date = hp.pressure_date AND t.sensor_id = hp.pressure_sensor_id)
 | 
				
			||||||
 | 
					UNION ALL
 | 
				
			||||||
 | 
					SELECT
 | 
				
			||||||
 | 
					  hp.*,
 | 
				
			||||||
 | 
					  t.id AS temperature_id,
 | 
				
			||||||
 | 
					  t.value AS temperature_value,
 | 
				
			||||||
 | 
					  t.date AS temperature_date,
 | 
				
			||||||
 | 
					  t.sensor_id AS temperature_sensor_id,
 | 
				
			||||||
 | 
					  t.creation_date AS temperature_creation_date,
 | 
				
			||||||
 | 
					  t.update_date AS temperature_update_date
 | 
				
			||||||
 | 
					FROM humidities_pressures hp
 | 
				
			||||||
 | 
					  LEFT JOIN temperatures_backup t ON (t.date = hp.pressure_date  AND t.sensor_id = hp.pressure_sensor_id)
 | 
				
			||||||
 | 
					WHERE t.date IS NULL
 | 
				
			||||||
 | 
					AND t.sensor_id IS NULL;
 | 
				
			||||||
 | 
					
 | 
				
			||||||
 | 
					-- The date and the SensorID are used as primary key between the tables
 | 
				
			||||||
 | 
					-- humidities, pressures and temperatures. Based on this information, a
 | 
				
			||||||
 | 
					-- MeasuredValueID is generated. The data records are then inserted into the
 | 
				
			||||||
 | 
					-- table.
 | 
				
			||||||
 | 
					INSERT INTO measured_values (id, creation_date, sensor_id)
 | 
				
			||||||
 | 
					SELECT
 | 
				
			||||||
 | 
					  LOWER(HEX(RANDOMBLOB(4)) || '-' || HEX(RANDOMBLOB(2)) || '-' || '4' || SUBSTR(HEX(RANDOMBLOB(2)), 2) || '-' || SUBSTR('AB89', 1 + (ABS(random()) % 4) , 1) || SUBSTR(HEX(RANDOMBLOB(2)), 2) || '-' || HEX(RANDOMBLOB(6))) AS measured_value_id,
 | 
				
			||||||
 | 
					  CASE WHEN humidity_date IS NOT NULL THEN humidity_date
 | 
				
			||||||
 | 
					    WHEN pressure_date IS NOT NULL THEN pressure_date
 | 
				
			||||||
 | 
					    WHEN temperature_date IS NOT NULL THEN temperature_date
 | 
				
			||||||
 | 
					    ELSE NULL
 | 
				
			||||||
 | 
					  END date,
 | 
				
			||||||
 | 
						CASE WHEN humidity_sensor_id IS NOT NULL THEN humidity_sensor_id
 | 
				
			||||||
 | 
					      WHEN pressure_sensor_id IS NOT NULL THEN pressure_sensor_id
 | 
				
			||||||
 | 
					      WHEN temperature_sensor_id IS NOT NULL THEN temperature_sensor_id
 | 
				
			||||||
 | 
					      ELSE NULL
 | 
				
			||||||
 | 
					  END sensor_id
 | 
				
			||||||
 | 
					FROM joined_values;
 | 
				
			||||||
 | 
					
 | 
				
			||||||
 | 
					-- In the following, the original data records from the backup are restored with
 | 
				
			||||||
 | 
					-- the difference that the MeasuredValueID is added as a foreign key based on
 | 
				
			||||||
 | 
					-- the date and the SensorID.
 | 
				
			||||||
 | 
					INSERT INTO humidities (id, value, date, measured_value_id, creation_date, update_date)
 | 
				
			||||||
 | 
					SELECT
 | 
				
			||||||
 | 
						jv.humidity_id,
 | 
				
			||||||
 | 
						jv.humidity_value,
 | 
				
			||||||
 | 
						jv.humidity_date,
 | 
				
			||||||
 | 
						(SELECT mv.id FROM measured_values mv WHERE mv.creation_date = jv.humidity_date AND mv.sensor_id = jv.humidity_sensor_id) AS measured_value,
 | 
				
			||||||
 | 
					  jv.humidity_creation_date,
 | 
				
			||||||
 | 
					  jv.humidity_update_date
 | 
				
			||||||
 | 
					FROM joined_values jv
 | 
				
			||||||
 | 
					WHERE humidity_id IS NOT NULL;
 | 
				
			||||||
 | 
					
 | 
				
			||||||
 | 
					INSERT INTO pressures (id, value, date, measured_value_id, creation_date, update_date)
 | 
				
			||||||
 | 
					SELECT
 | 
				
			||||||
 | 
						jv.pressure_id,
 | 
				
			||||||
 | 
						jv.pressure_value,
 | 
				
			||||||
 | 
						jv.pressure_date,
 | 
				
			||||||
 | 
						(SELECT mv.id FROM measured_values mv WHERE mv.creation_date = jv.pressure_date AND mv.sensor_id = jv.pressure_sensor_id) AS measured_value,
 | 
				
			||||||
 | 
					  jv.pressure_creation_date,
 | 
				
			||||||
 | 
					  jv.pressure_update_date
 | 
				
			||||||
 | 
					FROM joined_values jv
 | 
				
			||||||
 | 
					WHERE pressure_id IS NOT NULL;
 | 
				
			||||||
 | 
					
 | 
				
			||||||
 | 
					INSERT INTO temperatures (id, value, date, measured_value_id, creation_date, update_date)
 | 
				
			||||||
 | 
					SELECT
 | 
				
			||||||
 | 
						jv.temperature_id,
 | 
				
			||||||
 | 
						jv.temperature_value,
 | 
				
			||||||
 | 
						jv.temperature_date,
 | 
				
			||||||
 | 
						(SELECT mv.id FROM measured_values mv WHERE mv.creation_date = jv.temperature_date AND mv.sensor_id = jv.temperature_sensor_id) AS measured_value,
 | 
				
			||||||
 | 
					  jv.temperature_creation_date,
 | 
				
			||||||
 | 
					  jv.temperature_update_date
 | 
				
			||||||
 | 
					FROM joined_values jv
 | 
				
			||||||
 | 
					WHERE temperature_id IS NOT NULL;
 | 
				
			||||||
 | 
					
 | 
				
			||||||
 | 
					-- The remaining views and tables, which were only necessary for the migration,
 | 
				
			||||||
 | 
					-- are now removed.
 | 
				
			||||||
 | 
					DROP VIEW humidities_pressures;
 | 
				
			||||||
 | 
					DROP VIEW joined_values;
 | 
				
			||||||
 | 
					DROP TABLE humidities_backup;
 | 
				
			||||||
 | 
					DROP TABLE pressures_backup;
 | 
				
			||||||
 | 
					DROP TABLE temperatures_backup;
 | 
				
			||||||
		Reference in New Issue
	
	Block a user