VodPlayHistoryMapper.xml
10.4 KB
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
<?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.subsidy.mapper.VodPlayHistoryMapper">
<!-- 通用查询映射结果 -->
<resultMap id="BaseResultMap" type="com.subsidy.model.VodPlayHistoryDO">
<id column="id" property="id"/>
<result column="create_date" property="createDate"/>
<result column="update_date" property="updateDate"/>
<result column="delete_date" property="deleteDate"/>
<result column="class_id" property="classId"/>
<result column="vod_id" property="vodId"/>
<result column="member_id" property="memberId"/>
<result column="play_length" property="playLength"/>
<result column="play_record" property="playRecord"/>
</resultMap>
<!-- 通用查询结果列 -->
<sql id="Base_Column_List">
create_date,
update_date,
delete_date,
id, class_id, vod_id, member_id, play_length, play_record
</sql>
<delete id="deleteById">
delete from vod_play_history
</delete>
<select id="studyHistory" parameterType="long" resultType="com.subsidy.vo.vod.StudyHistoryVO">
SELECT
t2.id,
t2.vod_length,
t2.teacher_name,
t2.vod_url,
t2.vod_name,
t3.play_record,
t3.create_date,
IF
( t.play_length >= t2.vod_length, 'true', 'false' ) AS STATUS
FROM
(
SELECT
t.vod_id,
t.member_id,
sum( t.play_length ) AS play_length
FROM
vod_play_history t
WHERE
t.delete_date IS NULL
AND t.member_id = #{memberId}
GROUP BY
t.vod_id,
t.member_id
) t
LEFT JOIN vod_play_history t3 ON t.vod_id = t3.vod_id
AND t.member_id = t3.member_id
LEFT JOIN vod_dict t2 ON t.vod_id = t2.id
WHERE
t2.delete_date IS NULL
ORDER BY
t3.create_date DESC
</select>
<select id="getMemberStudyInfo" resultType="com.subsidy.vo.vod.GetMemberStudyInfoVO">
SELECT
t.member_id,
DATE_FORMAT( t.create_date, '%Y-%m-%d' ) as studyDate,
sum( t.play_length ) as playLength,
sum(
IF
( t.play_length >= t2.vod_length, t2.vod_length, t.play_length )) AS distinctLength
FROM
vod_play_history t
LEFT JOIN vod_dict t2 ON t.vod_id = t2.id
WHERE
t.delete_date IS NULL
AND t2.delete_date IS NULL
AND t.class_id = #{classId}
AND t.member_id IN
<foreach collection="memberIds" item="id" index="index" open="(" close=")" separator=",">
#{id}
</foreach>
AND DATE_FORMAT( t.create_date, '%Y-%m-%d' ) BETWEEN DATE_FORMAT( #{startDate}, '%Y-%m-%d' )
AND DATE_FORMAT( #{endDate}, '%Y-%m-%d' )
GROUP BY
t.member_id,
DATE_FORMAT( t.create_date, '%Y-%m-%d' )
</select>
<select id="getVodPlayHistory" resultType="com.subsidy.model.VodPlayHistoryDO">
SELECT
a.member_id,
a.class_id,
a.vod_id,
a.play_length,
a.play_count,
b.play_record
FROM
( SELECT sum( play_length ) as play_length, sum( play_count ) as play_count, member_id, class_id, vod_id FROM vod_play_history GROUP BY member_id, class_id, vod_id ) a
LEFT JOIN ( SELECT max( create_date ), play_record, member_id, class_id, vod_id FROM vod_play_history GROUP BY member_id, class_id, vod_id ) b ON a.member_id = b.member_id
AND a.class_id = b.class_id
AND a.vod_id = b.vod_id
</select>
<select id="memberDailyStudyLength" parameterType="long" resultType="integer">
SELECT
ifnull( sum( t.play_length ), 0 )
FROM
vod_play_history t
WHERE
t.delete_date IS NULL
AND DATE_FORMAT( t.create_date, '%Y-%m-%d' ) = DATE_FORMAT( now(), '%Y-%m-%d' )
AND t.member_id = #{memberId}
</select>
<select id="completeVodOrNot" resultType="integer">
SELECT
t.vod_id,
t.member_id,
IF
( sum( t.play_length )>= t2.vod_length, 1, 0 ) AS count
FROM
vod_play_history t
LEFT JOIN vod_dict t2 ON t.vod_id = t2.id
WHERE
t.delete_date IS NULL
AND t.member_id = #{memberId}
AND t.vod_id = #{vodId}
</select>
<select id="classStudyHistory" parameterType="long" resultType="com.subsidy.vo.sign.ClassSignInfoVO">
SELECT
t10.mem_cnt AS memberCount,
ifnull( floor( t2.ttl / t10.mem_cnt ), 0 ) AS studyVodCounts,
ifnull( t3.total_vods, 0 ) AS totalVodCounts,
ifnull( avg_playlength, 0 ) AS avgVodPlayLength,
ifnull( floor( t4.pass_cnt * 100 / t10.mem_cnt ), 0 ) AS passRate,
ifnull( t5.ask_cnt, 0 ) AS answerCount
FROM
( SELECT t.class_id, count( 1 ) AS mem_cnt FROM class_member_mapping t WHERE t.delete_date IS NULL AND t.class_id = #{classId} ) t10
LEFT JOIN (
SELECT
t.class_id,
count(
DISTINCT ( t.member_id )) AS mem_cnt,
round( sum( t.play_length )/ count( DISTINCT ( t.member_id )), 0 ) AS avg_playlength
FROM
vod_play_history t
WHERE
t.delete_date IS NULL
AND t.class_id = #{classId}
) t ON t.class_id = t10.class_id
LEFT JOIN (
SELECT
t3.class_id,
sum( t3.cnt ) AS ttl
FROM
(
SELECT
t.class_id,
t.member_id,
t.vod_id,
IF
( sum( t.play_length )>= t2.vod_length, 1, 0 ) AS cnt
FROM
vod_play_history t
LEFT JOIN vod_dict t2 ON t.vod_id = t2.id
WHERE
t.class_id = #{classId}
AND t.delete_date IS NULL
GROUP BY
t.class_id,
t.member_id,
t.vod_id
) t3
) t2 ON t.class_id = t2.class_id
LEFT JOIN (
SELECT
t.id,
count( 1 ) AS total_vods
FROM
class_dict t
LEFT JOIN course_content t2 ON t.course_id = t2.course_id
LEFT JOIN vod_dict t3 ON t2.id = t3.content_id
WHERE
t.delete_date IS NULL
AND t2.delete_date IS NULL
AND t3.delete_date IS NULL
AND t.id = #{classId}
) t3 ON t.class_id = t3.id
LEFT JOIN (
SELECT
t2.class_id,
sum(
IF
( t2.cnt >= t4.paper_cnt, 1, 0 )) AS pass_cnt
FROM
(
SELECT
t2.class_id,
t2.member_id,
sum( t2.cnt ) AS cnt
FROM
(
SELECT
t.paper_id,
t.class_id,
t.member_id,
IF
( max( t.score )>= 60, 1, 0 ) AS cnt
FROM
exercise_done_result t
WHERE
t.class_id = #{classId}
AND t.delete_date IS NULL
GROUP BY
t.paper_id,
t.class_id,
t.member_id
) t2
GROUP BY
t2.class_id,
t2.member_id
) t2
LEFT JOIN class_dict t3 ON t2.class_id = t3.id
LEFT JOIN ( SELECT t.course_id, count( 1 ) AS paper_cnt FROM paper_dict t WHERE t.delete_date IS NULL GROUP BY t.course_id ) t4 ON t3.course_id = t4.course_id
) t4 ON t.class_id = t4.class_id
LEFT JOIN ( SELECT t.class_id, sum( 1 ) AS ask_cnt FROM answering_question t WHERE t.class_id = #{classId} AND t.delete_date IS NULL ) t5 ON t.class_id = t5.class_id
</select>
<select id="memberRecentPlay" resultType="com.subsidy.vo.member.ContentVodNewVO">
SELECT
t2.play_record,
t2.vod_id
FROM
( SELECT max( t.create_date ) AS create_date FROM vod_play_history t WHERE t.delete_date is null and t.member_id = #{memberId} AND t.class_id = #{classId} ) t
LEFT JOIN vod_play_history t2 ON t.create_date = t2.create_date
WHERE
t2.member_id = #{memberId}
AND t2.class_id = #{classId}
</select>
<select id="memberStudyLog" resultType="com.subsidy.vo.administer.MemberStudyLogVO">
SELECT
DATE_SUB( t1.create_date, INTERVAL t1.play_length SECOND ) AS startDate,
t1.create_date AS endDate,
t1.vod_name,
'视频学习' AS studyType,
'有课互联系统' as platForm,
t1.play_length,
IF
( t2.total_length <= t1.vod_length, t2.total_length, t1.vod_length ) AS total_length
FROM
(
SELECT
t.vod_id,
t.create_date,
t2.vod_name,
t.play_length,
t2.vod_length
FROM
vod_play_history t
LEFT JOIN vod_dict t2 ON t.vod_id = t2.id
WHERE
t.class_id = #{classId}
AND t.member_id = #{memberId}
) t1
LEFT JOIN (
SELECT
t.vod_id,
sum( t.play_length ) AS total_length
FROM
vod_play_history t
LEFT JOIN vod_dict t2 ON t.vod_id = t2.id
WHERE
t.class_id = #{classId}
AND t.member_id = #{memberId}
GROUP BY
t.vod_id
) t2 ON t1.vod_id = t2.vod_id
ORDER BY
t1.create_date DESC
</select>
<select id="memberTotalLength" parameterType="long" resultType="integer">
SELECT
sum( play_length )
FROM
vod_play_history t
WHERE
t.delete_date IS NULL
AND t.member_id = #{memberId}
</select>
<select id="memberVodTotalLength" resultType="integer">
SELECT
ifnull(sum( t.play_length ),0)
FROM
vod_play_history t
WHERE
t.delete_date IS NULL
AND t.vod_id = #{vodId}
AND t.member_id = #{memberId}
</select>
<select id="exPlayInfo" resultType="com.subsidy.model.VodPlayHistoryDO">
SELECT
*
FROM
vod_play_history t
WHERE
t.delete_date IS NULL
AND t.member_id = #{memberId}
AND t.class_id = #{classId}
AND DATE_FORMAT( t.play_date, '%Y-%m-%d' ) = DATE_FORMAT( #{localDateTime}, '%Y-%m-%d' )
order by t.play_date desc
</select>
<select id="classMemberPlayLength" parameterType="long" resultType="com.subsidy.vo.vod.ClassMemberPlayLengthVO">
SELECT
t.member_id,
t.vod_id,
t3.vod_name,
sum( t.play_length ) AS play_length
FROM
vod_play_history t
LEFT JOIN class_member_mapping t2 ON t.member_id = t2.id
left join vod_dict t3 on t.vod_id = t3.id
WHERE
t.delete_date IS NULL
AND t.class_id = #{classId}
GROUP BY
t.class_id,
t.member_id,
t.vod_id,
t3.vod_name
</select>
</mapper>