Compare commits
3 Commits
test2
...
feat/new-d
Author | SHA1 | Date | |
---|---|---|---|
cc677e0c22
|
|||
077988b503
|
|||
a62bf175cb
|
3
.gitignore
vendored
3
.gitignore
vendored
@ -1,7 +1,8 @@
|
|||||||
# absolute files
|
# absolute files
|
||||||
bin
|
|
||||||
.env
|
.env
|
||||||
|
|
||||||
|
flucky*
|
||||||
|
|
||||||
# directories
|
# directories
|
||||||
.vscode/
|
.vscode/
|
||||||
|
|
||||||
|
77
Makefile
77
Makefile
@ -7,42 +7,9 @@ PREFIX?=/usr/local
|
|||||||
|
|
||||||
# BINARIES
|
# BINARIES
|
||||||
# ==============================================================================
|
# ==============================================================================
|
||||||
EXECUTABLE_TARGETS:= \
|
all: ${EXECUTABLE}
|
||||||
bin/linux/amd64/${EXECUTABLE} \
|
|
||||||
bin/linux/arm/5/${EXECUTABLE} \
|
|
||||||
bin/linux/arm/7/${EXECUTABLE} \
|
|
||||||
bin/tmp/${EXECUTABLE}
|
|
||||||
|
|
||||||
${EXECUTABLE}: bin/tmp/${EXECUTABLE}
|
${EXECUTABLE}:
|
||||||
|
|
||||||
bin/linux/amd64/${EXECUTABLE}:
|
|
||||||
CGO_ENABLED=1 \
|
|
||||||
GOOS=linux \
|
|
||||||
GOARCH=amd64 \
|
|
||||||
GOPROXY=$(shell go env GOPROXY) \
|
|
||||||
GOPRIVATE=$(shell go env GOPRIVATE) \
|
|
||||||
go build -ldflags "-X main.version=${VERSION:v%=%}" -o ${@}
|
|
||||||
|
|
||||||
bin/linux/arm/5/${EXECUTABLE}:
|
|
||||||
CGO_ENABLED=1 \
|
|
||||||
GOOS=linux \
|
|
||||||
GOARCH=arm \
|
|
||||||
GOARM=5 \
|
|
||||||
GOPROXY=$(shell go env GOPROXY) \
|
|
||||||
GOPRIVATE=$(shell go env GOPRIVATE) \
|
|
||||||
go build -ldflags "-X main.version=${VERSION:v%=%}" -o ${@}
|
|
||||||
|
|
||||||
bin/linux/arm/7/${EXECUTABLE}:
|
|
||||||
CC=arm-linux-gnueabihf-gcc \
|
|
||||||
CGO_ENABLED=1 \
|
|
||||||
GOOS=linux \
|
|
||||||
GOARCH=arm \
|
|
||||||
GOARM=7 \
|
|
||||||
GOPROXY=$(shell go env GOPROXY) \
|
|
||||||
GOPRIVATE=$(shell go env GOPRIVATE) \
|
|
||||||
go build -ldflags "-X main.version=${VERSION:v%=%}" -o ${@}
|
|
||||||
|
|
||||||
bin/tmp/${EXECUTABLE}:
|
|
||||||
CGO_ENABLED=1 \
|
CGO_ENABLED=1 \
|
||||||
GOPROXY=$(shell go env GOPROXY) \
|
GOPROXY=$(shell go env GOPROXY) \
|
||||||
GOPRIVATE=$(shell go env GOPRIVATE) \
|
GOPRIVATE=$(shell go env GOPRIVATE) \
|
||||||
@ -50,48 +17,48 @@ bin/tmp/${EXECUTABLE}:
|
|||||||
|
|
||||||
# COMPLETIONS
|
# COMPLETIONS
|
||||||
# ==============================================================================
|
# ==============================================================================
|
||||||
bin/tmp/${EXECUTABLE}.sh: bin/tmp/${EXECUTABLE}
|
${EXECUTABLE}.sh: ${EXECUTABLE}
|
||||||
bin/tmp/${EXECUTABLE} completion bash > ${@}
|
${EXECUTABLE} completion bash > ${@}
|
||||||
|
|
||||||
bin/tmp/${EXECUTABLE}.fish: bin/tmp/${EXECUTABLE}
|
${EXECUTABLE}.fish: ${EXECUTABLE}
|
||||||
bin/tmp/${EXECUTABLE} completion fish > ${@}
|
${EXECUTABLE} completion fish > ${@}
|
||||||
|
|
||||||
bin/tmp/${EXECUTABLE}.zsh: bin/tmp/${EXECUTABLE}
|
${EXECUTABLE}.zsh: ${EXECUTABLE}
|
||||||
bin/tmp/${EXECUTABLE} completion zsh > ${@}
|
${EXECUTABLE} completion zsh > ${@}
|
||||||
|
|
||||||
# UN/INSTALL
|
# UN/INSTALL
|
||||||
# ==============================================================================
|
# ==============================================================================
|
||||||
PHONY+=install
|
PHONY+=install
|
||||||
install: bin/tmp/${EXECUTABLE} bin/tmp/${EXECUTABLE}.sh bin/tmp/${EXECUTABLE}.fish bin/tmp/${EXECUTABLE}.zsh
|
install: ${EXECUTABLE} ${EXECUTABLE}.sh ${EXECUTABLE}.fish ${EXECUTABLE}.zsh
|
||||||
install --directory ${DESTDIR}${PREFIX}/bin
|
install --directory ${DESTDIR}${PREFIX}/bin
|
||||||
install --mode 755 bin/tmp/${EXECUTABLE} ${DESTDIR}${PREFIX}/bin/${EXECUTABLE}
|
install --mode 755 ${EXECUTABLE} ${DESTDIR}${PREFIX}/bin/${EXECUTABLE}
|
||||||
|
|
||||||
install --directory ${DESTDIR}/etc/bash_completion.d
|
|
||||||
install --mode 755 bin/tmp/${EXECUTABLE}.sh ${DESTDIR}/etc/bash_completion.d/${EXECUTABLE}.sh
|
|
||||||
|
|
||||||
install --directory ${DESTDIR}/usr/share/fish/vendor_completions.d
|
|
||||||
install --mode 644 bin/tmp/${EXECUTABLE}.fish ${DESTDIR}/usr/share/fish/vendor_completions.d/${EXECUTABLE}.fish
|
|
||||||
|
|
||||||
install --directory ${DESTDIR}/usr/lib/systemd/system
|
install --directory ${DESTDIR}/usr/lib/systemd/system
|
||||||
install --mode 644 systemd/${EXECUTABLE}.service ${DESTDIR}/usr/lib/systemd/system/${EXECUTABLE}.service
|
install --mode 644 systemd/${EXECUTABLE}.service ${DESTDIR}/usr/lib/systemd/system/${EXECUTABLE}.service
|
||||||
|
|
||||||
install --directory ${DESTDIR}/usr/share/licenses/${EXECUTABLE}
|
install --directory ${DESTDIR}${PREFIX}/share/bash-completion/completions/
|
||||||
install --mode 644 LICENSE ${DESTDIR}/usr/share/licenses/${EXECUTABLE}/LICENSE
|
install --mode 644 ${EXECUTABLE}.sh ${DESTDIR}${PREFIX}/share/bash-completion/completions/${EXECUTABLE}.sh
|
||||||
|
|
||||||
|
install --directory ${DESTDIR}${PREFIX}/fish/vendor_completions.d
|
||||||
|
install --mode 644 ${EXECUTABLE}.fish ${DESTDIR}${PREFIX}/fish/vendor_completions.d/${EXECUTABLE}.fish
|
||||||
|
|
||||||
|
install --directory ${DESTDIR}${PREFIX}/licenses/${EXECUTABLE}
|
||||||
|
install --mode 644 LICENSE ${DESTDIR}${PREFIX}/licenses/${EXECUTABLE}/LICENSE
|
||||||
|
|
||||||
PHONY+=uninstall
|
PHONY+=uninstall
|
||||||
uninstall:
|
uninstall:
|
||||||
-rm --recursive --force \
|
-rm --recursive --force \
|
||||||
${DESTDIR}${PREFIX}/bin/${EXECUTABLE} \
|
${DESTDIR}${PREFIX}/bin/${EXECUTABLE} \
|
||||||
${DESTDIR}/etc/bash_completion.d/${EXECUTABLE}.sh \
|
|
||||||
${DESTDIR}/usr/lib/systemd/system/${EXECUTABLE}.service \
|
${DESTDIR}/usr/lib/systemd/system/${EXECUTABLE}.service \
|
||||||
${DESTDIR}/usr/share/fish/vendor_completions.d/${EXECUTABLE}.fish \
|
${DESTDIR}${PREFIX}/share/bash-completion/completions/${EXECUTABLE}.sh \
|
||||||
${DESTDIR}/usr/share/licenses/${EXECUTABLE}/LICENSE
|
${DESTDIR}${PREFIX}/fish/vendor_completions.d/${EXECUTABLE}.fish \
|
||||||
|
${DESTDIR}${PREFIX}/licenses/${EXECUTABLE}/LICENSE
|
||||||
|
|
||||||
# CLEAN
|
# CLEAN
|
||||||
# ==============================================================================
|
# ==============================================================================
|
||||||
PHONY+=clean
|
PHONY+=clean
|
||||||
clean:
|
clean:
|
||||||
rm --force --recursive bin/ || true
|
rm --force --recursive ${EXECUTABLE}* || true
|
||||||
|
|
||||||
# TEST
|
# TEST
|
||||||
# ==============================================================================
|
# ==============================================================================
|
||||||
|
95
pkg/repository/postgres/ddl/8_table_measured_values.down.sql
Normal file
95
pkg/repository/postgres/ddl/8_table_measured_values.down.sql
Normal 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;
|
130
pkg/repository/postgres/ddl/8_table_measured_values.up.sql
Normal file
130
pkg/repository/postgres/ddl/8_table_measured_values.up.sql
Normal 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;
|
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