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

  1. <?xml version="1.0" encoding="UTF-8"?>
  2. <!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
  3. <mapper namespace="com.example.demo.mapper.coin.StatisticsMapper">
  4. <insert id="batchInsertPart1">
  5. <foreach collection="list" item="s" separator=";">
  6. INSERT INTO statistics (
  7. market, current_datetime,
  8. current_gold, daily_change,
  9. current_permanent, current_free_june,
  10. current_free_december, current_task
  11. ) VALUES (
  12. #{s.market}, #{s.currentDatetime},
  13. #{s.currentGold}, #{s.dailyChange},
  14. #{s.currentPermanent}, #{s.currentFreeJune},
  15. #{s.currentFreeDecember}, #{s.currentTask}
  16. )
  17. ON DUPLICATE KEY UPDATE
  18. current_gold = VALUES(current_gold),
  19. daily_change = VALUES(daily_change),
  20. current_permanent = VALUES(current_permanent),
  21. current_free_june = VALUES(current_free_june),
  22. current_free_december = VALUES(current_free_december),
  23. current_task = VALUES(current_task)
  24. </foreach>
  25. </insert>
  26. <insert id="batchInsertPart2">
  27. <foreach collection="list" item="s" separator=";">
  28. INSERT INTO statistics (
  29. market, current_datetime,
  30. recharge, money,
  31. consume_permanent, consume_free_june,
  32. consume_free_december, consume_task,
  33. refund_permanent, refund_free_june,
  34. refund_free_december, refund_task,
  35. recharge_num, first_recharge
  36. ) VALUES (
  37. #{s.market}, #{s.currentDatetime},
  38. #{s.recharge}, #{s.money},
  39. #{s.consumePermanent}, #{s.consumeFreeJune},
  40. #{s.consumeFreeDecember}, #{s.consumeTask},
  41. #{s.refundPermanent}, #{s.refundFreeJune},
  42. #{s.refundFreeDecember}, #{s.refundTask},
  43. #{s.rechargeNum}, #{s.firstRecharge}
  44. )
  45. ON DUPLICATE KEY UPDATE
  46. recharge = VALUES(recharge),
  47. money = VALUES(money),
  48. consume_permanent = VALUES(consume_permanent),
  49. consume_free_june = VALUES(consume_free_june),
  50. consume_free_december = VALUES(consume_free_december),
  51. consume_task = VALUES(consume_task),
  52. refund_permanent = VALUES(refund_permanent),
  53. refund_free_june = VALUES(refund_free_june),
  54. refund_free_december = VALUES(refund_free_december),
  55. refund_task = VALUES(refund_task),
  56. recharge_num = VALUES(recharge_num),
  57. first_recharge = VALUES(first_recharge)
  58. </foreach>
  59. </insert>
  60. <insert id="batchInsertYear">
  61. <foreach collection="list" item="s" separator=";">
  62. INSERT INTO statistics (
  63. market, current_datetime,
  64. yearly_recharge,
  65. yearly_money,
  66. yearly_consume,
  67. yearly_refund,
  68. yearly_recharge_num
  69. ) VALUES (
  70. #{s.market}, #{s.currentDatetime},
  71. #{s.yearlyRecharge},
  72. #{s.yearlyMoney},
  73. #{s.yearlyConsume},
  74. #{s.yearlyRefund},
  75. #{s.yearlyRechargeNum}
  76. )
  77. ON DUPLICATE KEY UPDATE
  78. yearly_recharge = VALUES(yearly_recharge),
  79. yearly_money = VALUES(yearly_money),
  80. yearly_consume = VALUES(yearly_consume),
  81. yearly_refund = VALUES(yearly_refund),
  82. yearly_recharge_num = VALUES(yearly_recharge_num)
  83. </foreach>
  84. </insert>
  85. <!-- 计算该天充值人数-->
  86. <select id="countRechargeNum" resultType="java.lang.Integer">
  87. SELECT COUNT(DISTINCT ugr.jwcode)
  88. FROM user_gold_record ugr
  89. INNER JOIN user u ON ugr.jwcode = u.jwcode
  90. WHERE u.market = #{market}
  91. AND ugr.type=0
  92. AND ugr.audit_status IN (1,3)
  93. AND ugr.audit_time BETWEEN #{startTime} AND #{endTime}
  94. AND u.flag = 1
  95. </select>
  96. <!--获取某地区某时间所在日期的数据(仅一条)-->
  97. <select id="selectByMarketAndDate" resultType="com.example.demo.domain.entity.Statistics">
  98. SELECT *
  99. FROM statistics
  100. WHERE market = #{market}
  101. AND current_datetime BETWEEN #{startDate} AND #{endDate}
  102. </select>
  103. <select id="selectByMarketsAndDate" resultType="com.example.demo.domain.entity.Statistics">
  104. SELECT * FROM statistics
  105. WHERE market IN
  106. <foreach item="market" collection="markets" open="(" separator="," close=")">
  107. #{market}
  108. </foreach>
  109. AND current_datetime BETWEEN #{startDate} AND #{endDate}
  110. </select>
  111. <select id="listPart1All" resultType="com.example.demo.domain.entity.Statistics">
  112. SELECT
  113. m.name as market,
  114. #{today} AS current_datetime,
  115. COALESCE(SUM(current_permanent_gold),0) +
  116. COALESCE(SUM(current_free_june),0) +
  117. COALESCE(SUM(current_free_december),0) +
  118. COALESCE(SUM(current_task_gold),0) AS current_gold,
  119. COALESCE(SUM(current_permanent_gold),0) AS current_permanent,
  120. COALESCE(SUM(current_free_june),0) AS current_free_june,
  121. COALESCE(SUM(current_free_december),0) AS current_free_december,
  122. COALESCE(SUM(current_task_gold),0) AS current_task,
  123. -- 与昨天差值(从 statistics 表取)
  124. (
  125. COALESCE(SUM(u.current_permanent_gold),0) +
  126. COALESCE(SUM(u.current_free_june),0) +
  127. COALESCE(SUM(u.current_free_december),0) +
  128. COALESCE(SUM(u.current_task_gold),0)
  129. ) - COALESCE(
  130. (
  131. SELECT s.current_gold
  132. FROM statistics s
  133. WHERE s.market = m.name
  134. AND s.current_datetime = DATE_SUB(#{today}, INTERVAL 1 DAY)
  135. LIMIT 1
  136. ), 0
  137. ) AS daily_change
  138. FROM user u
  139. left join market m on u.market=m.id
  140. where m.name IS NOT NULL
  141. and u.flag = 1
  142. GROUP BY market
  143. </select>
  144. <select id="listPart2All" resultType="com.example.demo.domain.entity.Statistics">
  145. SELECT
  146. m.name as market,
  147. '2025-08-04' AS current_datetime,
  148. COALESCE(SUM(CASE WHEN ugr.type=0 THEN ugr.permanent_gold+ugr.free_june+ugr.free_december+ugr.task_gold END),0) AS recharge,
  149. COALESCE(SUM(CASE WHEN ugr.type=0 THEN ugr.permanent_gold END),0) AS money,
  150. COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.permanent_gold END),0) AS consume_permanent,
  151. COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.free_june END),0) AS consume_free_june,
  152. COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.free_december END),0) AS consume_free_december,
  153. COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.task_gold END),0) AS consume_task,
  154. COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.permanent_gold END),0) AS refund_permanent,
  155. COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.free_june END),0) AS refund_free_june,
  156. COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.free_december END),0) AS refund_free_december,
  157. COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.task_gold END),0) AS refund_task,
  158. COUNT(DISTINCT CASE WHEN ugr.type=0 THEN ugr.jwcode END) AS recharge_num,
  159. COUNT(DISTINCT CASE WHEN ugr.type=0
  160. AND u.first_recharge BETWEEN #{start} AND #{end} THEN ugr.jwcode END) AS first_recharge
  161. FROM user_gold_record ugr
  162. JOIN user u ON ugr.jwcode = u.jwcode
  163. left join market m on u.market=m.id
  164. WHERE ugr.audit_status IN (1,3)
  165. AND ugr.flag = 1
  166. AND ugr.create_time BETWEEN #{start} AND #{end}
  167. AND m.name IS NOT NULL
  168. AND u.flag = 1
  169. GROUP BY u.market
  170. </select>
  171. <select id="listYearAll" resultType="com.example.demo.domain.entity.Statistics">
  172. SELECT m.name as market,
  173. COALESCE(SUM(s.recharge),0) AS yearly_recharge,
  174. #{today} AS current_datetime,
  175. COALESCE(SUM(s.money),0) AS yearly_money,
  176. COALESCE(SUM(s.consume_permanent+s.consume_free_june+s.consume_free_december+s.consume_task),0) AS yearly_consume,
  177. COALESCE(SUM(s.refund_permanent+s.refund_free_june+s.refund_free_december+s.refund_task),0) AS yearly_refund,
  178. COALESCE(SUM(s.recharge_num),0) AS yearly_recharge_num
  179. FROM statistics s
  180. left join market m on s.market=m.id
  181. WHERE current_datetime BETWEEN #{yearStart} AND #{end} AND m.name IS NOT NULL
  182. GROUP BY market
  183. </select>
  184. <select id="listPart2RangeAll" resultType="com.example.demo.domain.entity.Statistics">
  185. SELECT
  186. m.name as market,
  187. DATE(ugr.create_time) AS current_datetime, -- 只保留日期
  188. COALESCE(SUM(CASE WHEN ugr.type=0 THEN ugr.permanent_gold+ugr.free_june+ugr.free_december+ugr.task_gold END),0) AS recharge,
  189. COALESCE(SUM(CASE WHEN ugr.type=0 THEN ugr.permanent_gold END),0) AS money,
  190. COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.permanent_gold END),0) AS consume_permanent,
  191. COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.free_june END),0) AS consume_free_june,
  192. COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.free_december END),0) AS consume_free_december,
  193. COALESCE(SUM(CASE WHEN ugr.type=1 THEN -ugr.task_gold END),0) AS consume_task,
  194. COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.permanent_gold END),0) AS refund_permanent,
  195. COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.free_june END),0) AS refund_free_june,
  196. COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.free_december END),0) AS refund_free_december,
  197. COALESCE(SUM(CASE WHEN ugr.type=2 THEN ugr.task_gold END),0) AS refund_task,
  198. COUNT(DISTINCT CASE WHEN ugr.type=0 THEN ugr.jwcode END) AS recharge_num,
  199. COUNT(DISTINCT CASE WHEN ugr.type=0
  200. AND u.first_recharge BETWEEN d.date_start AND d.date_end THEN ugr.jwcode END) AS first_recharge
  201. FROM
  202. -- 生成 7 天日期序列
  203. (
  204. SELECT DATE_SUB(CURDATE(), INTERVAL seq DAY) AS create_date,
  205. DATE_SUB(CURDATE(), INTERVAL seq DAY) AS date_start,
  206. TIMESTAMP(DATE_SUB(CURDATE(), INTERVAL seq DAY), '23:59:59') AS date_end
  207. FROM (
  208. SELECT 0 AS seq UNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL
  209. SELECT 3 UNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6
  210. ) AS days
  211. ) d
  212. JOIN user_gold_record ugr
  213. ON ugr.create_time between d.date_start AND d.date_end
  214. JOIN user u ON ugr.jwcode = u.jwcode
  215. left join market m on u.market=m.id
  216. WHERE ugr.audit_status IN (1,3)
  217. AND ugr.flag = 1
  218. AND m.name IS NOT NULL
  219. AND u.flag = 1
  220. GROUP BY m.name, d.create_date
  221. </select>
  222. </mapper>