Skip to content

Commit

Permalink
feat: setup a sqitch to handle migrations (#23)
Browse files Browse the repository at this point in the history
feat: initialize sqitch

feat: create schema and roles for the postgrest api

feat: create roles to distinguish users esp & login

feat: Add table to store data

feat: add a table to store user and passwords

fix: test migrations

refactor: remove old useless stuff

feat: launch migration on docker start

fix: ensure container wait enougth before starting
  • Loading branch information
Rignchen authored Jun 10, 2024
1 parent d85de2d commit 2b4b46f
Show file tree
Hide file tree
Showing 20 changed files with 323 additions and 115 deletions.
3 changes: 0 additions & 3 deletions Dockerfile.Postgres

This file was deleted.

3 changes: 3 additions & 0 deletions Dockerfile.Sqitch
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
FROM sqitch/sqitch:v1.4.1.0
CMD ["deploy"]

96 changes: 0 additions & 96 deletions database/db.sql

This file was deleted.

56 changes: 56 additions & 0 deletions database/migration/deploy/data.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,56 @@
-- Deploy climat-guardian:data to pg

BEGIN;

create table api.data (
temperature real,
humidity real,
timestamp timestamp NOT NULL,
ip character varying(15) NOT NULL
);
grant select on api.data to web_user;

-- convert unix timestamp to timestamp and insert it
create or replace function api.insert_data(
temperature real,
humidity real,
ip varchar(15),
unix_timestamp bigint
)
returns void as $$
begin
-- if the ip said in the token is not the same as the one in the request, then this means that the user is not who he pretends to be and we should throw an error
if (current_setting('request.jwt.claims', true)::json->>'ip' != ip) then
raise exception insufficient_privilege
using hint = 'You are not who you pretend to be';
end if;
-- insert the data
insert into api.data("temperature", "humidity", "ip", "timestamp") values (temperature, humidity, ip, to_timestamp(unix_timestamp));
end $$ language plpgsql;
grant insert on api.data to esp32;

-- create a function to get the average temperature and humidity of each delta time
create function api.avg_date(
delta varchar
)
returns table(
avg_temperature double precision,
avg_humidity double precision,
date timestamp,
ip character varying(15),
count bigint
) as $$
begin
return query select
avg(temperature) as avg_temperature,
avg(humidity) as avg_humidity,
date_trunc(delta, timestamp) as date,
data.ip,
count(*) as count
from api.data
group by date, data.ip
order by date;
end;
$$ language plpgsql;

COMMIT;
8 changes: 8 additions & 0 deletions database/migration/deploy/postgrest.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
-- Deploy climat-guardian:postgrest to pg

BEGIN;

create schema api;
create role authenticator noinherit login password 'mysecretpassword';

COMMIT;
25 changes: 25 additions & 0 deletions database/migration/deploy/roles.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
-- Deploy climat-guardian:roles to pg

BEGIN;

-- anonymous role
create role web_anon nologin;
grant usage on schema api to web_anon;
grant web_anon to authenticator;

-- create role for the esp 32
create role esp32 nologin;
grant usage on schema api to esp32;
grant esp32 to authenticator;

-- create role for the users
create role web_user nologin;
grant usage on schema api to web_user;
grant web_user to authenticator;

-- create a role for the login
create role web_login nologin;
grant usage on schema api to web_login;
grant web_login to authenticator;

COMMIT;
18 changes: 18 additions & 0 deletions database/migration/deploy/user.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,18 @@
-- Deploy climat-guardian:user to pg

BEGIN;

create table api.users (
id serial primary key,
username character varying(50) NOT NULL UNIQUE,
password character varying(60) NOT NULL
);

grant usage, select on sequence api.users_id_seq to web_user;
grant insert on api.users to web_user; -- any user can add new users
grant select on api.users to web_login;

-- create first user to be able to connect first time
insert into api.users(username, password) values ('admin', '$2y$10$vJMf8H4u0f913VOJJDqVIeYrqnZBSzgYZ3Zyoh76MDjf6ZlmNDKPu');

COMMIT;
9 changes: 9 additions & 0 deletions database/migration/revert/data.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
-- Revert climat-guardian:data from pg

BEGIN;

drop table api.data;
drop function api.avg_date;
drop function api.insert_data;

COMMIT;
8 changes: 8 additions & 0 deletions database/migration/revert/postgrest.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
-- Revert climat-guardian:postgrest from pg

BEGIN;

drop schema api;
drop role authenticator;

COMMIT;
21 changes: 21 additions & 0 deletions database/migration/revert/roles.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
-- Revert climat-guardian:roles from pg

BEGIN;

-- anonymous role
revoke usage on schema api from web_anon;
drop role web_anon;

-- esp 32
revoke usage on schema api from esp32;
drop role esp32;

-- users
revoke usage on schema api from web_user;
drop role web_user;

-- login
revoke usage on schema api from web_login;
drop role web_login;

COMMIT;
7 changes: 7 additions & 0 deletions database/migration/revert/user.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
-- Revert climat-guardian:user from pg

BEGIN;

drop table api.users;

COMMIT;
68 changes: 68 additions & 0 deletions database/migration/sqitch
Original file line number Diff line number Diff line change
@@ -0,0 +1,68 @@
#!/usr/bin/env bash

# Determine which Docker image to run.
SQITCH_IMAGE=${SQITCH_IMAGE:=sqitch/sqitch:latest}

# Set up required pass-through variables.
user=${USER-$(whoami)}
passopt=(
-e "SQITCH_ORIG_SYSUSER=$user"
-e "SQITCH_ORIG_EMAIL=$user@$(hostname)"
-e "TZ=$(date +%Z)" \
-e "LESS=${LESS:--R}" \
)

# Handle OS-specific options.
case "$(uname -s)" in
Linux*)
passopt+=(-e "SQITCH_ORIG_FULLNAME=$(getent passwd $user | cut -d: -f5 | cut -d, -f1)")
passopt+=(-u $(id -u ${user}):$(id -g ${user}))
;;
Darwin*)
passopt+=(-e "SQITCH_ORIG_FULLNAME=$(/usr/bin/id -P $user | awk -F '[:]' '{print $8}')")
;;
MINGW*|CYGWIN*)
passopt+=(-e "SQITCH_ORIG_FULLNAME=$(net user $user)")
;;
*)
echo "Unknown OS: $(uname -s)"
exit 2
;;
esac

# Iterate over optional Sqitch and engine variables.
for var in \
SQITCH_CONFIG SQITCH_USERNAME SQITCH_PASSWORD SQITCH_FULLNAME SQITCH_EMAIL SQITCH_TARGET \
DBI_TRACE \
PGUSER PGPASSWORD PGHOST PGHOSTADDR PGPORT PGDATABASE PGSERVICE PGOPTIONS PGSSLMODE PGREQUIRESSL PGSSLCOMPRESSION PGREQUIREPEER PGKRBSRVNAME PGKRBSRVNAME PGGSSLIB PGCONNECT_TIMEOUT PGCLIENTENCODING PGTARGETSESSIONATTRS \
MYSQL_PWD MYSQL_HOST MYSQL_TCP_PORT \
TNS_ADMIN TWO_TASK ORACLE_SID \
ISC_USER ISC_PASSWORD \
VSQL_HOST VSQL_PORT VSQL_USER VSQL_PASSWORD VSQL_SSLMODE \
SNOWSQL_ACCOUNT SNOWSQL_USER SNOWSQL_PWD SNOWSQL_HOST SNOWSQL_PORT SNOWSQL_DATABASE SNOWSQL_REGION SNOWSQL_WAREHOUSE SNOWSQL_PRIVATE_KEY_PASSPHRASE SNOWSQL_ROLE
do
if [ -n "${!var}" ]; then
passopt+=(-e $var)
fi
done

# Determine the name of the container home directory.
homedst=/home
if [ $(id -u ${user}) -eq 0 ]; then
homedst=/root
fi
# Set HOME, since the user ID likely won't be the same as for the sqitch user.
passopt+=(-e "HOME=${homedst}")

# Determine necessary flags when stdin and/or stdout are opened on a TTY.
if [ -t 0 ] && [ -t 1 ]; then
passopt+=(--interactive --tty)
elif [ ! -t 0 ]; then
passopt+=(--interactive)
fi

# Run the container with the current and home directories mounted.
docker run --rm --network host \
--mount "type=bind,src=$(pwd),dst=/repo" \
--mount "type=bind,src=$HOME,dst=$homedst" \
"${passopt[@]}" "$SQITCH_IMAGE" "$@"
8 changes: 8 additions & 0 deletions database/migration/sqitch.conf
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
[core]
engine = pg
# plan_file = sqitch.plan
# top_dir = .
# [engine "pg"]
# target = db:pg:
# registry = sqitch
# client = psql
8 changes: 8 additions & 0 deletions database/migration/sqitch.plan
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
%syntax-version=1.0.0
%project=climat-guardian
%uri=https://github.com/museebolo/climat_guardian

postgrest 2024-06-07T14:50:40Z Nils <nils@fedora> # create schema and roles for the postgrest api
roles 2024-06-07T18:32:02Z Nils <nils@fedora> # create the role used by the user to distinguish users and esp
data 2024-06-07T20:09:18Z Nils <nils@fedora> # Add table to store data
user 2024-06-07T20:47:39Z Nils <nils@fedora> # create a user table to store every user and password
9 changes: 9 additions & 0 deletions database/migration/verify/data.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,9 @@
-- Verify climat-guardian:data on pg

BEGIN;

select * from api.data;
select api.insert_data(25.0, 50.0, '123.123.123.123', 1717796704);
select * from api.avg_date('day');

ROLLBACK;
8 changes: 8 additions & 0 deletions database/migration/verify/postgrest.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
-- Verify climat-guardian:postgrest on pg

BEGIN;

-- XXX Add verifications here.
-- I don't know how to test using sql

ROLLBACK;
8 changes: 8 additions & 0 deletions database/migration/verify/roles.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,8 @@
-- Verify climat-guardian:roles on pg

BEGIN;

-- XXX Add verifications here.
-- I don't know how to test using sql

ROLLBACK;
7 changes: 7 additions & 0 deletions database/migration/verify/user.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
-- Verify climat-guardian:user on pg

BEGIN;

select * from api.users;

ROLLBACK;
Loading

0 comments on commit 2b4b46f

Please sign in to comment.