幸运24-统计-平台统计-手写sql合并计算

This commit is contained in:
2025-09-10 18:12:46 +08:00
parent 54f2fe4f7d
commit a15559c89a
5 changed files with 154 additions and 16 deletions

View File

@@ -69,18 +69,6 @@ public class ShardingSphereConfig {
return ruleConfig;
}
/*private ReadwriteSplittingRuleConfiguration getReadWriteRuleConfig() {
//同一事务下强制使用主库
ReadwriteSplittingDataSourceGroupRuleConfiguration dataSourceGroupConfig = new ReadwriteSplittingDataSourceGroupRuleConfiguration(
"ds", "ds", Arrays.asList("ds", "ds_slave"), TransactionalReadQueryStrategy.PRIMARY, "weight_lb");
Properties algorithmProps = new Properties();
algorithmProps.setProperty("ds_slave", "4");
algorithmProps.setProperty("ds", "1");
Map<String, AlgorithmConfiguration> algorithmConfigMap = new HashMap<>(1);
algorithmConfigMap.put("weight_lb", new AlgorithmConfiguration("WEIGHT", algorithmProps));
return new ReadwriteSplittingRuleConfiguration(Collections.singleton(dataSourceGroupConfig), algorithmConfigMap);
}*/
private ReadwriteSplittingRuleConfiguration getReadWriteRuleConfig() {
//同一事务下强制使用主库
ReadwriteSplittingDataSourceGroupRuleConfiguration dataSourceGroupConfig = new ReadwriteSplittingDataSourceGroupRuleConfiguration(

View File

@@ -15,10 +15,20 @@ public interface Lucky24RecordMapper extends BaseMapper<Lucky24Record> {
@Param("poolTypeList")List<Integer> poolTypeList,
@Param("startTime") Date startTime, @Param("endTime") Date endTime);
List<Lucky24PlatformStat> listPlatformManual(@Param("zoneDate")String zoneDate, @Param("partitionId") Integer partitionId,
@Param("poolTypeList")List<Integer> poolTypeList,
@Param("startTime") Date startTime, @Param("endTime") Date endTime,
@Param("zoneDateTableName") String zoneDateTableName, @Param("systemDateTableName") String systemDateTableName);
List<Lucky24PlatformStat> listPlatformByPoolType(@Param("zoneDate")String zonedDate, @Param("partitionId") Integer partitionId,
@Param("poolTypeList")List<Integer> poolTypeList,
@Param("startTime") Date startTime, @Param("endTime") Date endTime);
List<Lucky24PlatformStat> listPlatformByPoolTypeManual(@Param("zoneDate")String zonedDate, @Param("partitionId") Integer partitionId,
@Param("poolTypeList")List<Integer> poolTypeList,
@Param("startTime") Date startTime, @Param("endTime") Date endTime,
@Param("zoneDateTableName") String zoneDateTableName, @Param("systemDateTableName") String systemDateTableName);
List<Lucky24PersonalStat> listPersonal(@Param("zoneDate")String zoneDate, @Param("partitionId") Integer partitionId,
@Param("poolTypeList")List<Integer> poolTypeList,
@Param("startTime") Date startTime, @Param("endTime") Date endTime,

View File

@@ -28,6 +28,68 @@
group by r.uid) r
</select>
<select id="listPlatformManual" resultType="com.accompany.sharding.vo.Lucky24PlatformStat">
/* SHARDINGSPHERE_HINT: DATA_SOURCE_NAME=ds_slave, SKIP_SQL_REWRITE=true */
select #{zoneDate} as `date`,
#{partitionId} as partition_id,
0 as pool_type,
ifnull(sum(`totalInput`),0) `totalInput`,
ifnull(sum(`totalOutput`),0) `totalOutput`,
ifnull(sum(`totalOutput`) / sum(`totalInput`),0) `productionRatio`,
count(distinct r.uid) `count`,
count(distinct (IF(`maxOutput` > 0, r.uid, null))) `winCount`,
ifnull(sum(`num`),0) `num`,
ifnull(sum(`winNum`),0) `winNum`,
ifnull(sum(`winNum`) / sum(`num`),0) `winRate`
from (
<choose>
<when test="systemDateTableName != null and systemDateTableName != ''">
select
r.uid,
sum(gift_num * gift_gold_price) `totalInput`,
sum(win_gold_num) `totalOutput`,
count(*) `num`,
count((case when win_gold_num > 0 then 1 end)) `winNum`,
max(win_gold_num) `maxOutput`
from `lucky_24_record_${zoneDateTableName}` r force index (lucky_24_record_partition_id_pool_type_create_time_uid_index)
where r.partition_id = #{partitionId}
and r.pool_type in <foreach collection="poolTypeList" item="poolType" separator="," open="(" close=")">#{poolType}</foreach>
and r.create_time >= #{startTime}
group by r.uid
union all
select
r.uid,
sum(gift_num * gift_gold_price) `totalInput`,
sum(win_gold_num) `totalOutput`,
count(*) `num`,
count((case when win_gold_num > 0 then 1 end)) `winNum`,
max(win_gold_num) `maxOutput`
from `lucky_24_record_${systemDateTableName}` r force index (lucky_24_record_partition_id_pool_type_create_time_uid_index)
where r.partition_id = #{partitionId}
and r.pool_type in <foreach collection="poolTypeList" item="poolType" separator="," open="(" close=")">#{poolType}</foreach>
and r.create_time &lt;= #{endTime}
group by r.uid
</when>
<otherwise>
select
r.uid,
sum(gift_num * gift_gold_price) `totalInput`,
sum(win_gold_num) `totalOutput`,
count(*) `num`,
count((case when win_gold_num > 0 then 1 end)) `winNum`,
max(win_gold_num) `maxOutput`
from `lucky_24_record_${zoneDateTableName}` r force index (lucky_24_record_partition_id_pool_type_create_time_uid_index)
where r.partition_id = #{partitionId}
and r.pool_type in <foreach collection="poolTypeList" item="poolType" separator="," open="(" close=")">#{poolType}</foreach>
and r.create_time between #{startTime} and #{endTime}
group by r.uid
</otherwise>
</choose>
) r
</select>
<select id="listPlatformByPoolType" resultType="com.accompany.sharding.vo.Lucky24PlatformStat">
select #{zoneDate} as `date`,
#{partitionId} as partition_id,
@@ -57,6 +119,72 @@
group by r.pool_type
</select>
<select id="listPlatformByPoolTypeManual" resultType="com.accompany.sharding.vo.Lucky24PlatformStat">
/* SHARDINGSPHERE_HINT: DATA_SOURCE_NAME=ds_slave, SKIP_SQL_REWRITE=true */
select #{zoneDate} as `date`,
#{partitionId} as partition_id,
pool_type,
ifnull(sum(`totalInput`),0) `totalInput`,
ifnull(sum(`totalOutput`),0) `totalOutput`,
ifnull(sum(`totalOutput`) / sum(`totalInput`),0) `productionRatio`,
count(distinct r.uid) `count`,
count(distinct (IF(`maxOutput` > 0, r.uid, null))) `winCount`,
ifnull(sum(`num`),0) `num`,
ifnull(sum(`winNum`),0) `winNum`,
ifnull(sum(`winNum`) / sum(`num`),0) `winRate`
from (
<choose>
<when test="systemDateTableName != null and systemDateTableName != ''">
select
r.pool_type,
r.uid,
sum(gift_num * gift_gold_price) `totalInput`,
sum(win_gold_num) `totalOutput`,
count(*) `num`,
count((case when win_gold_num > 0 then 1 end)) `winNum`,
max(win_gold_num) `maxOutput`
from `lucky_24_record_${zoneDateTableName}` r force index (lucky_24_record_partition_id_pool_type_create_time_uid_index)
where r.partition_id = #{partitionId}
and r.pool_type in <foreach collection="poolTypeList" item="poolType" separator="," open="(" close=")">#{poolType}</foreach>
and r.create_time >= #{startTime}
group by r.pool_type, r.uid
union all
select
r.pool_type,
r.uid,
sum(gift_num * gift_gold_price) `totalInput`,
sum(win_gold_num) `totalOutput`,
count(*) `num`,
count((case when win_gold_num > 0 then 1 end)) `winNum`,
max(win_gold_num) `maxOutput`
from `lucky_24_record_${systemDateTableName}` r force index (lucky_24_record_partition_id_pool_type_create_time_uid_index)
where r.partition_id = #{partitionId}
and r.pool_type in <foreach collection="poolTypeList" item="poolType" separator="," open="(" close=")">#{poolType}</foreach>
and r.create_time &lt;= #{endTime}
group by r.pool_type, r.uid
</when>
<otherwise>
select
r.pool_type,
r.uid,
sum(gift_num * gift_gold_price) `totalInput`,
sum(win_gold_num) `totalOutput`,
count(*) `num`,
count((case when win_gold_num > 0 then 1 end)) `winNum`,
max(win_gold_num) `maxOutput`
from `lucky_24_record_${zoneDateTableName}` r force index (lucky_24_record_partition_id_pool_type_create_time_uid_index)
where r.partition_id = #{partitionId}
and r.pool_type in <foreach collection="poolTypeList" item="poolType" separator="," open="(" close=")">#{poolType}</foreach>
and r.create_time between #{startTime} and #{endTime}
group by r.pool_type, r.uid
</otherwise>
</choose>
) r
group by r.pool_type
</select>
<select id="listPersonal" resultType="com.accompany.sharding.vo.Lucky24PersonalStat">
select #{zoneDate} as `date`,
#{partitionId} as partition_id,