Skip to content
Snippets Groups Projects
Commit 599c57b6 authored by Stefano Di Frischia's avatar Stefano Di Frischia
Browse files

L2SS: update hdbpp schema and add views

parent bbb0163a
No related branches found
No related tags found
1 merge request!177Resolve L2SS-429 "Timescaledb container"
FROM timescale/timescaledb:latest-pg12
COPY resources/schema.sql docker-entrypoint-initdb.d/002_schema.sql
COPY resources/users.sql docker-entrypoint-initdb.d/003_users.sql
COPY resources/cluster.sql docker-entrypoint-initdb.d/004_cluster.sql
#COPY resources/01_admin.sql docker-entrypoint-initdb.d/002_admin.sql
COPY resources/02_hdb_schema.sql docker-entrypoint-initdb.d/003_hdb_schema.sql
COPY resources/03_hdb_roles.sql docker-entrypoint-initdb.d/004_hdb_roles.sql
COPY resources/04_hdb_ext_aggregates.sql docker-entrypoint-initdb.d/005_hdb_ext_aggregates.sql
#COPY resources/05_cleanup.sql docker-entrypoint-initdb.d/006_cleanup.sql
CREATE ROLE hdb_admin WITH LOGIN PASSWORD 'hdbpp';
ALTER USER hdb_admin CREATEDB;
ALTER USER hdb_admin CREATEROLE;
ALTER USER hdb_admin SUPERUSER;
DROP DATABASE IF EXISTS hdb;
-- -----------------------------------------------------------------------------
-- This file is part of the hdbpp-timescale-project
--
-- Copyright (C) : 2014-2019
-- European Synchrotron Radiation Facility
-- BP 220, Grenoble 38043, FRANCE
--
-- libhdb++timescale is free software: you can redistribute it and/or modify
-- it under the terms of the Lesser GNU General Public License as published by
-- the Free Software Foundation, either version 3 of the License, or
-- (at your option) any later version.
--
-- libhdb++timescale is distributed in the hope that it will be useful,
-- but WITHOUT ANY WARRANTY; without even the implied warranty of
-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the Lesser
-- GNU General Public License for more details.
--
-- You should have received a copy of the Lesser GNU General Public License
-- along with libhdb++timescale. If not, see <http://www.gnu.org/licenses/>.
-- -----------------------------------------------------------------------------
-- Create the hdb database and use it
CREATE DATABASE hdb;
......@@ -8,26 +27,40 @@ CREATE DATABASE hdb;
CREATE EXTENSION IF NOT EXISTS timescaledb CASCADE;
-------------------------------------------------------------------------------
DO $$ BEGIN
CREATE DOMAIN uchar AS numeric(3) -- ALT smallint
CHECK(VALUE >= 0 AND VALUE <= 255);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
DO $$ BEGIN
CREATE DOMAIN ushort AS numeric(5) -- ALT integer
CHECK(VALUE >= 0 AND VALUE <= 65535);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
DO $$ BEGIN
CREATE DOMAIN ulong AS numeric(10) -- ALT bigint
CHECK(VALUE >= 0 AND VALUE <= 4294967295);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
DO $$ BEGIN
CREATE DOMAIN ulong64 AS numeric(20)
CHECK(VALUE >= 0 AND VALUE <= 18446744073709551615);
EXCEPTION
WHEN duplicate_object THEN null;
END $$;
-------------------------------------------------------------------------------
DROP TABLE IF EXISTS att_conf_type;
-- Mappings for ths Tango Data Type (used in att_conf)
CREATE TABLE att_conf_type (
CREATE TABLE IF NOT EXISTS att_conf_type (
att_conf_type_id serial NOT NULL,
type text NOT NULL,
type_num smallint NOT NULL,
type text NOT NULL UNIQUE,
type_num smallint NOT NULL UNIQUE,
PRIMARY KEY (att_conf_type_id)
);
......@@ -37,15 +70,13 @@ INSERT INTO att_conf_type (type, type_num) VALUES
('DEV_BOOLEAN', 1),('DEV_SHORT', 2),('DEV_LONG', 3),('DEV_FLOAT', 4),
('DEV_DOUBLE', 5),('DEV_USHORT', 6),('DEV_ULONG', 7),('DEV_STRING', 8),
('DEV_STATE', 19),('DEV_UCHAR',22),('DEV_LONG64', 23),('DEV_ULONG64', 24),
('DEV_ENCODED', 28),('DEV_ENUM', 29);
DROP TABLE IF EXISTS att_conf_format;
('DEV_ENCODED', 28),('DEV_ENUM', 30);
-- Mappings for ths Tango Data Format Type (used in att_conf)
CREATE TABLE att_conf_format (
CREATE TABLE IF NOT EXISTS att_conf_format (
att_conf_format_id serial NOT NULL,
format text NOT NULL,
format_num smallint NOT NULL,
format text NOT NULL UNIQUE,
format_num smallint NOT NULL UNIQUE,
PRIMARY KEY (att_conf_format_id)
);
......@@ -54,13 +85,11 @@ COMMENT ON TABLE att_conf_format is 'Attribute format type';
INSERT INTO att_conf_format (format, format_num) VALUES
('SCALAR', 0),('SPECTRUM', 1),('IMAGE', 2);
DROP TABLE IF EXISTS att_conf_write;
-- Mappings for the Tango Data Write Type (used in att_conf)
CREATE TABLE att_conf_write (
CREATE TABLE IF NOT EXISTS att_conf_write (
att_conf_write_id serial NOT NULL,
write text NOT NULL,
write_num smallint NOT NULL,
write text NOT NULL UNIQUE,
write_num smallint NOT NULL UNIQUE,
PRIMARY KEY (att_conf_write_id)
);
......@@ -94,13 +123,9 @@ CREATE TABLE IF NOT EXISTS att_conf (
);
COMMENT ON TABLE att_conf is 'Attribute Configuration Table';
CREATE INDEX IF NOT EXISTS att_conf_att_conf_id_idx ON att_conf (att_conf_id);
CREATE INDEX IF NOT EXISTS att_conf_att_conf_type_id_idx ON att_conf (att_conf_type_id);
-------------------------------------------------------------------------------
DROP TABLE IF EXISTS att_history_event;
CREATE TABLE att_history_event (
CREATE TABLE IF NOT EXISTS att_history_event (
att_history_event_id serial NOT NULL,
event text NOT NULL,
PRIMARY KEY (att_history_event_id)
......@@ -120,7 +145,6 @@ CREATE TABLE IF NOT EXISTS att_history (
);
COMMENT ON TABLE att_history is 'Attribute Configuration Events History Table';
CREATE INDEX IF NOT EXISTS att_history_att_conf_id_inx ON att_history (att_conf_id);
-------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS att_parameter (
......@@ -136,9 +160,13 @@ CREATE TABLE IF NOT EXISTS att_parameter (
archive_period text NOT NULL DEFAULT '',
description text NOT NULL DEFAULT '',
details json,
enum_labels text[] NOT NULL DEFAULT ARRAY[]::text[],
FOREIGN KEY (att_conf_id) REFERENCES att_conf (att_conf_id)
);
-- ALTER statement if the table was already created
-- ALTER TABLE att_parameter ADD COLUMN enum_labels text[] NOT NULL DEFAULT ARRAY[]::text[];
COMMENT ON TABLE att_parameter IS 'Attribute configuration parameters';
CREATE INDEX IF NOT EXISTS att_parameter_recv_time_idx ON att_parameter (recv_time);
CREATE INDEX IF NOT EXISTS att_parameter_att_conf_id_idx ON att_parameter (att_conf_id);
......@@ -153,7 +181,6 @@ CREATE TABLE IF NOT EXISTS att_error_desc (
);
COMMENT ON TABLE att_error_desc IS 'Error Description Table';
CREATE INDEX IF NOT EXISTS att_error_desc_att_error_desc_id_idx ON att_error_desc (att_error_desc_id);
-------------------------------------------------------------------------------
CREATE TABLE IF NOT EXISTS att_scalar_devboolean (
......@@ -644,6 +671,22 @@ CREATE INDEX IF NOT EXISTS att_scalar_devenum_att_conf_id_idx ON att_scalar_deve
CREATE INDEX IF NOT EXISTS att_scalar_devenum_att_conf_id_data_time_idx ON att_scalar_devenum (att_conf_id,data_time DESC);
SELECT create_hypertable('att_scalar_devenum', 'data_time', chunk_time_interval => interval '28 day', create_default_indexes => FALSE);
-- Trigger to set the enum_labels
CREATE OR REPLACE FUNCTION set_enum_label() RETURNS TRIGGER AS $$
DECLARE
BEGIN
IF NEW.value_r IS NOT NULL THEN
NEW.value_r_label := (SELECT enum_labels[NEW.value_r + 1] FROM att_parameter WHERE att_conf_id=NEW.att_conf_id ORDER BY recv_time DESC LIMIT 1);
END IF;
IF NEW.value_w IS NOT NULL THEN
NEW.value_w_label := (SELECT enum_labels[NEW.value_w + 1] FROM att_parameter WHERE att_conf_id=NEW.att_conf_id ORDER BY recv_time DESC LIMIT 1);
END IF;
RETURN NEW;
END
$$ LANGUAGE plpgsql;
CREATE TRIGGER enum_label_trigger BEFORE INSERT ON att_scalar_devenum FOR EACH ROW EXECUTE PROCEDURE set_enum_label();
CREATE TABLE IF NOT EXISTS att_array_devenum (
att_conf_id integer NOT NULL,
data_time timestamp WITH TIME ZONE NOT NULL,
......@@ -663,3 +706,25 @@ COMMENT ON TABLE att_array_devenum IS 'Array Enum Values Table';
CREATE INDEX IF NOT EXISTS att_array_devenum_att_conf_id_idx ON att_array_devenum (att_conf_id);
CREATE INDEX IF NOT EXISTS att_array_devenum_att_conf_id_data_time_idx ON att_array_devenum (att_conf_id,data_time DESC);
SELECT create_hypertable('att_array_devenum', 'data_time', chunk_time_interval => interval '28 day', create_default_indexes => FALSE);
-- Trigger to set the enum_labels
CREATE OR REPLACE FUNCTION set_enum_label_array() RETURNS TRIGGER AS $$
DECLARE
BEGIN
IF NEW.value_r IS NOT NULL THEN
WITH enum_labels AS (
SELECT enum_labels FROM att_parameter WHERE att_conf_id=NEW.att_conf_id ORDER BY recv_time DESC limit 1
)
SELECT array_agg(res) FROM (SELECT enum_labels[UNNEST(NEW.value_r)+ 1] FROM enum_labels) as res INTO NEW.value_r_label;
END IF;
IF NEW.value_w IS NOT NULL THEN
WITH enum_labels AS (
SELECT enum_labels FROM att_parameter WHERE att_conf_id=NEW.att_conf_id ORDER BY recv_time DESC limit 1
)
SELECT array_agg(res) FROM (SELECT enum_labels[UNNEST(NEW.value_w)+ 1] FROM enum_labels) as res INTO NEW.value_w_label;
END IF;
RETURN NEW;
END
$$ LANGUAGE plpgsql;
CREATE TRIGGER enum_label_trigger BEFORE INSERT ON att_array_devenum FOR EACH ROW EXECUTE PROCEDURE set_enum_label_array();
-- Roles
-- -----------------------------------------------------------------------------
-- This file is part of the hdbpp-timescale-project
--
-- Copyright (C) : 2014-2019
-- European Synchrotron Radiation Facility
-- BP 220, Grenoble 38043, FRANCE
--
-- libhdb++timescale is free software: you can redistribute it and/or modify
-- it under the terms of the Lesser GNU General Public License as published by
-- the Free Software Foundation, either version 3 of the License, or
-- (at your option) any later version.
--
-- libhdb++timescale is distributed in the hope that it will be useful,
-- but WITHOUT ANY WARRANTY; without even the implied warranty of
-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the Lesser
-- GNU General Public License for more details.
--
-- You should have received a copy of the Lesser GNU General Public License
-- along with libhdb++timescale. If not, see <http://www.gnu.org/licenses/>.
-- -----------------------------------------------------------------------------
-- Setup roles to access the hdb database
CREATE ROLE readonly;
CREATE ROLE readwrite;
......@@ -18,13 +39,3 @@ ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT USAGE ON SEQUENCES TO readwrite;
GRANT ALL ON SCHEMA public TO readwrite;
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO readwrite;
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA public TO readwrite;
-- Users
CREATE ROLE hdb_cfg_man WITH LOGIN PASSWORD 'hdbpp';
GRANT readwrite TO hdb_cfg_man;
CREATE ROLE hdb_event_sub WITH LOGIN PASSWORD 'hdbpp';
GRANT readwrite TO hdb_event_sub;
CREATE ROLE hdb_java_reporter WITH LOGIN PASSWORD 'hdbpp';
GRANT readonly TO hdb_java_reporter;
This diff is collapsed.
ALTER USER hdb_admin NOSUPERUSER;
ALTER TABLE att_scalar_devboolean CLUSTER ON att_scalar_devboolean_att_conf_id_data_time_idx;
ALTER TABLE att_array_devboolean CLUSTER ON att_array_devboolean_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devuchar CLUSTER ON att_scalar_devuchar_att_conf_id_data_time_idx;
ALTER TABLE att_array_devuchar CLUSTER ON att_array_devuchar_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devshort CLUSTER ON att_scalar_devshort_att_conf_id_data_time_idx;
ALTER TABLE att_array_devshort CLUSTER ON att_array_devshort_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devushort CLUSTER ON att_scalar_devushort_att_conf_id_data_time_idx;
ALTER TABLE att_array_devushort CLUSTER ON att_array_devushort_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devlong CLUSTER ON att_scalar_devlong_att_conf_id_data_time_idx;
ALTER TABLE att_array_devlong CLUSTER ON att_array_devlong_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devulong CLUSTER ON att_scalar_devulong_att_conf_id_data_time_idx;
ALTER TABLE att_array_devulong CLUSTER ON att_array_devulong_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devlong64 CLUSTER ON att_scalar_devlong64_att_conf_id_data_time_idx;
ALTER TABLE att_array_devlong64 CLUSTER ON att_array_devlong64_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devulong64 CLUSTER ON att_scalar_devulong64_att_conf_id_data_time_idx;
ALTER TABLE att_array_devulong64 CLUSTER ON att_array_devulong64_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devfloat CLUSTER ON att_scalar_devfloat_att_conf_id_data_time_idx;
ALTER TABLE att_array_devfloat CLUSTER ON att_array_devfloat_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devdouble CLUSTER ON att_scalar_devdouble_att_conf_id_data_time_idx;
ALTER TABLE att_array_devdouble CLUSTER ON att_array_devdouble_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devstring CLUSTER ON att_scalar_devstring_att_conf_id_data_time_idx;
ALTER TABLE att_array_devstring CLUSTER ON att_array_devstring_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devstate CLUSTER ON att_scalar_devstate_att_conf_id_data_time_idx;
ALTER TABLE att_array_devstate CLUSTER ON att_array_devstate_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devencoded CLUSTER ON att_scalar_devencoded_att_conf_id_data_time_idx;
ALTER TABLE att_array_devencoded CLUSTER ON att_array_devencoded_att_conf_id_data_time_idx;
ALTER TABLE att_scalar_devenum CLUSTER ON att_scalar_devenum_att_conf_id_data_time_idx;
ALTER TABLE att_array_devenum CLUSTER ON att_array_devenum_att_conf_id_data_time_idx;
CLUSTER att_scalar_devboolean;
CLUSTER att_array_devboolean;
CLUSTER att_scalar_devuchar;
CLUSTER att_array_devuchar;
CLUSTER att_scalar_devshort;
CLUSTER att_array_devshort;
CLUSTER att_scalar_devushort;
CLUSTER att_array_devushort;
CLUSTER att_scalar_devlong;
CLUSTER att_array_devlong;
CLUSTER att_scalar_devulong;
CLUSTER att_array_devulong;
CLUSTER att_scalar_devlong64;
CLUSTER att_array_devlong64;
CLUSTER att_scalar_devulong64;
CLUSTER att_array_devulong64;
CLUSTER att_scalar_devfloat;
CLUSTER att_array_devfloat;
CLUSTER att_scalar_devdouble;
CLUSTER att_array_devdouble;
CLUSTER att_scalar_devstring;
CLUSTER att_array_devstring;
CLUSTER att_scalar_devstate;
CLUSTER att_array_devstate;
CLUSTER att_scalar_devencoded;
CLUSTER att_array_devencoded;
CLUSTER att_scalar_devenum;
CLUSTER att_array_devenum;
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Please register or to comment