161 lines
4.8 KiB
Markdown
161 lines
4.8 KiB
Markdown
# Database Schema (PostgreSQL)
|
|
|
|
```sql
|
|
-- Multi-Tenant
|
|
CREATE TABLE companies (
|
|
id UUID PRIMARY KEY,
|
|
name VARCHAR(255) NOT NULL,
|
|
address TEXT,
|
|
contact_email VARCHAR(255),
|
|
contact_phone VARCHAR(50),
|
|
logo_url TEXT,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Users and Roles
|
|
CREATE TABLE roles (
|
|
id SERIAL PRIMARY KEY,
|
|
name VARCHAR(50) UNIQUE NOT NULL,
|
|
permissions JSONB
|
|
);
|
|
|
|
CREATE TABLE users (
|
|
id UUID PRIMARY KEY,
|
|
company_id UUID REFERENCES companies(id),
|
|
email VARCHAR(255) UNIQUE NOT NULL,
|
|
password_hash VARCHAR(255) NOT NULL,
|
|
first_name VARCHAR(100),
|
|
last_name VARCHAR(100),
|
|
role_id INTEGER REFERENCES roles(id),
|
|
hourly_rate DECIMAL(10, 2),
|
|
is_active BOOLEAN DEFAULT TRUE,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Customers
|
|
CREATE TABLE customers (
|
|
id UUID PRIMARY KEY,
|
|
company_id UUID NOT NULL REFERENCES companies(id),
|
|
name VARCHAR(255) NOT NULL,
|
|
contact_person VARCHAR(255),
|
|
email VARCHAR(255),
|
|
phone VARCHAR(50),
|
|
address TEXT,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Projects
|
|
CREATE TABLE projects (
|
|
id UUID PRIMARY KEY,
|
|
company_id UUID NOT NULL REFERENCES companies(id),
|
|
customer_id UUID REFERENCES customers(id),
|
|
name VARCHAR(255) NOT NULL,
|
|
description TEXT,
|
|
start_date DATE,
|
|
end_date DATE,
|
|
status VARCHAR(50),
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Activities
|
|
CREATE TABLE activities (
|
|
id UUID PRIMARY KEY,
|
|
company_id UUID NOT NULL REFERENCES companies(id),
|
|
name VARCHAR(255) NOT NULL,
|
|
description TEXT,
|
|
billing_rate DECIMAL(10, 2),
|
|
is_active BOOLEAN DEFAULT TRUE,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Time bookings
|
|
CREATE TABLE time_entries (
|
|
id UUID PRIMARY KEY,
|
|
company_id UUID NOT NULL REFERENCES companies(id),
|
|
user_id UUID NOT NULL REFERENCES users(id),
|
|
project_id UUID NOT NULL REFERENCES projects(id),
|
|
activity_id UUID NOT NULL REFERENCES activities(id),
|
|
start_time TIMESTAMP NOT NULL,
|
|
end_time TIMESTAMP NOT NULL,
|
|
duration INTEGER NOT NULL, -- in minutes
|
|
description TEXT,
|
|
billable_percentage INTEGER NOT NULL DEFAULT 100,
|
|
billing_rate DECIMAL(10, 2),
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Version 2: Sprint/Task Management
|
|
CREATE TABLE sprints (
|
|
id UUID PRIMARY KEY,
|
|
project_id UUID NOT NULL REFERENCES projects(id),
|
|
name VARCHAR(255) NOT NULL,
|
|
start_date DATE NOT NULL,
|
|
end_date DATE NOT NULL,
|
|
status VARCHAR(50),
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
CREATE TABLE task_statuses (
|
|
id SERIAL PRIMARY KEY,
|
|
company_id UUID NOT NULL REFERENCES companies(id),
|
|
name VARCHAR(100) NOT NULL,
|
|
color VARCHAR(7),
|
|
position INTEGER NOT NULL,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
CREATE TABLE tasks (
|
|
id UUID PRIMARY KEY,
|
|
company_id UUID NOT NULL REFERENCES companies(id),
|
|
project_id UUID NOT NULL REFERENCES projects(id),
|
|
sprint_id UUID REFERENCES sprints(id),
|
|
title VARCHAR(255) NOT NULL,
|
|
description TEXT,
|
|
assignee_id UUID REFERENCES users(id),
|
|
status_id INTEGER REFERENCES task_statuses(id),
|
|
priority VARCHAR(50),
|
|
estimate INTEGER, -- in minutes
|
|
due_date TIMESTAMP,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
CREATE TABLE kanban_boards (
|
|
id UUID PRIMARY KEY,
|
|
company_id UUID NOT NULL REFERENCES companies(id),
|
|
project_id UUID NOT NULL REFERENCES projects(id),
|
|
name VARCHAR(255) NOT NULL,
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
CREATE TABLE kanban_columns (
|
|
id UUID PRIMARY KEY,
|
|
board_id UUID NOT NULL REFERENCES kanban_boards(id),
|
|
name VARCHAR(100) NOT NULL,
|
|
position INTEGER NOT NULL,
|
|
task_status_id INTEGER REFERENCES task_statuses(id),
|
|
created_at TIMESTAMP NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP NOT NULL DEFAULT NOW()
|
|
);
|
|
|
|
-- Linking time entries and tasks
|
|
ALTER TABLE time_entries ADD COLUMN task_id UUID REFERENCES tasks(id);
|
|
|
|
-- Indexes for performance
|
|
CREATE INDEX idx_time_entries_user ON time_entries(user_id);
|
|
CREATE INDEX idx_time_entries_project ON time_entries(project_id);
|
|
CREATE INDEX idx_time_entries_date ON time_entries(start_time);
|
|
CREATE INDEX idx_projects_company ON projects(company_id);
|
|
CREATE INDEX idx_users_company ON users(company_id);
|
|
CREATE INDEX idx_tasks_project ON tasks(project_id);
|
|
CREATE INDEX idx_tasks_sprint ON tasks(sprint_id);
|