You've already forked FrameTour-BE
refactor(clickhouse): 将统计数据查询从 MyBatis 迁移到 JDBC 模板
- 移除 ClickHouseStatsMapper 接口及 XML 映射文件 - 使用 NamedParameterJdbcTemplate 替代 MyBatis 实现数据查询 - 添加日期格式化工具类处理 ClickHouse 时间格式 - 重构所有统计查询方法使用原生 SQL 字符串构建 - 添加 MySQL 主数据源配置确保多数据源正确配置 - 升级 ClickHouse JDBC 驱动版本到 0.8.5 - 解决 0.6.x 版本参数绑定问题通过手动 SQL 构建 - 保持原有查询逻辑不变仅改变实现方式
This commit is contained in:
@@ -1,269 +0,0 @@
|
||||
<?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.clickhouse.mapper.ClickHouseStatsMapper">
|
||||
|
||||
<!-- 统计预览视频人数 -->
|
||||
<select id="countPreviewVideoOfMember" resultType="java.lang.Integer">
|
||||
SELECT ifNull(count(1), 0) AS count
|
||||
FROM (
|
||||
SELECT 1
|
||||
FROM t_stats_record r
|
||||
INNER 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 = toString(#{scenicId})
|
||||
)
|
||||
AND r.action = 'LOAD'
|
||||
AND r.identifier = 'pages/videoSynthesis/buy'
|
||||
AND JSONExtractString(r.params, 'share') = ''
|
||||
<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
|
||||
)
|
||||
</select>
|
||||
|
||||
<!-- 统计扫码访问人数 -->
|
||||
<select id="countScanCodeOfMember" resultType="java.lang.Integer">
|
||||
SELECT ifNull(count(1), 0) AS count
|
||||
FROM (
|
||||
SELECT 1
|
||||
FROM t_stats_record r
|
||||
INNER 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 = toString(#{scenicId})
|
||||
)
|
||||
AND r.action = 'LAUNCH'
|
||||
AND JSONExtractInt(r.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
|
||||
)
|
||||
</select>
|
||||
|
||||
<!-- 统计推送订阅人数 -->
|
||||
<select id="countPushOfMember" resultType="java.lang.Integer">
|
||||
SELECT ifNull(count(1), 0) AS count
|
||||
FROM (
|
||||
SELECT 1
|
||||
FROM t_stats_record r
|
||||
INNER 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 = toString(#{scenicId})
|
||||
)
|
||||
AND r.action = 'PERM_REQ'
|
||||
AND r.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
|
||||
)
|
||||
</select>
|
||||
|
||||
<!-- 统计上传头像人数 -->
|
||||
<select id="countUploadFaceOfMember" resultType="java.lang.Integer">
|
||||
SELECT ifNull(count(1), 0) AS count
|
||||
FROM (
|
||||
SELECT 1
|
||||
FROM t_stats_record r
|
||||
INNER 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 = toString(#{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
|
||||
)
|
||||
</select>
|
||||
|
||||
<!-- 获取上传人脸的 face_id 列表(用于与 MySQL task 表关联) -->
|
||||
<select id="listFaceIdsWithUpload" resultType="java.lang.String">
|
||||
SELECT DISTINCT r.identifier
|
||||
FROM t_stats_record r
|
||||
INNER 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 = toString(#{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>
|
||||
</select>
|
||||
|
||||
<!-- 统计总访问人数 -->
|
||||
<select id="countTotalVisitorOfMember" resultType="java.lang.Integer">
|
||||
SELECT ifNull(count(1), 0) AS count
|
||||
FROM (
|
||||
SELECT 1
|
||||
FROM t_stats_record r
|
||||
INNER 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 = toString(#{scenicId})
|
||||
)
|
||||
AND r.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
|
||||
)
|
||||
</select>
|
||||
|
||||
<!-- 统计预览视频条数 -->
|
||||
<select id="countPreviewOfVideo" resultType="java.lang.Integer">
|
||||
SELECT ifNull(count(1), 0) AS count
|
||||
FROM (
|
||||
SELECT 1
|
||||
FROM t_stats_record r
|
||||
INNER 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 = toString(#{scenicId})
|
||||
)
|
||||
AND r.action = 'LOAD'
|
||||
AND r.identifier = 'pages/videoSynthesis/buy'
|
||||
AND JSONExtractString(r.params, 'id') != ''
|
||||
AND JSONExtractString(r.params, 'share') = ''
|
||||
<if test="startTime != null">
|
||||
AND s.create_time >= #{startTime}
|
||||
</if>
|
||||
<if test="endTime != null">
|
||||
AND s.create_time <= #{endTime}
|
||||
</if>
|
||||
GROUP BY JSONExtractString(r.params, 'id')
|
||||
)
|
||||
</select>
|
||||
|
||||
<!-- 获取用户分销员 ID 列表 -->
|
||||
<select id="getBrokerIdListForUser" resultType="java.lang.Long">
|
||||
SELECT toInt64(r.identifier) AS identifier
|
||||
FROM (
|
||||
SELECT identifier, max(r.create_time) AS createTime
|
||||
FROM t_stats_record r
|
||||
INNER JOIN t_stats s ON r.trace_id = s.trace_id
|
||||
WHERE r.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
|
||||
) sub
|
||||
ORDER BY createTime DESC
|
||||
</select>
|
||||
|
||||
<!-- 获取用户最近进入类型 -->
|
||||
<select id="getUserRecentEnterType" resultType="java.lang.Long">
|
||||
SELECT JSONExtractInt(r.params, 'scene') AS scene
|
||||
FROM t_stats_record r
|
||||
INNER JOIN t_stats s ON r.trace_id = s.trace_id
|
||||
WHERE r.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>
|
||||
|
||||
<!-- 获取用户项目 ID 列表 -->
|
||||
<select id="getProjectIdListForUser" resultType="java.lang.Long">
|
||||
SELECT toInt64(r.identifier) AS identifier
|
||||
FROM t_stats_record r
|
||||
INNER JOIN t_stats s ON r.trace_id = s.trace_id
|
||||
WHERE s.member_id = #{memberId}
|
||||
AND r.action = 'ENTER_PROJECT'
|
||||
AND r.create_time < #{endTime}
|
||||
AND r.create_time > #{startTime}
|
||||
ORDER BY r.create_time DESC
|
||||
LIMIT 1
|
||||
</select>
|
||||
|
||||
<!-- 统计分销员扫码次数 -->
|
||||
<select id="countBrokerScanCount" resultType="java.lang.Integer">
|
||||
SELECT count(1) AS count
|
||||
FROM t_stats_record
|
||||
WHERE action = 'CODE_SCAN'
|
||||
AND identifier = toString(#{brokerId})
|
||||
</select>
|
||||
|
||||
<!-- 按日期统计分销员扫码数据 -->
|
||||
<select id="getDailyScanStats" resultType="java.util.HashMap">
|
||||
SELECT
|
||||
toDate(create_time) AS date,
|
||||
count(DISTINCT id) AS scanCount
|
||||
FROM t_stats_record
|
||||
WHERE action = 'CODE_SCAN'
|
||||
AND identifier = toString(#{brokerId})
|
||||
AND toDate(create_time) BETWEEN toDate(#{startTime}) AND toDate(#{endTime})
|
||||
GROUP BY toDate(create_time)
|
||||
</select>
|
||||
|
||||
<!-- 按小时统计扫码人数 -->
|
||||
<select id="scanCodeMemberChartByHour" resultType="java.util.HashMap">
|
||||
SELECT
|
||||
formatDateTime(s.create_time, '%m-%d %H') AS t,
|
||||
count(DISTINCT s.member_id) AS count
|
||||
FROM t_stats_record r
|
||||
INNER 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 = toString(#{scenicId})
|
||||
</if>
|
||||
)
|
||||
AND r.action = 'LAUNCH'
|
||||
AND JSONExtractInt(r.params, 'scene') IN (1047, 1048, 1049)
|
||||
AND s.create_time BETWEEN #{startTime} AND #{endTime}
|
||||
GROUP BY formatDateTime(s.create_time, '%m-%d %H')
|
||||
</select>
|
||||
|
||||
<!-- 按日期统计扫码人数 -->
|
||||
<select id="scanCodeMemberChartByDate" resultType="java.util.HashMap">
|
||||
SELECT
|
||||
formatDateTime(s.create_time, '%m-%d') AS t,
|
||||
count(DISTINCT s.member_id) AS count
|
||||
FROM t_stats_record r
|
||||
INNER 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 = toString(#{scenicId})
|
||||
</if>
|
||||
)
|
||||
AND r.action = 'LAUNCH'
|
||||
AND JSONExtractInt(r.params, 'scene') IN (1047, 1048, 1049)
|
||||
AND s.create_time BETWEEN #{startTime} AND #{endTime}
|
||||
GROUP BY formatDateTime(s.create_time, '%m-%d')
|
||||
</select>
|
||||
|
||||
</mapper>
|
||||
Reference in New Issue
Block a user