-- 5 Why Analyzer Database Schema -- Database: db_A102 -- Version: 1.1.0 -- Created: 2025-12-05 -- Updated: 2025-12-09 (Added 5Why_ prefix to all tables) USE db_A102; -- ============================================ -- Table: 5Why_users (使用者資料表) -- ============================================ CREATE TABLE IF NOT EXISTS 5Why_users ( id INT AUTO_INCREMENT PRIMARY KEY, employee_id VARCHAR(50) UNIQUE NOT NULL COMMENT '工號', username VARCHAR(100) NOT NULL COMMENT '使用者名稱', email VARCHAR(255) UNIQUE NOT NULL COMMENT 'Email', password_hash VARCHAR(255) NOT NULL COMMENT '密碼雜湊', role ENUM('user', 'admin', 'super_admin') DEFAULT 'user' COMMENT '權限等級', department VARCHAR(100) COMMENT '部門', position VARCHAR(100) COMMENT '職位', is_active BOOLEAN DEFAULT TRUE COMMENT '帳號啟用狀態', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '建立時間', updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新時間', last_login_at TIMESTAMP NULL COMMENT '最後登入時間', INDEX idx_employee_id (employee_id), INDEX idx_email (email), INDEX idx_role (role) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='使用者資料表'; -- ============================================ -- Table: 5Why_analyses (分析記錄表) -- ============================================ CREATE TABLE IF NOT EXISTS 5Why_analyses ( id INT AUTO_INCREMENT PRIMARY KEY, user_id INT NOT NULL COMMENT '使用者ID', finding TEXT NOT NULL COMMENT 'Finding描述', job_content TEXT NOT NULL COMMENT '工作內容', output_language VARCHAR(10) NOT NULL DEFAULT 'zh-TW' COMMENT '輸出語言', problem_restatement TEXT COMMENT '問題重述(5W1H)', analysis_result JSON COMMENT '完整分析結果(JSON格式)', status ENUM('pending', 'processing', 'completed', 'failed') DEFAULT 'pending' COMMENT '分析狀態', error_message TEXT COMMENT '錯誤訊息', processing_time INT COMMENT '處理時間(秒)', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '建立時間', updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新時間', FOREIGN KEY (user_id) REFERENCES 5Why_users(id) ON DELETE CASCADE, INDEX idx_user_id (user_id), INDEX idx_status (status), INDEX idx_created_at (created_at) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='分析記錄表'; -- ============================================ -- Table: 5Why_analysis_perspectives (分析角度詳細表) -- ============================================ CREATE TABLE IF NOT EXISTS 5Why_analysis_perspectives ( id INT AUTO_INCREMENT PRIMARY KEY, analysis_id INT NOT NULL COMMENT '分析記錄ID', perspective VARCHAR(100) NOT NULL COMMENT '分析角度(流程面、系統面等)', perspective_icon VARCHAR(10) COMMENT 'Emoji圖示', root_cause TEXT COMMENT '根本原因', permanent_solution TEXT COMMENT '永久性對策', logic_check_forward TEXT COMMENT '順向邏輯檢核', logic_check_backward TEXT COMMENT '逆向邏輯檢核', logic_valid BOOLEAN DEFAULT TRUE COMMENT '邏輯是否有效', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '建立時間', FOREIGN KEY (analysis_id) REFERENCES 5Why_analyses(id) ON DELETE CASCADE, INDEX idx_analysis_id (analysis_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='分析角度詳細表'; -- ============================================ -- Table: 5Why_analysis_whys (5 Why詳細記錄表) -- ============================================ CREATE TABLE IF NOT EXISTS 5Why_analysis_whys ( id INT AUTO_INCREMENT PRIMARY KEY, perspective_id INT NOT NULL COMMENT '分析角度ID', level INT NOT NULL COMMENT 'Why層級(1-5)', question TEXT NOT NULL COMMENT '問題', answer TEXT NOT NULL COMMENT '答案', is_verified BOOLEAN DEFAULT FALSE COMMENT '是否已驗證', verification_note TEXT COMMENT '驗證說明', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '建立時間', FOREIGN KEY (perspective_id) REFERENCES 5Why_analysis_perspectives(id) ON DELETE CASCADE, INDEX idx_perspective_id (perspective_id), INDEX idx_level (level) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='5 Why詳細記錄表'; -- ============================================ -- Table: 5Why_llm_configs (LLM API配置表) -- ============================================ CREATE TABLE IF NOT EXISTS 5Why_llm_configs ( id INT AUTO_INCREMENT PRIMARY KEY, provider VARCHAR(50) NOT NULL COMMENT 'LLM提供商(ollama, gemini, deepseek, openai)', api_url VARCHAR(255) COMMENT 'API URL', api_key VARCHAR(255) COMMENT 'API Key(加密儲存)', model_name VARCHAR(100) COMMENT '模型名稱', is_active BOOLEAN DEFAULT FALSE COMMENT '是否啟用', max_tokens INT DEFAULT 6000 COMMENT '最大Token數', temperature DECIMAL(3,2) DEFAULT 0.7 COMMENT '溫度參數', timeout INT DEFAULT 120000 COMMENT 'Timeout(毫秒)', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '建立時間', updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新時間', created_by INT COMMENT '建立者ID', FOREIGN KEY (created_by) REFERENCES 5Why_users(id) ON DELETE SET NULL, INDEX idx_provider (provider), INDEX idx_is_active (is_active), UNIQUE KEY unique_active_provider (provider, is_active) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='LLM API配置表'; -- ============================================ -- Table: 5Why_system_settings (系統設定表) -- ============================================ CREATE TABLE IF NOT EXISTS 5Why_system_settings ( id INT AUTO_INCREMENT PRIMARY KEY, setting_key VARCHAR(100) UNIQUE NOT NULL COMMENT '設定鍵', setting_value TEXT COMMENT '設定值', setting_type VARCHAR(50) DEFAULT 'string' COMMENT '設定類型(string, number, boolean, json)', description TEXT COMMENT '說明', is_public BOOLEAN DEFAULT FALSE COMMENT '是否公開(前端可見)', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '建立時間', updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新時間', updated_by INT COMMENT '更新者ID', FOREIGN KEY (updated_by) REFERENCES 5Why_users(id) ON DELETE SET NULL, INDEX idx_setting_key (setting_key), INDEX idx_is_public (is_public) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='系統設定表'; -- ============================================ -- Table: 5Why_audit_logs (稽核日誌表) -- ============================================ CREATE TABLE IF NOT EXISTS 5Why_audit_logs ( id INT AUTO_INCREMENT PRIMARY KEY, user_id INT COMMENT '使用者ID', action VARCHAR(100) NOT NULL COMMENT '動作(login, logout, create_analysis, update_user等)', entity_type VARCHAR(50) COMMENT '實體類型(user, analysis, llm_config等)', entity_id INT COMMENT '實體ID', old_value JSON COMMENT '舊值', new_value JSON COMMENT '新值', ip_address VARCHAR(45) COMMENT 'IP位址', user_agent TEXT COMMENT 'User Agent', status ENUM('success', 'failed') DEFAULT 'success' COMMENT '執行狀態', error_message TEXT COMMENT '錯誤訊息', created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '建立時間', FOREIGN KEY (user_id) REFERENCES 5Why_users(id) ON DELETE SET NULL, INDEX idx_user_id (user_id), INDEX idx_action (action), INDEX idx_created_at (created_at), INDEX idx_entity (entity_type, entity_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='稽核日誌表'; -- ============================================ -- Table: 5Why_sessions (Session表) -- ============================================ CREATE TABLE IF NOT EXISTS 5Why_sessions ( session_id VARCHAR(128) PRIMARY KEY, expires BIGINT UNSIGNED NOT NULL, data TEXT, INDEX idx_expires (expires) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='Session表'; -- ============================================ -- Insert Default Data -- ============================================ -- 預設管理者帳號(密碼: Admin@123456) INSERT INTO 5Why_users (employee_id, username, email, password_hash, role, department, position) VALUES ('ADMIN001', 'admin', 'admin@example.com', '$2a$10$YourBcryptHashHere', 'super_admin', 'IT', 'System Administrator'), ('USER001', 'user001', 'user001@example.com', '$2a$10$YourBcryptHashHere', 'user', 'Manufacturing', 'Engineer'), ('USER002', 'user002', 'user002@example.com', '$2a$10$YourBcryptHashHere', 'admin', 'Quality', 'QA Manager') ON DUPLICATE KEY UPDATE updated_at = CURRENT_TIMESTAMP; -- 預設 Ollama LLM 配置 INSERT INTO 5Why_llm_configs (provider, api_url, model_name, is_active, max_tokens, temperature, timeout) VALUES ('ollama', 'https://ollama_pjapi.theaken.com', 'qwen2.5:3b', TRUE, 6000, 0.7, 120000) ON DUPLICATE KEY UPDATE updated_at = CURRENT_TIMESTAMP; -- 預設系統設定 INSERT INTO 5Why_system_settings (setting_key, setting_value, setting_type, description, is_public) VALUES ('app_name', '5 Why Root Cause Analyzer', 'string', '應用程式名稱', TRUE), ('app_version', '1.0.0', 'string', '應用程式版本', TRUE), ('max_analysis_per_day', '50', 'number', '每日最大分析次數', FALSE), ('enable_email_notification', 'false', 'boolean', '啟用Email通知', FALSE), ('default_language', 'zh-TW', 'string', '預設語言', TRUE), ('supported_languages', '["zh-TW","zh-CN","en","ja","ko","vi","th"]', 'json', '支援的語言列表', TRUE) ON DUPLICATE KEY UPDATE updated_at = CURRENT_TIMESTAMP; -- ============================================ -- Create Views (視圖) -- ============================================ -- 使用者分析統計視圖 CREATE OR REPLACE VIEW 5Why_user_analysis_stats AS SELECT u.id AS user_id, u.username, u.employee_id, u.department, COUNT(a.id) AS total_analyses, COUNT(CASE WHEN a.status = 'completed' THEN 1 END) AS completed_analyses, COUNT(CASE WHEN a.status = 'failed' THEN 1 END) AS failed_analyses, AVG(a.processing_time) AS avg_processing_time, MAX(a.created_at) AS last_analysis_at FROM 5Why_users u LEFT JOIN 5Why_analyses a ON u.id = a.user_id GROUP BY u.id, u.username, u.employee_id, u.department; -- 最近分析記錄視圖 CREATE OR REPLACE VIEW 5Why_recent_analyses AS SELECT a.id, a.finding, u.username, u.employee_id, a.output_language, a.status, a.processing_time, a.created_at FROM 5Why_analyses a JOIN 5Why_users u ON a.user_id = u.id ORDER BY a.created_at DESC LIMIT 100; -- ============================================ -- End of Schema -- ============================================