You've already forked FrameTour-BE
feat(database): 迁移统计数据查询到ClickHouse
- 添加ClickHouse数据源配置和相关依赖 - 实现ClickHouse统计查询服务和MySQL兜底方案 - 新增扫码统计、订单统计等数据查询接口 - 重构分销员数据统计逻辑,整合MySQL和ClickHouse数据源 - 更新应用配置文件以支持ClickHouse启用开关 - 修改分布式任务统计以支持跨库查询场景
This commit is contained in:
@@ -8,6 +8,17 @@ spring:
|
||||
lifecycle:
|
||||
timeout-per-shutdown-phase: 60s
|
||||
|
||||
# ClickHouse 配置
|
||||
clickhouse:
|
||||
enabled: true # true=ClickHouse, false=MySQL兜底
|
||||
datasource:
|
||||
jdbc-url: jdbc:clickhouse://100.64.0.7:8123/zt
|
||||
username: default
|
||||
password: ZhEnTuAi
|
||||
driver-class-name: com.clickhouse.jdbc.ClickHouseDriver
|
||||
maximum-pool-size: 10
|
||||
minimum-idle: 2
|
||||
|
||||
# Feign配置(简化版,基于Nacos服务发现)
|
||||
feign:
|
||||
client:
|
||||
|
||||
@@ -8,6 +8,17 @@ spring:
|
||||
lifecycle:
|
||||
timeout-per-shutdown-phase: 60s
|
||||
|
||||
# ClickHouse 配置
|
||||
clickhouse:
|
||||
enabled: true # 设置为 true 启用 ClickHouse,false 使用 MySQL 兜底
|
||||
datasource:
|
||||
jdbc-url: jdbc:clickhouse://100.64.0.7:8123/zt
|
||||
username: default
|
||||
password: ZhEnTuAi
|
||||
driver-class-name: com.clickhouse.jdbc.ClickHouseDriver
|
||||
maximum-pool-size: 20
|
||||
minimum-idle: 5
|
||||
|
||||
# 生产环境日志级别
|
||||
logging:
|
||||
level:
|
||||
|
||||
@@ -36,7 +36,6 @@
|
||||
</delete>
|
||||
<select id="list" resultType="com.ycwl.basic.model.pc.broker.resp.BrokerRespVO">
|
||||
select b.id, scenic_id, b.`name`, b.phone, b.broker_enable, b.broker_rate, b.status,
|
||||
(select count(1) from t_stats_record s where s.action = "CODE_SCAN" and s.identifier = b.id) as broker_scan_count,
|
||||
(select count(1) from broker_record r where r.broker_id = b.id) as broker_order_count,
|
||||
(select sum(order_price) from broker_record r where r.broker_id = b.id) as broker_order_amount,
|
||||
(select min(r.create_time) from broker_record r where r.broker_id = b.id) as first_broker_date,
|
||||
|
||||
@@ -107,4 +107,30 @@
|
||||
</set>
|
||||
where id = #{id}
|
||||
</update>
|
||||
|
||||
<!-- 按日期统计分销员订单数据(不含扫码统计) -->
|
||||
<select id="getDailyOrderStats" resultType="java.util.HashMap">
|
||||
WITH RECURSIVE
|
||||
date_series AS (SELECT DATE(#{startTime}) AS date
|
||||
UNION ALL
|
||||
SELECT DATE_ADD(date, INTERVAL 1 DAY)
|
||||
FROM date_series
|
||||
WHERE date < DATE(#{endTime}))
|
||||
SELECT ds.date,
|
||||
COALESCE(os.orderCount, 0) AS orderCount,
|
||||
COALESCE(os.totalOrderPrice, 0) AS totalOrderPrice,
|
||||
COALESCE(os.totalBrokerPrice, 0) AS totalBrokerPrice
|
||||
FROM date_series ds
|
||||
LEFT JOIN (
|
||||
SELECT DATE(create_time) AS date,
|
||||
COUNT(DISTINCT id) AS orderCount,
|
||||
COALESCE(SUM(order_price), 0) AS totalOrderPrice,
|
||||
COALESCE(SUM(broker_price), 0) AS totalBrokerPrice
|
||||
FROM broker_record
|
||||
WHERE broker_id = #{brokerId}
|
||||
AND DATE(create_time) BETWEEN DATE(#{startTime}) AND DATE(#{endTime})
|
||||
GROUP BY DATE(create_time)
|
||||
) os ON ds.date = os.date
|
||||
ORDER BY ds.date
|
||||
</select>
|
||||
</mapper>
|
||||
@@ -531,4 +531,24 @@
|
||||
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 = #{brokerId}
|
||||
</select>
|
||||
|
||||
<!-- 按日期统计分销员扫码数据 -->
|
||||
<select id="getDailyScanStats" resultType="java.util.HashMap">
|
||||
SELECT
|
||||
DATE(create_time) AS date,
|
||||
COUNT(DISTINCT id) AS scanCount
|
||||
FROM t_stats_record
|
||||
WHERE action = 'CODE_SCAN'
|
||||
AND identifier = #{brokerId}
|
||||
AND DATE(create_time) BETWEEN DATE(#{startTime}) AND DATE(#{endTime})
|
||||
GROUP BY DATE(create_time)
|
||||
</select>
|
||||
|
||||
</mapper>
|
||||
@@ -151,4 +151,26 @@
|
||||
order by create_time desc
|
||||
limit 1
|
||||
</select>
|
||||
|
||||
<!-- 根据 face_id 列表统计已完成任务的用户数 -->
|
||||
<select id="countCompletedTaskMembersByFaceIds" resultType="java.lang.Integer">
|
||||
SELECT COUNT(DISTINCT member_id) AS count
|
||||
FROM task
|
||||
WHERE status = 1
|
||||
AND face_id IN
|
||||
<foreach collection="faceIds" item="faceId" open="(" separator="," close=")">
|
||||
#{faceId}
|
||||
</foreach>
|
||||
</select>
|
||||
|
||||
<!-- 根据 face_id 列表统计已完成任务数 -->
|
||||
<select id="countCompletedTasksByFaceIds" resultType="java.lang.Integer">
|
||||
SELECT COUNT(1) AS count
|
||||
FROM task
|
||||
WHERE status = 1
|
||||
AND face_id IN
|
||||
<foreach collection="faceIds" item="faceId" open="(" separator="," close=")">
|
||||
#{faceId}
|
||||
</foreach>
|
||||
</select>
|
||||
</mapper>
|
||||
|
||||
269
src/main/resources/mapper/clickhouse/ClickHouseStatsMapper.xml
Normal file
269
src/main/resources/mapper/clickhouse/ClickHouseStatsMapper.xml
Normal file
@@ -0,0 +1,269 @@
|
||||
<?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