Browse Source

feat:修改了技师列表文档

景好勇 4 months ago
parent
commit
6d06fce055

+ 57 - 49
doc/系统设计/数据库设计/物理模型/分析后台设计增加/02技师列表.sql

@@ -1,6 +1,6 @@
 -- Active: xiaoding_test@@192.168.110.85@3306
-/*
 
+/*
 这段sql语句是根据"market_dist_teams"表获取的,这个表的解释是:
 1、当一个用户A邀请另一个用户B的时候,数据是这样的
 -  object_id是A的id
@@ -13,39 +13,41 @@
 -  user_id是C的id
 - 统计的时候B是C的一级邀请人
 - 统计的时候A是C的二级邀请人
-
 请重写我的统计sql
 */
 
-WITH 
-/* 一级邀请人信息 */
-inviter_level1 AS (
-    SELECT 
-        mdt1.user_id,
-        m1.nickname
-    FROM market_dist_teams mdt1
-    LEFT JOIN member_users m1 ON mdt1.object_id = m1.id 
-    WHERE mdt1.level = '1'
-),
-/* 二级邀请人信息 */
-inviter_level2 AS (
-    SELECT 
-        mdt1.user_id,
-        m2.nickname
-    FROM market_dist_teams mdt1
-    LEFT JOIN market_dist_teams mdt2 ON mdt1.object_id = mdt2.user_id
-    LEFT JOIN member_users m2 ON mdt2.object_id = m2.id
-    WHERE mdt1.level = '1'
-    AND mdt2.level = '1'
-),
-/* 钱包余额信息 */
-coach_wallet AS (
-    SELECT 
-        owner_id,
-        total_balance
-    FROM wallet 
-    WHERE owner_type = 'COACH'
-)
+-- 技师列表视图
+DROP VIEW IF EXISTS manage_coach_list;
+
+CREATE OR REPLACE VIEW manage_coach_list AS
+WITH
+    /* 一级邀请人信息 */
+    inviter_level1 AS (
+        SELECT mdt1.user_id, m1.nickname
+        FROM
+            market_dist_teams mdt1
+            LEFT JOIN member_users m1 ON mdt1.object_id = m1.id
+        WHERE
+            mdt1.level = 1
+    ),
+    /* 二级邀请人信息 */
+    inviter_level2 AS (
+        SELECT mdt1.user_id, m2.nickname
+        FROM
+            market_dist_teams mdt1
+            LEFT JOIN market_dist_teams mdt2 ON mdt1.object_id = mdt2.user_id
+            LEFT JOIN member_users m2 ON mdt2.object_id = m2.id
+        WHERE
+            mdt1.level = 1
+            AND mdt2.level = 1
+    ),
+    /* 钱包余额信息 */
+    coach_wallet AS (
+        SELECT owner_id, total_balance
+        FROM wallet
+        WHERE
+            owner_type = 'App\\Models\\CoachUser'
+    )
 SELECT
     /* 性别 */
     mu.gender,
@@ -66,15 +68,18 @@ SELECT
     /* 调度区域 */
     cl.location,
     /* 是否开通会员 */
-    CASE WHEN cu.is_vip = 1 THEN '是' ELSE '否' END,
+    CASE
+        WHEN cu.is_vip = 1 THEN '是'
+        ELSE '否'
+    END AS is_vip,
     /* 开通会员时间 */
     cu.vip_time,
     /* 一级邀请人 */
-    il1.nickname,
+    il1.nickname AS inviter_level1_name,
     /* 二级邀请人 */
-    il2.nickname,
+    il2.nickname AS inviter_level2_name,
     /* 余额 */
-    COALESCE(cw.total_balance, 0),
+    COALESCE(cw.total_balance, 0) AS balance,
     /* 状态 */
     cu.state,
     /* 邀请码 */
@@ -83,18 +88,21 @@ SELECT
     cu.qr_code,
     /* 认证状态 */
     CASE
-        WHEN cq.state = 'APPROVED' THEN '已认证'
-        WHEN cq.state = 'PENDING' THEN '认证中'
-        WHEN cq.state = 'REJECTED' THEN '认证失败'
+        WHEN cq.state = 2 THEN '已认证'
+        WHEN cq.state = 1 THEN '认证中'
+        WHEN cq.state = 3 THEN '认证失败'
         ELSE '未认证'
-    END
-FROM coach_users cu
-LEFT JOIN member_users mu ON cu.user_id = mu.id
-LEFT JOIN coach_info_records ci ON cu.info_record_id = ci.id
-LEFT JOIN coach_locations cl ON cu.id = cl.coach_id AND cl.type = 'CURRENT'
-LEFT JOIN shop_auth_records sar ON cu.shop_id = sar.id
-LEFT JOIN coach_qual_records cq ON cu.qualification_record_id = cq.id
-LEFT JOIN inviter_level1 il1 ON cu.user_id = il1.user_id
-LEFT JOIN inviter_level2 il2 ON cu.user_id = il2.user_id
-LEFT JOIN coach_wallet cw ON cu.user_id = cw.owner_id
-WHERE cu.deleted_at IS NULL;
+    END AS auth_status
+FROM
+    coach_users cu
+    LEFT JOIN member_users mu ON cu.user_id = mu.id
+    LEFT JOIN coach_info_records ci ON cu.info_record_id = ci.id
+    LEFT JOIN coach_locations cl ON cu.id = cl.coach_id
+    AND cl.type = 2
+    LEFT JOIN shop_auth_records sar ON cu.shop_id = sar.id
+    LEFT JOIN coach_qual_records cq ON cu.qualification_record_id = cq.id
+    LEFT JOIN inviter_level1 il1 ON cu.user_id = il1.user_id
+    LEFT JOIN inviter_level2 il2 ON cu.user_id = il2.user_id
+    LEFT JOIN coach_wallet cw ON cu.user_id = cw.owner_id
+WHERE
+    cu.deleted_at IS NULL;