Skip to content

Commit

Permalink
Merge pull request #76 from EURODEO/migrate
Browse files Browse the repository at this point in the history
Add migration framework so that changes to the database are executed once and consistent between environments.
  • Loading branch information
Jeffrey-Vervoort-KNMI authored Dec 13, 2023
2 parents 98f1976 + fd55f15 commit 2480e94
Show file tree
Hide file tree
Showing 7 changed files with 91 additions and 25 deletions.
14 changes: 14 additions & 0 deletions database/healthcheck_postgis_uptime.sh
Original file line number Diff line number Diff line change
@@ -0,0 +1,14 @@
#!/usr/bin/env bash

CONNECTION_STRING=$1 # Postgres connection string
UPTIME_AMOUNT=${2:-1} # Number of e.g. hours, minutes, seconds
UPTIME_TYPE=${3:-"minute"} # E.g. hour, minute, second

# Return exit code based on the uptime of postgres
if [[ $(psql "${CONNECTION_STRING}" -XtAc \
"SELECT COUNT(*) FROM (SELECT current_timestamp - pg_postmaster_start_time() AS uptime) AS t WHERE t.uptime > interval '${UPTIME_AMOUNT} ${UPTIME_TYPE}'") == 1 ]];
then
exit 0
else
exit 1
fi
19 changes: 14 additions & 5 deletions docker-compose.yml
Original file line number Diff line number Diff line change
Expand Up @@ -10,19 +10,29 @@ services:
volumes:
# - ts-data:/home/postgres/pgdata/data # for timescale image
- ts-data:/var/lib/postgresql/data # for postgres image
- ./datastore/ts-init.sql:/docker-entrypoint-initdb.d/init.sql
- ./database/healthcheck_postgis_uptime.sh:/healthcheck_postgis_uptime.sh # for the healthcheck
environment:
- POSTGRES_USER=postgres
- POSTGRES_PASSWORD=mysecretpassword
- POSTGRES_DB=data
restart: on-failure
healthcheck:
test: [ "CMD-SHELL", "psql postgresql://postgres:mysecretpassword@localhost/data -c \"SELECT COUNT(*) from OBSERVATION\"" ]
# HACK Due to the installation of Postgis extension the database is restarted, the healthcheck checks if the database is up for longer than specified time.
test: ["CMD-SHELL", "/healthcheck_postgis_uptime.sh postgresql://postgres:mysecretpassword@localhost/data 10 second"]
interval: 5s
timeout: 1s
retries: 3
start_period: 30s # Failures in 30 seconds do not mark container as unhealthy

migrate:
image: migrate/migrate:4
volumes:
- ./migrate/data/migrations:/data/migrations
command: ["-path", "/data/migrations", "-database", "postgres://postgres:mysecretpassword@db:5432/data?sslmode=disable", "up"]
depends_on:
db:
condition: service_healthy

store:
build:
context: datastore
Expand All @@ -45,11 +55,10 @@ services:
retries: 3
start_period: 30s # Failures in 30 seconds do not mark container as unhealthy
depends_on:
db:
condition: service_healthy
migrate:
condition: service_completed_successfully

api:
hostname: api
build:
context: . # TODO: Needed to get proto file. Find a better solution
dockerfile: api/Dockerfile
Expand Down
28 changes: 28 additions & 0 deletions migrate/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,28 @@
# Migration Framework
To have reproducible environments, support rollbacks and that every change is only executed once, we use [Golang Migrate](https://github.com/golang-migrate/migrate/tree/master) as a migration framework.

See the following URL for installation instructions and basic commands:
https://github.com/golang-migrate/migrate/tree/master/cmd/migrate

See the following URL for the migration file format instructions:
https://github.com/golang-migrate/migrate/blob/master/MIGRATIONS.md

## Practicalities
### Initialisation
The migration framework initialises the database. Therefore, no database tables exist before running the migrate step in the docker compose.

### File name format
The migration file name format follows the suggestion in [MIGRATIONS.md](https://github.com/golang-migrate/migrate/blob/master/MIGRATIONS.md) to use a timestamp as version.

```
{version}_{title}.up.{extension}
{version}_{title}.down.{extension}
```

On Linux, you can retrieve the current timestamp by running: `date +%s`.


### Migration Path
The path `./migrate/data/migrations` is mounted on the migrate container. Thus, the docker container only executes the migrations in this path.

The other path: `./migrate/data/not_supported_yet`, contains an example migration based on code comments about unfinished work from the initialise script. As the path is not mounted, the docker container does not execute migrations in that path. To try out the migrations move the files to `./migrate/data/migrations`.
5 changes: 5 additions & 0 deletions migrate/data/migrations/1701872471_initialise_schema.down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
-- Commented out the statements below as you never want to undo the initialise.
-- DROP TABLE IF EXISTS observation;
-- DROP TABLE IF EXISTS geo_point;
-- DROP TABLE IF EXISTS time_series;
-- DROP EXTENSION IF EXISTS postgis;
Original file line number Diff line number Diff line change
Expand Up @@ -47,14 +47,6 @@ CREATE TABLE geo_point (

CREATE INDEX geo_point_idx ON geo_point USING GIST(point);

-- not supported yet
-- CREATE TABLE geo_polygon (
-- id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
-- polygon GEOGRAPHY(Polygon, 4326) NOT NULL
-- )
--
-- CREATE INDEX geo_polygon_idx ON geo_polygon USING GIST(polygon);

CREATE TABLE observation (
ts_id BIGINT NOT NULL REFERENCES time_series(id) ON DELETE CASCADE,

Expand All @@ -64,27 +56,16 @@ CREATE TABLE observation (
-- Refer to geometry via a foreign key to ensure that each distinct geometry is
-- stored only once in the geo_* table, thus speeding up geo search.
geo_point_id BIGINT NOT NULL REFERENCES geo_point(id) ON DELETE CASCADE,
-- geo_polygon_id integer NOT NULL REFERENCES geo_polygon(id) ON DELETE CASCADE, -- not supported yet

pubtime timestamptz NOT NULL, -- required
data_id TEXT NOT NULL, -- required
history TEXT,
metadata_id TEXT NOT NULL, -- required

-- --- BEGIN for now support only a single instant for obs time ---------
obstime_instant timestamptz, -- NOT NULL, but implied by being part of PK
obstime_instant timestamptz, -- NOT NULL, but implied by being part of PK; obs time variant 1: single instant
-- --- END for now support only a single instant for obs time ---------

-- --- BEGIN support both single instant and interval for obs time ---------
-- obstime_instant timestamptz, -- obs time variant 1: single instant
-- obstime_start timestamptz, -- obs time variant 2: interval
-- obstime_end timestamptz,
-- CHECK ( -- ensure exactly one of [1] obstime_instant and [2] obstime_start/-end is defined
-- ((obstime_instant IS NOT NULL) AND (obstime_start IS NULL) AND (obstime_end IS NULL)) OR
-- ((obstime_instant IS NULL) AND (obstime_start IS NOT NULL) AND (obstime_end IS NOT NULL))
-- ),
-- --- END support both single instant and interval for obs time ---------

processing_level TEXT,
value TEXT NOT NULL, -- obs value
-- --- END metadata fields that usually vary with obs time ---
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
ALTER TABLE observation
DROP COLUMN IF EXISTS geo_polygon_id,
DROP COLUMN IF EXISTS obstime_start, -- obs time variant 2: interval
DROP COLUMN IF EXISTS obstime_end,
DROP CONSTRAINT IF EXISTS observation_chk_one_obs_time;

DROP TABLE IF EXISTS geo_polygon;
22 changes: 22 additions & 0 deletions migrate/data/not_supported_yet/1702281165_geo_polygon.up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
-- not supported yet
CREATE TABLE IF NOT EXISTS geo_polygon (
id BIGINT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
polygon GEOGRAPHY(Polygon, 4326) NOT NULL
);

CREATE INDEX geo_polygon_idx ON geo_polygon USING GIST(polygon);

------- BEGIN support both single instant and interval for obs time ---------
-- TODO: Fix geo_polygon_id. How to fill the existing rows, otherwise column cannot be added
-- ALTER TABLE observation
-- ADD geo_polygon_id integer NOT NULL REFERENCES geo_polygon(id) ON DELETE CASCADE; -- not supported yet

ALTER TABLE observation
ADD obstime_start timestamptz, -- obs time variant 2: interval
ADD obstime_end timestamptz,
ADD CONSTRAINT observation_chk_one_obs_time
CHECK ( -- ensure exactly one of [1] obstime_instant and [2] obstime_start/-end is defined
((obstime_instant IS NOT NULL) AND (obstime_start IS NULL) AND (obstime_end IS NULL)) OR
((obstime_instant IS NULL) AND (obstime_start IS NOT NULL) AND (obstime_end IS NOT NULL))
);
------- END support both single instant and interval for obs time ---------

0 comments on commit 2480e94

Please sign in to comment.