VodPlayHistoryMapper.xml 11.5 KB
<?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="memberStudy" 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,
        t1.play_length,
        IF
        ( t2.total_length &lt;= 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="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,
        t1.play_length,
        IF
        ( t2.total_length &lt;= 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>