157 lines
5.7 KiB
SQL
157 lines
5.7 KiB
SQL
CREATE DATABASE IF NOT EXISTS Chickens;
|
|
|
|
USE Chickens;
|
|
|
|
CREATE TABLE IF NOT EXISTS Users (
|
|
name TEXT UNIQUE NOT NULL,
|
|
creation_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS Nodes (
|
|
hardware_id VARCHAR(255) UNIQUE NOT NULL,
|
|
friendly_name TEXT NOT NULL,
|
|
creation_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
author TEXT NOT NULL,
|
|
CONSTRAINT FOREIGN KEY (author) REFERENCES Users(name)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS Groups (
|
|
name VARCHAR(255) UNIQUE NOT NULL,
|
|
author TEXT NOT NULL,
|
|
creation_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
CONSTRAINT FOREIGN KEY (author) REFERENCES Users(name)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS Node2Group (
|
|
node VARCHAR(255) NOT NULL,
|
|
node_group VARCHAR(255) NOT NULL,
|
|
author TEXT NOT NULL,
|
|
creation_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
CONSTRAINT unique_pairing UNIQUE(node, node_group),
|
|
CONSTRAINT FOREIGN KEY (author) REFERENCES Users(name),
|
|
CONSTRAINT FOREIGN KEY (node) REFERENCES Nodes(hardware_id),
|
|
CONSTRAINT FOREIGN KEY (node_group) REFERENCES Groups(name)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS GroupType (
|
|
name VARCHAR(255) UNIQUE NOT NULL,
|
|
author TEXT NOT NULL,
|
|
creation_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
CONSTRAINT FOREIGN KEY (author) REFERENCES Users(name)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS GroupParent (
|
|
child VARCHAR(255) NOT NULL,
|
|
parent VARCHAR(255) NOT NULL,
|
|
author TEXT NOT NULL,
|
|
creation_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
CONSTRAINT unique_relation UNIQUE(child, parent),
|
|
CONSTRAINT FOREIGN KEY (author) REFERENCES Users(name),
|
|
CONSTRAINT FOREIGN KEY (child) REFERENCES Nodes(hardware_id),
|
|
CONSTRAINT FOREIGN KEY (parent) REFERENCES Nodes(hardware_id)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS Group2Type (
|
|
group_name VARCHAR(255) NOT NULL,
|
|
type TEXT NOT NULL,
|
|
author TEXT NOT NULL,
|
|
creation_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
CONSTRAINT unique_grouptype UNIQUE(group_name, type),
|
|
CONSTRAINT FOREIGN KEY (author) REFERENCES Users(name),
|
|
CONSTRAINT FOREIGN KEY (group_name) REFERENCES Groups(name),
|
|
CONSTRAINT FOREIGN KEY (type) REFERENCES GroupType(name)
|
|
);
|
|
|
|
--CREATE TABLE IF NOT EXISTS Measurement (
|
|
-- source_node VARCHAR(255) NOT NULL,
|
|
-- reporting_node VARCHAR(255) NOT NULL,
|
|
-- associated_group TEXT NOT NULL,
|
|
-- collection_time TIMESTAMP NOT NULL,
|
|
-- server_received_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
-- temperature_18_inch FLOAT NOT NULL,
|
|
-- temperature_36_inch FLOAT NOT NULL,
|
|
-- device_temperature FLOAT NOT NULL,
|
|
-- ambient_temperature FLOAT NOT NULL,
|
|
-- relative_humidity FLOAT NOT NULL,
|
|
-- barometric_pressure FLOAT NOT NULL,
|
|
-- accelerometer_x FLOAT NOT NULL,
|
|
-- accelerometer_y FLOAT NOT NULL,
|
|
-- accelerometer_z FLOAT NOT NULL,
|
|
-- battery_charge_percent FLOAT NOT NULL,
|
|
-- battery_voltage FLOAT NOT NULL,
|
|
-- remaining_battery_capacity FLOAT NOT NULL,
|
|
-- CONSTRAINT device_measurement UNIQUE(source_node, collection_time),
|
|
-- CONSTRAINT FOREIGN KEY (source_node) REFERENCES Nodes(hardware_id),
|
|
-- CONSTRAINT FOREIGN KEY (reporting_node) REFERENCES Nodes(hardware_id),
|
|
-- CONSTRAINT FOREIGN KEY (associated_group) REFERENCES Groups(name)
|
|
--);
|
|
|
|
CREATE TABLE IF NOT EXISTS Measurement (
|
|
source_node VARCHAR(255) NOT NULL,
|
|
reporting_node VARCHAR(255) NOT NULL,
|
|
associated_group VARCHAR(255) NOT NULL,
|
|
collection_time TIMESTAMP NOT NULL,
|
|
server_received_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
temperature_18_inch FLOAT NOT NULL,
|
|
temperature_36_inch FLOAT NOT NULL,
|
|
device_temperature FLOAT NOT NULL,
|
|
ambient_temperature FLOAT NOT NULL,
|
|
relative_humidity FLOAT NOT NULL,
|
|
barometric_pressure FLOAT NOT NULL,
|
|
accelerometer_x FLOAT NOT NULL,
|
|
accelerometer_y FLOAT NOT NULL,
|
|
accelerometer_z FLOAT NOT NULL,
|
|
battery_charge_percent FLOAT NOT NULL,
|
|
battery_voltage FLOAT NOT NULL,
|
|
remaining_battery_capacity FLOAT NOT NULL,
|
|
CONSTRAINT device_measurement UNIQUE(source_node, collection_time),
|
|
CONSTRAINT FOREIGN KEY (source_node) REFERENCES Nodes(hardware_id),
|
|
CONSTRAINT FOREIGN KEY (reporting_node) REFERENCES Nodes(hardware_id)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS NodeRssiRecord (
|
|
node VARCHAR(255) NOT NULL,
|
|
neighbor VARCHAR(255) NOT NULL,
|
|
rssi INT NOT NULL,
|
|
collection_time TIMESTAMP NOT NULL,
|
|
server_received_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
CONSTRAINT unique_thing UNIQUE(node, neighbor, collection_time),
|
|
CONSTRAINT FOREIGN KEY (node) REFERENCES Nodes(hardware_id),
|
|
CONSTRAINT FOREIGN KEY (neighbor) REFERENCES Nodes(hardware_id)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS NodeFileManifest (
|
|
node VARCHAR(255) NOT NULL,
|
|
collection_time TIMESTAMP NOT NULL,
|
|
server_received_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
program_id INT NOT NULL,
|
|
program_version INT NOT NULL,
|
|
CONSTRAINT unique_version UNIQUE(node, collection_time, program_id),
|
|
CONSTRAINT FOREIGN KEY (node) REFERENCES Nodes(hardware_id)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS NodeReportedStatus (
|
|
node VARCHAR(255) NOT NULL,
|
|
collection_time TIMESTAMP NOT NULL,
|
|
server_received_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
measurement_interval_minutes INT NOT NULL,
|
|
wake_window_length_minutes INT NOT NULL,
|
|
offset_from_midnight_minutes INT NOT NULL,
|
|
sleep_duration_minutes INT NOT NULL,
|
|
number_saved_measurements INT NOT NULL,
|
|
when_time_was_last_updated TIMESTAMP NOT NULL,
|
|
CONSTRAINT unique_status UNIQUE(node, collection_time),
|
|
CONSTRAINT FOREIGN KEY (node) REFERENCES Nodes(hardware_id)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS NodeConfiguration (
|
|
node VARCHAR(255) NOT NULL,
|
|
author TEXT NOT NULL,
|
|
creation_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
measurement_interval_minutes INT NOT NULL,
|
|
offset_from_midnight_minutes INT NOT NULL,
|
|
wake_window_length_minutes INT NOT NULL,
|
|
CONSTRAINT FOREIGN KEY (author) REFERENCES Users(name),
|
|
CONSTRAINT FOREIGN KEY (node) REFERENCES Nodes(hardware_id)
|
|
);
|