11店铺订单.sql 3.3 KB

1234567891011121314151617181920212223242526272829303132333435363738394041424344454647484950515253545556575859606162636465666768697071
  1. -- Active: xiaoding_test@@192.168.110.85@3306@xiaoding_test
  2. /*
  3. 用户类型是order表中的order_source字段,用户昵称/店铺是通过order的order_source字段判断是用户通过平台下单是店铺在平台下应急订单,
  4. 用户昵称是order表通过user_id关联member_users表获取nickname字段为用户名称,
  5. 店铺名称是order表通过shop_id关联shop_auth_records并判断shop_id是否存在存在则获取shop_name字段为店铺名称不存在则空着即可,
  6. 订单类型是order表中的order_type字段,项目名称是order表的service_id关联shop_services表并判断是否存在service_id存在则获取name为项目名称不存在则空着即可,
  7. 订单金额是order表total_amount字段,到店时间是order表id关联order_records表并判断状态state为已到店状态时的created_at字段为到店时间,
  8. 订单状态是order表id关联order_records表最新的状态state,
  9. 店铺分成、推广分成、平台抽成都是order表id关联wallet_split_records通过该表中的split_type不同的分账类型去参与分成最后split_amount字段就是店铺分成、推广分成、平台抽成最终字段
  10. */
  11. /*
  12. 基础订单信息与分账记录统计查询
  13. */
  14. WITH order_arrival AS (
  15. /* 获取订单到店记录 */
  16. SELECT
  17. order_id,
  18. created_at AS arrival_time,
  19. state
  20. FROM order_records
  21. WHERE state = 'ARRIVED' /* 已到店状态 */
  22. ),
  23. latest_order_status AS (
  24. /* 获取订单最新状态 */
  25. SELECT
  26. order_id,
  27. state AS latest_state
  28. FROM order_records
  29. WHERE (order_id, created_at) IN (
  30. SELECT
  31. order_id,
  32. MAX(created_at)
  33. FROM order_records
  34. GROUP BY order_id
  35. )
  36. ),
  37. split_amounts AS (
  38. /* 获取各类分账金额 */
  39. SELECT
  40. order_id,
  41. MAX(CASE WHEN split_type = 'SHOP' THEN split_amount ELSE 0 END) AS shop_amount /* 店铺分成 */,
  42. MAX(CASE WHEN split_type = 'PROMOTION' THEN split_amount ELSE 0 END) AS promotion_amount /* 推广分成 */,
  43. MAX(CASE WHEN split_type = 'PLATFORM' THEN split_amount ELSE 0 END) AS platform_amount /* 平台抽成 */
  44. FROM wallet_split_records
  45. GROUP BY order_id
  46. )
  47. SELECT
  48. o.order_source /* 用户类型 */,
  49. CASE
  50. WHEN o.order_source = 'USER' THEN mu.nickname
  51. WHEN o.order_source = 'SHOP' THEN sar.shop_name
  52. ELSE NULL
  53. END AS source_name /* 用户昵称/店铺名称 */,
  54. o.order_type /* 订单类型 */,
  55. ss.name AS service_name /* 项目名称 */,
  56. o.total_amount /* 订单金额 */,
  57. oa.arrival_time /* 到店时间 */,
  58. los.latest_state /* 订单状态 */,
  59. COALESCE(sa.shop_amount, 0) AS shop_amount /* 店铺分成 */,
  60. COALESCE(sa.promotion_amount, 0) AS promotion_amount /* 推广分成 */,
  61. COALESCE(sa.platform_amount, 0) AS platform_amount /* 平台抽成 */
  62. FROM `order` o
  63. LEFT JOIN member_users mu ON o.user_id = mu.id /* 关联用户信息 */
  64. LEFT JOIN shop_auth_records sar ON o.shop_id = sar.shop_id /* 关联店铺信息 */
  65. LEFT JOIN shop_services ss ON o.service_id = ss.id /* 关联服务项目 */
  66. LEFT JOIN order_arrival oa ON o.id = oa.order_id /* 关联到店记录 */
  67. LEFT JOIN latest_order_status los ON o.id = los.order_id /* 关联最新状态 */
  68. LEFT JOIN split_amounts sa ON o.id = sa.order_id /* 关联分账信息 */
  69. ORDER BY o.id DESC /* 按订单ID倒序排列 */;