""" Align database schema to the unified design spec. Changes: - users: id INT, set defaults, drop extra columns not in design - user_teams/exams: user_id INT - teams: drop created_by/updated_by - training_*: fix defaults; set created_by/updated_by to BIGINT where required - training_reports: add unique(session_id) - create or replace view v_user_course_progress """ from alembic import op import sqlalchemy as sa # revision identifiers, used by Alembic. revision = "20250921_align_schema_to_design" down_revision = "9245f8845fe1" branch_labels = None depends_on = None def upgrade(): connection = op.get_bind() # users: enforce INT PK, defaults, and drop extra columns op.execute(""" ALTER TABLE `users` MODIFY COLUMN `id` INT AUTO_INCREMENT, MODIFY COLUMN `username` VARCHAR(50) NOT NULL, MODIFY COLUMN `email` VARCHAR(100) NOT NULL, MODIFY COLUMN `password_hash` VARCHAR(200) NOT NULL, MODIFY COLUMN `role` VARCHAR(20) DEFAULT 'trainee', MODIFY COLUMN `is_active` TINYINT(1) DEFAULT 1, MODIFY COLUMN `is_verified` TINYINT(1) DEFAULT 0, MODIFY COLUMN `created_at` DATETIME DEFAULT CURRENT_TIMESTAMP, MODIFY COLUMN `updated_at` DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP """) # Drop extra columns that are not in the design (ignore errors if absent) for col in [ "is_superuser", "department", "position", "last_login", "login_count", "failed_login_count", "locked_until", "created_by", "updated_by", "is_deleted", "deleted_at", ]: try: op.execute(f"ALTER TABLE `users` DROP COLUMN `{col}`") except Exception: pass # user_teams: user_id INT op.execute(""" ALTER TABLE `user_teams` MODIFY COLUMN `user_id` INT NOT NULL """) # exams: user_id INT op.execute(""" ALTER TABLE `exams` MODIFY COLUMN `user_id` INT NOT NULL """) # teams: drop created_by/updated_by to match design for col in ["created_by", "updated_by"]: try: op.execute(f"ALTER TABLE `teams` DROP COLUMN `{col}`") except Exception: pass # training_scenes: set defaults and BIGINT audit fields op.execute(""" ALTER TABLE `training_scenes` MODIFY COLUMN `status` ENUM('DRAFT','ACTIVE','INACTIVE') NOT NULL DEFAULT 'DRAFT', MODIFY COLUMN `is_public` TINYINT(1) NOT NULL DEFAULT 1, MODIFY COLUMN `created_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, MODIFY COLUMN `updated_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, MODIFY COLUMN `created_by` BIGINT NULL, MODIFY COLUMN `updated_by` BIGINT NULL """) # training_sessions: defaults and BIGINT audit fields op.execute(""" ALTER TABLE `training_sessions` MODIFY COLUMN `start_time` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, MODIFY COLUMN `status` ENUM('CREATED','IN_PROGRESS','COMPLETED','CANCELLED','ERROR') NOT NULL DEFAULT 'CREATED', MODIFY COLUMN `created_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, MODIFY COLUMN `updated_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, MODIFY COLUMN `created_by` BIGINT NULL, MODIFY COLUMN `updated_by` BIGINT NULL """) # training_messages: timestamps defaults op.execute(""" ALTER TABLE `training_messages` MODIFY COLUMN `created_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, MODIFY COLUMN `updated_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP """) # training_reports: timestamps defaults and BIGINT audit fields op.execute(""" ALTER TABLE `training_reports` MODIFY COLUMN `created_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP, MODIFY COLUMN `updated_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, MODIFY COLUMN `created_by` BIGINT NULL, MODIFY COLUMN `updated_by` BIGINT NULL """) # Add unique constraint for training_reports.session_id per design try: op.create_unique_constraint( "uq_training_reports_session_id", "training_reports", ["session_id"] ) except Exception: pass # Create or replace view v_user_course_progress op.execute(""" CREATE OR REPLACE VIEW v_user_course_progress AS SELECT u.id AS user_id, u.username, c.id AS course_id, c.name AS course_name, COUNT(DISTINCT e.id) AS exam_count, AVG(e.score) AS avg_score, MAX(e.score) AS best_score FROM users u CROSS JOIN courses c LEFT JOIN exams e ON e.user_id = u.id AND e.course_id = c.id AND e.status = 'submitted' GROUP BY u.id, c.id """) def downgrade(): # Drop the view to rollback try: op.execute("DROP VIEW IF EXISTS v_user_course_progress") except Exception: pass # Note: Full downgrade to previous heterogeneous state is not implemented to avoid data loss. # Keep this as a no-op for column-level reversions. pass