cemmetering-preprocessor/schema/create-schema.sql

82 lines
4.0 KiB
SQL

create database cem_monitoring;
-- create extension timescaledb;
create table application_t (
id serial not null primary key,
app_id VARCHAR(32) NOT NULL UNIQUE,
label varchar(128) not null unique
);
create table variable_t (
id serial not null primary key,
app integer references application_t(id),
converter_id varchar(16) not null,
device_id varchar(16) not null,
variable_id varchar(16) not null,
label varchar(128) not null unique,
unit varchar(16),
quantity varchar(32),
unique (app, converter_id, device_id, variable_id)
);
create table measurement_t (
time timestamp without time zone not null,
variable integer references variable_t (id),
value float
);
select create_hypertable('measurement_t', 'time');
insert into application_t (app_id, label) values('ku226', 'Kupferdreher Str. 226, Essen');
insert into variable_t (app, converter_id, device_id, variable_id, label, unit, quantity)
values ((select id from application_t where app_id = 'ku226'), '1', 'bhkw', 'u', 'BHKW Spannung', 'V', 'voltage'),
((select id from application_t where app_id = 'ku226'), '1', 'bhkw', 'p', 'BHKW Leistung', 'kW', 'power'),
((select id from application_t where app_id = 'ku226'), '1', 'bhkw', 'import', 'BHKW Energie Export', 'Wh', 'energy'),
((select id from application_t where app_id = 'ku226'), '1', 'bhkw', 'export', 'BHKW Energie Import', 'Wh', 'energy'),
((select id from application_t where app_id = 'ku226'), '1', 'pv', 'u', 'PV Spannung', 'V', 'voltage'),
((select id from application_t where app_id = 'ku226'), '1', 'pv', 'p', 'PV Leistung', 'kW', 'power'),
((select id from application_t where app_id = 'ku226'), '1', 'pv', 'import', 'PV Energie Export', 'Wh', 'energy'),
((select id from application_t where app_id = 'ku226'), '1', 'pv', 'export', 'PV Energie Import', 'Wh', 'energy'),
((select id from application_t where app_id = 'ku226'), '3', 'mains', 'import', 'Netz Energie Import', 'Wh', 'energy'),
((select id from application_t where app_id = 'ku226'), '3', 'mains', 'p', 'Netz Leistung', 'W', 'power'),
((select id from application_t where app_id = 'ku226'), '1', 'w1', 'p', 'Wohnung 1 Leistung', 'kW', 'power'),
((select id from application_t where app_id = 'ku226'), '1', 'w1', 'import', 'Wohnung 1 Energie Import', 'Wh', 'energy'),
((select id from application_t where app_id = 'ku226'), '1', 'w2', 'p', 'Wohnung 2 Leistung', 'kW', 'power'),
((select id from application_t where app_id = 'ku226'), '1', 'w2', 'import', 'Wohnung 2 Energie Import', 'Wh', 'energy'),
((select id from application_t where app_id = 'ku226'), '1', 'w3', 'p', 'Wohnung 3 Leistung', 'kW', 'power'),
((select id from application_t where app_id = 'ku226'), '1', 'w3', 'import', 'Wohnung 3 Energie Import', 'Wh', 'energy'),
((select id from application_t where app_id = 'ku226'), '1', 'w4', 'p', 'Wohnung 4 Leistung', 'kW', 'power'),
((select id from application_t where app_id = 'ku226'), '1', 'w4', 'import', 'Wohnung 4 Energie Import', 'Wh', 'energy'),
((select id from application_t where app_id = 'ku226'), '1', 'w5', 'p', 'Wohnung 5 Leistung', 'kW', 'power'),
((select id from application_t where app_id = 'ku226'), '1', 'w5', 'import', 'Wohnung 5 Energie Import', 'Wh', 'energy')
;
-- create user preprocessor password 'geheim';
grant select on application_t to preprocessor;
grant select on variable_t to preprocessor;
grant insert on measurement_t to preprocessor;
grant select on measurement_t to grafana;
create view measurement_v as
select m.time as time,
m.value as value,
v.quantity as quantity,
v.unit as unit,
v.label as variable,
a.label as application
from measurement_t m,
application_t a,
variable_t v
where m.variable = v.id and
v.app = a.id;
grant select on measurement_v to grafana;