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.
193 lines
8.7 KiB
193 lines
8.7 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.WorkBenchMapper">
|
|
<!--起止时间内的该地区充值金币数(永久+免费)若为空则默认0-->
|
|
<select id="sumRecharge" resultType="java.lang.Integer">
|
|
select sum(
|
|
|
|
COALESCE(recharge, 0)
|
|
)
|
|
from statistics
|
|
where market = #{market}
|
|
and current_datetime
|
|
between #{startDate} and #{endDate}
|
|
</select>
|
|
<!--起止时间内的该地区充值金额(永久金币数)-->
|
|
<select id="sumMoney" resultType="java.lang.Integer">
|
|
SELECT SUM(money)
|
|
FROM statistics
|
|
WHERE market = #{market}
|
|
AND current_datetime BETWEEN #{startDate} and #{endDate}
|
|
</select>
|
|
<!-- 起止时间内该地区消费金币数(永久+免费+任务)-->
|
|
<select id="sumConsume" resultType="java.lang.Integer">
|
|
SELECT SUM(
|
|
COALESCE(consume_permanent, 0) +
|
|
COALESCE(consume_free_june, 0) +
|
|
COALESCE(consume_free_december, 0) +
|
|
COALESCE(consume_task, 0)
|
|
)
|
|
FROM statistics
|
|
WHERE market = #{market}
|
|
AND current_datetime BETWEEN
|
|
#{startDate} and #{endDate}
|
|
</select>
|
|
<!--起止时间内的该地区退款金币数(永久+免费+任务)-->
|
|
<select id="sumRefund" resultType="java.lang.Integer">
|
|
SELECT SUM(
|
|
COALESCE(refund_permanent, 0) +
|
|
COALESCE(refund_free_june, 0) +
|
|
COALESCE(refund_free_december, 0) +
|
|
COALESCE(refund_task, 0)
|
|
)
|
|
FROM statistics
|
|
WHERE market = #{market}
|
|
AND current_datetime BETWEEN
|
|
#{startDate} and #{endDate}
|
|
</select>
|
|
<!--起止时间内该地区充值人头数(根据精网号去重,老数据有多人共用一个精网号的问题)-->
|
|
<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.pay_time BETWEEN
|
|
#{startDate} and #{endDate}
|
|
AND ugr.audit_status IN (1,3)
|
|
and ugr.flag=1
|
|
AND u.flag = 1
|
|
|
|
</select>
|
|
<!--给定时间范围内的该地区消费永久金币数-->
|
|
<select id="sumCPermanent" resultType="java.lang.Integer">
|
|
SELECT SUM(
|
|
COALESCE(consume_permanent, 0)
|
|
)
|
|
FROM statistics
|
|
WHERE market = #{market}
|
|
AND current_datetime BETWEEN
|
|
#{startDate} and #{endDate}
|
|
</select>
|
|
<!--给定时间范围内的该地区消费免费金币数-->
|
|
<select id="sumCFree" resultType="java.lang.Integer">
|
|
SELECT SUM(
|
|
COALESCE(refund_free_june, 0) +
|
|
COALESCE(refund_free_december, 0)
|
|
)
|
|
FROM statistics
|
|
WHERE market = #{market}
|
|
AND current_datetime BETWEEN
|
|
#{startDate} and #{endDate}
|
|
</select>
|
|
<!--给定时间范围内的该地区消费任务金币数-->
|
|
<select id="sumCTask" resultType="java.lang.Integer">
|
|
SELECT SUM(
|
|
COALESCE(refund_task, 0)
|
|
)
|
|
FROM statistics
|
|
WHERE market = #{market}
|
|
AND current_datetime BETWEEN
|
|
#{startDate} and #{endDate}
|
|
</select>
|
|
<!-- 获取指定地区在时间段内的全部统计数据 -->
|
|
<select id="getFullStatisticsByMarketAndDate" resultType="com.example.demo.domain.vo.coin.WorkbenchFullStatistics">
|
|
SELECT
|
|
SUM(s.recharge) AS totalRecharge,
|
|
SUM(s.money) AS totalMoney,
|
|
SUM(s.consume_permanent) AS totalConsumePermanent,
|
|
SUM(s.consume_free_june + s.consume_free_december) AS totalConsumeFree,
|
|
SUM(s.consume_task) AS totalConsumeTask,
|
|
SUM(s.refund_permanent + s.refund_free_june + s.refund_free_december + s.refund_task) AS totalRefund,
|
|
(
|
|
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.pay_time BETWEEN #{startDate} AND #{endDate}
|
|
AND ugr.audit_status IN (1, 3)
|
|
and ugr.flag=1
|
|
AND u.flag = 1
|
|
) AS totalRechargeNum
|
|
FROM statistics s
|
|
WHERE s.market = #{market}
|
|
AND s.current_datetime BETWEEN #{startDate} AND #{endDate};
|
|
</select>
|
|
<select id="getFullStatisticsByMarketAndDate1"
|
|
resultType="com.example.demo.domain.vo.coin.WorkbenchFullStatistics">
|
|
SELECT
|
|
s.market,
|
|
SUM(s.recharge) AS totalRecharge,
|
|
SUM(s.money) AS totalMoney,
|
|
SUM(s.consume_permanent) AS totalConsumePermanent,
|
|
SUM(s.consume_free_june + s.consume_free_december) AS totalConsumeFree,
|
|
SUM(s.consume_task) AS totalConsumeTask
|
|
FROM statistics s
|
|
WHERE s.market IN
|
|
<foreach item="market" collection="markets" open="(" separator="," close=")">#{market}</foreach>
|
|
AND s.current_datetime BETWEEN #{startDate} AND #{endDate}
|
|
GROUP BY s.market;
|
|
</select>
|
|
<!--获取用户的地区权限列表-->
|
|
<select id="getAdminMarket" resultType="java.lang.String">
|
|
select market from admin
|
|
where account = #{account}
|
|
</select>
|
|
<!--获取全部用户角色-->
|
|
<select id="getMarket" resultType="java.lang.String">
|
|
select DISTINCT name from market where type=2
|
|
</select>
|
|
<!--40天内单个地区的图表数据 按天-->
|
|
<select id="getDayStatistics" resultType="com.example.demo.domain.vo.coin.WorkbenchMarketGraph">
|
|
select market,recharge as sumRechargePermanent,money as sumMoney,
|
|
(recharge - money) as sumRechargeFree,
|
|
consume_permanent as sumConsumePermanent,
|
|
(consume_free_june + consume_free_december) as sumConsumeFree,
|
|
consume_task as sumConsumeTask,
|
|
current_datetime as currentDate
|
|
from statistics where market=#{market}
|
|
and DATE(current_datetime) >= #{startDate}
|
|
AND DATE(current_datetime) < #{endDate}
|
|
order by current_datetime desc
|
|
|
|
</select>
|
|
<!--40天以上单个地区的图表数据 按月 首尾截断-->
|
|
<select id="getMonthStatistics" resultType="com.example.demo.domain.vo.coin.WorkbenchMarketGraph">
|
|
select DATE_FORMAT(current_datetime, '%Y-%m') as month,
|
|
market,
|
|
sum(recharge) as sumRechargePermanent,
|
|
sum(money) as sumMoney,
|
|
sum(recharge - money) as sumRechargeFree,
|
|
sum(consume_permanent) as sumConsumePermanent,
|
|
sum(consume_free_june + consume_free_december) as sumConsumeFree,
|
|
sum(consume_task) as sumConsumeTask,
|
|
current_datetime as currentMonth
|
|
from statistics
|
|
where market = #{market}
|
|
and current_datetime >= #{startDate}
|
|
and current_datetime < #{endDate}
|
|
group by month
|
|
order by month
|
|
</select>
|
|
<!--获取各地区-->
|
|
<select id="getRevenue" resultType="com.example.demo.domain.vo.coin.WorkbenchRevenue">
|
|
SELECT m.name AS market,
|
|
SUM(CASE WHEN r.id = 2 THEN cr.received_amount ELSE 0 END) AS hkd,
|
|
SUM(CASE WHEN r.id = 3 THEN cr.received_amount ELSE 0 END) AS sgd,
|
|
SUM(CASE WHEN r.id = 4 THEN cr.received_amount ELSE 0 END) AS myr,
|
|
SUM(CASE WHEN r.id = 5 THEN cr.received_amount ELSE 0 END) AS thb,
|
|
SUM(CASE WHEN r.id = 6 THEN cr.received_amount ELSE 0 END) AS cad,
|
|
SUM(CASE WHEN r.id = 7 THEN cr.received_amount ELSE 0 END) AS vdn,
|
|
SUM(CASE WHEN r.id = 8 THEN cr.received_amount ELSE 0 END) AS krw,
|
|
ROUND( SUM(cr.received_amount * r.num), 2) AS totalSGD
|
|
FROM cash_record cr
|
|
JOIN market m ON cr.received_market = m.id
|
|
JOIN rate r ON cr.received_currency = r.id
|
|
WHERE cr.received_currency IN (2,3,4,5,6,7,8) -- 只统计这7种币
|
|
AND m.name IN
|
|
<foreach item="market" collection="markets" open="(" separator="," close=")">#{market}</foreach>
|
|
AND cr.audit_time BETWEEN #{startDate} AND #{endDate}
|
|
AND cr.order_type=1
|
|
AND cr.status IN (1,3,4)
|
|
GROUP BY m.name;
|
|
</select>
|
|
</mapper>
|