123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161 |
- <?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.fs.statis.mapper.FsStatsMemberDailyMapper">
- <update id="refreshMemberDailyData">
- insert into fs_stats_member_daily
- (
- stat_date,user_id,nick_name,real_name,phone,tag,company_group_id,company_id,company_name,company_user_id,company_user_name,
- train_camp_id,train_camp_name,period_id,period_name,course_id,course_name,video_id,video_name,is_over,watch_count,watch_duration,
- answer_count,answer_correct_count,red_packet_count,red_packet_amount
- )
- select
- #{date} as stat_date,
- u.user_id as user_id,
- u.nickname as nick_name,
- u.real_name as real_name,
- u.phone as phone,
- concat_ws(',', t.tag) as tag,
- null as company_group_id,
- c.company_id as company_id,
- c.company_name as company_name,
- cu.user_id as company_user_id,
- cu.nick_name as company_user_name,
- uctc.training_camp_id as train_camp_id,
- uctc.training_camp_name as train_camp_name,
- ucp.period_id as period_id,
- ucp.period_name as period_name,
- uc.course_id as course_id,
- uc.course_name as course_name,
- ucv.video_id as video_id,
- ucv.title as video_name,
- max(case when cwl.log_type = 2 then 1 else 0 end)
- as is_over,
- count(cwl.log_id) as watch_count,
- sum(cwl.duration) as watch_duration,
- count(cal.log_id) as answer_count,
- count(case when cal.is_right = 1 then cal.log_id end)
- as answer_correct_count,
- count(crpl.log_id) as red_packet_count,
- ifnull(sum(crpl.amount),0) as red_packet_amount
- from fs_course_watch_log cwl
- inner join fs_user u on u.user_id = cwl.user_id
- left join company_tag_user ctu on ctu.company_id = cwl.company_id and ctu.company_user_id = cwl.company_user_id and ctu.user_id = cwl.user_id
- left join company_tag t on FIND_IN_SET(t.tag_id, ctu.tag_ids)
- left join fs_user_course_period ucp on ucp.period_id = cwl.period_id
- left join fs_user_course_training_camp uctc on uctc.training_camp_id = ucp.training_camp_id
- left join company c on c.company_id = cwl.company_id
- left join company_user cu on cu.company_id = cwl.company_id and cu.user_id = cwl.company_user_id
- left join fs_user_course uc on uc.course_id = cwl.course_id
- left join fs_user_course_video ucv on ucv.course_id = cwl.course_id and ucv.video_id = cwl.video_id
- left join fs_course_answer_logs cal on cal.watch_log_id = cwl.log_id
- left join fs_course_red_packet_log crpl on crpl.watch_log_id = cwl.log_id
- <![CDATA[
- where cwl.create_time >= #{date} and cwl.create_time < date_add(#{date}, interval 1 day)
- ]]>
- group by
- cwl.user_id,
- cwl.company_id,
- cwl.company_user_id,
- ucp.training_camp_id,
- cwl.period_id,
- cwl.course_id,
- cwl.video_id
- on duplicate key update
- nick_name = values(nick_name),
- real_name = values(real_name),
- phone = values(phone),
- tag = values(tag),
- company_name = values(company_name),
- company_user_name = values(company_user_name),
- train_camp_name = values(train_camp_name),
- period_name = values(period_name),
- course_name = values(course_name),
- video_name = values(video_name),
- is_over = values(is_over),
- watch_count = values(watch_count),
- watch_duration = values(watch_duration),
- answer_count = values(answer_count),
- answer_correct_count = values(answer_correct_count),
- red_packet_count = values(red_packet_count),
- red_packet_amount = values(red_packet_amount)
- </update>
- <select id="selectDailyData" resultType="com.fs.statis.vo.FsStatsMemberDailyVO">
- select
- <choose>
- <when test="params.type == 1">
- fsmd.stat_date,
- </when>
- <otherwise>
- date_format(fsmd.stat_date, '%Y-%m') as stat_date,
- </otherwise>
- </choose>
- fsmd.user_id,
- fsmd.nick_name,
- fsmd.real_name,
- fsmd.phone,
- fsmd.tag,
- fsmd.company_id,
- fsmd.company_name,
- fsmd.company_user_id,
- fsmd.company_user_name,
- count(fsmd.id) as count,
- sum(fsmd.is_over) as overCount,
- sum(fsmd.watch_count) as watchCount,
- sum(fsmd.watch_duration) as watchDuration,
- sum(fsmd.answer_count) as answerCount,
- sum(fsmd.answer_correct_count) as anserCorrectCount,
- sum(fsmd.red_packet_count) as redPacketCount,
- sum(fsmd.red_packet_amount) redPacketAmount
- from fs_stats_member_daily fsmd
- <where>
- <if test="params.startDate != null">
- and fsmd.stat_date >= #{params.startDate}
- </if>
- <if test="params.endDate != null">
- <![CDATA[
- and fsmd.stat_date < #{params.endDate}
- ]]>
- </if>
- <if test="params.companyId != null">
- and fsmd.company_id = #{params.companyId}
- </if>
- <if test="params.companyUserId != null">
- and fsmd.company_user_id = #{params.companyUserId}
- </if>
- <if test="params.userId != null">
- and fsmd.user_id = #{params.userId}
- </if>
- <if test="params.phone != null and params.phone != ''">
- and fsmd.phone like concat('%', #{params.phone}, '%')
- </if>
- <if test="params.trainCampId != null">
- and fsmd.train_camp_id = #{params.trainCampId}
- </if>
- <if test="params.periodId != null">
- and fsmd.period_id = #{params.periodId}
- </if>
- <if test="params.courseId != null">
- and fsmd.course_id = #{params.courseId}
- </if>
- <if test="params.videoId != null">
- and fsmd.video_id = #{params.videoId}
- </if>
- </where>
- group by
- <choose>
- <when test="params.type == 1">
- stat_date,
- </when>
- <otherwise>
- date_format(stat_date, '%Y-%m'),
- </otherwise>
- </choose>
- user_id,
- company_id,
- company_user_id
- </select>
- </mapper>
|