Files
schoolNews/schoolNewsServ/system/src/main/resources/mapper/UserMapper.xml

367 lines
15 KiB
XML
Raw Normal View History

2025-09-28 17:32:37 +08:00
<?xml version="1.0" encoding="UTF-8"?>
<!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
<mapper namespace="org.xyzh.system.mapper.UserMapper">
<!-- 基础结果映射 -->
<resultMap id="BaseResultMap" type="org.xyzh.common.dto.user.TbSysUser">
<id column="id" property="id" jdbcType="VARCHAR"/>
<result column="username" property="username" jdbcType="VARCHAR"/>
<result column="password" property="password" jdbcType="VARCHAR"/>
<result column="email" property="email" jdbcType="VARCHAR"/>
<result column="phone" property="phone" jdbcType="VARCHAR"/>
<result column="wechat_id" property="wechatID" jdbcType="VARCHAR"/>
<result column="create_time" property="createTime" jdbcType="TIMESTAMP"/>
<result column="update_time" property="updateTime" jdbcType="TIMESTAMP"/>
<result column="delete_time" property="deleteTime" jdbcType="TIMESTAMP"/>
2025-10-05 18:00:29 +08:00
<result column="deleted" property="deleted" jdbcType="INTEGER"/>
2025-09-28 17:32:37 +08:00
<result column="status" property="status" jdbcType="INTEGER"/>
</resultMap>
2025-10-06 16:20:05 +08:00
<resultMap id="UserInfoResultMap" type="org.xyzh.common.dto.user.TbSysUserInfo">
<id column="id" property="id" jdbcType="VARCHAR"/>
<result column="user_id" property="userID" jdbcType="VARCHAR"/>
<result column="avatar" property="avatar" jdbcType="VARCHAR"/>
<result column="gender" property="gender" jdbcType="INTEGER"/>
<result column="family_name" property="familyName" jdbcType="VARCHAR"/>
<result column="given_name" property="givenName" jdbcType="VARCHAR"/>
<result column="full_name" property="fullName" jdbcType="VARCHAR"/>
<result column="id_card" property="idCard" jdbcType="VARCHAR"/>
<result column="address" property="address" jdbcType="VARCHAR"/>
<result column="create_time" property="createTime" jdbcType="TIMESTAMP"/>
<result column="update_time" property="updateTime" jdbcType="TIMESTAMP"/>
<result column="delete_time" property="deleteTime" jdbcType="TIMESTAMP"/>
<result column="deleted" property="deleted" jdbcType="INTEGER"/>
</resultMap>
2025-10-18 17:57:14 +08:00
<resultMap id="UserInfoTotalResultMap" type="org.xyzh.common.vo.UserVO">
<result column="user_id" property="userID" jdbcType="VARCHAR"/>
<result column="avatar" property="avatar" jdbcType="VARCHAR"/>
<result column="gender" property="gender" jdbcType="INTEGER"/>
<result column="phone" property="phone" jdbcType="VARCHAR"/>
<result column="email" property="email" jdbcType="VARCHAR"/>
<result column="dept_name" property="deptName" jdbcType="VARCHAR"/>
<result column="role_name" property="roleName" jdbcType="VARCHAR"/>
<result column="level" property="level" jdbcType="INTEGER"/>
<result column="id_card" property="idCard" jdbcType="VARCHAR"/>
<result column="address" property="address" jdbcType="VARCHAR"/>
<result column="create_time" property="createTime" jdbcType="TIMESTAMP"/>
<result column="update_time" property="updateTime" jdbcType="TIMESTAMP"/>
<result column="delete_time" property="deleteTime" jdbcType="TIMESTAMP"/>
<result column="deleted" property="deleted" jdbcType="INTEGER"/>
</resultMap>
2025-09-28 17:32:37 +08:00
<!-- 基础字段 -->
<sql id="Base_Column_List">
id, username, password, email, phone, wechat_id,
create_time, update_time, delete_time, deleted, status
</sql>
2025-10-06 16:20:05 +08:00
<sql id="FullUser_Column_List">
id, user_id, avatar, gender, family_name, given_name, full_name, id_card, address,
create_time, update_time, delete_time, deleted, status
</sql>
<!-- 用户信息字段 -->
<sql id="UserInfo_Column_List">
id, user_id, avatar, gender, family_name, given_name, full_name, id_card, address,
create_time, update_time, delete_time, deleted
</sql>
2025-09-28 17:32:37 +08:00
<!-- 通用条件 -->
<sql id="Where_Clause">
<where>
deleted = 0
<if test="username != null and username != ''">
AND username LIKE CONCAT('%', #{username}, '%')
</if>
<if test="email != null and email != ''">
AND email LIKE CONCAT('%', #{email}, '%')
</if>
<if test="phone != null and phone != ''">
AND phone = #{phone}
</if>
<if test="status != null">
AND status = #{status}
</if>
</where>
</sql>
2025-10-22 17:57:30 +08:00
<sql id="Filter_Clause">
<where>
deleted = 0
<if test="filter.id != null and filter.id != ''">
AND id = #{filter.id}
</if>
<if test="filter.username != null and filter.username != ''">
AND username = #{filter.username}
</if>
<if test="filter.email != null and filter.email != ''">
AND email = #{filter.email}
</if>
<if test="filter.phone != null and filter.phone != ''">
AND phone = #{filter.phone}
</if>
<if test="filter.status != null">
AND status = #{filter.status}
</if>
<if test="filter.wechatID != null and filter.wechatID != ''">
AND wechat_id = #{filter.wechatID}
</if>
</where>
</sql>
2025-09-28 17:32:37 +08:00
<!-- 根据用户名查询用户 -->
<select id="selectByUsername" resultMap="BaseResultMap">
SELECT
<include refid="Base_Column_List"/>
FROM tb_sys_user
WHERE deleted = 0
AND username = #{username}
LIMIT 1
</select>
<!-- 根据邮箱查询用户 -->
<select id="selectByEmail" resultMap="BaseResultMap">
SELECT
<include refid="Base_Column_List"/>
FROM tb_sys_user
WHERE deleted = 0
AND email = #{email}
LIMIT 1
</select>
<!-- 根据手机号查询用户 -->
<select id="selectByPhone" resultMap="BaseResultMap">
SELECT
<include refid="Base_Column_List"/>
FROM tb_sys_user
WHERE deleted = 0
AND phone = #{phone}
LIMIT 1
</select>
<!-- 根据过滤条件查询用户 -->
<select id="selectByFilter" resultMap="BaseResultMap">
SELECT
<include refid="Base_Column_List"/>
FROM tb_sys_user
<where>
deleted = 0
<if test="filter.id != null and filter.id != ''">
AND id = #{filter.id}
</if>
<if test="filter.username != null and filter.username != ''">
AND username = #{filter.username}
</if>
<if test="filter.email != null and filter.email != ''">
AND email = #{filter.email}
</if>
<if test="filter.phone != null and filter.phone != ''">
AND phone = #{filter.phone}
</if>
<if test="filter.status != null">
AND status = #{filter.status}
</if>
<if test="filter.wechatID != null and filter.wechatID != ''">
AND wechat_id = #{filter.wechatID}
</if>
</where>
</select>
<!-- 查询用户列表 -->
<select id="selectUserList" resultMap="BaseResultMap">
SELECT
<include refid="Base_Column_List"/>
FROM tb_sys_user
<include refid="Where_Clause"/>
ORDER BY create_time DESC
</select>
2025-10-22 17:57:30 +08:00
<!-- 查询用户列表(分页) -->
<select id="selectUserPage" resultMap="BaseResultMap">
SELECT
<include refid="Base_Column_List"/>
FROM tb_sys_user
2025-10-23 18:57:25 +08:00
<include refid="Filter_Clause"/>
2025-10-22 17:57:30 +08:00
ORDER BY create_time DESC
LIMIT #{pageParam.pageSize} OFFSET #{pageParam.offset}
</select>
2025-09-28 17:32:37 +08:00
<!-- 批量删除用户(逻辑删除) -->
<update id="batchDeleteByIds">
UPDATE tb_sys_user
SET deleted = 1,
delete_time = NOW(),
updater = #{updater}
WHERE deleted = 0
AND id IN
<foreach collection="userIds" item="userId" open="(" separator="," close=")">
#{userId}
</foreach>
</update>
<!-- 插入用户 -->
2025-10-09 16:35:49 +08:00
<insert id="insertUser" parameterType="org.xyzh.common.dto.user.TbSysUser">
2025-09-28 17:32:37 +08:00
INSERT INTO tb_sys_user
<trim prefix="(" suffix=")" suffixOverrides=",">
2025-10-09 16:35:49 +08:00
<if test="user.id != null">id,</if>
<if test="user.username != null">username,</if>
<if test="user.password != null">password,</if>
<if test="user.email != null">email,</if>
<if test="user.phone != null">phone,</if>
<if test="user.wechatID != null">wechat_id,</if>
<if test="user.status != null">status,</if>
<if test="user.createTime != null">create_time,</if>
2025-09-28 17:32:37 +08:00
deleted
</trim>
2025-10-09 16:35:49 +08:00
VALUES
<trim prefix="(" suffix=")" suffixOverrides=",">
<if test="user.id != null">#{user.id},</if>
<if test="user.username != null">#{user.username},</if>
<if test="user.password != null">#{user.password},</if>
<if test="user.email != null">#{user.email},</if>
<if test="user.phone != null">#{user.phone},</if>
<if test="user.wechatID != null">#{user.wechatID},</if>
<if test="user.status != null">#{user.status},</if>
<if test="user.createTime != null">#{user.createTime},</if>
2025-09-28 17:32:37 +08:00
0
</trim>
</insert>
<!-- 更新用户 -->
2025-10-09 16:35:49 +08:00
<update id="updateUser" parameterType="org.xyzh.common.dto.user.TbSysUser">
2025-09-28 17:32:37 +08:00
UPDATE tb_sys_user
<set>
2025-10-09 16:35:49 +08:00
<if test="user.username != null">username = #{user.username},</if>
<if test="user.password != null">password = #{user.password},</if>
<if test="user.email != null">email = #{user.email},</if>
<if test="user.phone != null">phone = #{user.phone},</if>
<if test="user.wechatID != null">wechat_id = #{user.wechatID},</if>
<if test="user.status != null">status = #{user.status},</if>
2025-09-28 17:32:37 +08:00
update_time = NOW()
</set>
2025-10-09 16:35:49 +08:00
WHERE id = #{user.id} AND deleted = 0
2025-09-28 17:32:37 +08:00
</update>
<!-- 根据ID删除逻辑删除 -->
2025-10-09 16:35:49 +08:00
<update id="deleteUser">
2025-09-28 17:32:37 +08:00
UPDATE tb_sys_user
SET deleted = 1,
delete_time = NOW()
WHERE id = #{id} AND deleted = 0
</update>
2025-10-07 11:02:35 +08:00
<!-- 用户信息相关 -->
<!-- 根据用户ID查询用户信息 -->
<select id="selectUserInfoById" resultMap="UserInfoResultMap">
SELECT
<include refid="UserInfo_Column_List"/>
FROM tb_sys_user_info
WHERE deleted = 0
AND user_id = #{userId}
LIMIT 1
</select>
<!-- 更新用户信息 -->
<update id="updateUserInfo">
UPDATE tb_sys_user_info
<set>
<if test="userInfo.avatar != null">avatar = #{userInfo.avatar},</if>
<if test="userInfo.gender != null">gender = #{userInfo.gender},</if>
<if test="userInfo.familyName != null">family_name = #{userInfo.familyName},</if>
<if test="userInfo.givenName != null">given_name = #{userInfo.givenName},</if>
<if test="userInfo.fullName != null">full_name = #{userInfo.fullName},</if>
<if test="userInfo.idCard != null">id_card = #{userInfo.idCard},</if>
<if test="userInfo.address != null">address = #{userInfo.address},</if>
<if test="userInfo.updateTime != null">update_time = #{userInfo.updateTime}</if>
<if test="userInfo.updateTime == null">update_time = NOW() </if>
</set>
WHERE user_id = #{userInfo.userID} AND deleted = 0
</update>
2025-10-18 17:57:14 +08:00
2025-10-20 15:08:20 +08:00
<!-- 获取用户完整部门路径 -->
<select id="getUserDeptPath" resultType="java.lang.String">
WITH RECURSIVE dept_hierarchy AS (
-- 基础查询:获取用户直接所属的部门
SELECT
tsd.dept_id,
tsd.name,
tsd.parent_id,
tsd.name as dept_path,
1 as level
FROM tb_sys_user_info tsui
INNER JOIN tb_sys_user_dept_role tsudr ON tsui.user_id = tsudr.user_id
INNER JOIN tb_sys_dept tsd ON tsudr.dept_id = tsd.dept_id
WHERE tsui.user_id = #{userId} AND tsui.deleted = 0
UNION ALL
-- 递归查询:向上查找父部门
SELECT
p.dept_id,
p.name,
p.parent_id,
CONCAT(p.name, '/', dh.dept_path) as dept_path,
dh.level + 1 as level
FROM tb_sys_dept p
INNER JOIN dept_hierarchy dh ON p.dept_id = dh.parent_id
WHERE p.deleted = 0
)
SELECT dh.dept_path
FROM dept_hierarchy dh
WHERE dh.parent_id IS NULL -- 只取最顶层的部门路径
LIMIT 1
</select>
2025-10-18 17:57:14 +08:00
2025-10-20 15:08:20 +08:00
<!-- selectUserInfoTotal -->
<select id="selectUserInfoTotal" resultMap="UserInfoTotalResultMap">
WITH RECURSIVE dept_hierarchy AS (
-- 基础查询:获取用户直接所属的部门
SELECT
tsd.dept_id,
tsd.name,
tsd.parent_id,
tsd.name as dept_path,
1 as level
FROM tb_sys_user_info tsui
INNER JOIN tb_sys_user_dept_role tsudr ON tsui.user_id = tsudr.user_id
INNER JOIN tb_sys_dept tsd ON tsudr.dept_id = tsd.dept_id
WHERE tsui.user_id = #{userId} AND tsui.deleted = 0
UNION ALL
-- 递归查询:向上查找父部门
SELECT
p.dept_id,
p.name,
p.parent_id,
CONCAT(p.name, '/', dh.dept_path) as dept_path,
dh.level + 1 as level
FROM tb_sys_dept p
INNER JOIN dept_hierarchy dh ON p.dept_id = dh.parent_id
WHERE p.deleted = 0
)
2025-10-18 17:57:14 +08:00
SELECT
tus.id as user_id,
tus.username,
tus.phone,
tus.email,
tsui.avatar,
tsui.gender,
2025-10-20 15:08:20 +08:00
dh.dept_path as dept_name,
2025-10-18 17:57:14 +08:00
tsr.name as role_name,
tsui.level,
tsui.id_card,
tsui.address
FROM tb_sys_user_info tsui
INNER JOIN tb_sys_user tus ON tsui.user_id = tus.id
INNER JOIN tb_sys_user_dept_role tsudr ON tsui.user_id = tsudr.user_id
2025-10-20 15:08:20 +08:00
INNER JOIN dept_hierarchy dh ON tsudr.dept_id = dh.dept_id
2025-10-18 17:57:14 +08:00
INNER JOIN tb_sys_role tsr ON tsudr.role_id = tsr.role_id
2025-10-20 15:08:20 +08:00
WHERE tsui.user_id = #{userId}
AND tsui.deleted = 0
AND dh.parent_id IS NULL -- 只取最顶层的部门路径
2025-10-18 17:57:14 +08:00
</select>
2025-09-28 17:32:37 +08:00
</mapper>