Files
MHXY_WEB_VUE/backend/database/roles_init.sql
2026-01-04 21:04:30 +08:00

124 lines
3.9 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters
This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
-- ============================================
-- 梦幻西游一站式运营管理平台 - 角色表初始化脚本
-- MySQL 8.4 兼容版本
-- 创建日期2026-01-04
-- ============================================
-- 使用数据库
USE mhxy_web_vue;
-- 设置字符集
SET NAMES utf8mb4;
SET FOREIGN_KEY_CHECKS = 0;
-- ============================================
-- 表admin_roles管理员角色表
-- ============================================
DROP TABLE IF EXISTS `admin_roles`;
CREATE TABLE `admin_roles` (
`id` INT UNSIGNED NOT NULL AUTO_INCREMENT COMMENT '主键ID',
`role_name` VARCHAR(50) NOT NULL COMMENT '角色名称',
`role_code` VARCHAR(50) NOT NULL COMMENT '角色编码',
`description` VARCHAR(255) NULL COMMENT '角色描述',
`status` TINYINT NOT NULL DEFAULT 1 COMMENT '状态1:正常, 0:禁用)',
`created_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updated_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
PRIMARY KEY (`id`),
UNIQUE INDEX `idx_role_code` (`role_code`),
INDEX `idx_status` (`status`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='管理员角色表';
-- ============================================
-- 插入默认角色数据
-- ============================================
INSERT INTO `admin_roles` (`role_name`, `role_code`, `description`, `status`)
VALUES
('超级管理员', 'super_admin', '拥有系统所有权限', 1),
('系统管理员', 'system_admin', '管理系统配置和用户', 1),
('运营管理员', 'operation_admin', '负责运营相关功能', 1),
('数据管理员', 'data_admin', '负责数据查询和导出', 1);
-- ============================================
-- 修改 admin_users 表的 role_id 字段类型为 INT UNSIGNED
-- ============================================
ALTER TABLE `admin_users`
MODIFY COLUMN `role_id` INT UNSIGNED NOT NULL DEFAULT 1 COMMENT '角色ID1:超级管理员)';
-- ============================================
-- 删除 admin_users 表上的外键约束(如果存在)
-- ============================================
-- 创建存储过程来删除外键
DROP PROCEDURE IF EXISTS drop_foreign_key_if_exists;
DELIMITER $$
CREATE PROCEDURE drop_foreign_key_if_exists()
BEGIN
DECLARE fk_name VARCHAR(64);
-- 查询外键名称
SELECT CONSTRAINT_NAME INTO fk_name
FROM information_schema.KEY_COLUMN_USAGE
WHERE TABLE_SCHEMA = 'mhxy_web_vue'
AND TABLE_NAME = 'admin_users'
AND CONSTRAINT_NAME = 'fk_admin_users_role_id'
AND REFERENCED_TABLE_NAME = 'admin_roles';
-- 如果外键存在,则删除
IF fk_name IS NOT NULL THEN
SET @sql = CONCAT('ALTER TABLE `admin_users` DROP FOREIGN KEY `', fk_name, '`');
PREPARE stmt FROM @sql;
EXECUTE stmt;
DEALLOCATE PREPARE stmt;
END IF;
END$$
DELIMITER ;
-- 执行存储过程
CALL drop_foreign_key_if_exists();
-- 删除存储过程
DROP PROCEDURE IF EXISTS drop_foreign_key_if_exists;
-- ============================================
-- 添加外键约束
-- ============================================
ALTER TABLE `admin_users`
ADD CONSTRAINT `fk_admin_users_role_id`
FOREIGN KEY (`role_id`) REFERENCES `admin_roles` (`id`)
ON DELETE RESTRICT
ON UPDATE CASCADE;
-- ============================================
-- 更新现有管理员账号的角色ID
-- ============================================
UPDATE `admin_users`
SET `role_id` = 1
WHERE `username` = 'admin';
-- ============================================
-- 验证数据
-- ============================================
SELECT
id,
role_name,
role_code,
description,
status,
created_at
FROM admin_roles;
SELECT
au.id,
au.username,
au.real_name,
au.role_id,
ar.role_name,
au.status,
au.created_at
FROM admin_users au
LEFT JOIN admin_roles ar ON au.role_id = ar.id;
SET FOREIGN_KEY_CHECKS = 1;
-- 初始化完成