146 lines
5.3 KiB
MySQL
146 lines
5.3 KiB
MySQL
|
DROP TABLE IF EXISTS devices CASCADE;
|
||
|
DROP TABLE IF EXISTS sensors CASCADE;
|
||
|
DROP TABLE IF EXISTS humidities CASCADE;
|
||
|
DROP TABLE IF EXISTS pressures CASCADE;
|
||
|
DROP TABLE IF EXISTS temperatures CASCADE;
|
||
|
|
||
|
|
||
|
-- +----------------------------------------+
|
||
|
-- | TABLES |
|
||
|
-- +----------------------------------------+
|
||
|
CREATE TABLE IF NOT EXISTS devices(
|
||
|
device_id CHAR(36) CONSTRAINT pk_devices PRIMARY KEY,
|
||
|
device_name VARCHAR(32) NOT NULL,
|
||
|
device_location VARCHAR(32),
|
||
|
device_last_contact TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||
|
creation_date TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
|
||
|
);
|
||
|
|
||
|
CREATE TABLE IF NOT EXISTS sensors (
|
||
|
sensor_id CHAR(36) CONSTRAINT pk_sensors PRIMARY KEY,
|
||
|
sensor_name VARCHAR(32) NOT NULL,
|
||
|
sensor_location VARCHAR(32) NOT NULL,
|
||
|
wire_id VARCHAR(15),
|
||
|
i2c_bus VARCHAR(255),
|
||
|
i2c_address VARCHAR(12),
|
||
|
gpio_number VARCHAR(6),
|
||
|
sensor_model VARCHAR(16) NOT NULL,
|
||
|
sensor_enabled BOOLEAN DEFAULT TRUE NOT NULL,
|
||
|
sensor_last_contact TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||
|
device_id CHAR(36),
|
||
|
creation_date TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL
|
||
|
);
|
||
|
|
||
|
CREATE TABLE IF NOT EXISTS humidities (
|
||
|
humidity_id CHAR(36) CONSTRAINT pk_humidities PRIMARY KEY,
|
||
|
humidity_value NUMERIC(9,3) NOT NULL,
|
||
|
humidity_from_date TIMESTAMP WITH TIME ZONE NOT NULL,
|
||
|
humidity_till_date TIMESTAMP WITH TIME ZONE,
|
||
|
sensor_id CHAR(36),
|
||
|
creation_date TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||
|
update_date TIMESTAMP WITH TIME ZONE
|
||
|
);
|
||
|
|
||
|
CREATE TABLE IF NOT EXISTS pressures (
|
||
|
pressure_id CHAR(36) CONSTRAINT pk_pressures PRIMARY KEY,
|
||
|
pressure_value NUMERIC(10,3) NOT NULL,
|
||
|
pressure_from_date TIMESTAMP WITH TIME ZONE NOT NULL,
|
||
|
pressure_till_date TIMESTAMP WITH TIME ZONE,
|
||
|
sensor_id CHAR(36),
|
||
|
creation_date TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||
|
update_date TIMESTAMP WITH TIME ZONE
|
||
|
);
|
||
|
|
||
|
CREATE TABLE IF NOT EXISTS temperatures (
|
||
|
temperature_id CHAR(36) CONSTRAINT pk_temperatures PRIMARY KEY,
|
||
|
temperature_value NUMERIC(5,3) NOT NULL,
|
||
|
temperature_from_date TIMESTAMP WITH TIME ZONE NOT NULL,
|
||
|
temperature_till_date TIMESTAMP WITH TIME ZONE,
|
||
|
sensor_id CHAR(36),
|
||
|
creation_date TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||
|
update_date TIMESTAMP WITH TIME ZONE
|
||
|
);
|
||
|
|
||
|
-- +----------------------------------------+
|
||
|
-- | FOREIGN-KEYS |
|
||
|
-- +----------------------------------------+
|
||
|
ALTER TABLE sensors
|
||
|
ADD FOREIGN KEY (device_id)
|
||
|
REFERENCES devices(device_id)
|
||
|
ON DELETE CASCADE
|
||
|
ON UPDATE CASCADE;
|
||
|
|
||
|
ALTER TABLE humidities
|
||
|
ADD FOREIGN KEY (sensor_id)
|
||
|
REFERENCES sensors(sensor_id)
|
||
|
ON DELETE CASCADE
|
||
|
ON UPDATE CASCADE;
|
||
|
|
||
|
ALTER TABLE pressures
|
||
|
ADD FOREIGN KEY (sensor_id)
|
||
|
REFERENCES sensors(sensor_id)
|
||
|
ON DELETE CASCADE
|
||
|
ON UPDATE CASCADE;
|
||
|
|
||
|
ALTER TABLE temperatures
|
||
|
ADD FOREIGN KEY (sensor_id)
|
||
|
REFERENCES sensors(sensor_id)
|
||
|
ON DELETE CASCADE
|
||
|
ON UPDATE CASCADE;
|
||
|
|
||
|
-- +----------------------------------------+
|
||
|
-- | Trigger-Functions |
|
||
|
-- +----------------------------------------+
|
||
|
CREATE OR REPLACE FUNCTION device_last_contact()
|
||
|
RETURNS trigger AS
|
||
|
$BODY$
|
||
|
BEGIN
|
||
|
UPDATE devices
|
||
|
SET device_last_contact = CURRENT_TIMESTAMP
|
||
|
WHERE device_id = NEW.device_id;
|
||
|
RETURN NEW;
|
||
|
END;
|
||
|
$BODY$ LANGUAGE plpgsql;
|
||
|
|
||
|
CREATE OR REPLACE FUNCTION sensor_last_contact()
|
||
|
RETURNS trigger AS
|
||
|
$BODY$
|
||
|
BEGIN
|
||
|
UPDATE sensors
|
||
|
SET sensor_last_contact = CURRENT_TIMESTAMP,
|
||
|
sensor_enabled = true
|
||
|
WHERE sensor_id = NEW.sensor_id;
|
||
|
RETURN NEW;
|
||
|
END;
|
||
|
$BODY$ LANGUAGE plpgsql;
|
||
|
|
||
|
-- +----------------------------------------+
|
||
|
-- | Trigger |
|
||
|
-- +----------------------------------------+
|
||
|
DROP TRIGGER IF EXISTS ai_humidities ON humidities;
|
||
|
DROP TRIGGER IF EXISTS ai_pressure ON pressures;
|
||
|
DROP TRIGGER IF EXISTS ai_temperatures ON temperatures;
|
||
|
|
||
|
CREATE TRIGGER au_sensors
|
||
|
AFTER UPDATE
|
||
|
ON sensors
|
||
|
FOR EACH ROW
|
||
|
EXECUTE PROCEDURE device_last_contact();
|
||
|
|
||
|
CREATE TRIGGER ai_humidities
|
||
|
AFTER INSERT
|
||
|
ON humidities
|
||
|
FOR EACH ROW
|
||
|
EXECUTE PROCEDURE sensor_last_contact();
|
||
|
|
||
|
CREATE TRIGGER ai_pressures
|
||
|
AFTER INSERT
|
||
|
ON pressures
|
||
|
FOR EACH ROW
|
||
|
EXECUTE PROCEDURE sensor_last_contact();
|
||
|
|
||
|
CREATE TRIGGER ai_temperatures
|
||
|
AFTER INSERT
|
||
|
ON temperatures
|
||
|
FOR EACH ROW
|
||
|
EXECUTE PROCEDURE sensor_last_contact();
|