fee_feature.sql 8.0 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235
  1. -- Transfer模块手续费功能数据库修改SQL
  2. -- 添加手续费相关字段和功能
  3. -- =====================================================
  4. -- 1. 应用表添加手续费配置字段
  5. -- =====================================================
  6. -- 添加手续费相关字段到 transfer_apps 表
  7. ALTER TABLE kku_transfer_apps
  8. ADD COLUMN fee_in_rate DECIMAL(5,4) DEFAULT 0.0000 COMMENT '转入手续费率(0.0000-1.0000)',
  9. ADD COLUMN fee_out_rate DECIMAL(5,4) DEFAULT 0.0000 COMMENT '转出手续费率(0.0000-1.0000)',
  10. ADD COLUMN fee_in_min DECIMAL(15,4) DEFAULT 0.0000 COMMENT '转入最低手续费',
  11. ADD COLUMN fee_in_max DECIMAL(15,4) DEFAULT 0.0000 COMMENT '转入最高手续费(0为不限制)',
  12. ADD COLUMN fee_out_min DECIMAL(15,4) DEFAULT 0.0000 COMMENT '转出最低手续费',
  13. ADD COLUMN fee_out_max DECIMAL(15,4) DEFAULT 0.0000 COMMENT '转出最高手续费(0为不限制)',
  14. ADD COLUMN fee_account_uid INT DEFAULT 0 COMMENT '手续费收取账户UID';
  15. -- =====================================================
  16. -- 2. 订单表添加手续费记录字段
  17. -- =====================================================
  18. -- 添加手续费相关字段到 transfer_orders 表
  19. ALTER TABLE kku_transfer_orders
  20. ADD COLUMN fee_rate DECIMAL(5,4) DEFAULT 0.0000 COMMENT '使用的手续费率',
  21. ADD COLUMN fee_amount DECIMAL(15,4) DEFAULT 0.0000 COMMENT '手续费金额',
  22. ADD COLUMN actual_amount DECIMAL(15,4) DEFAULT 0.0000 COMMENT '实际到账金额(扣除手续费后)';
  23. -- =====================================================
  24. -- 3. 手续费相关索引
  25. -- =====================================================
  26. -- 手续费账户查询索引
  27. CREATE INDEX idx_transfer_apps_fee_account ON kku_transfer_apps(fee_account_uid);
  28. -- 手续费金额统计索引
  29. CREATE INDEX idx_transfer_orders_fee_amount ON kku_transfer_orders(fee_amount, created_at);
  30. -- 应用手续费统计索引
  31. CREATE INDEX idx_transfer_orders_app_fee ON kku_transfer_orders(transfer_app_id, fee_amount, created_at);
  32. -- =====================================================
  33. -- 4. 手续费统计视图
  34. -- =====================================================
  35. -- 创建手续费统计视图
  36. CREATE VIEW v_transfer_fee_stats AS
  37. SELECT
  38. ta.id as app_id,
  39. ta.keyname as app_keyname,
  40. ta.title as app_title,
  41. COUNT(to1.id) as total_orders,
  42. SUM(to1.fee_amount) as total_fee_amount,
  43. AVG(to1.fee_rate) as avg_fee_rate,
  44. SUM(CASE WHEN to1.type = 1 THEN to1.fee_amount ELSE 0 END) as in_fee_amount,
  45. SUM(CASE WHEN to1.type = 2 THEN to1.fee_amount ELSE 0 END) as out_fee_amount,
  46. COUNT(CASE WHEN to1.type = 1 THEN 1 END) as in_orders,
  47. COUNT(CASE WHEN to1.type = 2 THEN 1 END) as out_orders,
  48. DATE(to1.created_at) as stat_date
  49. FROM kku_transfer_apps ta
  50. LEFT JOIN kku_transfer_orders to1 ON ta.id = to1.transfer_app_id
  51. WHERE to1.status = 100 -- 只统计已完成的订单
  52. GROUP BY ta.id, DATE(to1.created_at)
  53. ORDER BY stat_date DESC, total_fee_amount DESC;
  54. -- =====================================================
  55. -- 5. 手续费计算函数
  56. -- =====================================================
  57. -- 创建手续费计算函数
  58. DELIMITER //
  59. CREATE FUNCTION calculate_transfer_fee(
  60. amount DECIMAL(15,4),
  61. fee_rate DECIMAL(5,4),
  62. min_fee DECIMAL(15,4),
  63. max_fee DECIMAL(15,4)
  64. ) RETURNS DECIMAL(15,4)
  65. READS SQL DATA
  66. DETERMINISTIC
  67. COMMENT '计算转账手续费'
  68. BEGIN
  69. DECLARE calculated_fee DECIMAL(15,4);
  70. -- 按比例计算手续费
  71. SET calculated_fee = amount * fee_rate;
  72. -- 应用最低手续费限制
  73. IF calculated_fee < min_fee THEN
  74. SET calculated_fee = min_fee;
  75. END IF;
  76. -- 应用最高手续费限制(如果设置了)
  77. IF max_fee > 0 AND calculated_fee > max_fee THEN
  78. SET calculated_fee = max_fee;
  79. END IF;
  80. RETURN calculated_fee;
  81. END //
  82. DELIMITER ;
  83. -- =====================================================
  84. -- 6. 手续费统计存储过程
  85. -- =====================================================
  86. -- 创建手续费统计存储过程
  87. DELIMITER //
  88. CREATE PROCEDURE get_fee_statistics(
  89. IN app_id INT,
  90. IN start_date DATE,
  91. IN end_date DATE
  92. )
  93. READS SQL DATA
  94. COMMENT '获取指定应用和时间范围的手续费统计'
  95. BEGIN
  96. SELECT
  97. ta.keyname as app_name,
  98. ta.title as app_title,
  99. COUNT(to1.id) as total_orders,
  100. SUM(to1.amount) as total_amount,
  101. SUM(to1.fee_amount) as total_fee,
  102. AVG(to1.fee_rate) as avg_fee_rate,
  103. SUM(to1.actual_amount) as total_actual_amount,
  104. -- 转入统计
  105. COUNT(CASE WHEN to1.type = 1 THEN 1 END) as in_orders,
  106. SUM(CASE WHEN to1.type = 1 THEN to1.amount ELSE 0 END) as in_amount,
  107. SUM(CASE WHEN to1.type = 1 THEN to1.fee_amount ELSE 0 END) as in_fee,
  108. -- 转出统计
  109. COUNT(CASE WHEN to1.type = 2 THEN 1 END) as out_orders,
  110. SUM(CASE WHEN to1.type = 2 THEN to1.amount ELSE 0 END) as out_amount,
  111. SUM(CASE WHEN to1.type = 2 THEN to1.fee_amount ELSE 0 END) as out_fee,
  112. -- 时间范围
  113. start_date,
  114. end_date
  115. FROM kku_transfer_apps ta
  116. LEFT JOIN kku_transfer_orders to1 ON ta.id = to1.transfer_app_id
  117. WHERE (app_id = 0 OR ta.id = app_id)
  118. AND to1.status = 100
  119. AND DATE(to1.created_at) BETWEEN start_date AND end_date
  120. GROUP BY ta.id
  121. ORDER BY total_fee DESC;
  122. END //
  123. DELIMITER ;
  124. -- =====================================================
  125. -- 7. 示例数据和测试
  126. -- =====================================================
  127. -- 更新现有应用的手续费配置示例
  128. UPDATE kku_transfer_apps
  129. SET
  130. fee_in_rate = 0.0050, -- 转入手续费 0.5%
  131. fee_out_rate = 0.0100, -- 转出手续费 1.0%
  132. fee_in_min = 0.1000, -- 转入最低手续费 0.1
  133. fee_in_max = 10.0000, -- 转入最高手续费 10
  134. fee_out_min = 0.2000, -- 转出最低手续费 0.2
  135. fee_out_max = 20.0000, -- 转出最高手续费 20
  136. fee_account_uid = 1 -- 手续费收取账户
  137. WHERE keyname = 'test_app';
  138. -- 测试手续费计算函数
  139. SELECT
  140. 100.0000 as amount,
  141. calculate_transfer_fee(100.0000, 0.0050, 0.1000, 10.0000) as calculated_fee,
  142. '应该返回 0.5000' as expected;
  143. SELECT
  144. 10.0000 as amount,
  145. calculate_transfer_fee(10.0000, 0.0050, 0.1000, 10.0000) as calculated_fee,
  146. '应该返回 0.1000 (最低手续费)' as expected;
  147. SELECT
  148. 5000.0000 as amount,
  149. calculate_transfer_fee(5000.0000, 0.0050, 0.1000, 10.0000) as calculated_fee,
  150. '应该返回 10.0000 (最高手续费)' as expected;
  151. -- =====================================================
  152. -- 8. 数据迁移和兼容性
  153. -- =====================================================
  154. -- 为现有订单设置默认的手续费字段值
  155. UPDATE kku_transfer_orders
  156. SET
  157. fee_rate = 0.0000,
  158. fee_amount = 0.0000,
  159. actual_amount = amount
  160. WHERE fee_rate IS NULL OR actual_amount IS NULL;
  161. -- =====================================================
  162. -- 9. 权限和安全
  163. -- =====================================================
  164. -- 创建手续费管理角色(可选)
  165. -- CREATE ROLE 'transfer_fee_manager';
  166. -- GRANT SELECT, UPDATE ON kku_transfer_apps TO 'transfer_fee_manager';
  167. -- GRANT SELECT ON kku_transfer_orders TO 'transfer_fee_manager';
  168. -- GRANT EXECUTE ON PROCEDURE get_fee_statistics TO 'transfer_fee_manager';
  169. -- =====================================================
  170. -- 10. 监控和报警
  171. -- =====================================================
  172. -- 手续费异常监控查询
  173. -- 查找手续费异常高的订单
  174. SELECT
  175. id,
  176. transfer_app_id,
  177. amount,
  178. fee_rate,
  179. fee_amount,
  180. actual_amount,
  181. created_at
  182. FROM kku_transfer_orders
  183. WHERE fee_rate > 0.1000 -- 手续费率超过10%
  184. OR fee_amount > amount * 0.1 -- 手续费超过金额的10%
  185. ORDER BY created_at DESC
  186. LIMIT 100;
  187. -- 手续费收入日报
  188. SELECT
  189. DATE(created_at) as date,
  190. COUNT(*) as orders,
  191. SUM(fee_amount) as total_fee,
  192. AVG(fee_rate) as avg_rate
  193. FROM kku_transfer_orders
  194. WHERE status = 100
  195. AND fee_amount > 0
  196. AND created_at >= DATE_SUB(CURDATE(), INTERVAL 30 DAY)
  197. GROUP BY DATE(created_at)
  198. ORDER BY date DESC;