-- Gitea Project Management Database Schema -- Users table (can sync with Gitea users) CREATE TABLE users ( id BIGINT PRIMARY KEY AUTO_INCREMENT, gitea_user_id BIGINT UNIQUE, username VARCHAR(255) NOT NULL UNIQUE, email VARCHAR(255) NOT NULL, full_name VARCHAR(255), avatar_url VARCHAR(500), role ENUM('admin', 'manager', 'developer', 'tester', 'viewer') DEFAULT 'developer', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP ); -- Projects table CREATE TABLE projects ( id BIGINT PRIMARY KEY AUTO_INCREMENT, name VARCHAR(255) NOT NULL, description TEXT, gitea_org VARCHAR(255), status ENUM('active', 'archived', 'planning') DEFAULT 'planning', priority ENUM('low', 'medium', 'high', 'critical') DEFAULT 'medium', start_date DATE, end_date DATE, owner_id BIGINT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (owner_id) REFERENCES users(id) ); -- Project members table CREATE TABLE project_members ( id BIGINT PRIMARY KEY AUTO_INCREMENT, project_id BIGINT, user_id BIGINT, role ENUM('owner', 'manager', 'developer', 'tester', 'viewer') DEFAULT 'developer', joined_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE, FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE, UNIQUE KEY unique_project_user (project_id, user_id) ); -- Epics table (大型需求) CREATE TABLE epics ( id BIGINT PRIMARY KEY AUTO_INCREMENT, project_id BIGINT, title VARCHAR(255) NOT NULL, description TEXT, status ENUM('backlog', 'planning', 'in_progress', 'testing', 'done', 'cancelled') DEFAULT 'backlog', priority ENUM('low', 'medium', 'high', 'critical') DEFAULT 'medium', assignee_id BIGINT, reporter_id BIGINT, start_date DATE, due_date DATE, estimated_hours DECIMAL(8,2), actual_hours DECIMAL(8,2) DEFAULT 0, progress_percentage TINYINT DEFAULT 0, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE, FOREIGN KEY (assignee_id) REFERENCES users(id), FOREIGN KEY (reporter_id) REFERENCES users(id) ); -- Stories table (用户故事) CREATE TABLE stories ( id BIGINT PRIMARY KEY AUTO_INCREMENT, epic_id BIGINT, project_id BIGINT, title VARCHAR(255) NOT NULL, description TEXT, acceptance_criteria TEXT, status ENUM('backlog', 'todo', 'in_progress', 'review', 'testing', 'done', 'cancelled') DEFAULT 'backlog', priority ENUM('low', 'medium', 'high', 'critical') DEFAULT 'medium', story_points TINYINT, assignee_id BIGINT, reporter_id BIGINT, sprint_id BIGINT, estimated_hours DECIMAL(8,2), actual_hours DECIMAL(8,2) DEFAULT 0, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (epic_id) REFERENCES epics(id) ON DELETE SET NULL, FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE, FOREIGN KEY (assignee_id) REFERENCES users(id), FOREIGN KEY (reporter_id) REFERENCES users(id) ); -- Tasks table (具体任务) CREATE TABLE tasks ( id BIGINT PRIMARY KEY AUTO_INCREMENT, story_id BIGINT, project_id BIGINT, title VARCHAR(255) NOT NULL, description TEXT, status ENUM('todo', 'in_progress', 'review', 'testing', 'done', 'blocked') DEFAULT 'todo', priority ENUM('low', 'medium', 'high', 'critical') DEFAULT 'medium', task_type ENUM('feature', 'bug', 'improvement', 'research', 'documentation') DEFAULT 'feature', assignee_id BIGINT, reporter_id BIGINT, estimated_hours DECIMAL(8,2), actual_hours DECIMAL(8,2) DEFAULT 0, due_date DATE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (story_id) REFERENCES stories(id) ON DELETE SET NULL, FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE, FOREIGN KEY (assignee_id) REFERENCES users(id), FOREIGN KEY (reporter_id) REFERENCES users(id) ); -- Gitea integrations table (关联 Gitea 仓库对象) CREATE TABLE gitea_relations ( id BIGINT PRIMARY KEY AUTO_INCREMENT, task_id BIGINT, gitea_repo_id BIGINT, gitea_repo_name VARCHAR(255), relation_type ENUM('branch', 'commit', 'pull_request', 'issue') NOT NULL, gitea_object_id VARCHAR(255) NOT NULL, gitea_object_number BIGINT, gitea_object_title VARCHAR(255), gitea_object_url VARCHAR(500), created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (task_id) REFERENCES tasks(id) ON DELETE CASCADE, INDEX idx_task_relation (task_id, relation_type), INDEX idx_gitea_object (gitea_repo_id, relation_type, gitea_object_id) ); -- Sprints/Iterations table CREATE TABLE sprints ( id BIGINT PRIMARY KEY AUTO_INCREMENT, project_id BIGINT, name VARCHAR(255) NOT NULL, description TEXT, status ENUM('planning', 'active', 'completed') DEFAULT 'planning', start_date DATE, end_date DATE, goal TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE ); -- Comments table CREATE TABLE comments ( id BIGINT PRIMARY KEY AUTO_INCREMENT, entity_type ENUM('project', 'epic', 'story', 'task') NOT NULL, entity_id BIGINT NOT NULL, user_id BIGINT, content TEXT NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (user_id) REFERENCES users(id), INDEX idx_entity (entity_type, entity_id) ); -- Tags table CREATE TABLE tags ( id BIGINT PRIMARY KEY AUTO_INCREMENT, name VARCHAR(100) NOT NULL UNIQUE, color VARCHAR(7) DEFAULT '#1890ff', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Entity tags table (many-to-many) CREATE TABLE entity_tags ( id BIGINT PRIMARY KEY AUTO_INCREMENT, entity_type ENUM('project', 'epic', 'story', 'task') NOT NULL, entity_id BIGINT NOT NULL, tag_id BIGINT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (tag_id) REFERENCES tags(id) ON DELETE CASCADE, UNIQUE KEY unique_entity_tag (entity_type, entity_id, tag_id) ); -- Time logs table CREATE TABLE time_logs ( id BIGINT PRIMARY KEY AUTO_INCREMENT, task_id BIGINT, user_id BIGINT, hours DECIMAL(8,2) NOT NULL, description TEXT, log_date DATE NOT NULL, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (task_id) REFERENCES tasks(id) ON DELETE CASCADE, FOREIGN KEY (user_id) REFERENCES users(id) ); -- Webhooks configuration table CREATE TABLE webhook_configs ( id BIGINT PRIMARY KEY AUTO_INCREMENT, project_id BIGINT, gitea_repo_id BIGINT, gitea_repo_name VARCHAR(255), webhook_url VARCHAR(500), secret VARCHAR(255), events JSON, active BOOLEAN DEFAULT TRUE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, FOREIGN KEY (project_id) REFERENCES projects(id) ON DELETE CASCADE ); -- Add indexes for better performance CREATE INDEX idx_projects_status ON projects(status); CREATE INDEX idx_epics_project_status ON epics(project_id, status); CREATE INDEX idx_stories_project_status ON stories(project_id, status); CREATE INDEX idx_stories_epic ON stories(epic_id); CREATE INDEX idx_tasks_project_status ON tasks(project_id, status); CREATE INDEX idx_tasks_story ON tasks(story_id); CREATE INDEX idx_tasks_assignee ON tasks(assignee_id); CREATE INDEX idx_gitea_relations_task ON gitea_relations(task_id);