137 lines
6.2 KiB
SQL
137 lines
6.2 KiB
SQL
-- =============================================
|
||
-- 项目人员关联表
|
||
-- 用于管理项目、机组、任务组、任务的人员关系
|
||
-- @author wangna
|
||
-- @date 2025/08/05
|
||
-- =============================================
|
||
|
||
-- 项目人员关联表
|
||
CREATE TABLE `project_member` (
|
||
`member_id` varchar(64) NOT NULL COMMENT '关联ID',
|
||
`project_id` varchar(64) NOT NULL COMMENT '项目ID',
|
||
`turbine_id` varchar(64) DEFAULT NULL COMMENT '机组ID(可选,关联到具体机组)',
|
||
`task_group_id` varchar(64) DEFAULT NULL COMMENT '任务组ID(可选,关联到具体任务组)',
|
||
`task_id` varchar(64) DEFAULT NULL COMMENT '任务ID(可选,关联到具体任务)',
|
||
`user_id` varchar(64) NOT NULL COMMENT '用户ID',
|
||
`role_type` varchar(50) NOT NULL COMMENT '项目角色类型',
|
||
`job_code` varchar(50) DEFAULT NULL COMMENT '具体岗位代码',
|
||
`job_desc` varchar(500) DEFAULT NULL COMMENT '岗位描述',
|
||
`join_date` date NOT NULL COMMENT '加入时间',
|
||
`leave_date` date DEFAULT NULL COMMENT '离开时间',
|
||
`status` varchar(20) DEFAULT 'ACTIVE' COMMENT '状态:ACTIVE-在职,INACTIVE-离职,SUSPENDED-暂停',
|
||
`remark` varchar(500) DEFAULT NULL COMMENT '备注',
|
||
`create_by` varchar(64) DEFAULT NULL COMMENT '创建人',
|
||
`create_time` datetime DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
`update_by` varchar(64) DEFAULT NULL COMMENT '更新人',
|
||
`update_time` datetime DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
PRIMARY KEY (`member_id`),
|
||
KEY `idx_project_id` (`project_id`),
|
||
KEY `idx_turbine_id` (`turbine_id`),
|
||
KEY `idx_task_group_id` (`task_group_id`),
|
||
KEY `idx_task_id` (`task_id`),
|
||
KEY `idx_user_id` (`user_id`),
|
||
KEY `idx_role_type` (`role_type`),
|
||
KEY `idx_status` (`status`),
|
||
UNIQUE KEY `uk_project_user_role` (`project_id`, `user_id`, `role_type`, `turbine_id`, `task_group_id`, `task_id`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='项目人员关联表';
|
||
|
||
-- 添加复合索引以提高查询性能
|
||
CREATE INDEX `idx_project_member_composite` ON `project_member` (`project_id`, `status`, `role_type`);
|
||
CREATE INDEX `idx_project_member_user_status` ON `project_member` (`user_id`, `status`);
|
||
CREATE INDEX `idx_project_member_turbine_status` ON `project_member` (`turbine_id`, `status`);
|
||
CREATE INDEX `idx_project_member_task_status` ON `project_member` (`task_id`, `status`);
|
||
|
||
-- =============================================
|
||
-- 数据迁移脚本(可选)
|
||
-- 将现有项目的人员数据迁移到新表
|
||
-- =============================================
|
||
|
||
-- 迁移项目经理数据
|
||
INSERT INTO project_member (member_id, project_id, user_id, role_type, job_code, join_date, status, create_time)
|
||
SELECT
|
||
UUID() as member_id,
|
||
project_id,
|
||
project_manager_id as user_id,
|
||
'PROJECT_MANAGER' as role_type,
|
||
'PROJECT_MANAGER' as job_code,
|
||
create_time as join_date,
|
||
'ACTIVE' as status,
|
||
create_time
|
||
FROM project
|
||
WHERE project_manager_id IS NOT NULL AND project_manager_id != '';
|
||
|
||
-- 迁移安全员数据
|
||
INSERT INTO project_member (member_id, project_id, user_id, role_type, job_code, join_date, status, create_time)
|
||
SELECT
|
||
UUID() as member_id,
|
||
project_id,
|
||
auditor_id as user_id,
|
||
'SAFETY_OFFICER' as role_type,
|
||
'SAFETY_MANAGER' as job_code,
|
||
create_time as join_date,
|
||
'ACTIVE' as status,
|
||
create_time
|
||
FROM project
|
||
WHERE auditor_id IS NOT NULL AND auditor_id != '';
|
||
|
||
-- 迁移质量员数据
|
||
INSERT INTO project_member (member_id, project_id, user_id, role_type, job_code, join_date, status, create_time)
|
||
SELECT
|
||
UUID() as member_id,
|
||
project_id,
|
||
quality_officer_id as user_id,
|
||
'QUALITY_OFFICER' as role_type,
|
||
'QUALITY_MANAGER' as job_code,
|
||
create_time as join_date,
|
||
'ACTIVE' as status,
|
||
create_time
|
||
FROM project
|
||
WHERE quality_officer_id IS NOT NULL AND quality_officer_id != '';
|
||
|
||
-- 迁移施工组长数据
|
||
INSERT INTO project_member (member_id, project_id, user_id, role_type, job_code, join_date, status, create_time)
|
||
SELECT
|
||
UUID() as member_id,
|
||
project_id,
|
||
construct_team_leader_id as user_id,
|
||
'TEAM_LEADER' as role_type,
|
||
'TEAM_LEADER' as job_code,
|
||
create_time as join_date,
|
||
'ACTIVE' as status,
|
||
create_time
|
||
FROM project
|
||
WHERE construct_team_leader_id IS NOT NULL AND construct_team_leader_id != '';
|
||
|
||
-- 迁移施工人员数据(需要处理逗号分隔的多个ID)
|
||
-- 注意:这个脚本需要根据实际情况调整,因为constructor_ids是逗号分隔的字符串
|
||
-- 建议在应用层处理这个迁移逻辑
|
||
|
||
-- =============================================
|
||
-- 示例数据插入
|
||
-- =============================================
|
||
|
||
-- 插入示例项目人员数据
|
||
INSERT INTO project_member (member_id, project_id, user_id, role_type, job_code, job_desc, join_date, status, remark) VALUES
|
||
('pm001', 'project001', 'user001', 'PROJECT_MANAGER', 'PROJECT_MANAGER', '项目经理', '2025-01-01', 'ACTIVE', '项目负责人'),
|
||
('pm002', 'project001', 'user002', 'SAFETY_OFFICER', 'SAFETY_MANAGER', '安全经理', '2025-01-01', 'ACTIVE', '负责项目安全'),
|
||
('pm003', 'project001', 'user003', 'QUALITY_OFFICER', 'QUALITY_MANAGER', '质量经理', '2025-01-01', 'ACTIVE', '负责项目质量'),
|
||
('pm004', 'project001', 'user004', 'CONSTRUCTOR', 'GROUND_SERVICE', '地勤人员', '2025-01-01', 'ACTIVE', '地勤工作'),
|
||
('pm005', 'project001', 'user005', 'CONSTRUCTOR', 'DRIVER', '司机', '2025-01-01', 'ACTIVE', '负责运输'),
|
||
('pm006', 'project001', 'user006', 'CONSTRUCTOR', 'ASCENDING', '登高人员', '2025-01-01', 'ACTIVE', '高空作业');
|
||
|
||
-- =============================================
|
||
-- 查询示例
|
||
-- =============================================
|
||
|
||
-- 查询项目所有人员
|
||
-- SELECT * FROM project_member WHERE project_id = 'project001' AND status = 'ACTIVE';
|
||
|
||
-- 查询项目的项目经理
|
||
-- SELECT * FROM project_member WHERE project_id = 'project001' AND role_type = 'PROJECT_MANAGER' AND status = 'ACTIVE';
|
||
|
||
-- 查询用户参与的所有项目
|
||
-- SELECT DISTINCT project_id FROM project_member WHERE user_id = 'user001' AND status = 'ACTIVE';
|
||
|
||
-- 查询机组人员
|
||
-- SELECT * FROM project_member WHERE turbine_id = 'turbine001' AND status = 'ACTIVE';
|
||
CREATE INDEX `idx_project_member_task_status` ON `project_member` (`task_id`, `status`); |