[init] Add initial database migration files for PostgreSQL, SQLite, and MySQL
This commit is contained in:
36
api/migrations/postgresql/001_init.down.sql
Normal file
36
api/migrations/postgresql/001_init.down.sql
Normal file
@@ -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;
|
151
api/migrations/postgresql/001_init.up.sql
Normal file
151
api/migrations/postgresql/001_init.up.sql
Normal file
@@ -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();
|
Reference in New Issue
Block a user