From 598fef10b7f2b3ba9cc53d86023614939bff4472 Mon Sep 17 00:00:00 2001 From: Anton Shubin <2spy4x@gmail.com> Date: Mon, 22 Jan 2024 23:18:45 +0800 Subject: [PATCH] feat: design db, configure Docker compose to spin up Postgres --- .env.example | 4 + .gitignore | 25 ++++ README.md | 34 ++++++ bun.lockb | Bin 0 -> 4177 bytes dev.compose.yml | 28 +++++ package.json | 21 ++++ sql/lib/db.js | 7 ++ sql/lib/env.js | 14 +++ sql/migrate.js | 77 ++++++++++++ sql/migrations/2024-01-22_13-26_init.sql | 148 +++++++++++++++++++++++ sql/purge.js | 45 +++++++ 11 files changed, 403 insertions(+) create mode 100644 .env.example create mode 100644 .gitignore create mode 100644 README.md create mode 100755 bun.lockb create mode 100644 dev.compose.yml create mode 100644 package.json create mode 100644 sql/lib/db.js create mode 100644 sql/lib/env.js create mode 100644 sql/migrate.js create mode 100644 sql/migrations/2024-01-22_13-26_init.sql create mode 100644 sql/purge.js diff --git a/.env.example b/.env.example new file mode 100644 index 0000000..00baf78 --- /dev/null +++ b/.env.example @@ -0,0 +1,4 @@ +DB_HOST=localhost +DB_USER=gb-light +DB_NAME=gb-light +DB_PASS=localPassword \ No newline at end of file diff --git a/.gitignore b/.gitignore new file mode 100644 index 0000000..94cbff5 --- /dev/null +++ b/.gitignore @@ -0,0 +1,25 @@ +# OS +.DS_Store + +# IDE +.idea +.vscode + +# Configs +.env +.env.* +!.env.example + +# Packages +node_modules + +# Artifacts +/build +/.svelte-kit +/package +vite.config.js.timestamp-* +vite.config.ts.timestamp-* +/.volumes + +# Logs +*.log diff --git a/README.md b/README.md new file mode 100644 index 0000000..ffc4e2c --- /dev/null +++ b/README.md @@ -0,0 +1,34 @@ +# GB-Lux + +This is a prototype/draft of a light control system. +At the moment it is at database design stage. + +### Prerequisites + +- [Docker](https://docs.docker.com/get-docker/) +- [Bun](https://bun.sh/) + +## Installation + +1. Clone the repository + +2. Install dependencies +```bash +bun install +``` + +3. Copy `.env.example` to `.env` and fill in the values or leave them as is: +```bash +cp .env.example .env +``` +4. Spin up database: +```bash +docker compose -f dev.compose.yml up +``` + +5. Apply database migrations: +```bash +bun db:migrate +``` + +6. Now you can connect to the database with your favorite client (e.g. [DBeaver](https://dbeaver.io/)) using the credentials from `.env` file. diff --git a/bun.lockb b/bun.lockb new file mode 100755 index 0000000000000000000000000000000000000000..7ccb51881c6cd0bb51e972289079f527c62f5327 GIT binary patch literal 4177 zcmeHK2~ZSA6rIIIVKtxz5+qP^MFreh*acj|5kZYfKoBofjw+5}SpvJu%y2AtK!J)@ z;(<}Tl^_a&i4Y~Af-wfc6%1e$F`}Y^f{1A0O(5O7+b|{(h_Nb3Rk~{G&-CXwge2A^I7Y$&7dKKG@>!TTlHi6($*3Tj8*9VSz%Z<6X7|xE8Ro4V zPsOmRt3}O*W5NwDl&@$NF11WuRN7&AQWp#YjiWM{*6(bR`Z*X4z(}d8OD3gg5lK*? zQX1$`F@QlyMc}nIusSRZ8wIQ;u<-dg=pV`Ghb(Y>gW_V(K~{N>8UI1vB{wtA!~*~H z<%t(M6vHh`J#3P@65B=9X=Cr2X-l0?xA|;4mUVWEe0M~hcmr?o7ZZ-SIHLaD?Hb!OUV}{!Ttc947_e+`K|7R&@Sb3>J;09!7GhEVU>s;%vKo)p^H=9T0q{;> zeuOs|Y-06$G`}GLx&gc<=r;lv>K}{-jq?L|JAj871v&Z>Xb=K~UkC7x01x8;@xaG{s{f$~m@n{xjcI`-l+8AF3~iBTrb{*NWEclNsH{F< zU1cRm`}yt1K?Rc^`TA99zdP^7IJ4)q8(wN}!KhPRMvLcgN0cAy>==@3a zbj>aAwk{|C*b$n)hPvFDzK+3*;;z)YYZb@$+fM$KX}KS79~rRfv4MhrBjl8;d+4Ev zhxxr)y~!5hvPZFjMm0D^Zam_?*Vrk~cl(9>t@l>8Ov;QhV(Nu^2{pD~sTU7xt4cW> zC%5a!u`fT@*i_#A>5qqs&5NUS^xIQAW1H(&-*1+!&RM$er{?*~9A13$$^A*k^D5?L zm{t4QTL2>DhvA46Sawu5wzAq|^sVrLQ*DHchjVSPte zPp_)MmB9T9a{_(8(6jPz2mKcCkOz(993$Yn0of20cSt61?mJ>hB%CFqaG8OF}`RiVRZxs0Gf zNU@Bbs=VcazpQYYmQf$@cqAbbQ#2{ZC9DGv)n>S_c(@D$!KQ YHGo(9^94}#KY(QmRH0Gty?>qg4P0F$OaK4? literal 0 HcmV?d00001 diff --git a/dev.compose.yml b/dev.compose.yml new file mode 100644 index 0000000..49c46a2 --- /dev/null +++ b/dev.compose.yml @@ -0,0 +1,28 @@ +version: '3.8' +services: + postgres: + container_name: postgres + image: postgres:15-alpine + restart: unless-stopped + volumes: + - ./.volumes/postgres:/var/lib/postgresql/data + environment: + - PGUSER=${DB_USER} + - POSTGRES_USER=${DB_USER} + - POSTGRES_PASSWORD=${DB_PASS} + - POSTGRES_DB=${DB_NAME} + ports: + - 5432:5432 + deploy: + resources: + limits: + cpus: '0.5' + memory: 512M + healthcheck: + test: ["CMD", "pg_isready", "-U", "${POSTGRES_USER}"] + interval: 1m + timeout: 10s + retries: 3 + start_period: 40s + security_opt: + - no-new-privileges:true \ No newline at end of file diff --git a/package.json b/package.json new file mode 100644 index 0000000..85dc128 --- /dev/null +++ b/package.json @@ -0,0 +1,21 @@ +{ + "name": "gb-lux", + "version": "0.0.1", + "private": true, + "type": "module", + "scripts": { + "dev": "docker compose -f dev.compose.yml up", + "dev:docker:build": "docker compose -f dev.compose.yml build", + "dev:docker:clean": "docker rmi $(docker images -f \"dangling=true\" -q)", + "db:migrate": "bun ./sql/migrate.js", + "db:purge": "bun ./sql/purge.js", + "db:seed": "bun ./sql/seed.js" + }, + "dependencies": { + "postgres": "3.4.3" + }, + "devDependencies": { + "dotenv": "16.3.2", + "@types/bun": "latest" + } +} \ No newline at end of file diff --git a/sql/lib/db.js b/sql/lib/db.js new file mode 100644 index 0000000..66b0684 --- /dev/null +++ b/sql/lib/db.js @@ -0,0 +1,7 @@ +import postgres from 'postgres'; +import { env } from './env.js'; + +export const sql = postgres({ + ...env.db, + transform: postgres.camel, +}); diff --git a/sql/lib/env.js b/sql/lib/env.js new file mode 100644 index 0000000..912bc81 --- /dev/null +++ b/sql/lib/env.js @@ -0,0 +1,14 @@ +import { config } from 'dotenv'; + +const isProd = process.env.NODE_ENV === 'prod' || process.env.NODE_ENV === 'production'; +config({ path: isProd ? '.env.prod' : '.env' }); + +export const env = { + isProd, + db: { + host: process.env.DB_HOST, + user: process.env.DB_USER, + pass: process.env.DB_PASS, + db: process.env.DB_NAME, + }, +}; diff --git a/sql/migrate.js b/sql/migrate.js new file mode 100644 index 0000000..a9a5a87 --- /dev/null +++ b/sql/migrate.js @@ -0,0 +1,77 @@ +import { readdirSync, readFileSync } from 'fs'; +import { extname, join } from 'path'; +import { sql } from './lib/db.js'; + +const migrationsFolder = './sql/migrations'; +const fileExtension = '.sql'; + +async function applyMigrations() { + try { + // check if migrations table exists + const tableExists = + await sql`SELECT exists (SELECT FROM information_schema.tables WHERE table_name = 'migrations')`; + + // create migrations table if it does not exist + if (!tableExists[0].exists) { + await sql` + CREATE TABLE migrations ( + id SERIAL PRIMARY KEY, + name VARCHAR(100) NOT NULL, + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP + ) + `; + console.log('Migrations table was created.\n'); + } + } catch (err) { + console.error('❌ Failed to create migrations table', err); + process.exit(1); + } + + let migrations = []; + + try { + // get list of migrations from database + const migrationsResult = await sql`SELECT name FROM migrations`; + migrations = migrationsResult.map(({ name }) => name); + } catch (err) { + console.error('❌ Failed to get migrations from database', err); + process.exit(1); + } + + try { + // read directory and get .sql files + const files = readdirSync(migrationsFolder); + + const migrationsToApply = files + .filter(file => extname(file) === fileExtension) + .map(file => file.replace(fileExtension, '')) + .filter(file => !migrations.includes(file)) + .sort(); + + if (!migrationsToApply.length) { + console.log('✅ No new migrations to apply.'); + process.exit(0); + } + console.log(`Applying ${migrationsToApply.length} migration(s):`); + + for (let migration of migrationsToApply) { + console.log('- ' + migration); + // read SQL file + const sqlScript = readFileSync(join(migrationsFolder, migration + fileExtension), 'utf8'); + // execute the SQL script + await sql.begin(async tx => { + await tx.unsafe(sqlScript); + // record that this migration has been run + await tx`INSERT INTO migrations (name) VALUES (${migration})`; + }); + } + + console.log('\n✅ Migrations successfully applied.'); + process.exit(0); + } catch (err) { + console.error('\n❌ Failed to apply migrations\n', err); + process.exit(1); + } +} + +void applyMigrations(); diff --git a/sql/migrations/2024-01-22_13-26_init.sql b/sql/migrations/2024-01-22_13-26_init.sql new file mode 100644 index 0000000..e6a4a9e --- /dev/null +++ b/sql/migrations/2024-01-22_13-26_init.sql @@ -0,0 +1,148 @@ +CREATE TABLE organisations +( + id SERIAL PRIMARY KEY, + name VARCHAR(50) NOT NULL, + role INT2 NOT NULL DEFAULT 0, -- 0 - client, 1 - Yume, maybe more roles in the future + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP +); + +CREATE TABLE users +( + id SERIAL PRIMARY KEY, + organisation_id INT4 NOT NULL, + permission INT2, + email VARCHAR(50), + first_name VARCHAR(50), + last_name VARCHAR(50), + photo_url VARCHAR(200), + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (organisation_id) REFERENCES organisations (id) ON DELETE CASCADE ON UPDATE CASCADE +); + +CREATE TABLE keys +( + id SERIAL PRIMARY KEY, + user_id INT4 NOT NULL, + kind INT2 NOT NULL, + identification VARCHAR(50) NOT NULL, + secret VARCHAR(60), + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (user_id) REFERENCES users (id) ON DELETE CASCADE ON UPDATE CASCADE +); + +CREATE TABLE sessions +( + id SERIAL PRIMARY KEY, + token VARCHAR(32) NOT NULL, + user_id INT4 NOT NULL, + key_id INT4 NOT NULL, + expires_at timestamp(3) without time zone, + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (user_id) REFERENCES users (id) ON DELETE CASCADE ON UPDATE CASCADE, + FOREIGN KEY (key_id) REFERENCES keys (id) ON DELETE CASCADE ON UPDATE CASCADE +); + +CREATE TABLE projects +( + id SERIAL PRIMARY KEY, + organisation_id INT4 NOT NULL, + name VARCHAR(50) NOT NULL, + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (organisation_id) REFERENCES organisations (id) ON DELETE CASCADE ON UPDATE CASCADE +); + +CREATE TABLE device_groups +( + id SERIAL PRIMARY KEY, + project_id INT4 NOT NULL, + name VARCHAR(50) NOT NULL, + force_status INT2 NOT NULL DEFAULT 0, -- 0 - no force, 1 - force on, 2 - force off + lux_threshold INT2, -- Triggers the light if the lux level is below this threshold + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (project_id) REFERENCES projects (id) ON DELETE CASCADE ON UPDATE CASCADE +); + +CREATE TABLE device_group_daily_schedule +( + id SERIAL PRIMARY KEY, + device_group_id INT4 NOT NULL, + day_of_week INT2 NOT NULL, -- 0 - Sunday, 1 - Monday, 2 - Tuesday, 3 - Wednesday, 4 - Thursday, 5 - Friday, 6 - Saturday + start_time TIME NOT NULL, + end_time TIME NOT NULL, + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (device_group_id) REFERENCES device_groups (id) ON DELETE CASCADE ON UPDATE CASCADE +); + + +-- We might need to separate light, gateways and sensors into different tables. For now, let's discuss it. +CREATE TABLE devices +( + id SERIAL PRIMARY KEY, + uuid VARCHAR(36) NOT NULL, + gbtb_id VARCHAR(50) NOT NULL, -- QUESTION: What type is gbtb_id? Is it a string or an integer? + device_group_id INT4 NOT NULL, + name VARCHAR(50) NOT NULL, + lamppost_number VARCHAR(50), -- QUESTION: What type is lamppost_number? Is it a string or an integer? + started_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, -- for calculating the uptime/running hours + lux_level INT2, + role INT2 NOT NULL DEFAULT 0, -- 0 - light, 1 - motion sensor, 2 - gateway, maybe more roles in the future + + -- geolocation. We can use Postgres plugin "PostGIS" for this, but it's not necessary for now + latitude FLOAT4, + longitude FLOAT4, + altitude FLOAT4, + + status INT2 NOT NULL DEFAULT 0, -- 0 - off, 1 - on, maybe more statuses in the future + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (device_group_id) REFERENCES device_groups (id) ON DELETE CASCADE ON UPDATE CASCADE +); + +CREATE TABLE measures +( + id SERIAL PRIMARY KEY, + device_id INT4 NOT NULL, + measure_type INT2 NOT NULL DEFAULT 0, -- 0 - temperature, 1 - humidity, 2 - light, 3 - motion, 4 - voltage, 5 - power consumption, maybe more in the future + value INT4 NOT NULL, + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (device_id) REFERENCES devices (id) ON DELETE CASCADE ON UPDATE CASCADE +); + +CREATE TABLE commands +( + id SERIAL PRIMARY KEY, + organisation_id INT4 NOT NULL, + originator_id INT4, + originator_type INT2 NOT NULL DEFAULT 0, -- 0 - user, 1 - device, 2 - device group, 3 - organisation, maybe more in the future + command_type INT2 NOT NULL, -- 0 - on, 1 - off, 2 - force on, 3 - force off, 4 - reboot, 5 - reset, etc + comment VARCHAR(100), + entity INT4 NOT NULL, + entity_type INT2 NOT NULL DEFAULT 0, -- 0 - device, 1 - device group, 2 - organisation, 3 - user, maybe more in the future + scheduled_at TIMESTAMP(3), -- NULL if the command is executed immediately + executed_at TIMESTAMP(3), -- NULL if the command is not executed yet + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (organisation_id) REFERENCES organisations (id) ON DELETE CASCADE ON UPDATE CASCADE +-- No other FKs, because we don't want to delete the history when the entity is deleted +); + +CREATE TABLE alerts +( + id SERIAL PRIMARY KEY, + organisation_id INT4 NOT NULL, + alert_type INT2 NOT NULL, -- 0 - temperature, 1 - humidity, 2 - light, 3 - motion, 4 - voltage, 5 - power consumption, maybe more in the future + entity INT4 NOT NULL, + entity_type INT2 NOT NULL DEFAULT 0, -- 0 - device, 1 - device group, 2 - organisation, 3 - user, maybe more in the future + created_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP(3) NOT NULL DEFAULT CURRENT_TIMESTAMP, + FOREIGN KEY (organisation_id) REFERENCES organisations (id) ON DELETE CASCADE ON UPDATE CASCADE +-- No other FKs, because we don't want to delete the history when the entity is deleted +); \ No newline at end of file diff --git a/sql/purge.js b/sql/purge.js new file mode 100644 index 0000000..caa7688 --- /dev/null +++ b/sql/purge.js @@ -0,0 +1,45 @@ +import { env } from './lib/env.js'; +import { sql } from './lib/db.js'; + +/** Drops all tables from the database. + * if NODE_ENV!='prod' || 'production' and not --prod - then abort */ +async function purge() { + if (env.isProd && !process.argv.includes('--prod')) { + console.error('❌ Cannot purge database in production'); + process.exit(1); + } + let tables = []; + try { + console.log('Fetching table names...'); + const result = await sql` + SELECT table_name + FROM information_schema.tables + WHERE table_schema = 'public' + AND table_type = 'BASE TABLE' + `; + tables = result.map(({ tableName }) => tableName); + } catch (err) { + console.error('❌ Failed to fetch table names', err); + process.exit(1); + } + + if (!tables.length) { + console.log('\n✅ No tables to purge.'); + process.exit(0); + } + + try { + console.log(`Purging ${tables.length} tables:`); + for (let table of tables) { + console.log('- ' + table); + await sql`DROP TABLE ${sql(table)} CASCADE`; + } + console.log('\n✅ Database purged.'); + process.exit(0); + } catch (err) { + console.error('\n❌ Failed to purge database\n', err); + process.exit(1); + } +} + +void purge();