11店铺订单.sql 4.3 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899
  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表的project_id关联shop_services表并判断是否存在project_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. DROP VIEW IF EXISTS manage_shop_order;
  15. CREATE OR REPLACE VIEW manage_shop_order AS
  16. WITH
  17. order_arrival AS (
  18. /* 获取订单到店记录 */
  19. SELECT
  20. order_id,
  21. created_at AS arrival_time,
  22. state
  23. FROM order_records /* 关联到店记录 */
  24. WHERE
  25. state = 10 /* 已到店状态 */
  26. ),
  27. latest_order_status AS (
  28. /* 获取订单最新状态 */
  29. SELECT order_id, state AS latest_state
  30. FROM order_records /* 关联订单状态 */
  31. WHERE (order_id, created_at) IN (
  32. SELECT order_id, MAX(created_at)
  33. FROM order_records /* 关联订单状态 */
  34. GROUP BY
  35. order_id /* 按订单ID分组 */
  36. )
  37. ),
  38. split_amounts AS (
  39. /* 获取各类分账金额 */
  40. SELECT
  41. order_id,
  42. MAX(
  43. CASE
  44. WHEN split_type = 'SHOP' THEN split_amount
  45. ELSE 0
  46. END
  47. ) AS shop_amount /* 店铺分成 */,
  48. MAX(
  49. CASE
  50. WHEN split_type = 'PROMOTION' THEN split_amount
  51. ELSE 0
  52. END
  53. ) AS promotion_amount /* 推广分成 */,
  54. MAX(
  55. CASE
  56. WHEN split_type = 'PLATFORM' THEN split_amount
  57. ELSE 0
  58. END
  59. ) AS platform_amount /* 平台抽成 */
  60. FROM wallet_split_records /* 关联分账记录 */
  61. GROUP BY
  62. order_id /* 按订单ID分组 */
  63. )
  64. SELECT
  65. o.id AS order_id /* 序号 */,
  66. o.order_no AS order_no /* 订单编号 */,
  67. o.source AS source /* 订单来源 */,
  68. CASE
  69. WHEN o.source = 1 THEN mu.nickname
  70. WHEN o.source = 2 THEN sar.shop_name
  71. ELSE NULL
  72. END AS source_name /* 用户昵称/店铺名称 */,
  73. o.type AS type /* 订单类型 */,
  74. ss.name AS service_name /* 项目名称 */,
  75. o.total_amount AS total_amount /* 订单金额 */,
  76. oa.arrival_time AS arrival_time /* 到店时间 */,
  77. los.latest_state AS latest_state /* 订单状态 */,
  78. COALESCE(sar.contact_phone, '') AS shop_phone /* 店铺联系电话 */,
  79. COALESCE(mu.mobile, '') AS coach_phone /* 技师联系方式 */,
  80. o.area_code AS area_code /* 区域 */,
  81. o.address AS address /* 位置 */,
  82. o.distance AS distance /* 距离 */,
  83. COALESCE(sa.shop_amount, 0) AS shop_amount /* 店铺分成 */,
  84. COALESCE(sa.promotion_amount, 0) AS promotion_amount /* 推广分成 */,
  85. COALESCE(sa.platform_amount, 0) AS platform_amount /* 平台抽成 */
  86. FROM
  87. `order` o
  88. LEFT JOIN member_users mu ON o.user_id = mu.id /* 关联用户信息 */
  89. LEFT JOIN shop_auth_records sar ON o.shop_id = sar.shop_id /* 关联店铺信息 */
  90. LEFT JOIN shop_services ss ON o.project_id = ss.id /* 关联服务项目 */
  91. LEFT JOIN order_arrival oa ON o.id = oa.order_id /* 关联到店记录 */
  92. LEFT JOIN latest_order_status los ON o.id = los.order_id /* 关联最新状态 */
  93. LEFT JOIN split_amounts sa ON o.id = sa.order_id /* 关联分账信息 */
  94. ORDER BY o.id DESC /* 按订单ID倒序排列 */;
  95. SELECT * FROM manage_shop_order;