fee_daily_stats.sql 4.9 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123
  1. -- Transfer模块手续费每日统计表
  2. -- 用于记录每日手续费统计数据,按当天时间范围统计
  3. -- =====================================================
  4. -- 手续费每日统计表
  5. -- =====================================================
  6. CREATE TABLE `kku_transfer_fee_daily_stats` (
  7. `id` bigint unsigned NOT NULL AUTO_INCREMENT COMMENT '主键ID',
  8. `stat_date` date NOT NULL COMMENT '统计日期',
  9. `transfer_app_id` int unsigned NOT NULL COMMENT '划转应用ID',
  10. -- 转入统计
  11. `in_order_count` int unsigned NOT NULL DEFAULT 0 COMMENT '转入订单数量',
  12. `in_total_amount` decimal(30,10) NOT NULL DEFAULT 0.0000000000 COMMENT '转入总金额',
  13. `in_fee_amount` decimal(30,10) NOT NULL DEFAULT 0.0000000000 COMMENT '转入手续费总额',
  14. `in_avg_fee_rate` decimal(8,5) NOT NULL DEFAULT 0.00000 COMMENT '转入平均手续费率',
  15. -- 转出统计
  16. `out_order_count` int unsigned NOT NULL DEFAULT 0 COMMENT '转出订单数量',
  17. `out_total_amount` decimal(30,10) NOT NULL DEFAULT 0.0000000000 COMMENT '转出总金额',
  18. `out_fee_amount` decimal(30,10) NOT NULL DEFAULT 0.0000000000 COMMENT '转出手续费总额',
  19. `out_avg_fee_rate` decimal(8,5) NOT NULL DEFAULT 0.00000 COMMENT '转出平均手续费率',
  20. -- 汇总统计
  21. `total_order_count` int unsigned NOT NULL DEFAULT 0 COMMENT '总订单数量',
  22. `total_amount` decimal(30,10) NOT NULL DEFAULT 0.0000000000 COMMENT '总交易金额',
  23. `total_fee_amount` decimal(30,10) NOT NULL DEFAULT 0.0000000000 COMMENT '总手续费金额',
  24. `avg_fee_rate` decimal(8,5) NOT NULL DEFAULT 0.00000 COMMENT '平均手续费率',
  25. -- 时间戳
  26. `created_at` timestamp NULL DEFAULT NULL COMMENT '创建时间',
  27. `updated_at` timestamp NULL DEFAULT NULL COMMENT '更新时间',
  28. PRIMARY KEY (`id`),
  29. UNIQUE KEY `uk_stat_date_app` (`stat_date`, `transfer_app_id`),
  30. KEY `idx_stat_date` (`stat_date`),
  31. KEY `idx_transfer_app_id` (`transfer_app_id`),
  32. KEY `idx_created_at` (`created_at`),
  33. CONSTRAINT `fk_fee_daily_stats_app` FOREIGN KEY (`transfer_app_id`) REFERENCES `kku_transfer_apps` (`id`)
  34. ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='手续费每日统计表';
  35. -- =====================================================
  36. -- 索引优化
  37. -- =====================================================
  38. -- 手续费金额统计索引
  39. CREATE INDEX `idx_total_fee_amount` ON `kku_transfer_fee_daily_stats` (`total_fee_amount`, `stat_date`);
  40. -- 应用统计查询索引
  41. CREATE INDEX `idx_app_date_range` ON `kku_transfer_fee_daily_stats` (`transfer_app_id`, `stat_date`, `total_fee_amount`);
  42. -- =====================================================
  43. -- 统计视图
  44. -- =====================================================
  45. -- 手续费月度统计视图
  46. CREATE VIEW `v_transfer_fee_monthly_stats` AS
  47. SELECT
  48. YEAR(stat_date) as year,
  49. MONTH(stat_date) as month,
  50. transfer_app_id,
  51. ta.keyname as app_keyname,
  52. ta.title as app_title,
  53. SUM(total_order_count) as monthly_order_count,
  54. SUM(total_amount) as monthly_total_amount,
  55. SUM(total_fee_amount) as monthly_fee_amount,
  56. AVG(avg_fee_rate) as monthly_avg_fee_rate,
  57. SUM(in_order_count) as monthly_in_orders,
  58. SUM(in_fee_amount) as monthly_in_fee,
  59. SUM(out_order_count) as monthly_out_orders,
  60. SUM(out_fee_amount) as monthly_out_fee,
  61. COUNT(*) as stat_days
  62. FROM `kku_transfer_fee_daily_stats` tfs
  63. LEFT JOIN `kku_transfer_apps` ta ON tfs.transfer_app_id = ta.id
  64. GROUP BY YEAR(stat_date), MONTH(stat_date), transfer_app_id
  65. ORDER BY year DESC, month DESC, monthly_fee_amount DESC;
  66. -- 手续费应用汇总视图
  67. CREATE VIEW `v_transfer_fee_app_summary` AS
  68. SELECT
  69. transfer_app_id,
  70. ta.keyname as app_keyname,
  71. ta.title as app_title,
  72. COUNT(*) as stat_days,
  73. SUM(total_order_count) as total_orders,
  74. SUM(total_amount) as total_amount,
  75. SUM(total_fee_amount) as total_fee,
  76. AVG(avg_fee_rate) as avg_fee_rate,
  77. SUM(in_order_count) as total_in_orders,
  78. SUM(in_fee_amount) as total_in_fee,
  79. SUM(out_order_count) as total_out_orders,
  80. SUM(out_fee_amount) as total_out_fee,
  81. MIN(stat_date) as first_stat_date,
  82. MAX(stat_date) as last_stat_date
  83. FROM `kku_transfer_fee_daily_stats` tfs
  84. LEFT JOIN `kku_transfer_apps` ta ON tfs.transfer_app_id = ta.id
  85. GROUP BY transfer_app_id
  86. ORDER BY total_fee DESC;
  87. -- =====================================================
  88. -- 示例查询
  89. -- =====================================================
  90. -- 查询最近7天的手续费统计
  91. -- SELECT * FROM `kku_transfer_fee_daily_stats`
  92. -- WHERE stat_date >= DATE_SUB(CURDATE(), INTERVAL 7 DAY)
  93. -- ORDER BY stat_date DESC;
  94. -- 查询指定应用的手续费统计
  95. -- SELECT * FROM `kku_transfer_fee_daily_stats`
  96. -- WHERE transfer_app_id = 1
  97. -- ORDER BY stat_date DESC;
  98. -- 查询手续费收入最高的日期
  99. -- SELECT stat_date, SUM(total_fee_amount) as daily_fee
  100. -- FROM `kku_transfer_fee_daily_stats`
  101. -- GROUP BY stat_date
  102. -- ORDER BY daily_fee DESC
  103. -- LIMIT 10;