From 0949b1e7f5730bc565c57574e55f32a8736faec7 Mon Sep 17 00:00:00 2001 From: vikingowl Date: Sat, 23 Aug 2025 19:46:51 +0200 Subject: [PATCH] [init] Add initial database migration files for PostgreSQL, SQLite, and MySQL --- api/migrations/mysql/001_init.down.sql | 27 ++++ api/migrations/mysql/001_init.up.sql | 116 +++++++++++++++ api/migrations/postgresql/001_init.down.sql | 36 +++++ api/migrations/postgresql/001_init.up.sql | 151 ++++++++++++++++++++ api/migrations/sqlite3/001_init.down.sql | 33 +++++ api/migrations/sqlite3/001_init.up.sql | 116 +++++++++++++++ 6 files changed, 479 insertions(+) create mode 100644 api/migrations/mysql/001_init.down.sql create mode 100644 api/migrations/mysql/001_init.up.sql create mode 100644 api/migrations/postgresql/001_init.down.sql create mode 100644 api/migrations/postgresql/001_init.up.sql create mode 100644 api/migrations/sqlite3/001_init.down.sql create mode 100644 api/migrations/sqlite3/001_init.up.sql diff --git a/api/migrations/mysql/001_init.down.sql b/api/migrations/mysql/001_init.down.sql new file mode 100644 index 0000000..1e3ece9 --- /dev/null +++ b/api/migrations/mysql/001_init.down.sql @@ -0,0 +1,27 @@ +-- Down migration for 001_init + +START TRANSACTION; + +-- Disable FK checks to avoid dependency issues during drops +SET FOREIGN_KEY_CHECKS = 0; + +-- Drop indexes (will be removed automatically with tables, but explicit drops keep intent clear) +DROP INDEX idx_routes_project_id ON routes; +DROP INDEX idx_projects_workspace_id ON projects; +DROP INDEX idx_workspaces_owner_id ON workspaces; + +-- Drop tables in reverse dependency order +DROP TABLE IF EXISTS role_permissions; +DROP TABLE IF EXISTS workspace_members; +DROP TABLE IF EXISTS routes; +DROP TABLE IF EXISTS projects; +DROP TABLE IF EXISTS permissions; +DROP TABLE IF EXISTS roles; +DROP TABLE IF EXISTS workspaces; +DROP TABLE IF EXISTS plans; +DROP TABLE IF EXISTS users; + +-- Re-enable FK checks +SET FOREIGN_KEY_CHECKS = 1; + +COMMIT; diff --git a/api/migrations/mysql/001_init.up.sql b/api/migrations/mysql/001_init.up.sql new file mode 100644 index 0000000..8292fce --- /dev/null +++ b/api/migrations/mysql/001_init.up.sql @@ -0,0 +1,116 @@ +-- =========== +-- Users & Plans +-- =========== + +CREATE TABLE users ( + id INT AUTO_INCREMENT PRIMARY KEY, + email VARCHAR(255) NOT NULL UNIQUE, + username VARCHAR(255), + hashed_password TEXT NOT NULL, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP +); + +CREATE TABLE plans ( + id INT AUTO_INCREMENT PRIMARY KEY, + name VARCHAR(255) NOT NULL UNIQUE, -- 'Free', 'Pro', 'Enterprise' + -- Features des Plans als JSON. + features JSON NOT NULL, + stripe_price_id VARCHAR(255) UNIQUE, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP +); + +-- =========== +-- Tenancy (Workspaces & Members) +-- =========== + +CREATE TABLE workspaces ( + id INT AUTO_INCREMENT PRIMARY KEY, + name VARCHAR(255) NOT NULL, + owner_id INT NOT NULL, + plan_id INT NOT NULL, + subscription_status VARCHAR(255) NOT NULL, -- z.B. 'active', 'trialing' + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + FOREIGN KEY (owner_id) REFERENCES users(id), + FOREIGN KEY (plan_id) REFERENCES plans(id) +); + +CREATE TABLE workspace_members ( + user_id INT NOT NULL, + workspace_id INT NOT NULL, + role_id INT NOT NULL, + joined_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + PRIMARY KEY (user_id, workspace_id), + FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, + FOREIGN KEY (workspace_id) REFERENCES workspaces(id) ON DELETE CASCADE, + FOREIGN KEY (role_id) REFERENCES roles(id) +); + +-- =========== +-- RBAC (Roles & Permissions) +-- =========== + +CREATE TABLE roles ( + id INT AUTO_INCREMENT PRIMARY KEY, + name VARCHAR(255) NOT NULL UNIQUE -- 'Workspace Owner', 'Admin', 'Developer', 'Viewer' +); + +CREATE TABLE permissions ( + id INT AUTO_INCREMENT PRIMARY KEY, + action VARCHAR(255) NOT NULL UNIQUE, -- 'project:create', 'route:delete', etc. + description TEXT +); + +CREATE TABLE role_permissions ( + role_id INT NOT NULL, + permission_id INT NOT NULL, + PRIMARY KEY (role_id, permission_id), + FOREIGN KEY (role_id) REFERENCES roles(id) ON DELETE CASCADE, + FOREIGN KEY (permission_id) REFERENCES permissions(id) ON DELETE CASCADE +); + +-- =========== +-- Product Logic (Projects & Routes) +-- =========== + +CREATE TABLE projects ( + id INT AUTO_INCREMENT PRIMARY KEY, + workspace_id INT NOT NULL, + name VARCHAR(255) NOT NULL, + description TEXT, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + FOREIGN KEY (workspace_id) REFERENCES workspaces(id) ON DELETE CASCADE +); + +CREATE TABLE routes ( + id INT AUTO_INCREMENT PRIMARY KEY, + project_id INT NOT NULL, + -- Matching Rules + method VARCHAR(10) NOT NULL, + path TEXT NOT NULL, + request_body_contains TEXT, + -- Protocol Dispatcher + protocol VARCHAR(20) NOT NULL CHECK(protocol IN ('REST_JSON', 'GRAPHQL', 'RAW_BYTESTREAM', 'JSON_RPC')), + schema_definition TEXT, + -- Response Definition + response_mode VARCHAR(10) NOT NULL CHECK(response_mode IN ('STATIC', 'DYNAMIC')) DEFAULT 'STATIC', + response_script TEXT, + status_code INT NOT NULL DEFAULT 200, + -- JSON für Header und TEXT für Body + response_headers JSON, + response_body TEXT, + created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE +); + +-- =========== +-- Indizes für schnelle Abfragen +-- =========== + +CREATE INDEX idx_workspaces_owner_id ON workspaces(owner_id); +CREATE INDEX idx_projects_workspace_id ON projects(workspace_id); +CREATE INDEX idx_routes_project_id ON routes(project_id); diff --git a/api/migrations/postgresql/001_init.down.sql b/api/migrations/postgresql/001_init.down.sql new file mode 100644 index 0000000..d59b43f --- /dev/null +++ b/api/migrations/postgresql/001_init.down.sql @@ -0,0 +1,36 @@ +-- =========== +-- Down Migration +-- =========== + +-- Drop triggers (must be dropped before their tables) +DROP TRIGGER IF EXISTS update_routes_updated_at ON routes; +DROP TRIGGER IF EXISTS update_projects_updated_at ON projects; +DROP TRIGGER IF EXISTS update_workspaces_updated_at ON workspaces; +DROP TRIGGER IF EXISTS update_plans_updated_at ON plans; +DROP TRIGGER IF EXISTS update_users_updated_at ON users; + +-- Drop the trigger function (after all triggers are gone) +DROP FUNCTION IF EXISTS update_updated_at_column(); + +-- Drop indexes +DROP INDEX IF EXISTS idx_routes_project_id; +DROP INDEX IF EXISTS idx_projects_workspace_id; +DROP INDEX IF EXISTS idx_workspaces_owner_id; + +-- Drop tables in reverse dependency order +-- Product Logic +DROP TABLE IF EXISTS routes; +DROP TABLE IF EXISTS projects; + +-- RBAC +DROP TABLE IF EXISTS role_permissions; +DROP TABLE IF EXISTS permissions; +DROP TABLE IF EXISTS roles; + +-- Tenancy +DROP TABLE IF EXISTS workspace_members; +DROP TABLE IF EXISTS workspaces; + +-- Users & Plans +DROP TABLE IF EXISTS plans; +DROP TABLE IF EXISTS users; diff --git a/api/migrations/postgresql/001_init.up.sql b/api/migrations/postgresql/001_init.up.sql new file mode 100644 index 0000000..c51dbe1 --- /dev/null +++ b/api/migrations/postgresql/001_init.up.sql @@ -0,0 +1,151 @@ +-- =========== +-- Users & Plans +-- =========== + +-- A function to automatically update 'updated_at' columns +CREATE +OR REPLACE +FUNCTION update_updated_at_column() +RETURNS TRIGGER AS $$ +BEGIN NEW.updated_at = NOW(); +RETURN NEW; +END; +$$ language 'plpgsql'; + +CREATE TABLE users +( + id SERIAL PRIMARY KEY, + email TEXT NOT NULL UNIQUE, + username TEXT, + hashed_password TEXT NOT NULL, + created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP +); + +CREATE TABLE plans +( + id SERIAL PRIMARY KEY, + name TEXT NOT NULL UNIQUE, -- 'Free', 'Pro', 'Enterprise' + -- Features des Plans als JSONB. Flexibel und indizierbar. + features JSONB NOT NULL, + stripe_price_id TEXT UNIQUE, + created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP +); + +-- =========== +-- Tenancy (Workspaces & Members) +-- =========== + +CREATE TABLE workspaces +( + id SERIAL PRIMARY KEY, + name TEXT NOT NULL, + owner_id INTEGER NOT NULL REFERENCES users (id), + plan_id INTEGER NOT NULL REFERENCES plans (id), + subscription_status TEXT NOT NULL, -- z.B. 'active', 'trialing' + created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP +); + +CREATE TABLE workspace_members +( + user_id INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE, + workspace_id INTEGER NOT NULL REFERENCES workspaces (id) ON DELETE CASCADE, + role_id INTEGER NOT NULL REFERENCES roles (id), + joined_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, + PRIMARY KEY (user_id, workspace_id) +); + +-- =========== +-- RBAC (Roles & Permissions) +-- =========== + +CREATE TABLE roles +( + id SERIAL PRIMARY KEY, + name TEXT NOT NULL UNIQUE -- 'Workspace Owner', 'Admin', 'Developer', 'Viewer' +); + +CREATE TABLE permissions +( + id SERIAL PRIMARY KEY, + action TEXT NOT NULL UNIQUE, -- 'project:create', 'route:delete', etc. + description TEXT +); + +CREATE TABLE role_permissions +( + role_id INTEGER NOT NULL REFERENCES roles (id) ON DELETE CASCADE, + permission_id INTEGER NOT NULL REFERENCES permissions (id) ON DELETE CASCADE, + PRIMARY KEY (role_id, permission_id) +); + +-- =========== +-- Product Logic (Projects & Routes) +-- =========== + +CREATE TABLE projects +( + id SERIAL PRIMARY KEY, + workspace_id INTEGER NOT NULL REFERENCES workspaces (id) ON DELETE CASCADE, + name TEXT NOT NULL, + description TEXT, + created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP +); + +CREATE TABLE routes +( + id SERIAL PRIMARY KEY, + project_id INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE, + -- Matching Rules + method TEXT NOT NULL, + path TEXT NOT NULL, + request_body_contains TEXT, + -- Protocol Dispatcher + protocol TEXT NOT NULL CHECK (protocol IN ('REST_JSON', 'GRAPHQL', 'RAW_BYTESTREAM', 'JSON_RPC')), + schema_definition TEXT, + -- Response Definition + response_mode TEXT NOT NULL CHECK (response_mode IN ('STATIC', 'DYNAMIC')) DEFAULT 'STATIC', + response_script TEXT, + status_code INTEGER NOT NULL DEFAULT 200, + -- JSONB für Header und Text für Body + response_headers JSONB, + response_body TEXT, + created_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMPTZ DEFAULT CURRENT_TIMESTAMP +); + +-- =========== +-- Indizes für schnelle Abfragen (Syntax is the same) +-- =========== + +CREATE INDEX idx_workspaces_owner_id ON workspaces (owner_id); +CREATE INDEX idx_projects_workspace_id ON projects (workspace_id); +CREATE INDEX idx_routes_project_id ON routes (project_id); + +-- =========== +-- Trigger to auto-update 'updated_at' fields +-- Apply this to all tables that have the 'updated_at' column +-- =========== +CREATE TRIGGER update_users_updated_at + BEFORE UPDATE + ON users + FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column(); +CREATE TRIGGER update_plans_updated_at + BEFORE UPDATE + ON plans + FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column(); +CREATE TRIGGER update_workspaces_updated_at + BEFORE UPDATE + ON workspaces + FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column(); +CREATE TRIGGER update_projects_updated_at + BEFORE UPDATE + ON projects + FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column(); +CREATE TRIGGER update_routes_updated_at + BEFORE UPDATE + ON routes + FOR EACH ROW EXECUTE PROCEDURE update_updated_at_column(); diff --git a/api/migrations/sqlite3/001_init.down.sql b/api/migrations/sqlite3/001_init.down.sql new file mode 100644 index 0000000..b743626 --- /dev/null +++ b/api/migrations/sqlite3/001_init.down.sql @@ -0,0 +1,33 @@ +-- =========== +-- Down Migration for 001_init +-- =========== + +-- Drop indexes (reverse of creation order isn't required for indexes, but do before tables) +DROP INDEX IF EXISTS idx_routes_project_id; +DROP INDEX IF EXISTS idx_projects_workspace_id; +DROP INDEX IF EXISTS idx_workspaces_owner_id; + +-- =========== +-- Product Logic (Projects & Routes) +-- =========== +DROP TABLE IF EXISTS routes; +DROP TABLE IF EXISTS projects; + +-- =========== +-- RBAC (Roles & Permissions) +-- =========== +DROP TABLE IF EXISTS role_permissions; +DROP TABLE IF EXISTS permissions; +DROP TABLE IF EXISTS roles; + +-- =========== +-- Tenancy (Workspaces & Members) +-- =========== +DROP TABLE IF EXISTS workspace_members; +DROP TABLE IF EXISTS workspaces; + +-- =========== +-- Users & Plans +-- =========== +DROP TABLE IF EXISTS plans; +DROP TABLE IF EXISTS users; diff --git a/api/migrations/sqlite3/001_init.up.sql b/api/migrations/sqlite3/001_init.up.sql new file mode 100644 index 0000000..e6b5c8a --- /dev/null +++ b/api/migrations/sqlite3/001_init.up.sql @@ -0,0 +1,116 @@ +-- =========== +-- Users & Plans +-- =========== + +CREATE TABLE users +( + id INTEGER PRIMARY KEY, + email TEXT NOT NULL UNIQUE, + username TEXT, + hashed_password TEXT NOT NULL, + created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP +); + +CREATE TABLE plans +( + id INTEGER PRIMARY KEY, + name TEXT NOT NULL UNIQUE, -- 'Free', 'Pro', 'Enterprise' + -- Features des Plans als JSON. Flexibel für zukünftige Änderungen. + features TEXT NOT NULL, + stripe_price_id TEXT UNIQUE, + created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP +); + +-- =========== +-- Tenancy (Workspaces & Members) +-- =========== + +CREATE TABLE workspaces +( + id INTEGER PRIMARY KEY, + name TEXT NOT NULL, + owner_id INTEGER NOT NULL REFERENCES users (id), + plan_id INTEGER NOT NULL REFERENCES plans (id), + subscription_status TEXT NOT NULL, -- z.B. 'active', 'trialing' + created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP +); + +CREATE TABLE workspace_members +( + user_id INTEGER NOT NULL REFERENCES users (id) ON DELETE CASCADE, + workspace_id INTEGER NOT NULL REFERENCES workspaces (id) ON DELETE CASCADE, + role_id INTEGER NOT NULL REFERENCES roles (id), + joined_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, + PRIMARY KEY (user_id, workspace_id) +); + +-- =========== +-- RBAC (Roles & Permissions) +-- =========== + +CREATE TABLE roles +( + id INTEGER PRIMARY KEY, + name TEXT NOT NULL UNIQUE -- 'Workspace Owner', 'Admin', 'Developer', 'Viewer' +); + +CREATE TABLE permissions +( + id INTEGER PRIMARY KEY, + action TEXT NOT NULL UNIQUE, -- 'project:create', 'route:delete', etc. + description TEXT +); + +CREATE TABLE role_permissions +( + role_id INTEGER NOT NULL REFERENCES roles (id) ON DELETE CASCADE, + permission_id INTEGER NOT NULL REFERENCES permissions (id) ON DELETE CASCADE, + PRIMARY KEY (role_id, permission_id) +); + +-- =========== +-- Product Logic (Projects & Routes) +-- =========== + +CREATE TABLE projects +( + id INTEGER PRIMARY KEY, + workspace_id INTEGER NOT NULL REFERENCES workspaces (id) ON DELETE CASCADE, + name TEXT NOT NULL, + description TEXT, + created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP +); + +CREATE TABLE routes +( + id INTEGER PRIMARY KEY, + project_id INTEGER NOT NULL REFERENCES projects (id) ON DELETE CASCADE, + -- Matching Rules + method TEXT NOT NULL, + path TEXT NOT NULL, + request_body_contains TEXT, + -- Protocol Dispatcher (kompatibel mit SQLite & Postgres) + protocol TEXT NOT NULL CHECK (protocol IN ('REST_JSON', 'GRAPHQL', 'RAW_BYTESTREAM', 'JSON_RPC')), + schema_definition TEXT, + -- Response Definition + response_mode TEXT NOT NULL CHECK (response_mode IN ('STATIC', 'DYNAMIC')) DEFAULT 'STATIC', + response_script TEXT, + status_code INTEGER NOT NULL DEFAULT 200, + -- Für SQLite: TEXT-Spalte, die JSON enthält. + response_headers TEXT, -- In Postgres: JSONB + response_body TEXT, + created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, + updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP +); + +-- =========== +-- Indizes für schnelle Abfragen +-- =========== + +CREATE INDEX idx_workspaces_owner_id ON workspaces (owner_id); +CREATE INDEX idx_projects_workspace_id ON projects (workspace_id); +CREATE INDEX idx_routes_project_id ON routes (project_id);