164 lines
6.8 KiB
SQL
164 lines
6.8 KiB
SQL
-- 创建OA模块相关表(租户应用)
|
||
-- 创建时间: 2025
|
||
-- 描述: 创建租户部门表、租户职位表和租户员工表
|
||
|
||
SET NAMES utf8mb4;
|
||
SET FOREIGN_KEY_CHECKS = 0;
|
||
|
||
-- =============================================
|
||
-- 1. 创建租户部门表
|
||
-- =============================================
|
||
CREATE TABLE IF NOT EXISTS yz_tenant_departments (
|
||
id INT PRIMARY KEY AUTO_INCREMENT COMMENT '部门ID',
|
||
tenant_id INT NOT NULL DEFAULT 0 COMMENT '租户ID',
|
||
name VARCHAR(100) NOT NULL COMMENT '部门名称',
|
||
code VARCHAR(50) DEFAULT NULL COMMENT '部门编码',
|
||
parent_id INT DEFAULT 0 COMMENT '父部门ID,0表示顶级部门',
|
||
description TEXT DEFAULT NULL COMMENT '部门描述',
|
||
manager_id INT DEFAULT NULL COMMENT '部门经理ID',
|
||
sort_order INT DEFAULT 0 COMMENT '排序序号',
|
||
status TINYINT DEFAULT 1 COMMENT '状态:1-启用,0-禁用',
|
||
create_time DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
update_time DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
delete_time DATETIME DEFAULT NULL COMMENT '删除时间(软删除)',
|
||
|
||
-- 索引
|
||
INDEX idx_tenant_id (tenant_id),
|
||
INDEX idx_code (code),
|
||
INDEX idx_parent_id (parent_id),
|
||
INDEX idx_status (status),
|
||
INDEX idx_sort_order (sort_order)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='租户部门表';
|
||
|
||
-- =============================================
|
||
-- 2. 创建租户职位表
|
||
-- =============================================
|
||
CREATE TABLE IF NOT EXISTS yz_tenant_positions (
|
||
id INT PRIMARY KEY AUTO_INCREMENT COMMENT '职位ID',
|
||
tenant_id INT NOT NULL DEFAULT 0 COMMENT '租户ID',
|
||
name VARCHAR(100) NOT NULL COMMENT '职位名称',
|
||
code VARCHAR(50) DEFAULT NULL COMMENT '职位编码',
|
||
department_id INT DEFAULT NULL COMMENT '所属部门ID',
|
||
level INT DEFAULT 0 COMMENT '职位级别',
|
||
description TEXT DEFAULT NULL COMMENT '职位描述',
|
||
sort_order INT DEFAULT 0 COMMENT '排序序号',
|
||
status TINYINT DEFAULT 1 COMMENT '状态:1-启用,0-禁用',
|
||
create_time DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
update_time DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
delete_time DATETIME DEFAULT NULL COMMENT '删除时间(软删除)',
|
||
|
||
-- 索引
|
||
INDEX idx_tenant_id (tenant_id),
|
||
INDEX idx_code (code),
|
||
INDEX idx_department_id (department_id),
|
||
INDEX idx_status (status),
|
||
INDEX idx_sort_order (sort_order)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='租户职位表';
|
||
|
||
-- =============================================
|
||
-- 3. 创建租户员工表(如果不存在)
|
||
-- =============================================
|
||
CREATE TABLE IF NOT EXISTS yz_tenant_employees (
|
||
id INT PRIMARY KEY AUTO_INCREMENT COMMENT '员工ID',
|
||
tenant_id INT NOT NULL DEFAULT 0 COMMENT '租户ID',
|
||
employee_no VARCHAR(50) NOT NULL COMMENT '工号',
|
||
name VARCHAR(50) NOT NULL COMMENT '姓名',
|
||
phone VARCHAR(20) DEFAULT NULL COMMENT '手机号',
|
||
email VARCHAR(100) DEFAULT NULL COMMENT '邮箱',
|
||
department_id INT DEFAULT NULL COMMENT '部门ID',
|
||
position_id INT DEFAULT NULL COMMENT '职位ID',
|
||
status TINYINT DEFAULT 1 COMMENT '状态:1-在职,0-离职',
|
||
create_time DATETIME DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
update_time DATETIME DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
delete_time DATETIME DEFAULT NULL COMMENT '删除时间(软删除)',
|
||
|
||
-- 索引
|
||
INDEX idx_tenant_id (tenant_id),
|
||
INDEX idx_employee_no (employee_no),
|
||
INDEX idx_name (name),
|
||
INDEX idx_department_id (department_id),
|
||
INDEX idx_position_id (position_id),
|
||
INDEX idx_status (status),
|
||
INDEX idx_create_time (create_time)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='租户员工表';
|
||
|
||
-- =============================================
|
||
-- 4. 更新用户表,添加部门和职位字段(如果不存在)
|
||
-- =============================================
|
||
-- 检查并添加 department_id 字段
|
||
SET @dbname = DATABASE();
|
||
SET @tablename = 'yz_users';
|
||
SET @columnname = 'department_id';
|
||
SET @preparedStatement = (SELECT IF(
|
||
(
|
||
SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
|
||
WHERE
|
||
(TABLE_SCHEMA = @dbname)
|
||
AND (TABLE_NAME = @tablename)
|
||
AND (COLUMN_NAME = @columnname)
|
||
) > 0,
|
||
'SELECT "Column department_id already exists in yz_users" AS "";',
|
||
'ALTER TABLE yz_users ADD COLUMN department_id INT DEFAULT NULL COMMENT ''部门ID'' AFTER role;'
|
||
));
|
||
PREPARE alterIfNotExists FROM @preparedStatement;
|
||
EXECUTE alterIfNotExists;
|
||
DEALLOCATE PREPARE alterIfNotExists;
|
||
|
||
-- 检查并添加 position_id 字段
|
||
SET @columnname = 'position_id';
|
||
SET @preparedStatement = (SELECT IF(
|
||
(
|
||
SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
|
||
WHERE
|
||
(TABLE_SCHEMA = @dbname)
|
||
AND (TABLE_NAME = @tablename)
|
||
AND (COLUMN_NAME = @columnname)
|
||
) > 0,
|
||
'SELECT "Column position_id already exists in yz_users" AS "";',
|
||
'ALTER TABLE yz_users ADD COLUMN position_id INT DEFAULT NULL COMMENT ''职位ID'' AFTER department_id;'
|
||
));
|
||
PREPARE alterIfNotExists FROM @preparedStatement;
|
||
EXECUTE alterIfNotExists;
|
||
DEALLOCATE PREPARE alterIfNotExists;
|
||
|
||
-- =============================================
|
||
-- 5. 更新租户员工表,添加部门和职位字段(如果不存在)
|
||
-- =============================================
|
||
-- 检查并添加 department_id 字段
|
||
SET @tablename = 'yz_tenant_employees';
|
||
SET @columnname = 'department_id';
|
||
SET @preparedStatement = (SELECT IF(
|
||
(
|
||
SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
|
||
WHERE
|
||
(TABLE_SCHEMA = @dbname)
|
||
AND (TABLE_NAME = @tablename)
|
||
AND (COLUMN_NAME = @columnname)
|
||
) > 0,
|
||
'SELECT "Column department_id already exists in yz_employees" AS "";',
|
||
'ALTER TABLE yz_tenant_employees ADD COLUMN department_id INT DEFAULT NULL COMMENT ''部门ID'' AFTER email;'
|
||
));
|
||
PREPARE alterIfNotExists FROM @preparedStatement;
|
||
EXECUTE alterIfNotExists;
|
||
DEALLOCATE PREPARE alterIfNotExists;
|
||
|
||
-- 检查并添加 position_id 字段
|
||
SET @columnname = 'position_id';
|
||
SET @preparedStatement = (SELECT IF(
|
||
(
|
||
SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
|
||
WHERE
|
||
(TABLE_SCHEMA = @dbname)
|
||
AND (TABLE_NAME = @tablename)
|
||
AND (COLUMN_NAME = @columnname)
|
||
) > 0,
|
||
'SELECT "Column position_id already exists in yz_tenant_employees" AS "";',
|
||
'ALTER TABLE yz_tenant_employees ADD COLUMN position_id INT DEFAULT NULL COMMENT ''职位ID'' AFTER department_id;'
|
||
));
|
||
PREPARE alterIfNotExists FROM @preparedStatement;
|
||
EXECUTE alterIfNotExists;
|
||
DEALLOCATE PREPARE alterIfNotExists;
|
||
|
||
SET FOREIGN_KEY_CHECKS = 1;
|
||
|