| 123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242 |
- <?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="com.ruoyi.learn.mapper.LearnStudentMapper">
- <resultMap type="LearnStudent" id="LearnStudentResult">
- <result property="studentId" column="student_id" />
- <result property="classId" column="class_id" />
- <result property="schoolId" column="school_id" />
- <result property="campusId" column="campus_id" />
- <result property="universityId" column="university_id" />
- <result property="directKey" column="direct_key" />
- <result property="modules" column="modules" />
- <result property="majorGroup" column="major_group" />
- <result property="majorPlanId" column="major_plan_id" />
- </resultMap>
- <sql id="selectLearnStudentVo">
- select student_id, class_id, school_id,campus_id, university_id,direct_key, modules, major_group,major_plan_id from learn_student
- </sql>
- <select id="selectLearnStudentList" parameterType="LearnStudent" resultMap="LearnStudentResult">
- <include refid="selectLearnStudentVo"/>
- <where>
- <if test="directKey != null and directKey != ''"> and direct_key = #{directKey}</if>
- </where>
- </select>
- <select id="selectLearnStudentsByMap" parameterType="map" resultMap="LearnStudentResult"> <!-- 排除本批次已经生成的 -->
- SELECT ls.`student_id`, ls.`university_id`, ls.`major_group`, ls.`major_plan_id`, ls.`direct_key`, u.exam_type examType, ls.campus_id, ls.class_id, ls.school_id
- FROM `learn_student` ls
- LEFT JOIN `learn_test_student` ts ON ts.`student_id` = ls.`student_id` AND ts.`batch_id` = #{batchId} and ts.build_type = #{buildType} and ts.subject_id = #{subjectId} and ts.class_id = ls.class_id
- JOIN `sys_user` u ON ls.`student_id` = u.`user_id`
- <where> ts.`id` IS NULL
- <choose><when test="directed and universityId != null"> AND ls.`university_id` = #{universityId}</when>
- <when test="directed and universityId == null"> AND ls.`university_id` is not null</when></choose>
- <if test="classIds != null and classIds.size() > 0"> AND ls.`class_id` IN <foreach item="id" collection="classIds" open="(" separator="," close=")">#{id}</foreach></if>
- <if test="universityId != null"> AND ls.`university_id` = #{universityId}</if>
- <if test="majorGroup != null"> AND ls.`major_group` = #{majorGroup}</if>
- <if test="majorPlanId != null"> AND ls.`major_plan_id` = #{majorPlanId}</if>
- <if test="examType != null and examType != ''"> AND u.`exam_type` = #{examType}</if>
- </where>
- </select>
- <select id="selectClassStudents" resultMap="LearnStudentResult">
- SELECT ls.*, u.nick_name studentName , tp.`paper_id` paperId, ts.`status`
- FROM `learn_student` ls
- JOIN `sys_user` u ON ls.`student_id` = u.`user_id`
- LEFT JOIN `learn_test_paper` tp ON tp.`batch_id` = #{batchId} AND tp.`direct_key` = ls.`direct_key`
- LEFT JOIN `learn_test_student` ts ON ts.`batch_id` = #{batchId} AND ls.`student_id` = ts.`student_id`
- where ts.`id` IS NULL AND ls.`class_id` IN <foreach item="id" collection="classIds" open="(" separator="," close=")">#{id}</foreach>
- </select>
- <select id="selectLearnStudentByStudentId" parameterType="Long" resultMap="LearnStudentResult">
- <include refid="selectLearnStudentVo"/>
- where student_id = #{studentId}
- </select>
- <insert id="insertLearnStudent" parameterType="LearnStudent">
- insert into learn_student
- <trim prefix="(" suffix=")" suffixOverrides=",">
- <if test="studentId != null">student_id,</if>
- <if test="classId != null">class_id,</if>
- <if test="schoolId != null">school_id,</if>
- <if test="campusId != null">campus_id,</if>
- <if test="universityId != null">university_id,</if>
- <if test="directKey != null">direct_key,</if>
- <if test="modules != null">modules,</if>
- <if test="majorGroup != null">major_group,</if>
- <if test="majorPlanId != null">major_plan_id,</if>
- </trim>
- <trim prefix="values (" suffix=")" suffixOverrides=",">
- <if test="studentId != null">#{studentId},</if>
- <if test="classId != null">#{classId},</if>
- <if test="schoolId != null">#{schoolId},</if>
- <if test="campusId != null">#{campusId},</if>
- <if test="universityId != null">#{universityId},</if>
- <if test="directKey != null">#{directKey},</if>
- <if test="modules != null">#{modules},</if>
- <if test="majorGroup != null">#{majorGroup},</if>
- <if test="majorPlanId != null">#{majorPlanId},</if>
- </trim>
- </insert>
- <update id="updateLearnStudent" parameterType="LearnStudent">
- update learn_student
- <trim prefix="SET" suffixOverrides=",">
- <if test="classId != null">class_id = #{classId},</if>
- <if test="schoolId != null">school_id = #{schoolId},</if>
- <if test="campusId != null">campus_id = #{campusId},</if>
- <if test="universityId != null">university_id = #{universityId},</if>
- <if test="directKey != null">direct_key = #{directKey},</if>
- <if test="modules != null">modules = #{modules},</if>
- <if test="majorGroup != null">major_group = #{majorGroup},</if>
- <if test="majorPlanId != null">major_plan_id = #{majorPlanId},</if>
- </trim>
- where student_id = #{studentId}
- </update>
- <delete id="deleteLearnStudentByStudentId" parameterType="Long">
- delete from learn_student where student_id = #{studentId}
- </delete>
- <delete id="deleteLearnStudentByStudentIds" parameterType="String">
- delete from learn_student where student_id in
- <foreach item="studentId" collection="array" open="(" separator="," close=")">
- #{studentId}
- </foreach>
- </delete>
- <!-- 统计学习记录 -->
- <select id="statisticStudyRecord" parameterType="com.ruoyi.learn.dto.StudyRecordStatisticsDTO" resultType="com.ruoyi.learn.dto.StudyRecordStatisticsDTO">
- WITH T1 AS (
- <!-- 定义查询 1 的聚合结果(做题统计)-->
- <!-- 优化:从learn_answer开始JOIN,利用索引,避免date()函数 -->
- SELECT
- a.student_id,
- COUNT(*) AS num,
- SUM(IF(a.state = 1, 1, 0)) AS correct,
- ROUND(SUM(IF(a.state = 1, 1, 0)) * 100.0 / COUNT(*), 1) AS rate,
- COUNT(DISTINCT IF(le.paper_type IN (20,30), le.paper_id, null)) paperCount,
- ROUND(SUM(IF(a.`state` = 1 AND le.paper_type IN (20,30), 1, 0)) * 100.0 / NULLIF(SUM(IF(le.paper_type IN (20,30), 1, 0)), 0), 1) paperRate
- FROM `learn_answer` a
- INNER JOIN `learn_examinee` le ON a.`examinee_id` = le.`examinee_id` AND le.state >= 4
- INNER JOIN `sys_user` u ON le.student_id = u.user_id
- INNER JOIN `dz_cards` dc ON u.card_id = dc.card_id
- WHERE a.`state` > 0
- <if test="studyTimeBegin != null and studyTimeBegin != ''">
- <!-- 优化:去掉date()函数,直接比较datetime,可以使用索引 -->
- AND (a.create_time >= CONCAT(#{studyTimeBegin}, ' 00:00:00') OR le.end_time >= CONCAT(#{studyTimeBegin}, ' 00:00:00'))
- </if>
- <if test="studyTimeEnd != null and studyTimeEnd != ''">
- <!-- 优化:去掉date()函数,直接比较datetime,可以使用索引 -->
- AND (a.create_time <= CONCAT(#{studyTimeEnd}, ' 23:59:59') OR le.end_time <= CONCAT(#{studyTimeEnd}, ' 23:59:59'))
- </if>
- GROUP BY a.student_id
- ),
- T2 AS (
- <!-- 定义查询 2 的聚合结果(视频观看统计)-->
- <!-- 优化:去掉date()函数,直接比较datetime,可以使用索引 -->
- SELECT
- ls.student_id,
- COUNT(DISTINCT vw.title) AS total,
- ROUND(SUM(vw.duration * vw.percent / 100.0)) AS value
- FROM `b_customer_video_watches` vw
- INNER JOIN `learn_student` ls ON vw.customerCode = ls.student_id
- <where>
- <if test="studyTimeBegin != null and studyTimeBegin != ''">
- AND vw.time >= CONCAT(#{studyTimeBegin}, ' 00:00:00')
- </if>
- <if test="studyTimeEnd != null and studyTimeEnd != ''">
- AND vw.time <= CONCAT(#{studyTimeEnd}, ' 23:59:59')
- </if>
- </where>
- GROUP BY ls.student_id
- ),
- AllStudents AS (
- <!-- 提取所有涉及的唯一 Student ID-->
- <!-- 优化:使用UNION ALL代替UNION,如果确定student_id不重复可以提升性能 -->
- SELECT student_id FROM T1
- UNION
- SELECT student_id FROM T2
- ),
- StudentBaseInfo AS (
- <!-- 获取所有涉及学生的基础信息-->
- <!-- 优化:简化COALESCE,去掉不必要的NULL判断 -->
- SELECT DISTINCT
- dc.dept_id,
- asl.student_id,
- dc.school_id,
- dc.class_id,
- dc.campus_id,
- dc.campus_class_id,
- dc.agent_id,
- dc.leaf_agent_id,
- u.nick_name AS nick_name,
- dc.card_no
- FROM AllStudents asl
- LEFT JOIN `sys_user` u ON asl.student_id = u.user_id
- LEFT JOIN `dz_cards` dc ON u.card_id = dc.card_id
- )
- <!-- 主查询:将统计数据 LEFT JOIN 到基础信息上-->
- SELECT
- <!-- 基础信息字段(已补齐,始终输出)-->
- SBI.school_id as schoolId,
- SBI.class_id as classId,
- SBI.campus_id as campusId,
- SBI.campus_class_id as campusClassId,
- SBI.agent_id as agentId,
- SBI.leaf_agent_id as leafAgentId,
- SBI.nick_name as nickName,
- SBI.card_no as cardNo,
- SBI.student_id as studentId,
- <!-- T1 统计结果-->
- COALESCE(T1.num, 0) AS num,
- COALESCE(T1.correct, 0) AS correct,
- <!-- RATE 字段处理:如果 T1.num 为 0 则 Rate 为 0-->
- CASE
- WHEN COALESCE(T1.num, 0) = 0 THEN 0
- ELSE T1.rate
- END AS rate,
- COALESCE(T1.paperCount, 0) AS paperCount,
- COALESCE(T1.paperRate, 0) AS paperRate,
- <!-- T2 统计结果-->
- COALESCE(T2.total, 0) AS videoTotalTitles,
- COALESCE(T2.value, 0) AS videoDurationValue
- FROM
- StudentBaseInfo AS SBI
- LEFT JOIN
- T1 ON SBI.student_id = T1.student_id
- LEFT JOIN
- T2 ON SBI.student_id = T2.student_id
- <where>
- <if test="deptId != null"> AND SBI.dept_id = #{deptId}</if>
- <if test="schoolId != null"> AND SBI.school_id = #{schoolId}</if>
- <if test="teacherId != null">
- <!-- 优化:将子查询改为EXISTS,性能更好 -->
- AND EXISTS (
- SELECT 1 FROM dz_teacher_class t
- WHERE t.teacher_id = #{teacherId}
- AND NOW() < t.out_date
- AND (t.class_id = SBI.class_id OR t.class_id = SBI.campus_class_id)
- )
- </if>
- <if test="classId != null"> AND SBI.class_id = #{classId}</if>
- <if test="campusId != null"> AND SBI.campus_id = #{campusId}</if>
- <if test="campusClassId != null"> AND SBI.campus_class_id = #{campusClassId}</if>
- <if test="agentId != null"> AND (SBI.agent_id = #{agentId} OR SBI.leaf_agent_id = #{agentId})</if>
- <if test="nickName != null and nickName != ''"> AND SBI.nick_name LIKE CONCAT('%', #{nickName}, '%')</if>
- <if test="cardNo != null and cardNo != ''"> AND SBI.card_no LIKE CONCAT('%', #{cardNo}, '%')</if>
- </where>
- ORDER BY
- SBI.student_id
- </select>
- </mapper>
|