Skip to content
Snippets Groups Projects
Commit de0dc5ee authored by Joost Hemmen's avatar Joost Hemmen :basketball:
Browse files

add flyway migrations for sms table, frontend, mqtt_auth, s3map, postgis

parent 8c3b6a4f
No related branches found
No related tags found
1 merge request!212Replace database scripts with flyway migrations
Pipeline #449556 failed
Showing
with 267 additions and 303 deletions
#!/bin/bash
set -e
psql -v ON_ERROR_STOP=1 --username "$POSTGRES_USER" --dbname "$POSTGRES_DB" <<-EOSQL
CREATE EXTENSION postgis SCHEMA public;
EOSQL
BEGIN;
-- public.contact definition
CREATE TABLE public.measured_quantity (
id serial4 NOT NULL PRIMARY KEY,
term varchar(255) NOT NULL,
provenance_uri varchar(255),
definition text
);
COMMIT;
\ No newline at end of file
BEGIN;
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_cv_measured_quantity (
id int4 not null,
term varchar(255) not null,
provenance_uri varchar(255),
definition text
)
SERVER sms_cv_db OPTIONS (schema_name 'public', table_name 'measured_quantity');
COMMIT;
\ No newline at end of file
#!/bin/bash
set -e
if [ "$CV_ACCESS_TYPE" == "db" ]; then
psql -v ON_ERROR_STOP=1 -U "$POSTGRES_USER" -f /sql/sms_cv/sms_cv_ddl.sql
echo 'setting up sms_cv foreign data wrapper and remote tables'
psql -v ON_ERROR_STOP=1 -U "$POSTGRES_USER" <<-EOSQL
CREATE extension if not exists postgres_fdw;
CREATE SERVER sms_cv_db
FOREIGN DATA WRAPPER postgres_fdw
OPTIONS (host '$CV_DB_HOST', dbname '$CV_DB_DB', port '$CV_DB_PORT');
CREATE USER MAPPING FOR $POSTGRES_USER
SERVER sms_cv_db
OPTIONS (user '$CV_DB_USER', password '$CV_DB_PASSWORD');
EOSQL
psql -v ON_ERROR_STOP=1 -U "$POSTGRES_USER" -f /sql/sms_cv/sms_cv_foreign_tables.sql
echo 'sms_cv remote tables created'
fi
\ No newline at end of file
BEGIN;
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_contact (
id integer not null,
organization varchar(1024),
given_name varchar(256),
family_name varchar(256),
email varchar(256),
orcid varchar(32)
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'contact');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_configuration (
id integer not null,
label varchar(256),
description text,
persistent_identifier varchar(256),
status varchar(256),
project varchar(256),
is_internal boolean,
is_public boolean
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'configuration');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_configuration_contact_role (
configuration_id integer not null,
contact_id integer not null
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'configuration_contact_role');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_configuration_dynamic_location_begin_action (
id integer not null,
label varchar(256),
configuration_id integer not null,
begin_date timestamp with time zone not null,
x_property_id integer,
y_property_id integer,
z_property_id integer,
epsg_code varchar(256),
elevation_datum_name varchar(256),
begin_description text,
end_date timestamp with time zone
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'configuration_dynamic_location_begin_action');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_configuration_static_location_begin_action (
id integer not null,
x double precision,
y double precision,
z double precision,
label varchar(256),
configuration_id integer not null,
begin_date timestamp with time zone,
begin_description text,
end_date timestamp with time zone
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'configuration_static_location_begin_action');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_device (
id integer not null,
short_name varchar(256),
description text,
device_type_name varchar(256),
manufacturer_name varchar(256),
model varchar(256),
serial_number varchar(256),
persistent_identifier varchar(256),
is_internal boolean,
is_public boolean
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'device');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_device_mount_action (
id integer not null,
configuration_id integer not null,
device_id integer not null,
offset_x double precision,
offset_y double precision,
offset_z double precision,
begin_date timestamp with time zone not null,
end_date timestamp with time zone
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'device_mount_action');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_device_property (
id integer not null,
device_id integer not null,
property_name varchar(256) not null,
property_uri varchar(256),
label varchar(256),
unit_name varchar(256),
unit_uri varchar(256),
resolution double precision,
resolution_unit_name varchar(256),
accuracy double precision,
measuring_range_min double precision,
measuring_range_max double precision,
aggregation_type_name varchar(256)
)
SERVER sms_db OPTIONS(schema_name 'public', table_name 'device_property');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_datastream_link (
id integer not null,
thing_id uuid,
device_property_id integer not null,
device_mount_action_id integer not null,
datasource_id varchar(256),
datastream_id integer not null,
begin_date timestamp with time zone,
end_date timestamp with time zone,
aggregation_period double precision,
license_uri varchar(256),
license_name varchar(256)
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'datastream_link');
COMMIT;
#!/bin/bash
set -e
if [ "$SMS_ACCESS_TYPE" == "db" ]; then
psql -v ON_ERROR_STOP=1 -U "$POSTGRES_USER" -f /sql/sms/sms_ddl.sql
echo 'setting up sms foreign data wrapper and remote tables'
psql -v ON_ERROR_STOP=1 -U "$POSTGRES_USER" <<-EOSQL
CREATE extension if not exists postgres_fdw;
CREATE SERVER sms_db
FOREIGN DATA WRAPPER postgres_fdw
OPTIONS (host '$SMS_DB_HOST', dbname '$SMS_DB_DB', port '$SMS_DB_PORT');
CREATE USER MAPPING FOR $POSTGRES_USER
SERVER sms_db
OPTIONS (user '$SMS_DB_USER', password '$SMS_DB_PASSWORD');
EOSQL
psql -v ON_ERROR_STOP=1 -U "$POSTGRES_USER" -f /sql/sms/sms_foreign_tables.sql
echo 'sms remote tables created'
fi
\ No newline at end of file
#!/bin/bash
set -e
psql -v ON_ERROR_STOP=1 --username "$POSTGRES_USER" --dbname "$POSTGRES_DB" <<-EOSQL
CREATE ROLE $S3MAP_POSTGRES_USER WITH LOGIN PASSWORD '$S3MAP_POSTGRES_PASS';
GRANT $S3MAP_POSTGRES_USER TO postgres;
CREATE SCHEMA IF NOT EXISTS $S3MAP_POSTGRES_USER AUTHORIZATION $S3MAP_POSTGRES_USER;
SET search_path TO $S3MAP_POSTGRES_USER;
GRANT CONNECT ON DATABASE postgres TO $S3MAP_POSTGRES_USER;
ALTER ROLE $S3MAP_POSTGRES_USER SET search_path to $S3MAP_POSTGRES_USER;
GRANT USAGE ON SCHEMA $S3MAP_POSTGRES_USER TO $S3MAP_POSTGRES_USER;
GRANT ALL ON SCHEMA $S3MAP_POSTGRES_USER TO $S3MAP_POSTGRES_USER;
CREATE TABLE "mapping" (
"id" bigserial NOT NULL PRIMARY KEY,
"bucket_name" varchar(256) NOT NULL UNIQUE,
"thing_uuid" uuid NOT NULL,
"thing_name" varchar(256) NOT NULL,
"db_url" varchar(256) NOT NULL,
"filename_pattern" varchar(256) NULL,
"parser" varchar(256) NULL
);
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA $S3MAP_POSTGRES_USER TO $S3MAP_POSTGRES_USER;
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA $S3MAP_POSTGRES_USER TO $S3MAP_POSTGRES_USER;
EOSQL
......@@ -65,35 +65,7 @@ services:
POSTGRES_USER: "${POSTGRES_USER}"
POSTGRES_PASSWORD: "${POSTGRES_PASSWORD}"
PGDATA: "/var/lib/postgresql/data/pgdata"
MQTT_AUTH_POSTGRES_USER: "${MQTT_AUTH_POSTGRES_USER}"
MQTT_AUTH_POSTGRES_PASS: "${MQTT_AUTH_POSTGRES_PASS}"
S3MAP_POSTGRES_USER: "${S3MAP_POSTGRES_USER}"
S3MAP_POSTGRES_PASS: "${S3MAP_POSTGRES_PASS}"
FRONTEND_POSTGRES_USER: "${FRONTEND_POSTGRES_USER}"
FRONTEND_POSTGRES_PASS: "${FRONTEND_POSTGRES_PASS}"
SMS_DB_USER: "${SMS_DB_USER}"
SMS_DB_PASSWORD: "${SMS_DB_PASSWORD}"
SMS_DB_PORT: "${SMS_DB_PORT}"
SMS_DB_DB: "${SMS_DB_DB}"
SMS_DB_HOST: "${SMS_DB_HOST}"
SMS_ACCESS_TYPE: "${SMS_ACCESS_TYPE}"
CV_DB_USER: "${CV_DB_USER}"
CV_DB_PASSWORD: "${CV_DB_PASSWORD}"
CV_DB_PORT: "${CV_DB_PORT}"
CV_DB_DB: "${CV_DB_DB}"
CV_DB_HOST: "${CV_DB_HOST}"
CV_ACCESS_TYPE: "${CV_ACCESS_TYPE}"
volumes:
- "./data/postgres/sms_db/sms_ddl.sql:/sql/sms/sms_ddl.sql"
- "./data/postgres/sms_db/sms_foreign_tables.sql:/sql/sms/sms_foreign_tables.sql"
- "./data/postgres/sms_db/sms_init_tables.sh:/docker-entrypoint-initdb.d/01_sms_init_tables.sh"
- "./data/postgres/sms_cv_db/sms_cv_ddl.sql:/sql/sms_cv/sms_cv_ddl.sql"
- "./data/postgres/sms_cv_db/sms_cv_foreign_tables.sql:/sql/sms_cv/sms_cv_foreign_tables.sql"
- "./data/postgres/sms_cv_db/sms_cv_init_tables.sh:/docker-entrypoint-initdb.d/02_sms_cv_init_tables.sh"
- "./data/postgres/postgis.sh:/docker-entrypoint-initdb.d/03_postgis.sh"
- "./mosquitto/mosquitto-go-auth.sh:/docker-entrypoint-initdb.d/mosquitto-go-auth.sh:ro"
- "./frontend/frontend-database.sh:/docker-entrypoint-initdb.d/frontend-database.sh:ro"
- "./dispatcher/s3_to_db.sh:/docker-entrypoint-initdb.d/s3_to_db.sh:ro"
- "./data/postgres/data:/var/lib/postgresql/data"
- "./data/postgres/postgres-force-ssl.sh:/docker-entrypoint-initdb.d/postgres-force-ssl.sh"
- "${POSTGRES_TLS_CERT_PATH}:/var/lib/postgresql/server.crt"
......@@ -390,6 +362,24 @@ services:
FLYWAY_BASELINE_VERSION: "${FLYWAY_BASELINE_VERSION}"
FLYWAY_PLACEHOLDERS_CONFIGDB_USER: "${CONFIGDB_USER}"
FLYWAY_PLACEHOLDERS_CONFIGDB_PASSWORD: "${CONFIGDB_PASSWORD}"
FLYWAY_PLACEHOLDERS_S3MAP_USER: "${S3MAP_POSTGRES_USER}"
FLYWAY_PLACEHOLDERS_S3MAP_PASSWORD: "${S3MAP_POSTGRES_PASS}"
FLYWAY_PLACEHOLDERS_MQTT_AUTH_USER: "${MQTT_AUTH_POSTGRES_USER}"
FLYWAY_PLACEHOLDERS_MQTT_AUTH_PASSWORD: "${MQTT_AUTH_POSTGRES_PASS}"
FLYWAY_PLACEHOLDERS_FRONTEND_USER: "${FRONTEND_POSTGRES_USER}"
FLYWAY_PLACEHOLDERS_FRONTEND_PASSWORD: "${FRONTEND_POSTGRES_PASS}"
FLYWAY_PLACEHOLDERS_SMS_ACCESS_TYPE: "${SMS_ACCESS_TYPE}"
FLYWAY_PLACEHOLDERS_SMS_DB_USER: "${SMS_DB_USER}"
FLYWAY_PLACEHOLDERS_SMS_DB_PASSWORD: "${SMS_DB_PASSWORD}"
FLYWAY_PLACEHOLDERS_SMS_DB_PORT: "${SMS_DB_PORT}"
FLYWAY_PLACEHOLDERS_SMS_DB_DB: "${SMS_DB_DB}"
FLYWAY_PLACEHOLDERS_SMS_DB_HOST: "${SMS_DB_HOST}"
FLYWAY_PLACEHOLDERS_CV_ACCESS_TYPE: "${CV_ACCESS_TYPE}"
FLYWAY_PLACEHOLDERS_CV_DB_USER: "${CV_DB_USER}"
FLYWAY_PLACEHOLDERS_CV_DB_PASSWORD: "${CV_DB_PASSWORD}"
FLYWAY_PLACEHOLDERS_CV_DB_PORT: "${CV_DB_PORT}"
FLYWAY_PLACEHOLDERS_CV_DB_DB: "${CV_DB_DB}"
FLYWAY_PLACEHOLDERS_CV_DB_HOST: "${CV_DB_HOST}"
depends_on:
database:
condition: service_healthy
......
flyway.baselineOnMigrate=true
flyway.locations=filesystem:/flyway/sql
flyway.defaultSchema=public
flyway.schemas=public,config_db
flyway.schemas=public
flyway.jdbcProperties.sslrootcert=/etc/ssl/certs/ca-certificates.crt
\ No newline at end of file
CREATE ROLE ${frontend_user} WITH LOGIN PASSWORD '${frontend_password}';
GRANT ${frontend_user} TO ${flyway:user};
CREATE SCHEMA IF NOT EXISTS ${frontend_user} AUTHORIZATION ${frontend_user};
SET search_path TO ${frontend_user};
GRANT CONNECT ON DATABASE ${flyway:database} TO ${frontend_user};
ALTER ROLE ${frontend_user} SET search_path to ${frontend_user};
GRANT USAGE ON SCHEMA ${frontend_user} TO ${frontend_user};
GRANT ALL ON SCHEMA ${frontend_user} TO ${frontend_user};
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA ${frontend_user} TO ${frontend_user};
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA ${frontend_user} TO ${frontend_user};
\ No newline at end of file
CREATE EXTENSION IF NOT EXISTS postgis SCHEMA public;
\ No newline at end of file
CREATE ROLE ${mqtt_auth_user} WITH LOGIN PASSWORD '${mqtt_auth_password}';
GRANT ${mqtt_auth_user} TO ${flyway:user};
CREATE SCHEMA IF NOT EXISTS ${mqtt_auth_user} AUTHORIZATION ${mqtt_auth_user};
SET search_path TO ${mqtt_auth_user};
GRANT CONNECT ON DATABASE ${flyway:database} TO ${mqtt_auth_user};
ALTER ROLE ${mqtt_auth_user} SET search_path to ${mqtt_auth_user};
GRANT USAGE ON SCHEMA ${mqtt_auth_user} TO ${mqtt_auth_user};
GRANT ALL ON SCHEMA ${mqtt_auth_user} TO ${mqtt_auth_user};
CREATE TABLE "mqtt_user"
(
"id" bigserial NOT NULL PRIMARY KEY,
"project_uuid" uuid NOT NULL,
"thing_uuid" uuid NOT NULL UNIQUE,
"username" varchar(256) NOT NULL UNIQUE,
"password" varchar(256) NOT NULL,
"db_schema" varchar(256) NOT NULL,
"description" text NULL,
"properties" jsonb NULL,
constraint mqtt_user_project_thing_unique
unique (project_uuid, thing_uuid)
);
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA ${mqtt_auth_user} TO ${mqtt_auth_user};
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA ${mqtt_auth_user} TO ${mqtt_auth_user};
\ No newline at end of file
CREATE ROLE ${s3map_user} WITH LOGIN PASSWORD '${s3map_password}';
GRANT ${s3map_user} TO ${flyway:user};
CREATE SCHEMA IF NOT EXISTS ${s3map_user} AUTHORIZATION ${s3map_user};
SET search_path TO ${s3map_user};
GRANT CONNECT ON DATABASE ${flyway:database} TO ${s3map_user};
ALTER ROLE ${s3map_user} SET search_path to ${s3map_user};
GRANT USAGE ON SCHEMA ${s3map_user} TO ${s3map_user};
GRANT ALL ON SCHEMA ${s3map_user} TO ${s3map_user};
CREATE TABLE "mapping" (
"id" bigserial NOT NULL PRIMARY KEY,
"bucket_name" varchar(256) NOT NULL UNIQUE,
"thing_uuid" uuid NOT NULL,
"thing_name" varchar(256) NOT NULL,
"db_url" varchar(256) NOT NULL,
"filename_pattern" varchar(256) NULL,
"parser" varchar(256) NULL
);
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA ${s3map_user} TO ${s3map_user};
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA ${s3map_user} TO ${s3map_user};
\ No newline at end of file
-- Purpose: Create a foreign server pointing to the SMS database.
DO $$
BEGIN
IF '${sms_access_type}' = 'db' THEN
RAISE NOTICE 'Creating foreign server sms_db';
CREATE extension IF NOT EXISTS postgres_fdw;
CREATE SERVER sms_db
FOREIGN DATA WRAPPER postgres_fdw
OPTIONS (host '${sms_db_host}', dbname '${sms_db_db}', port '${sms_db_port}');
CREATE USER MAPPING FOR ${flyway:user}
SERVER sms_db
OPTIONS (user '${sms_db_user}', password '${sms_db_password}');
ELSE
RAISE NOTICE 'Skipping creation of foreign server sms_db because sms_access_type is not db';
END IF;
END $$;
-- Purpose: Create local tables to mock the sms database
BEGIN;
create table public.contact
......@@ -16,7 +34,6 @@ create table public.contact
orcid varchar(32) unique
);
create table public.configuration
(
created_at timestamp with time zone,
......@@ -40,7 +57,6 @@ create table public.configuration
unique
);
create table public.configuration_contact_role
(
role_name varchar not null,
......@@ -50,7 +66,6 @@ create table public.configuration_contact_role
configuration_id integer not null
);
create table public.configuration_dynamic_location_begin_action
(
created_at timestamp with time zone,
......@@ -74,7 +89,6 @@ create table public.configuration_dynamic_location_begin_action
label varchar(256)
);
create table public.configuration_static_location_begin_action
(
created_at timestamp with time zone,
......@@ -98,7 +112,6 @@ create table public.configuration_static_location_begin_action
label varchar(256)
);
create table public.device
(
created_at timestamp with time zone,
......@@ -131,7 +144,6 @@ create table public.device
schema_version varchar(256)
);
create table public.device_mount_action
(
created_at timestamp with time zone,
......@@ -153,7 +165,6 @@ create table public.device_mount_action
end_contact_id integer
);
create table public.device_property
(
id serial primary key,
......@@ -182,7 +193,6 @@ create table public.device_property
aggregation_type_name varchar(256)
);
create table public.datastream_link
(
created_at timestamp with time zone,
......@@ -206,30 +216,137 @@ create table public.datastream_link
tsm_endpoint_id integer
);
COMMIT;
-- public.contact foreign keys
--ALTER TABLE public.contact ADD CONSTRAINT "fk_Contact_created_by_id" FOREIGN KEY (created_by_id) REFERENCES public."user"(id);
--ALTER TABLE public.contact ADD CONSTRAINT "fk_Contact_updated_by_id" FOREIGN KEY (updated_by_id) REFERENCES public."user"(id);
-- Purpose: Create foreign tables for the SMS database.
DO $$
BEGIN
IF '${sms_access_type}' = 'db' THEN
RAISE NOTICE 'Creating foreign tables for sms';
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_contact (
id integer not null,
organization varchar(1024),
given_name varchar(256),
family_name varchar(256),
email varchar(256),
orcid varchar(32)
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'contact');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_configuration (
id integer not null,
label varchar(256),
description text,
persistent_identifier varchar(256),
status varchar(256),
project varchar(256),
is_internal boolean,
is_public boolean
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'configuration');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_configuration_contact_role (
configuration_id integer not null,
contact_id integer not null
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'configuration_contact_role');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_configuration_dynamic_location_begin_action (
id integer not null,
label varchar(256),
configuration_id integer not null,
begin_date timestamp with time zone not null,
x_property_id integer,
y_property_id integer,
z_property_id integer,
epsg_code varchar(256),
elevation_datum_name varchar(256),
begin_description text,
end_date timestamp with time zone
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'configuration_dynamic_location_begin_action');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_configuration_static_location_begin_action (
id integer not null,
x double precision,
y double precision,
z double precision,
label varchar(256),
configuration_id integer not null,
begin_date timestamp with time zone,
begin_description text,
end_date timestamp with time zone
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'configuration_static_location_begin_action');
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_device (
id integer not null,
short_name varchar(256),
description text,
device_type_name varchar(256),
manufacturer_name varchar(256),
model varchar(256),
serial_number varchar(256),
persistent_identifier varchar(256),
is_internal boolean,
is_public boolean
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'device');
-- public."user" foreign keys
--ALTER TABLE public."user" ADD CONSTRAINT user_contact_id_fkey FOREIGN KEY (contact_id) REFERENCES public.contact(id);
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_device_mount_action (
id integer not null,
configuration_id integer not null,
device_id integer not null,
offset_x double precision,
offset_y double precision,
offset_z double precision,
begin_date timestamp with time zone not null,
end_date timestamp with time zone
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'device_mount_action');
-- public.configuration foreign keys
--ALTER TABLE public.configuration ADD CONSTRAINT "fk_Configuration_created_by_id" REFERENCES public."user";
--ALTER TABLE public.configuration ADD CONSTRAINT "fk_Configuration_updated_by_id" REFERENCES public."user";
-- public.configuration_static_location_begin_action
--ALTER TABLE public.configuration_static_location_begin_action ADD CONSTRAINT configuration_static_location_begin_action_configuration_id_fkey REFERENCES public.configuration;
--ALTER TABLE public.configuration_static_location_begin_action ADD CONSTRAINT configuration_static_location_begin_action_contact_id_fkey REFERENCES public.contact;
--ALTER TABLE public.configuration_static_location_begin_action CONSTRAINT "fk_ConfigurationStaticLocationBeginAction_created_by_id" REFERENCES public."user";
--ALTER TABLE public.configuration_static_location_begin_action CONSTRAINT "fk_ConfigurationStaticLocationBeginAction_updated_by_id" REFERENCES public."user";
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_device_property (
id integer not null,
device_id integer not null,
property_name varchar(256) not null,
property_uri varchar(256),
label varchar(256),
unit_name varchar(256),
unit_uri varchar(256),
resolution double precision,
resolution_unit_name varchar(256),
accuracy double precision,
measuring_range_min double precision,
measuring_range_max double precision,
aggregation_type_name varchar(256)
)
SERVER sms_db OPTIONS(schema_name 'public', table_name 'device_property');
-- public.configuration_dynamic_location_begin_action
--ALTER TABLE public.configuration_dynamic_location_begin_action ADD CONSTRAINT configuration_dynamic_location_begin_action_configuration_id_fkey REFERENCES public.configuration;
--ALTER TABLE public.configuration_dynamic_location_begin_action ADD CONSTRAINT configuration_dynamic_location_begin_action_contact_id_fkey REFERENCES public.contact;
--ALTER TABLE public.configuration_dynamic_location_begin_action CONSTRAINT "fk_ConfigurationDynamicLocationBeginAction_created_by_id" REFERENCES public."user";
--ALTER TABLE public.configuration_dymamic_location_begin_action CONSTRAINT "fk_ConfigurationDynamicLocationBeginAction_updated_by_id" REFERENCES public."user";
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_datastream_link (
id integer not null,
thing_id uuid,
device_property_id integer not null,
device_mount_action_id integer not null,
datasource_id varchar(256),
datastream_id integer not null,
begin_date timestamp with time zone,
end_date timestamp with time zone,
aggregation_period double precision,
license_uri varchar(256),
license_name varchar(256)
)
SERVER sms_db OPTIONS (schema_name 'public', table_name 'datastream_link');
ELSE
RAISE NOTICE 'Skipping creation of foreign tables for sms because sms_access_type is not db';
END IF;
END $$;
-- Purpose: Create a foreign server pointing to the SMS-CV database.
DO $$
BEGIN
IF '${cv_access_type}' = 'db' THEN
RAISE NOTICE 'Creating foreign server sms_cv_db';
CREATE extension IF NOT EXISTS postgres_fdw;
CREATE SERVER sms_cv_db
FOREIGN DATA WRAPPER postgres_fdw
OPTIONS (host '${cv_db_host}', dbname '${cv_db_db}', port '${cv_db_port}');
CREATE USER MAPPING FOR ${flyway:user}
SERVER sms_cv_db
OPTIONS (user '${cv_db_user}', password '${cv_db_password}');
ELSE
RAISE NOTICE 'Skipping creation of foreign server sms_cv_db because cv_access_type is not db';
END IF;
END $$;
-- Purpose: Create local tables to mock the SMS-CV database
BEGIN;
CREATE TABLE public.measured_quantity (
id serial4 NOT NULL PRIMARY KEY,
term varchar(255) NOT NULL,
provenance_uri varchar(255),
definition text
);
COMMIT;
-- Purpose: Create foreign tables for the SMS-CV database.
DO $$
BEGIN
IF '${cv_access_type}' = 'db' THEN
RAISE NOTICE 'Creating foreign tables for sms_cv';
CREATE FOREIGN TABLE IF NOT EXISTS public.sms_cv_measured_quantity (
id int4 not null,
term varchar(255) not null,
provenance_uri varchar(255),
definition text
)
SERVER sms_cv_db OPTIONS (schema_name 'public', table_name 'measured_quantity');
ELSE
RAISE NOTICE 'Skipping creation of foreign tables for sms because sms_access_type is not db';
END IF;
END $$;
\ No newline at end of file
#!/bin/bash
set -e
psql -v ON_ERROR_STOP=1 --username "$POSTGRES_USER" --dbname "$POSTGRES_DB" <<-EOSQL
CREATE ROLE $MQTT_AUTH_POSTGRES_USER WITH LOGIN PASSWORD '$MQTT_AUTH_POSTGRES_PASS';
GRANT $MQTT_AUTH_POSTGRES_USER TO postgres;
CREATE SCHEMA IF NOT EXISTS $MQTT_AUTH_POSTGRES_USER AUTHORIZATION $MQTT_AUTH_POSTGRES_USER;
SET search_path TO $MQTT_AUTH_POSTGRES_USER;
GRANT CONNECT ON DATABASE postgres TO $MQTT_AUTH_POSTGRES_USER;
ALTER ROLE $MQTT_AUTH_POSTGRES_USER SET search_path to $MQTT_AUTH_POSTGRES_USER;
GRANT USAGE ON SCHEMA $MQTT_AUTH_POSTGRES_USER TO $MQTT_AUTH_POSTGRES_USER;
GRANT ALL ON SCHEMA $MQTT_AUTH_POSTGRES_USER TO $MQTT_AUTH_POSTGRES_USER;
CREATE TABLE "mqtt_user"
(
"id" bigserial NOT NULL PRIMARY KEY,
"project_uuid" uuid NOT NULL,
"thing_uuid" uuid NOT NULL UNIQUE,
"username" varchar(256) NOT NULL UNIQUE,
"password" varchar(256) NOT NULL,
"db_schema" varchar(256) NOT NULL,
"description" text NULL,
"properties" jsonb NULL,
constraint mqtt_user_project_thing_unique
unique (project_uuid, thing_uuid)
);
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA $MQTT_AUTH_POSTGRES_USER TO $MQTT_AUTH_POSTGRES_USER;
GRANT ALL PRIVILEGES ON ALL SEQUENCES IN SCHEMA $MQTT_AUTH_POSTGRES_USER TO $MQTT_AUTH_POSTGRES_USER;
EOSQL
\ No newline at end of file
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment