Files
omega/DATABASE_SCHEMA.md
Fran Jurmanović bc868abbef init docs
2025-07-06 15:05:04 +02:00

107 lines
4.2 KiB
Markdown

-- ##################################################################
-- ## Core Entity Tables
-- ##################################################################
-- users: Stores individual user information and credentials.
CREATE TABLE users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
email VARCHAR(255) UNIQUE NOT NULL,
password_hash VARCHAR(255) NOT NULL,
full_name VARCHAR(255),
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- roles: Defines the roles that can be assigned to users.
CREATE TABLE roles (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- CHANGED: from SERIAL to UUID
name VARCHAR(50) UNIQUE NOT NULL -- e.g., 'admin', 'member', 'billing_manager'
);
-- permissions: Defines specific, granular permissions.
CREATE TABLE permissions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- CHANGED: from SERIAL to UUID
name VARCHAR(100) UNIQUE NOT NULL -- e.g., 'project:create', 'task:delete', 'user:invite'
);
-- types: Stores the different "types" a project can be, now linked to a user.
CREATE TABLE types (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(), -- CHANGED: from SERIAL to UUID
user_id UUID REFERENCES users(id) ON DELETE SET NULL, -- ADDED: Makes types user-specific. Can be NULL for system default types.
name VARCHAR(100) NOT NULL,
description TEXT,
UNIQUE(user_id, name) -- A user can't have two types with the same name.
);
-- projects: The central table for projects.
CREATE TABLE projects (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
name VARCHAR(255) NOT NULL,
description TEXT,
owner_id UUID NOT NULL REFERENCES users(id),
type_id UUID NOT NULL REFERENCES types(id), -- CHANGED: from INT to UUID
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- tasks: Stores tasks, which belong to a project.
CREATE TYPE task_status AS ENUM ('todo', 'in_progress', 'done', 'canceled');
CREATE TYPE task_priority AS ENUM ('low', 'medium', 'high');
CREATE TABLE tasks (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
title VARCHAR(255) NOT NULL,
description TEXT,
status task_status NOT NULL DEFAULT 'todo',
priority task_priority NOT NULL DEFAULT 'medium',
project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
due_date DATE,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- integrations: Stores configuration for integrations linked to a project.
CREATE TABLE integrations (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
type VARCHAR(50) NOT NULL, -- e.g., 'github', 'slack'
config JSONB NOT NULL,
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
UNIQUE(project_id, type)
);
-- ##################################################################
-- ## Join Tables (for Relationships)
-- ##################################################################
-- user_roles: Assigns global roles to users.
CREATE TABLE user_roles (
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE, -- CHANGED: from INT to UUID
PRIMARY KEY (user_id, role_id)
);
-- role_permissions: Assigns permissions to roles.
CREATE TABLE role_permissions (
role_id UUID NOT NULL REFERENCES roles(id) ON DELETE CASCADE, -- CHANGED: from INT to UUID
permission_id UUID NOT NULL REFERENCES permissions(id) ON DELETE CASCADE, -- CHANGED: from INT to UUID
PRIMARY KEY (role_id, permission_id)
);
-- project_members: Links users to the projects they are a part of.
CREATE TABLE project_members (
project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
role_id UUID NOT NULL REFERENCES roles(id), -- CHANGED: from INT to UUID
PRIMARY KEY (project_id, user_id)
);
-- task_assignees: Assigns one or more users to a specific task.
CREATE TABLE task_assignees (
task_id UUID NOT NULL REFERENCES tasks(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
PRIMARY KEY (task_id, user_id)
);