You've already forked FrameTour-BE
476 lines
19 KiB
XML
476 lines
19 KiB
XML
<?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.ycwl.basic.mapper.StatisticsMapper">
|
|
<insert id="addStatisticsRecord">
|
|
insert into statistics(member_id,type,morph_id,scenic_id)
|
|
value (#{memberId},#{type},#{morphId},#{scenicId})
|
|
|
|
</insert>
|
|
<select id="countOrderAmount" resultType="java.math.BigDecimal">
|
|
select ifnull(sum(pay_price),0) as payPrice
|
|
from `order`
|
|
where
|
|
(status = 1 or status = 2) and scenic_id = #{scenicId}
|
|
<if test="startTime!= null">
|
|
and pay_at >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and pay_at <= #{endTime}
|
|
</if>
|
|
</select>
|
|
<select id="countPreviewVideoOfMember" resultType="java.lang.Integer">
|
|
SELECT
|
|
IFNULL(count(1), 0) AS count
|
|
FROM (
|
|
select count(1) as count
|
|
FROM `t_stats_record` r
|
|
left join `t_stats` s on r.trace_id=s.trace_id
|
|
where r.trace_id in (select trace_id from `t_stats_record` where action = 'ENTER_SCENIC' and `identifier`=#{scenicId})
|
|
and action = 'LOAD'
|
|
and identifier = 'pages/videoSynthesis/buy'
|
|
and JSON_EXTRACT(`params`, '$.share') is null
|
|
<if test="startTime!= null">
|
|
and r.create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and r.create_time <= #{endTime}
|
|
</if>
|
|
group by s.member_id
|
|
)a
|
|
</select>
|
|
<select id="countScanCodeOfMember" resultType="java.lang.Integer">
|
|
SELECT
|
|
IFNULL(count(1), 0) AS count
|
|
FROM (
|
|
select 1
|
|
FROM `t_stats_record` r
|
|
left join `t_stats` s on r.trace_id=s.trace_id
|
|
where r.trace_id in (select trace_id from `t_stats_record` where action = 'ENTER_SCENIC' and `identifier`=#{scenicId})
|
|
and action = 'LAUNCH'
|
|
and JSON_EXTRACT(`params`, '$.scene') in (1047,1048,1049)
|
|
<if test="startTime!= null">
|
|
and s.create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and s.create_time <= #{endTime}
|
|
</if>
|
|
group by s.member_id
|
|
) AS subquery;
|
|
</select>
|
|
<select id="countClickPayOfMember" resultType="java.lang.Integer">
|
|
SELECT
|
|
IFNULL(count(1), 0) AS count
|
|
FROM (
|
|
select count(1) as count
|
|
from `order`
|
|
where scenic_id = #{scenicId}
|
|
<if test="startTime!= null">
|
|
and pay_at >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and pay_at <= #{endTime}
|
|
</if>
|
|
group by member_id
|
|
)a
|
|
</select>
|
|
<select id="countPayOfMember" resultType="java.lang.Integer">
|
|
SELECT
|
|
IFNULL(count(1), 0) AS count
|
|
FROM (
|
|
select count(1) as count
|
|
from `statistics`
|
|
where scenic_id = #{scenicId} and type in (3,4)
|
|
<if test="startTime!= null">
|
|
and create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and create_time <= #{endTime}
|
|
</if>
|
|
group by member_id
|
|
)a
|
|
</select>
|
|
<select id="countSceneOrderNum" resultType="java.lang.Integer">
|
|
SELECT
|
|
IFNULL(count(count), 0) AS count
|
|
FROM (
|
|
select count(1) as count
|
|
from statistics
|
|
where type=4 and scenic_id = #{scenicId}
|
|
<if test="startTime!= null">
|
|
and create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and create_time <= #{endTime}
|
|
</if>
|
|
group by morph_id
|
|
)a
|
|
</select>
|
|
<select id="countPushOrderNum" resultType="java.lang.Integer">
|
|
SELECT
|
|
IFNULL(count(count), 0) AS count
|
|
FROM (
|
|
select count(1) as count
|
|
from statistics
|
|
where type=3 and scenic_id = #{scenicId}
|
|
<if test="startTime!= null">
|
|
and create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and create_time <= #{endTime}
|
|
</if>
|
|
group by morph_id
|
|
)a
|
|
</select>
|
|
<select id="countPushOfMember" resultType="java.lang.Integer">
|
|
SELECT
|
|
IFNULL(count(1), 0) AS count
|
|
FROM (
|
|
select count(1) as count
|
|
FROM `t_stats_record` r
|
|
left join `t_stats` s on r.trace_id=s.trace_id
|
|
where r.trace_id in (select trace_id from `t_stats_record` where action = 'ENTER_SCENIC' and `identifier`=#{scenicId})
|
|
and action = 'PERM_REQ' and identifier = 'NOTIFY'
|
|
<if test="startTime!= null">
|
|
and r.create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and r.create_time <= #{endTime}
|
|
</if>
|
|
group by s.member_id
|
|
)a
|
|
</select>
|
|
<select id="countCameraShotOfMember" resultType="java.lang.Integer">
|
|
select count(1) as count
|
|
from face_sample
|
|
where scenic_id = #{scenicId}
|
|
<if test="startTime!= null">
|
|
and create_at >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and create_at <= #{endTime}
|
|
</if>
|
|
</select>
|
|
<select id="countUploadFaceOfMember" resultType="java.lang.Integer">
|
|
select ifnull(count(1),0) as count
|
|
from(
|
|
select 1 as count
|
|
from t_stats_record r
|
|
left join `t_stats` s on r.trace_id=s.trace_id
|
|
where r.trace_id in (select trace_id from `t_stats_record` where action = 'ENTER_SCENIC' and `identifier`=#{scenicId})
|
|
and r.action = 'FACE_UPLOAD'
|
|
<if test="startTime!= null">
|
|
and s.create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and s.create_time <= #{endTime}
|
|
</if>
|
|
group by s.member_id
|
|
) a
|
|
</select>
|
|
<select id="countCompleteVideoOfMember" resultType="java.lang.Integer">
|
|
select ifnull(count(1),0) as count
|
|
from(
|
|
select 1 from (
|
|
select r.identifier, s.member_id
|
|
from t_stats_record r
|
|
left join `t_stats` s on r.trace_id=s.trace_id
|
|
where r.trace_id in (select trace_id from `t_stats_record` where action = 'ENTER_SCENIC' and `identifier`=#{scenicId})
|
|
and r.action = 'FACE_UPLOAD'
|
|
<if test="startTime!= null">
|
|
and s.create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and s.create_time <= #{endTime}
|
|
</if>
|
|
GROUP BY r.identifier, s.member_id
|
|
) stat left join task on task.face_id = stat.identifier and task.`status` = 1
|
|
where task.id is not null
|
|
group by stat.member_id
|
|
) a
|
|
</select>
|
|
<select id="countTotalVisitorOfMember" resultType="java.lang.Integer">
|
|
SELECT
|
|
IFNULL(count(1), 0) AS count
|
|
FROM (
|
|
select 1
|
|
FROM `t_stats_record` r
|
|
left join `t_stats` s on r.trace_id=s.trace_id
|
|
where r.trace_id in (select trace_id from `t_stats_record` where action = 'ENTER_SCENIC' and `identifier`=#{scenicId})
|
|
and action = "LAUNCH"
|
|
<if test="startTime!= null">
|
|
and s.create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and s.create_time <= #{endTime}
|
|
</if>
|
|
group by s.member_id
|
|
) AS subquery;
|
|
</select>
|
|
<select id="countCompleteOfVideo" resultType="java.lang.Integer">
|
|
select ifnull(count(1),0) as count
|
|
from(
|
|
select 1 from (
|
|
select r.identifier, s.member_id
|
|
from t_stats_record r
|
|
left join `t_stats` s on r.trace_id=s.trace_id
|
|
where r.trace_id in (select trace_id from `t_stats_record` where action = 'ENTER_SCENIC' and `identifier`=#{scenicId})
|
|
and r.action = 'FACE_UPLOAD'
|
|
<if test="startTime!= null">
|
|
and s.create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and s.create_time <= #{endTime}
|
|
</if>
|
|
GROUP BY r.identifier, s.member_id
|
|
) stat left join task on task.face_id = stat.identifier and task.`status` = 1
|
|
where task.id is not null
|
|
) a
|
|
</select>
|
|
<select id="countPreviewOfVideo" resultType="java.lang.Integer">
|
|
SELECT
|
|
IFNULL(SUM(count), 0) AS count
|
|
FROM (
|
|
select 1 as count
|
|
FROM `t_stats_record` r
|
|
left join `t_stats` s on r.trace_id=s.trace_id
|
|
where r.trace_id in (select trace_id from `t_stats_record` where action = 'ENTER_SCENIC' and `identifier`=#{scenicId})
|
|
and action = 'LOAD'
|
|
and identifier = 'pages/videoSynthesis/buy'
|
|
and JSON_EXTRACT(`params`, '$.id') is not null
|
|
and JSON_EXTRACT(`params`, '$.share') is null
|
|
<if test="startTime!= null">
|
|
and s.create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and s.create_time <= #{endTime}
|
|
</if>
|
|
group by JSON_EXTRACT(`params`, "$.id")
|
|
)a
|
|
</select>
|
|
<select id="countPayOfOrder" resultType="java.lang.Integer">
|
|
select count(1) as count
|
|
from `order`
|
|
where
|
|
(status = 1 or status = 2) and scenic_id = #{scenicId}
|
|
<if test="startTime!= null">
|
|
and pay_at >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and pay_at <= #{endTime}
|
|
</if>
|
|
</select>
|
|
<select id="countRefundOfOrder" resultType="java.lang.Integer">
|
|
select count(1) as count
|
|
from `order`
|
|
where
|
|
refund_status = 1 and scenic_id = #{scenicId}
|
|
<if test="startTime!= null">
|
|
and refund_at >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and refund_at <= #{endTime}
|
|
</if>
|
|
</select>
|
|
<select id="countRefundAmount" resultType="java.math.BigDecimal">
|
|
select ifnull(sum(pay_price),0) as payPrice
|
|
from `order`
|
|
where
|
|
refund_status = 1 and scenic_id = #{scenicId}
|
|
<if test="startTime!= null">
|
|
and create_at >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and create_at <= #{endTime}
|
|
</if>
|
|
</select>
|
|
<select id="getBrokerIdListForUser" resultType="java.lang.Long">
|
|
select identifier
|
|
from (
|
|
select identifier, max(r.create_time) as createTime
|
|
FROM `t_stats_record` r
|
|
left join `t_stats` s on r.trace_id=s.trace_id
|
|
where action = "CODE_SCAN"
|
|
and s.member_id = #{memberId}
|
|
<if test="startTime!= null">
|
|
and r.create_time >= #{startTime}
|
|
</if>
|
|
<if test="endTime!= null">
|
|
and r.create_time <= #{endTime}
|
|
</if>
|
|
group by identifier
|
|
) a
|
|
order by createTime desc
|
|
</select>
|
|
<select id="getUserRecentEnterType" resultType="java.lang.Long">
|
|
select JSON_EXTRACT(`params`, '$.scene')
|
|
FROM `t_stats_record` r
|
|
left join `t_stats` s on r.trace_id=s.trace_id
|
|
where action = "LAUNCH" and s.member_id = #{memberId}
|
|
<if test="endTime!= null">
|
|
and r.create_time <= #{endTime}
|
|
</if>
|
|
order by r.create_time desc
|
|
limit 1
|
|
</select>
|
|
<select id="listStatByScenic" resultType="com.ycwl.basic.model.mobile.statistic.resp.AppStatisticsFunnelVO">
|
|
SELECT cs1 AS cameraShotOfMemberNum, v1 AS totalVisitorOfMemberNum, sv1 AS scanCodeVisitorOfMemberNum, u1 AS uploadFaceOfMemberNum, m1 AS pushOfMemberNum, gv1 AS completeVideoOfMemberNum, gv2 AS completeOfVideoNum, pv1 AS previewVideoOfMemberNum, pv2 AS previewOfVideoNum, cp1 AS clickOnPayOfMemberNum, o1 AS payOfMemberNum, o2 AS payOfOrderNum, o3 AS payOfOrderAmount, ro2 AS refundOfOrderNum, ro3 AS refundOfOrderAmount
|
|
FROM scenic_stats
|
|
WHERE scenic_id = #{scenicId}
|
|
AND date BETWEEN #{startTime} AND #{endTime}
|
|
</select>
|
|
<select id="orderChartByDate" resultType="java.util.HashMap">
|
|
WITH RECURSIVE date_series AS (
|
|
SELECT
|
|
DATE(#{startTime}) AS date_value
|
|
UNION ALL
|
|
SELECT
|
|
DATE_ADD(date_value, INTERVAL 1 DAY) AS date_value
|
|
FROM date_series
|
|
WHERE DATE_ADD(date_value, INTERVAL 1 DAY) <= DATE(#{endTime})
|
|
)
|
|
SELECT
|
|
DATE(date_series.date_value) as t,
|
|
COALESCE(COUNT(`order`.id), 0) AS count,
|
|
COALESCE(SUM(`order`.pay_price), 0) AS price
|
|
FROM date_series
|
|
LEFT JOIN `order` ON DATE(`order`.create_at) = date_series.date_value
|
|
<if test="scenicId != null">
|
|
AND `order`.scenic_id = #{scenicId}
|
|
</if>
|
|
AND (`order`.STATUS = 1 OR `order`.STATUS = 2)
|
|
GROUP BY date_series.date_value
|
|
ORDER BY date_series.date_value
|
|
</select>
|
|
<select id="orderChartByHour" resultType="java.util.HashMap">
|
|
WITH RECURSIVE hour_series AS (
|
|
SELECT
|
|
#{startTime} AS hour_time,
|
|
DATE_FORMAT(#{startTime}, '%m-%d %H') AS HOUR
|
|
UNION ALL
|
|
SELECT
|
|
DATE_ADD(hour_time, INTERVAL 1 HOUR) AS hour_time,
|
|
DATE_FORMAT(DATE_ADD(hour_time, INTERVAL 1 HOUR), '%m-%d %H') AS HOUR
|
|
FROM hour_series
|
|
WHERE DATE_ADD(hour_time, INTERVAL 1 HOUR) <= #{endTime}
|
|
)
|
|
SELECT
|
|
hour_series.HOUR as t,
|
|
COALESCE(COUNT(`order`.id), 0) AS count,
|
|
COALESCE(SUM(`order`.pay_price), 0) AS price
|
|
FROM hour_series
|
|
LEFT JOIN `order` ON DATE_FORMAT(`order`.create_at, '%m-%d %H') = hour_series.HOUR
|
|
<if test="scenicId != null">
|
|
AND `order`.scenic_id = #{scenicId}
|
|
</if>
|
|
AND (`order`.STATUS = 1 OR `order`.STATUS = 2)
|
|
GROUP BY hour_series.HOUR, hour_series.hour_time
|
|
ORDER BY hour_series.hour_time
|
|
</select>
|
|
<insert id="insertStat">
|
|
REPLACE INTO scenic_stats (scenic_id, date, cs1, v1, sv1, u1, m1, gv1, gv2, pv1, pv2, cp1, o1, o2, o3, ro2, ro3)
|
|
VALUES (#{scenicId}, #{date}, #{data.cameraShotOfMemberNum}, #{data.totalVisitorOfMemberNum}, #{data.scanCodeVisitorOfMemberNum}, #{data.uploadFaceOfMemberNum}, #{data.pushOfMemberNum}, #{data.completeVideoOfMemberNum}, #{data.completeOfVideoNum}, #{data.previewVideoOfMemberNum}, #{data.previewOfVideoNum}, #{data.clickOnPayOfMemberNum}, #{data.payOfMemberNum}, #{data.payOfOrderNum}, #{data.payOfOrderAmount}, #{data.refundOfOrderNum}, #{data.refundOfOrderAmount})
|
|
</insert>
|
|
<select id="scanCodeMemberChartByHour" resultType="java.util.HashMap">
|
|
WITH RECURSIVE hour_series AS (
|
|
SELECT
|
|
#{startTime} AS hour_time,
|
|
DATE_FORMAT(#{startTime}, '%m-%d %H') AS HOUR
|
|
UNION ALL
|
|
SELECT
|
|
DATE_ADD(hour_time, INTERVAL 1 HOUR) AS hour_time,
|
|
DATE_FORMAT(DATE_ADD(hour_time, INTERVAL 1 HOUR), '%m-%d %H') AS HOUR
|
|
FROM hour_series
|
|
WHERE DATE_ADD(hour_time, INTERVAL 1 HOUR) <= #{endTime}
|
|
)
|
|
SELECT
|
|
hour_series.HOUR as t,
|
|
COALESCE(scan_data.member_count, 0) AS count,
|
|
COALESCE(order_data.order_count, 0) AS orderCount,
|
|
COALESCE(order_data.order_amount, 0) AS orderAmount
|
|
FROM hour_series
|
|
LEFT JOIN (
|
|
SELECT
|
|
DATE_FORMAT(s.create_time, '%m-%d %H') AS hour_key,
|
|
COUNT(DISTINCT s.member_id) AS member_count
|
|
FROM `t_stats_record` r
|
|
LEFT JOIN `t_stats` s ON r.trace_id = s.trace_id
|
|
WHERE r.trace_id IN (
|
|
SELECT trace_id FROM `t_stats_record`
|
|
WHERE action = 'ENTER_SCENIC'
|
|
<if test="scenicId != null">
|
|
AND `identifier` = #{scenicId}
|
|
</if>
|
|
)
|
|
AND r.action = 'LAUNCH'
|
|
AND JSON_EXTRACT(`params`, '$.scene') IN (1047, 1048, 1049)
|
|
AND s.create_time BETWEEN #{startTime} AND #{endTime}
|
|
GROUP BY DATE_FORMAT(s.create_time, '%m-%d %H')
|
|
) scan_data ON scan_data.hour_key = hour_series.HOUR
|
|
LEFT JOIN (
|
|
SELECT
|
|
DATE_FORMAT(create_at, '%m-%d %H') AS hour_key,
|
|
COUNT(id) AS order_count,
|
|
SUM(pay_price) AS order_amount
|
|
FROM `order`
|
|
WHERE (status = 1 OR status = 2)
|
|
<if test="scenicId != null">
|
|
AND scenic_id = #{scenicId}
|
|
</if>
|
|
AND create_at BETWEEN #{startTime} AND #{endTime}
|
|
GROUP BY DATE_FORMAT(create_at, '%m-%d %H')
|
|
) order_data ON order_data.hour_key = hour_series.HOUR
|
|
ORDER BY hour_series.hour_time
|
|
</select>
|
|
<select id="scanCodeMemberChartByDate" resultType="java.util.HashMap">
|
|
WITH RECURSIVE date_series AS (
|
|
SELECT
|
|
DATE(#{startTime}) AS date_value,
|
|
DATE_FORMAT(#{startTime}, '%m-%d') AS DATE_KEY
|
|
UNION ALL
|
|
SELECT
|
|
DATE_ADD(date_value, INTERVAL 1 DAY) AS date_value,
|
|
DATE_FORMAT(DATE_ADD(date_value, INTERVAL 1 DAY), '%m-%d') AS DATE_KEY
|
|
FROM date_series
|
|
WHERE DATE_ADD(date_value, INTERVAL 1 DAY) <= DATE(#{endTime})
|
|
)
|
|
SELECT
|
|
date_series.DATE_KEY as t,
|
|
COALESCE(scan_data.member_count, 0) AS count,
|
|
COALESCE(order_data.order_count, 0) AS orderCount,
|
|
COALESCE(order_data.order_amount, 0) AS orderAmount
|
|
FROM date_series
|
|
LEFT JOIN (
|
|
SELECT
|
|
DATE_FORMAT(s.create_time, '%m-%d') AS date_key,
|
|
COUNT(DISTINCT s.member_id) AS member_count
|
|
FROM `t_stats_record` r
|
|
LEFT JOIN `t_stats` s ON r.trace_id = s.trace_id
|
|
WHERE r.trace_id IN (
|
|
SELECT trace_id FROM `t_stats_record`
|
|
WHERE action = 'ENTER_SCENIC'
|
|
<if test="scenicId != null">
|
|
AND `identifier` = #{scenicId}
|
|
</if>
|
|
)
|
|
AND r.action = 'LAUNCH'
|
|
AND JSON_EXTRACT(`params`, '$.scene') IN (1047, 1048, 1049)
|
|
AND s.create_time BETWEEN #{startTime} AND #{endTime}
|
|
GROUP BY DATE_FORMAT(s.create_time, '%m-%d')
|
|
) scan_data ON scan_data.date_key = date_series.DATE_KEY
|
|
LEFT JOIN (
|
|
SELECT
|
|
DATE_FORMAT(create_at, '%m-%d') AS date_key,
|
|
COUNT(id) AS order_count,
|
|
SUM(pay_price) AS order_amount
|
|
FROM `order`
|
|
WHERE (status = 1 OR status = 2)
|
|
<if test="scenicId != null">
|
|
AND scenic_id = #{scenicId}
|
|
</if>
|
|
AND create_at BETWEEN #{startTime} AND #{endTime}
|
|
GROUP BY DATE_FORMAT(create_at, '%m-%d')
|
|
) order_data ON order_data.date_key = date_series.DATE_KEY
|
|
ORDER BY date_series.date_value
|
|
</select>
|
|
|
|
</mapper> |