- 创建普拉提分类和动作数据的SQL导入脚本,支持垫上普拉提和器械普拉提的分类管理 - 实现数据库结构迁移脚本,添加新字段以支持普拉提类型和器械名称 - 更新数据库升级总结文档,详细说明数据库结构变更和数据导入步骤 - 创建训练会话相关表,支持每日训练实例功能 - 引入训练会话管理模块,整合训练计划与实际训练会话的关系
139 lines
5.3 KiB
SQL
139 lines
5.3 KiB
SQL
-- 训练计划相关表单独创建脚本
|
||
-- 此脚本仅创建训练计划相关的表,前提是动作表已经存在
|
||
|
||
-- 禁用外键检查
|
||
SET FOREIGN_KEY_CHECKS = 0;
|
||
|
||
-- 删除训练计划相关表(如果存在)
|
||
DROP TABLE IF EXISTS `t_schedule_exercises`;
|
||
DROP TABLE IF EXISTS `t_training_plans`;
|
||
|
||
-- 重新启用外键检查
|
||
SET FOREIGN_KEY_CHECKS = 1;
|
||
|
||
-- 创建训练计划表
|
||
CREATE TABLE `t_training_plans` (
|
||
`id` char(36) NOT NULL COMMENT '训练计划唯一ID',
|
||
`is_active` tinyint(1) NOT NULL DEFAULT '0' COMMENT '是否激活',
|
||
`user_id` varchar(255) NOT NULL COMMENT '用户ID',
|
||
`name` varchar(255) DEFAULT NULL COMMENT '计划名称',
|
||
`created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
`start_date` datetime NOT NULL COMMENT '开始日期',
|
||
`mode` enum('daysOfWeek','sessionsPerWeek') NOT NULL COMMENT '计划模式',
|
||
`days_of_week` json NOT NULL COMMENT '周几训练(0-6)',
|
||
`sessions_per_week` int NOT NULL COMMENT '每周训练次数',
|
||
`goal` enum('postpartum_recovery','fat_loss','posture_correction','core_strength','flexibility','rehab','stress_relief','') NOT NULL COMMENT '训练目标',
|
||
`start_weight_kg` float DEFAULT NULL COMMENT '起始体重(公斤)',
|
||
`preferred_time_of_day` enum('morning','noon','evening','') NOT NULL DEFAULT '' COMMENT '偏好训练时间',
|
||
`updated_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
`deleted` tinyint(1) NOT NULL DEFAULT '0' COMMENT '是否已删除',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_user_id` (`user_id`),
|
||
KEY `idx_is_active` (`is_active`),
|
||
KEY `idx_deleted` (`deleted`),
|
||
KEY `idx_user_active` (`user_id`, `is_active`, `deleted`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='训练计划表';
|
||
|
||
-- 创建训练计划动作表
|
||
CREATE TABLE `t_schedule_exercises` (
|
||
`id` char(36) NOT NULL COMMENT '计划动作唯一ID',
|
||
`training_plan_id` char(36) NOT NULL COMMENT '训练计划ID',
|
||
`user_id` varchar(255) NOT NULL COMMENT '用户ID',
|
||
`exercise_key` varchar(255) DEFAULT NULL COMMENT '关联的动作key(仅exercise类型)',
|
||
`name` varchar(255) NOT NULL COMMENT '项目名称',
|
||
`sets` int DEFAULT NULL COMMENT '组数',
|
||
`reps` int DEFAULT NULL COMMENT '重复次数',
|
||
`duration_sec` int DEFAULT NULL COMMENT '持续时长(秒)',
|
||
`rest_sec` int DEFAULT NULL COMMENT '休息时长(秒)',
|
||
`note` text DEFAULT NULL COMMENT '备注',
|
||
`item_type` enum('exercise','rest','note') NOT NULL DEFAULT 'exercise' COMMENT '项目类型',
|
||
`completed` tinyint(1) NOT NULL DEFAULT '0' COMMENT '是否已完成',
|
||
`sort_order` int NOT NULL COMMENT '排序顺序',
|
||
`created_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
`updated_at` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
`deleted` tinyint(1) NOT NULL DEFAULT '0' COMMENT '是否已删除',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_training_plan_id` (`training_plan_id`),
|
||
KEY `idx_exercise_key` (`exercise_key`),
|
||
KEY `idx_user_id` (`user_id`),
|
||
KEY `idx_sort_order` (`sort_order`),
|
||
KEY `idx_item_type` (`item_type`),
|
||
KEY `idx_plan_sort` (`training_plan_id`, `sort_order`),
|
||
CONSTRAINT `fk_schedule_exercises_training_plan` FOREIGN KEY (`training_plan_id`) REFERENCES `t_training_plans` (`id`) ON DELETE CASCADE ON UPDATE CASCADE,
|
||
CONSTRAINT `fk_schedule_exercises_exercise` FOREIGN KEY (`exercise_key`) REFERENCES `t_exercises` (`key`) ON DELETE SET NULL ON UPDATE CASCADE
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='训练计划动作表';
|
||
|
||
-- 验证表创建
|
||
SELECT
|
||
TABLE_NAME,
|
||
TABLE_COMMENT,
|
||
ENGINE
|
||
FROM INFORMATION_SCHEMA.TABLES
|
||
WHERE TABLE_SCHEMA = DATABASE()
|
||
AND TABLE_NAME IN ('t_training_plans', 't_schedule_exercises')
|
||
ORDER BY TABLE_NAME;
|
||
|
||
-- 验证外键约束
|
||
SELECT
|
||
CONSTRAINT_NAME,
|
||
TABLE_NAME,
|
||
COLUMN_NAME,
|
||
REFERENCED_TABLE_NAME,
|
||
REFERENCED_COLUMN_NAME
|
||
FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE
|
||
WHERE TABLE_SCHEMA = DATABASE()
|
||
AND REFERENCED_TABLE_NAME IS NOT NULL
|
||
AND TABLE_NAME = 't_schedule_exercises'
|
||
ORDER BY CONSTRAINT_NAME;
|
||
|
||
-- 测试外键约束(插入测试数据)
|
||
-- 注意:这需要先有有效的 exercise_key 数据
|
||
|
||
/*
|
||
示例测试(请根据实际数据调整):
|
||
|
||
-- 插入测试训练计划
|
||
INSERT INTO t_training_plans (
|
||
id, user_id, name, start_date, mode, days_of_week, sessions_per_week, goal
|
||
) VALUES (
|
||
'550e8400-e29b-41d4-a716-446655440000',
|
||
'test_user_123',
|
||
'测试训练计划',
|
||
NOW(),
|
||
'daysOfWeek',
|
||
'[1,3,5]',
|
||
3,
|
||
'core_strength'
|
||
);
|
||
|
||
-- 插入测试动作
|
||
INSERT INTO t_schedule_exercises (
|
||
id, training_plan_id, user_id, exercise_key, name, sets, reps, item_type, sort_order
|
||
) VALUES (
|
||
'550e8400-e29b-41d4-a716-446655440001',
|
||
'550e8400-e29b-41d4-a716-446655440000',
|
||
'test_user_123',
|
||
'mat_hundred',
|
||
'百次拍打',
|
||
3,
|
||
10,
|
||
'exercise',
|
||
1
|
||
);
|
||
|
||
-- 验证数据
|
||
SELECT
|
||
tp.name as plan_name,
|
||
se.name as exercise_name,
|
||
se.exercise_key,
|
||
e.target_muscle_groups
|
||
FROM t_training_plans tp
|
||
JOIN t_schedule_exercises se ON tp.id = se.training_plan_id
|
||
LEFT JOIN t_exercises e ON se.exercise_key = e.key
|
||
WHERE tp.user_id = 'test_user_123';
|
||
|
||
-- 清理测试数据
|
||
DELETE FROM t_schedule_exercises WHERE user_id = 'test_user_123';
|
||
DELETE FROM t_training_plans WHERE user_id = 'test_user_123';
|
||
*/
|