02技师列表.sql 3.0 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108
  1. -- Active: xiaoding_test@@192.168.110.85@3306
  2. /*
  3. 这段sql语句是根据"market_dist_teams"表获取的,这个表的解释是:
  4. 1、当一个用户A邀请另一个用户B的时候,数据是这样的
  5. - object_id是A的id
  6. - object_type是A的用户类型
  7. - user_id是B的id
  8. - 统计的时候A是B的一级邀请人
  9. 2、当用户B邀请C的时候,数据是这样的
  10. - object_id是B的id
  11. - object_type是B的用户类型
  12. - user_id是C的id
  13. - 统计的时候B是C的一级邀请人
  14. - 统计的时候A是C的二级邀请人
  15. 请重写我的统计sql
  16. */
  17. -- 技师列表视图
  18. DROP VIEW IF EXISTS manage_coach_list;
  19. CREATE OR REPLACE VIEW manage_coach_list AS
  20. WITH
  21. /* 一级邀请人信息 */
  22. inviter_level1 AS (
  23. SELECT mdt1.user_id, m1.nickname
  24. FROM
  25. market_dist_teams mdt1
  26. LEFT JOIN member_users m1 ON mdt1.object_id = m1.id
  27. WHERE
  28. mdt1.level = 1
  29. ),
  30. /* 二级邀请人信息 */
  31. inviter_level2 AS (
  32. SELECT mdt1.user_id, m2.nickname
  33. FROM
  34. market_dist_teams mdt1
  35. LEFT JOIN market_dist_teams mdt2 ON mdt1.object_id = mdt2.user_id
  36. LEFT JOIN member_users m2 ON mdt2.object_id = m2.id
  37. WHERE
  38. mdt1.level = 1
  39. AND mdt2.level = 1
  40. ),
  41. /* 钱包余额信息 */
  42. coach_wallet AS (
  43. SELECT owner_id, total_balance
  44. FROM wallet
  45. WHERE
  46. owner_type = 'App\\Models\\CoachUser'
  47. )
  48. SELECT
  49. /* 性别 */
  50. mu.gender,
  51. /* 技师名称 */
  52. ci.nickname,
  53. /* 头像 */
  54. ci.avatar,
  55. /* 手机号码 */
  56. mu.mobile,
  57. /* 注册地址 */
  58. mu.register_area,
  59. /* 注册时间 */
  60. mu.created_at,
  61. /* 当前所属区域 */
  62. cl.city,
  63. /* 所属店铺 */
  64. sar.shop_name,
  65. /* 调度区域 */
  66. cl.location,
  67. /* 是否开通会员 */
  68. CASE
  69. WHEN cu.is_vip = 1 THEN '是'
  70. ELSE '否'
  71. END AS is_vip,
  72. /* 开通会员时间 */
  73. cu.vip_time,
  74. /* 一级邀请人 */
  75. il1.nickname AS inviter_level1_name,
  76. /* 二级邀请人 */
  77. il2.nickname AS inviter_level2_name,
  78. /* 余额 */
  79. COALESCE(cw.total_balance, 0) AS balance,
  80. /* 状态 */
  81. cu.state,
  82. /* 邀请码 */
  83. cu.invite_code,
  84. /* 二维码 */
  85. cu.qr_code,
  86. /* 认证状态 */
  87. CASE
  88. WHEN cq.state = 2 THEN '已认证'
  89. WHEN cq.state = 1 THEN '认证中'
  90. WHEN cq.state = 3 THEN '认证失败'
  91. ELSE '未认证'
  92. END AS auth_status
  93. FROM
  94. coach_users cu
  95. LEFT JOIN member_users mu ON cu.user_id = mu.id
  96. LEFT JOIN coach_info_records ci ON cu.info_record_id = ci.id
  97. LEFT JOIN coach_locations cl ON cu.id = cl.coach_id
  98. AND cl.type = 2
  99. LEFT JOIN shop_auth_records sar ON cu.shop_id = sar.id
  100. LEFT JOIN coach_qual_records cq ON cu.qualification_record_id = cq.id
  101. LEFT JOIN inviter_level1 il1 ON cu.user_id = il1.user_id
  102. LEFT JOIN inviter_level2 il2 ON cu.user_id = il2.user_id
  103. LEFT JOIN coach_wallet cw ON cu.user_id = cw.owner_id
  104. WHERE
  105. cu.deleted_at IS NULL;