Files
owlibou_hoot/api/migrations/postgresql/001_init.up.sql

152 lines
4.8 KiB
PL/PgSQL

-- ===========
-- 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();