-- ===================================================== -- 重新設計評分數據庫架構 -- 讓評分系統完全基於 competition_rules 的動態內容 -- ===================================================== -- 1. 創建新的評分記錄表(基於競賽規則) CREATE TABLE `judge_scores` ( `id` VARCHAR(36) PRIMARY KEY, `judge_id` VARCHAR(36) NOT NULL, `app_id` VARCHAR(36) NOT NULL, `competition_id` VARCHAR(36) NOT NULL, `total_score` DECIMAL(5,2) NOT NULL, `comments` TEXT, `submitted_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (`judge_id`) REFERENCES `judges`(`id`) ON DELETE CASCADE, FOREIGN KEY (`app_id`) REFERENCES `apps`(`id`) ON DELETE CASCADE, FOREIGN KEY (`competition_id`) REFERENCES `competitions`(`id`) ON DELETE CASCADE, UNIQUE KEY `unique_judge_app_competition` (`judge_id`, `app_id`, `competition_id`), INDEX `idx_judge` (`judge_id`), INDEX `idx_app` (`app_id`), INDEX `idx_competition` (`competition_id`), INDEX `idx_total_score` (`total_score`) ); -- 2. 創建評分項目詳情表(存儲具體的評分項目和分數) CREATE TABLE `judge_score_details` ( `id` VARCHAR(36) PRIMARY KEY, `judge_score_id` VARCHAR(36) NOT NULL, `rule_id` VARCHAR(36) NOT NULL, `rule_name` VARCHAR(200) NOT NULL, `score` INT NOT NULL CHECK (`score` >= 1 AND `score` <= 10), `weight` DECIMAL(5,2) NOT NULL DEFAULT 0.00, `created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (`judge_score_id`) REFERENCES `judge_scores`(`id`) ON DELETE CASCADE, FOREIGN KEY (`rule_id`) REFERENCES `competition_rules`(`id`) ON DELETE CASCADE, UNIQUE KEY `unique_score_rule` (`judge_score_id`, `rule_id`), INDEX `idx_judge_score` (`judge_score_id`), INDEX `idx_rule` (`rule_id`) ); -- 3. 備份現有的 app_judge_scores 數據(如果需要) CREATE TABLE `app_judge_scores_backup` AS SELECT * FROM `app_judge_scores`; -- 4. 遷移現有數據到新結構 INSERT INTO `judge_scores` ( `id`, `judge_id`, `app_id`, `competition_id`, `total_score`, `comments`, `submitted_at` ) SELECT `id`, `judge_id`, `app_id`, COALESCE( (SELECT ca.competition_id FROM competition_apps ca WHERE ca.app_id = ajs.app_id LIMIT 1), 'unknown-competition' ) as competition_id, `total_score`, `comments`, `submitted_at` FROM `app_judge_scores` ajs; -- 5. 遷移評分詳情數據 INSERT INTO `judge_score_details` ( `id`, `judge_score_id`, `rule_id`, `rule_name`, `score`, `weight` ) SELECT UUID() as id, ajs.id as judge_score_id, 'migration-innovation' as rule_id, '創新程度' as rule_name, ajs.innovation_score as score, 20.00 as weight FROM `app_judge_scores` ajs WHERE ajs.innovation_score > 0 UNION ALL SELECT UUID() as id, ajs.id as judge_score_id, 'migration-technical' as rule_id, '技術實現' as rule_name, ajs.technical_score as score, 20.00 as weight FROM `app_judge_scores` ajs WHERE ajs.technical_score > 0 UNION ALL SELECT UUID() as id, ajs.id as judge_score_id, 'migration-usability' as rule_id, '實用性' as rule_name, ajs.usability_score as score, 20.00 as weight FROM `app_judge_scores` ajs WHERE ajs.usability_score > 0 UNION ALL SELECT UUID() as id, ajs.id as judge_score_id, 'migration-presentation' as rule_id, '展示效果' as rule_name, ajs.presentation_score as score, 20.00 as weight FROM `app_judge_scores` ajs WHERE ajs.presentation_score > 0 UNION ALL SELECT UUID() as id, ajs.id as judge_score_id, 'migration-impact' as rule_id, '影響力' as rule_name, ajs.impact_score as score, 20.00 as weight FROM `app_judge_scores` ajs WHERE ajs.impact_score > 0; -- 6. 刪除舊的 app_judge_scores 表 -- DROP TABLE `app_judge_scores`; -- 7. 創建視圖以保持向後兼容性 CREATE VIEW `app_judge_scores` AS SELECT js.id, js.judge_id, js.app_id, js.total_score, js.comments, js.submitted_at, -- 動態生成評分字段(基於競賽規則) COALESCE(MAX(CASE WHEN jsd.rule_name = '創新程度' THEN jsd.score END), 0) as innovation_score, COALESCE(MAX(CASE WHEN jsd.rule_name = '技術實現' THEN jsd.score END), 0) as technical_score, COALESCE(MAX(CASE WHEN jsd.rule_name = '實用性' THEN jsd.score END), 0) as usability_score, COALESCE(MAX(CASE WHEN jsd.rule_name = '展示效果' THEN jsd.score END), 0) as presentation_score, COALESCE(MAX(CASE WHEN jsd.rule_name = '影響力' THEN jsd.score END), 0) as impact_score FROM `judge_scores` js LEFT JOIN `judge_score_details` jsd ON js.id = jsd.judge_score_id GROUP BY js.id, js.judge_id, js.app_id, js.total_score, js.comments, js.submitted_at;