You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

230 lines
11 KiB

<?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.example.demo.mapper.coin.StatisticsMapper">
<insert id="batchInsertPart1">
<foreach collection="list" item="s" separator=";">
INSERT INTO statistics (
market, current_datetime,
current_gold, daily_change,
current_permanent, current_free_june,
current_free_december, current_task
) VALUES (
#{s.market}, #{s.currentDatetime},
#{s.currentGold}, #{s.dailyChange},
#{s.currentPermanent}, #{s.currentFreeJune},
#{s.currentFreeDecember}, #{s.currentTask}
)
ON DUPLICATE KEY UPDATE
current_gold = VALUES(current_gold),
daily_change = VALUES(daily_change),
current_permanent = VALUES(current_permanent),
current_free_june = VALUES(current_free_june),
current_free_december = VALUES(current_free_december),
current_task = VALUES(current_task)
</foreach>
</insert>
<insert id="batchInsertPart2">
<foreach collection="list" item="s" separator=";">
INSERT INTO statistics (
market, current_datetime,
recharge, money,
consume_permanent, consume_free_june,
consume_free_december, consume_task,
refund_permanent, refund_free_june,
refund_free_december, refund_task,
recharge_num, first_recharge
) VALUES (
#{s.market}, #{s.currentDatetime},
#{s.recharge}, #{s.money},
#{s.consumePermanent}, #{s.consumeFreeJune},
#{s.consumeFreeDecember}, #{s.consumeTask},
#{s.refundPermanent}, #{s.refundFreeJune},
#{s.refundFreeDecember}, #{s.refundTask},
#{s.rechargeNum}, #{s.firstRecharge}
)
ON DUPLICATE KEY UPDATE
recharge = VALUES(recharge),
money = VALUES(money),
consume_permanent = VALUES(consume_permanent),
consume_free_june = VALUES(consume_free_june),
consume_free_december = VALUES(consume_free_december),
consume_task = VALUES(consume_task),
refund_permanent = VALUES(refund_permanent),
refund_free_june = VALUES(refund_free_june),
refund_free_december = VALUES(refund_free_december),
refund_task = VALUES(refund_task),
recharge_num = VALUES(recharge_num),
first_recharge = VALUES(first_recharge)
</foreach>
</insert>
<insert id="batchInsertYear">
<foreach collection="list" item="s" separator=";">
INSERT INTO statistics (
market, current_datetime,
yearly_recharge,
yearly_money,
yearly_consume,
yearly_refund,
yearly_recharge_num
) VALUES (
#{s.market}, #{s.currentDatetime},
#{s.yearlyRecharge},
#{s.yearlyMoney},
#{s.yearlyConsume},
#{s.yearlyRefund},
#{s.yearlyRechargeNum}
)
ON DUPLICATE KEY UPDATE
yearly_recharge = VALUES(yearly_recharge),
yearly_money = VALUES(yearly_money),
yearly_consume = VALUES(yearly_consume),
yearly_refund = VALUES(yearly_refund),
yearly_recharge_num = VALUES(yearly_recharge_num)
</foreach>
</insert>
<!-- 计算该天充值人数-->
<select id="countRechargeNum" resultType="java.lang.Integer">
SELECT COUNT(DISTINCT ugr.jwcode)
FROM user_gold_record ugr
INNER JOIN user u ON ugr.jwcode = u.jwcode
WHERE u.market = #{market}
AND ugr.type=0
AND ugr.audit_status IN (1,3)
AND ugr.audit_time BETWEEN #{startTime} AND #{endTime}
AND u.flag = 1
</select>
<!--获取某地区某时间所在日期的数据(仅一条)-->
<select id="selectByMarketAndDate" resultType="com.example.demo.domain.entity.Statistics">
SELECT *
FROM statistics
WHERE market = #{market}
AND current_datetime BETWEEN #{startDate} AND #{endDate}
</select>
<select id="selectByMarketsAndDate" resultType="com.example.demo.domain.entity.Statistics">
SELECT * FROM statistics
WHERE market IN
<foreach item="market" collection="markets" open="(" separator="," close=")">
#{market}
</foreach>
AND current_datetime BETWEEN #{startDate} AND #{endDate}
</select>
<select id="listPart1All" resultType="com.example.demo.domain.entity.Statistics">
SELECT
m.name as market,
#{today} AS current_datetime,
COALESCE(SUM(current_permanent_gold),0) +
COALESCE(SUM(current_free_june),0) +
COALESCE(SUM(current_free_december),0) +
COALESCE(SUM(current_task_gold),0) AS current_gold,
COALESCE(SUM(current_permanent_gold),0) AS current_permanent,
COALESCE(SUM(current_free_june),0) AS current_free_june,
COALESCE(SUM(current_free_december),0) AS current_free_december,
COALESCE(SUM(current_task_gold),0) AS current_task,
-- 与昨天差值(从 statistics 表取)
(
COALESCE(SUM(u.current_permanent_gold),0) +
COALESCE(SUM(u.current_free_june),0) +
COALESCE(SUM(u.current_free_december),0) +
COALESCE(SUM(u.current_task_gold),0)
) - COALESCE(
(
SELECT s.current_gold
FROM statistics s
WHERE s.market = m.name
AND s.current_datetime = DATE_SUB(#{today}, INTERVAL 1 DAY)
LIMIT 1
), 0
) AS daily_change
FROM user u
left join market m on u.market=m.id
where m.name IS NOT NULL
and u.flag = 1
GROUP BY market
</select>
<select id="listPart2All" resultType="com.example.demo.domain.entity.Statistics">
SELECT
m.name as market,
'2025-08-04' AS current_datetime,
COALESCE(SUM(CASE WHEN ugr.type=0 THEN ugr.permanent_gold+ugr.free_june+ugr.free_december+ugr.task_gold END),0) AS recharge,
COALESCE(SUM(CASE WHEN ugr.type=0 THEN ugr.permanent_gold END),0) AS money,
COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.permanent_gold END),0) AS consume_permanent,
COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.free_june END),0) AS consume_free_june,
COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.free_december END),0) AS consume_free_december,
COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.task_gold END),0) AS consume_task,
COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.permanent_gold END),0) AS refund_permanent,
COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.free_june END),0) AS refund_free_june,
COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.free_december END),0) AS refund_free_december,
COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.task_gold END),0) AS refund_task,
COUNT(DISTINCT CASE WHEN ugr.type=0 THEN ugr.jwcode END) AS recharge_num,
COUNT(DISTINCT CASE WHEN ugr.type=0
AND u.first_recharge BETWEEN #{start} AND #{end} THEN ugr.jwcode END) AS first_recharge
FROM user_gold_record ugr
JOIN user u ON ugr.jwcode = u.jwcode
left join market m on u.market=m.id
WHERE ugr.audit_status IN (1,3)
AND ugr.flag = 1
AND ugr.create_time BETWEEN #{start} AND #{end}
AND m.name IS NOT NULL
AND u.flag = 1
GROUP BY u.market
</select>
<select id="listYearAll" resultType="com.example.demo.domain.entity.Statistics">
SELECT m.name as market,
COALESCE(SUM(s.recharge),0) AS yearly_recharge,
#{today} AS current_datetime,
COALESCE(SUM(s.money),0) AS yearly_money,
COALESCE(SUM(s.consume_permanent+s.consume_free_june+s.consume_free_december+s.consume_task),0) AS yearly_consume,
COALESCE(SUM(s.refund_permanent+s.refund_free_june+s.refund_free_december+s.refund_task),0) AS yearly_refund,
COALESCE(SUM(s.recharge_num),0) AS yearly_recharge_num
FROM statistics s
left join market m on s.market=m.id
WHERE current_datetime BETWEEN #{yearStart} AND #{end} AND m.name IS NOT NULL
GROUP BY market
</select>
<select id="listPart2RangeAll" resultType="com.example.demo.domain.entity.Statistics">
SELECT
m.name as market,
DATE(ugr.create_time) AS current_datetime, -- 只保留日期
COALESCE(SUM(CASE WHEN ugr.type=0 THEN ugr.permanent_gold+ugr.free_june+ugr.free_december+ugr.task_gold END),0) AS recharge,
COALESCE(SUM(CASE WHEN ugr.type=0 THEN ugr.permanent_gold END),0) AS money,
COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.permanent_gold END),0) AS consume_permanent,
COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.free_june END),0) AS consume_free_june,
COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.free_december END),0) AS consume_free_december,
COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.task_gold END),0) AS consume_task,
COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.permanent_gold END),0) AS refund_permanent,
COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.free_june END),0) AS refund_free_june,
COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.free_december END),0) AS refund_free_december,
COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.task_gold END),0) AS refund_task,
COUNT(DISTINCT CASE WHEN ugr.type=0 THEN ugr.jwcode END) AS recharge_num,
COUNT(DISTINCT CASE WHEN ugr.type=0
AND u.first_recharge BETWEEN d.date_start AND d.date_end THEN ugr.jwcode END) AS first_recharge
FROM
-- 生成 7 天日期序列
(
SELECT DATE_SUB(CURDATE(), INTERVAL seq DAY) AS create_date,
DATE_SUB(CURDATE(), INTERVAL seq DAY) AS date_start,
TIMESTAMP(DATE_SUB(CURDATE(), INTERVAL seq DAY), '23:59:59') AS date_end
FROM (
SELECT 0 AS seq UNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL
SELECT 3 UNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6
) AS days
) d
JOIN user_gold_record ugr
ON ugr.create_time between d.date_start AND d.date_end
JOIN user u ON ugr.jwcode = u.jwcode
left join market m on u.market=m.id
WHERE ugr.audit_status IN (1,3)
AND ugr.flag = 1
AND m.name IS NOT NULL
AND u.flag = 1
GROUP BY m.name, d.create_date
</select>
</mapper>