LearnStudentMapper.xml 12 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242
  1. <?xml version="1.0" encoding="UTF-8" ?>
  2. <!DOCTYPE mapper
  3. PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN"
  4. "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
  5. <mapper namespace="com.ruoyi.learn.mapper.LearnStudentMapper">
  6. <resultMap type="LearnStudent" id="LearnStudentResult">
  7. <result property="studentId" column="student_id" />
  8. <result property="classId" column="class_id" />
  9. <result property="schoolId" column="school_id" />
  10. <result property="campusId" column="campus_id" />
  11. <result property="universityId" column="university_id" />
  12. <result property="directKey" column="direct_key" />
  13. <result property="modules" column="modules" />
  14. <result property="majorGroup" column="major_group" />
  15. <result property="majorPlanId" column="major_plan_id" />
  16. </resultMap>
  17. <sql id="selectLearnStudentVo">
  18. select student_id, class_id, school_id,campus_id, university_id,direct_key, modules, major_group,major_plan_id from learn_student
  19. </sql>
  20. <select id="selectLearnStudentList" parameterType="LearnStudent" resultMap="LearnStudentResult">
  21. <include refid="selectLearnStudentVo"/>
  22. <where>
  23. <if test="directKey != null and directKey != ''"> and direct_key = #{directKey}</if>
  24. </where>
  25. </select>
  26. <select id="selectLearnStudentsByMap" parameterType="map" resultMap="LearnStudentResult"> <!-- 排除本批次已经生成的 -->
  27. 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
  28. FROM `learn_student` ls
  29. 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
  30. JOIN `sys_user` u ON ls.`student_id` = u.`user_id`
  31. <where> ts.`id` IS NULL
  32. <choose><when test="directed and universityId != null"> AND ls.`university_id` = #{universityId}</when>
  33. <when test="directed and universityId == null"> AND ls.`university_id` is not null</when></choose>
  34. <if test="classIds != null and classIds.size() > 0"> AND ls.`class_id` IN <foreach item="id" collection="classIds" open="(" separator="," close=")">#{id}</foreach></if>
  35. <if test="universityId != null"> AND ls.`university_id` = #{universityId}</if>
  36. <if test="majorGroup != null"> AND ls.`major_group` = #{majorGroup}</if>
  37. <if test="majorPlanId != null"> AND ls.`major_plan_id` = #{majorPlanId}</if>
  38. <if test="examType != null and examType != ''"> AND u.`exam_type` = #{examType}</if>
  39. </where>
  40. </select>
  41. <select id="selectClassStudents" resultMap="LearnStudentResult">
  42. SELECT ls.*, u.nick_name studentName , tp.`paper_id` paperId, ts.`status`
  43. FROM `learn_student` ls
  44. JOIN `sys_user` u ON ls.`student_id` = u.`user_id`
  45. LEFT JOIN `learn_test_paper` tp ON tp.`batch_id` = #{batchId} AND tp.`direct_key` = ls.`direct_key`
  46. LEFT JOIN `learn_test_student` ts ON ts.`batch_id` = #{batchId} AND ls.`student_id` = ts.`student_id`
  47. where ts.`id` IS NULL AND ls.`class_id` IN <foreach item="id" collection="classIds" open="(" separator="," close=")">#{id}</foreach>
  48. </select>
  49. <select id="selectLearnStudentByStudentId" parameterType="Long" resultMap="LearnStudentResult">
  50. <include refid="selectLearnStudentVo"/>
  51. where student_id = #{studentId}
  52. </select>
  53. <insert id="insertLearnStudent" parameterType="LearnStudent">
  54. insert into learn_student
  55. <trim prefix="(" suffix=")" suffixOverrides=",">
  56. <if test="studentId != null">student_id,</if>
  57. <if test="classId != null">class_id,</if>
  58. <if test="schoolId != null">school_id,</if>
  59. <if test="campusId != null">campus_id,</if>
  60. <if test="universityId != null">university_id,</if>
  61. <if test="directKey != null">direct_key,</if>
  62. <if test="modules != null">modules,</if>
  63. <if test="majorGroup != null">major_group,</if>
  64. <if test="majorPlanId != null">major_plan_id,</if>
  65. </trim>
  66. <trim prefix="values (" suffix=")" suffixOverrides=",">
  67. <if test="studentId != null">#{studentId},</if>
  68. <if test="classId != null">#{classId},</if>
  69. <if test="schoolId != null">#{schoolId},</if>
  70. <if test="campusId != null">#{campusId},</if>
  71. <if test="universityId != null">#{universityId},</if>
  72. <if test="directKey != null">#{directKey},</if>
  73. <if test="modules != null">#{modules},</if>
  74. <if test="majorGroup != null">#{majorGroup},</if>
  75. <if test="majorPlanId != null">#{majorPlanId},</if>
  76. </trim>
  77. </insert>
  78. <update id="updateLearnStudent" parameterType="LearnStudent">
  79. update learn_student
  80. <trim prefix="SET" suffixOverrides=",">
  81. <if test="classId != null">class_id = #{classId},</if>
  82. <if test="schoolId != null">school_id = #{schoolId},</if>
  83. <if test="campusId != null">campus_id = #{campusId},</if>
  84. <if test="universityId != null">university_id = #{universityId},</if>
  85. <if test="directKey != null">direct_key = #{directKey},</if>
  86. <if test="modules != null">modules = #{modules},</if>
  87. <if test="majorGroup != null">major_group = #{majorGroup},</if>
  88. <if test="majorPlanId != null">major_plan_id = #{majorPlanId},</if>
  89. </trim>
  90. where student_id = #{studentId}
  91. </update>
  92. <delete id="deleteLearnStudentByStudentId" parameterType="Long">
  93. delete from learn_student where student_id = #{studentId}
  94. </delete>
  95. <delete id="deleteLearnStudentByStudentIds" parameterType="String">
  96. delete from learn_student where student_id in
  97. <foreach item="studentId" collection="array" open="(" separator="," close=")">
  98. #{studentId}
  99. </foreach>
  100. </delete>
  101. <!-- 统计学习记录 -->
  102. <select id="statisticStudyRecord" parameterType="com.ruoyi.learn.dto.StudyRecordStatisticsDTO" resultType="com.ruoyi.learn.dto.StudyRecordStatisticsDTO">
  103. WITH T1 AS (
  104. <!-- 定义查询 1 的聚合结果(做题统计)-->
  105. <!-- 优化:从learn_answer开始JOIN,利用索引,避免date()函数 -->
  106. SELECT
  107. a.student_id,
  108. COUNT(*) AS num,
  109. SUM(IF(a.state = 1, 1, 0)) AS correct,
  110. ROUND(SUM(IF(a.state = 1, 1, 0)) * 100.0 / COUNT(*), 1) AS rate,
  111. COUNT(DISTINCT IF(le.paper_type IN (20,30), le.paper_id, null)) paperCount,
  112. 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
  113. FROM `learn_answer` a
  114. INNER JOIN `learn_examinee` le ON a.`examinee_id` = le.`examinee_id` AND le.state >= 4
  115. INNER JOIN `sys_user` u ON le.student_id = u.user_id
  116. INNER JOIN `dz_cards` dc ON u.card_id = dc.card_id
  117. WHERE a.`state` > 0
  118. <if test="studyTimeBegin != null and studyTimeBegin != ''">
  119. <!-- 优化:去掉date()函数,直接比较datetime,可以使用索引 -->
  120. AND (a.create_time &gt;= CONCAT(#{studyTimeBegin}, ' 00:00:00') OR le.end_time &gt;= CONCAT(#{studyTimeBegin}, ' 00:00:00'))
  121. </if>
  122. <if test="studyTimeEnd != null and studyTimeEnd != ''">
  123. <!-- 优化:去掉date()函数,直接比较datetime,可以使用索引 -->
  124. AND (a.create_time &lt;= CONCAT(#{studyTimeEnd}, ' 23:59:59') OR le.end_time &lt;= CONCAT(#{studyTimeEnd}, ' 23:59:59'))
  125. </if>
  126. GROUP BY a.student_id
  127. ),
  128. T2 AS (
  129. <!-- 定义查询 2 的聚合结果(视频观看统计)-->
  130. <!-- 优化:去掉date()函数,直接比较datetime,可以使用索引 -->
  131. SELECT
  132. ls.student_id,
  133. COUNT(DISTINCT vw.title) AS total,
  134. ROUND(SUM(vw.duration * vw.percent / 100.0)) AS value
  135. FROM `b_customer_video_watches` vw
  136. INNER JOIN `learn_student` ls ON vw.customerCode = ls.student_id
  137. <where>
  138. <if test="studyTimeBegin != null and studyTimeBegin != ''">
  139. AND vw.time &gt;= CONCAT(#{studyTimeBegin}, ' 00:00:00')
  140. </if>
  141. <if test="studyTimeEnd != null and studyTimeEnd != ''">
  142. AND vw.time &lt;= CONCAT(#{studyTimeEnd}, ' 23:59:59')
  143. </if>
  144. </where>
  145. GROUP BY ls.student_id
  146. ),
  147. AllStudents AS (
  148. <!-- 提取所有涉及的唯一 Student ID-->
  149. <!-- 优化:使用UNION ALL代替UNION,如果确定student_id不重复可以提升性能 -->
  150. SELECT student_id FROM T1
  151. UNION
  152. SELECT student_id FROM T2
  153. ),
  154. StudentBaseInfo AS (
  155. <!-- 获取所有涉及学生的基础信息-->
  156. <!-- 优化:简化COALESCE,去掉不必要的NULL判断 -->
  157. SELECT DISTINCT
  158. dc.dept_id,
  159. asl.student_id,
  160. dc.school_id,
  161. dc.class_id,
  162. dc.campus_id,
  163. dc.campus_class_id,
  164. dc.agent_id,
  165. dc.leaf_agent_id,
  166. u.nick_name AS nick_name,
  167. dc.card_no
  168. FROM AllStudents asl
  169. LEFT JOIN `sys_user` u ON asl.student_id = u.user_id
  170. LEFT JOIN `dz_cards` dc ON u.card_id = dc.card_id
  171. )
  172. <!-- 主查询:将统计数据 LEFT JOIN 到基础信息上-->
  173. SELECT
  174. <!-- 基础信息字段(已补齐,始终输出)-->
  175. SBI.school_id as schoolId,
  176. SBI.class_id as classId,
  177. SBI.campus_id as campusId,
  178. SBI.campus_class_id as campusClassId,
  179. SBI.agent_id as agentId,
  180. SBI.leaf_agent_id as leafAgentId,
  181. SBI.nick_name as nickName,
  182. SBI.card_no as cardNo,
  183. SBI.student_id as studentId,
  184. <!-- T1 统计结果-->
  185. COALESCE(T1.num, 0) AS num,
  186. COALESCE(T1.correct, 0) AS correct,
  187. <!-- RATE 字段处理:如果 T1.num 为 0 则 Rate 为 0-->
  188. CASE
  189. WHEN COALESCE(T1.num, 0) = 0 THEN 0
  190. ELSE T1.rate
  191. END AS rate,
  192. COALESCE(T1.paperCount, 0) AS paperCount,
  193. COALESCE(T1.paperRate, 0) AS paperRate,
  194. <!-- T2 统计结果-->
  195. COALESCE(T2.total, 0) AS videoTotalTitles,
  196. COALESCE(T2.value, 0) AS videoDurationValue
  197. FROM
  198. StudentBaseInfo AS SBI
  199. LEFT JOIN
  200. T1 ON SBI.student_id = T1.student_id
  201. LEFT JOIN
  202. T2 ON SBI.student_id = T2.student_id
  203. <where>
  204. <if test="deptId != null"> AND SBI.dept_id = #{deptId}</if>
  205. <if test="schoolId != null"> AND SBI.school_id = #{schoolId}</if>
  206. <if test="teacherId != null">
  207. <!-- 优化:将子查询改为EXISTS,性能更好 -->
  208. AND EXISTS (
  209. SELECT 1 FROM dz_teacher_class t
  210. WHERE t.teacher_id = #{teacherId}
  211. AND NOW() &lt; t.out_date
  212. AND (t.class_id = SBI.class_id OR t.class_id = SBI.campus_class_id)
  213. )
  214. </if>
  215. <if test="classId != null"> AND SBI.class_id = #{classId}</if>
  216. <if test="campusId != null"> AND SBI.campus_id = #{campusId}</if>
  217. <if test="campusClassId != null"> AND SBI.campus_class_id = #{campusClassId}</if>
  218. <if test="agentId != null"> AND (SBI.agent_id = #{agentId} OR SBI.leaf_agent_id = #{agentId})</if>
  219. <if test="nickName != null and nickName != ''"> AND SBI.nick_name LIKE CONCAT('%', #{nickName}, '%')</if>
  220. <if test="cardNo != null and cardNo != ''"> AND SBI.card_no LIKE CONCAT('%', #{cardNo}, '%')</if>
  221. </where>
  222. ORDER BY
  223. SBI.student_id
  224. </select>
  225. </mapper>