80 lines
2.2 KiB
SQL
80 lines
2.2 KiB
SQL
-- 迁移脚本:为用户表添加租户内自增UID字段
|
||
-- 执行时间:需要手动执行此脚本
|
||
|
||
-- 1. 为yz_users表添加uid字段
|
||
ALTER TABLE yz_users ADD COLUMN uid INT DEFAULT 0 COMMENT '租户内用户ID,自增';
|
||
|
||
-- 2. 为现有用户分配uid(使用存储过程或手动更新)
|
||
-- 方法1:使用存储过程(推荐)
|
||
DELIMITER //
|
||
|
||
CREATE PROCEDURE update_user_uids()
|
||
BEGIN
|
||
DECLARE done INT DEFAULT FALSE;
|
||
DECLARE current_tenant_id INT;
|
||
DECLARE current_id INT;
|
||
DECLARE uid_counter INT DEFAULT 1;
|
||
|
||
-- 游标用于遍历所有租户
|
||
DECLARE tenant_cursor CURSOR FOR
|
||
SELECT DISTINCT tenant_id FROM yz_users WHERE delete_time IS NULL ORDER BY tenant_id;
|
||
|
||
-- 游标用于遍历每个租户内的用户
|
||
DECLARE user_cursor CURSOR FOR
|
||
SELECT id FROM yz_users
|
||
WHERE tenant_id = current_tenant_id AND delete_time IS NULL
|
||
ORDER BY id;
|
||
|
||
DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;
|
||
|
||
OPEN tenant_cursor;
|
||
|
||
tenant_loop: LOOP
|
||
FETCH tenant_cursor INTO current_tenant_id;
|
||
IF done THEN
|
||
LEAVE tenant_loop;
|
||
END IF;
|
||
|
||
SET uid_counter = 1;
|
||
SET done = FALSE;
|
||
|
||
OPEN user_cursor;
|
||
|
||
user_loop: LOOP
|
||
FETCH user_cursor INTO current_id;
|
||
IF done THEN
|
||
LEAVE user_loop;
|
||
END IF;
|
||
|
||
UPDATE yz_users SET uid = uid_counter WHERE id = current_id;
|
||
SET uid_counter = uid_counter + 1;
|
||
END LOOP user_loop;
|
||
|
||
CLOSE user_cursor;
|
||
SET done = FALSE;
|
||
END LOOP tenant_loop;
|
||
|
||
CLOSE tenant_cursor;
|
||
END //
|
||
|
||
DELIMITER ;
|
||
|
||
-- 执行存储过程
|
||
CALL update_user_uids();
|
||
|
||
-- 删除存储过程
|
||
DROP PROCEDURE update_user_uids();
|
||
|
||
-- 3. 创建索引以提高查询性能
|
||
CREATE INDEX idx_yz_users_tenant_uid ON yz_users(tenant_id, uid);
|
||
CREATE INDEX idx_yz_users_uid ON yz_users(uid);
|
||
|
||
-- 4. 验证迁移结果
|
||
-- SELECT tenant_id, uid, username FROM yz_users WHERE delete_time IS NULL ORDER BY tenant_id, uid;
|
||
|
||
-- 5. 添加注释说明
|
||
-- uid字段说明:
|
||
-- - 在每个tenant_id下从1开始递增
|
||
-- - 不同租户的uid可以重复
|
||
-- - 用于租户内的用户标识,避免使用全局id
|