93 lines
3.7 KiB
SQL
93 lines
3.7 KiB
SQL
-- Create enum for project status
|
|
CREATE TYPE project_status AS ENUM ('PLANNING', 'IN_PROGRESS', 'COMPLETED', 'ON_HOLD', 'CANCELLED');
|
|
|
|
-- Create projects table
|
|
CREATE TABLE IF NOT EXISTS projects (
|
|
id SERIAL PRIMARY KEY,
|
|
name VARCHAR(255) NOT NULL,
|
|
description TEXT,
|
|
status project_status NOT NULL DEFAULT 'PLANNING',
|
|
client_id INTEGER REFERENCES users(id) ON DELETE SET NULL,
|
|
ipfs_metadata_cid VARCHAR(255), -- CID for project metadata stored on IPFS
|
|
start_date DATE,
|
|
end_date DATE,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create indexes for projects
|
|
CREATE INDEX idx_projects_client_id ON projects(client_id);
|
|
CREATE INDEX idx_projects_status ON projects(status);
|
|
CREATE INDEX idx_projects_ipfs_cid ON projects(ipfs_metadata_cid) WHERE ipfs_metadata_cid IS NOT NULL;
|
|
|
|
-- Create enum for task status
|
|
CREATE TYPE task_status AS ENUM ('TODO', 'IN_PROGRESS', 'BLOCKED', 'COMPLETED', 'CANCELLED');
|
|
|
|
-- Create tasks table
|
|
CREATE TABLE IF NOT EXISTS tasks (
|
|
id SERIAL PRIMARY KEY,
|
|
project_id INTEGER NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
|
|
title VARCHAR(255) NOT NULL,
|
|
description TEXT,
|
|
status task_status NOT NULL DEFAULT 'TODO',
|
|
assignee_id INTEGER REFERENCES users(id) ON DELETE SET NULL,
|
|
due_date DATE,
|
|
completed_at TIMESTAMP,
|
|
priority INTEGER DEFAULT 0, -- 0 = normal, higher = more urgent
|
|
estimated_hours DECIMAL(10, 2),
|
|
actual_hours DECIMAL(10, 2),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create indexes for tasks
|
|
CREATE INDEX idx_tasks_project_id ON tasks(project_id);
|
|
CREATE INDEX idx_tasks_assignee_id ON tasks(assignee_id);
|
|
CREATE INDEX idx_tasks_status ON tasks(status);
|
|
CREATE INDEX idx_tasks_due_date ON tasks(due_date) WHERE due_date IS NOT NULL;
|
|
|
|
-- Create work_orders table
|
|
CREATE TABLE IF NOT EXISTS work_orders (
|
|
id SERIAL PRIMARY KEY,
|
|
project_id INTEGER NOT NULL REFERENCES projects(id) ON DELETE CASCADE,
|
|
title VARCHAR(255) NOT NULL,
|
|
description TEXT,
|
|
order_number VARCHAR(50) UNIQUE NOT NULL,
|
|
ipfs_document_cid VARCHAR(255), -- CID for work order document on IPFS
|
|
created_by INTEGER REFERENCES users(id) ON DELETE SET NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create indexes for work_orders
|
|
CREATE INDEX idx_work_orders_project_id ON work_orders(project_id);
|
|
CREATE INDEX idx_work_orders_order_number ON work_orders(order_number);
|
|
CREATE INDEX idx_work_orders_created_by ON work_orders(created_by);
|
|
|
|
-- Create task_comments table for collaboration
|
|
CREATE TABLE IF NOT EXISTS task_comments (
|
|
id SERIAL PRIMARY KEY,
|
|
task_id INTEGER NOT NULL REFERENCES tasks(id) ON DELETE CASCADE,
|
|
user_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
|
comment TEXT NOT NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Create index for task_comments
|
|
CREATE INDEX idx_task_comments_task_id ON task_comments(task_id);
|
|
CREATE INDEX idx_task_comments_user_id ON task_comments(user_id);
|
|
|
|
-- Create triggers for updated_at
|
|
CREATE TRIGGER update_projects_updated_at BEFORE UPDATE ON projects
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_tasks_updated_at BEFORE UPDATE ON tasks
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_work_orders_updated_at BEFORE UPDATE ON work_orders
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_task_comments_updated_at BEFORE UPDATE ON task_comments
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|