|
14 | 14 | -- 4. 用戶名稱為`好野人`,Email 為`richman@hexschooltest.io`,Role為`USER`
|
15 | 15 | -- 5. 用戶名稱為`Q太郎`,Email 為`starplatinum@hexschooltest.io`,Role為`USER`
|
16 | 16 | -- 6. 用戶名稱為 透明人,Email 為 opacity0@hexschooltest.io,Role 為 USER
|
| 17 | +INSERT INTO |
| 18 | + "USER" (name, email, role) |
| 19 | +VALUES |
| 20 | + ('李燕容', 'lee2000@hexschooltest.io', 'USER'), |
| 21 | + ('王小明', 'wXlTq@hexschooltest.io', 'USER'), |
| 22 | + ('肌肉棒子', 'muscle@hexschooltest.io', 'USER'), |
| 23 | + ('好野人', 'richman@hexschooltest.io', 'USER'), |
| 24 | + ('Q太郎', 'starplatinum@hexschooltest.io', 'USER'), |
| 25 | + ('透明人', 'opacity0@hexschooltest.io', 'USER'); |
17 | 26 |
|
18 | 27 | -- 1-2 修改:用 Email 找到 李燕容、肌肉棒子、Q太郎,如果他的 Role 為 USER 將他的 Role 改為 COACH
|
19 |
| - |
20 |
| --- 1-3 刪除:刪除USER 資料表中,用 Email 找到透明人,並刪除該筆資料 |
21 |
| - |
22 |
| --- 1-4 查詢:取得USER 資料表目前所有用戶數量(提示:使用count函式) |
23 |
| - |
24 |
| --- 1-5 查詢:取得 USER 資料表所有用戶資料,並列出前 3 筆(提示:使用limit語法) |
25 |
| - |
| 28 | +UPDATE |
| 29 | + "USER" |
| 30 | +SET |
| 31 | + role = 'COACH', |
| 32 | + updated_at = CURRENT_TIMESTAMP |
| 33 | +WHERE |
| 34 | + email IN ( |
| 35 | + 'lee2000@hexschooltest.io', |
| 36 | + 'muscle@hexschooltest.io', |
| 37 | + 'starplatinum@hexschooltest.io' |
| 38 | + ) |
| 39 | + AND role = 'USER'; |
| 40 | + |
| 41 | +-- 1-3 刪除:刪除 USER 資料表中,用 Email 找到透明人,並刪除該筆資料 |
| 42 | +DELETE FROM |
| 43 | + "USER" |
| 44 | +WHERE |
| 45 | + email = 'opacity0@hexschooltest.io'; |
| 46 | + |
| 47 | +-- 1-4 查詢:取得 USER 資料表目前所有用戶數量(提示:使用count函式) |
| 48 | +SELECT |
| 49 | + COUNT(*) as total_users |
| 50 | +FROM |
| 51 | + "USER"; |
| 52 | + |
| 53 | +-- 1-5 查詢:取得 USER 資料表所有用戶資料,並列出前 3 筆(提示:使用 limit 語法) |
| 54 | +SELECT |
| 55 | + * |
| 56 | +FROM |
| 57 | + "USER" |
| 58 | +LIMIT |
| 59 | + 3; |
26 | 60 |
|
27 | 61 | -- ████████ █████ █ ████
|
28 | 62 | -- █ █ ██ █ █ █
|
|
35 | 69 | -- 1. 名稱為 `7 堂組合包方案`,價格為`1,400` 元,堂數為`7`
|
36 | 70 | -- 2. 名稱為`14 堂組合包方案`,價格為`2,520` 元,堂數為`14`
|
37 | 71 | -- 3. 名稱為 `21 堂組合包方案`,價格為`4,800` 元,堂數為`21`
|
| 72 | +INSERT INTO |
| 73 | + "CREDIT_PACKAGE" (name, credit_amount, price) |
| 74 | +VALUES |
| 75 | + ('7 堂組合包方案', 7, 1400.00), |
| 76 | + ('14 堂組合包方案', 14, 2520.00), |
| 77 | + ('21 堂組合包方案', 21, 4800.00); |
38 | 78 |
|
39 | 79 | -- 2-2. 新增:在 `CREDIT_PURCHASE` 資料表,新增三筆資料:(請使用 name 欄位做子查詢)
|
40 | 80 | -- 1. `王小明` 購買 `14 堂組合包方案`
|
41 | 81 | -- 2. `王小明` 購買 `21 堂組合包方案`
|
42 | 82 | -- 3. `好野人` 購買 `14 堂組合包方案`
|
43 |
| - |
| 83 | +INSERT INTO "CREDIT_PURCHASE" |
| 84 | + (user_id, credit_package_id, purchased_credits, price_paid) |
| 85 | +SELECT |
| 86 | + (SELECT id FROM "USER" WHERE name = '王小明'), |
| 87 | + (SELECT id FROM "CREDIT_PACKAGE" WHERE name = '14 堂組合包方案'), |
| 88 | + (SELECT credit_amount FROM "CREDIT_PACKAGE" WHERE name = '14 堂組合包方案'), |
| 89 | + (SELECT price FROM "CREDIT_PACKAGE" WHERE name = '14 堂組合包方案'); |
| 90 | + |
| 91 | +INSERT INTO "CREDIT_PURCHASE" |
| 92 | + (user_id, credit_package_id, purchased_credits, price_paid) |
| 93 | +SELECT |
| 94 | + (SELECT id FROM "USER" WHERE name = '王小明'), |
| 95 | + (SELECT id FROM "CREDIT_PACKAGE" WHERE name = '21 堂組合包方案'), |
| 96 | + (SELECT credit_amount FROM "CREDIT_PACKAGE" WHERE name = '21 堂組合包方案'), |
| 97 | + (SELECT price FROM "CREDIT_PACKAGE" WHERE name = '21 堂組合包方案'); |
| 98 | + |
| 99 | +INSERT INTO "CREDIT_PURCHASE" |
| 100 | + (user_id, credit_package_id, purchased_credits, price_paid) |
| 101 | +SELECT |
| 102 | + (SELECT id FROM "USER" WHERE name = '好野人'), |
| 103 | + (SELECT id FROM "CREDIT_PACKAGE" WHERE name = '14 堂組合包方案'), |
| 104 | + (SELECT credit_amount FROM "CREDIT_PACKAGE" WHERE name = '14 堂組合包方案'), |
| 105 | + (SELECT price FROM "CREDIT_PACKAGE" WHERE name = '14 堂組合包方案'); |
44 | 106 |
|
45 | 107 | -- ████████ █████ █ ████
|
46 | 108 | -- █ █ ██ █ █ ██
|
47 | 109 | -- █ █████ ███ ███ ███
|
48 | 110 | -- █ █ █ ██ █ ██
|
49 | 111 | -- █ █ █████ █ █ ████
|
50 | 112 | -- ===================== ====================
|
51 |
| --- 3. 教練資料 ,資料表為 COACH ,SKILL,COACH_LINK_SKILL |
| 113 | +-- 3. 教練資料,資料表為 COACH ,SKILL,COACH_LINK_SKILL |
52 | 114 | -- 3-1 新增:在`COACH`資料表新增三筆教練資料,資料需求如下:
|
53 | 115 | -- 1. 將用戶`李燕容`新增為教練,並且年資設定為2年(提示:使用`李燕容`的email ,取得 `李燕容` 的 `id` )
|
54 | 116 | -- 2. 將用戶`肌肉棒子`新增為教練,並且年資設定為2年
|
55 | 117 | -- 3. 將用戶`Q太郎`新增為教練,並且年資設定為2年
|
| 118 | +INSERT INTO "COACH" (user_id, experience_years) |
| 119 | +SELECT id, 2 |
| 120 | +FROM "USER" |
| 121 | +WHERE email IN ( |
| 122 | + 'lee2000@hexschooltest.io', |
| 123 | + 'muscle@hexschooltest.io', |
| 124 | + 'starplatinum@hexschooltest.io' |
| 125 | +); |
56 | 126 |
|
57 | 127 | -- 3-2. 新增:承1,為三名教練新增專長資料至 `COACH_LINK_SKILL` ,資料需求如下:
|
58 | 128 | -- 1. 所有教練都有 `重訓` 專長
|
59 | 129 | -- 2. 教練`肌肉棒子` 需要有 `瑜伽` 專長
|
60 | 130 | -- 3. 教練`Q太郎` 需要有 `有氧運動` 與 `復健訓練` 專長
|
| 131 | +INSERT INTO "COACH_LINK_SKILL" (coach_id, skill_id) |
| 132 | +SELECT |
| 133 | + "COACH".id, |
| 134 | + (SELECT id FROM "SKILL" WHERE name = '重訓') |
| 135 | +FROM "COACH"; |
| 136 | + |
| 137 | +INSERT INTO "COACH_LINK_SKILL" (coach_id, skill_id) |
| 138 | +SELECT |
| 139 | + "COACH".id, |
| 140 | + (SELECT id FROM "SKILL" WHERE name = '瑜伽') |
| 141 | +FROM "COACH" |
| 142 | +JOIN "USER" ON "COACH".user_id = "USER".id |
| 143 | +WHERE "USER".email = 'muscle@hexschooltest.io'; |
| 144 | + |
| 145 | +INSERT INTO "COACH_LINK_SKILL" (coach_id, skill_id) |
| 146 | +SELECT |
| 147 | + "COACH".id, |
| 148 | + (SELECT id FROM "SKILL" WHERE name = '有氧運動') |
| 149 | +FROM "COACH" |
| 150 | +JOIN "USER" ON "COACH".user_id = "USER".id |
| 151 | +WHERE "USER".email = 'starplatinum@hexschooltest.io'; |
| 152 | + |
| 153 | +INSERT INTO "COACH_LINK_SKILL" (coach_id, skill_id) |
| 154 | +SELECT |
| 155 | + "COACH".id, |
| 156 | + (SELECT id FROM "SKILL" WHERE name = '復健訓練') |
| 157 | +FROM "COACH" |
| 158 | +JOIN "USER" ON "COACH".user_id = "USER".id |
| 159 | +WHERE "USER".email = 'starplatinum@hexschooltest.io'; |
61 | 160 |
|
62 | 161 | -- 3-3 修改:更新教練的經驗年數,資料需求如下:
|
63 | 162 | -- 1. 教練`肌肉棒子` 的經驗年數為3年
|
64 | 163 | -- 2. 教練`Q太郎` 的經驗年數為5年
|
| 164 | +UPDATE "COACH" |
| 165 | +SET |
| 166 | + experience_years = 3, |
| 167 | + updated_at = CURRENT_TIMESTAMP |
| 168 | +FROM "USER" |
| 169 | +WHERE "COACH".user_id = "USER".id |
| 170 | +AND "USER".email = 'muscle@hexschooltest.io'; |
| 171 | + |
| 172 | +UPDATE "COACH" |
| 173 | +SET |
| 174 | + experience_years = 5, |
| 175 | + updated_at = CURRENT_TIMESTAMP |
| 176 | +FROM "USER" |
| 177 | +WHERE "COACH".user_id = "USER".id |
| 178 | +AND "USER".email = 'starplatinum@hexschooltest.io'; |
65 | 179 |
|
66 | 180 | -- 3-4 刪除:新增一個專長 空中瑜伽 至 SKILL 資料表,之後刪除此專長。
|
| 181 | +INSERT INTO "SKILL" (name) |
| 182 | +VALUES ('空中瑜伽'); |
67 | 183 |
|
| 184 | +DELETE FROM "SKILL" |
| 185 | +WHERE name = '空中瑜伽'; |
68 | 186 |
|
69 | 187 | -- ████████ █████ █ █ █
|
70 | 188 | -- █ █ ██ █ █ █ █
|
|
82 | 200 | -- 5. 授課結束時間`end_at`設定為2024-11-25 16:00:00
|
83 | 201 | -- 6. 最大授課人數`max_participants` 設定為10
|
84 | 202 | -- 7. 授課連結設定`meeting_url`為 https://test-meeting.test.io
|
85 |
| - |
| 203 | +INSERT INTO "COURSE" ( |
| 204 | + user_id, |
| 205 | + skill_id, |
| 206 | + name, |
| 207 | + start_at, |
| 208 | + end_at, |
| 209 | + max_participants, |
| 210 | + meeting_url |
| 211 | +) |
| 212 | +SELECT |
| 213 | + "USER".id, |
| 214 | + (SELECT id FROM "SKILL" WHERE name = '重訓'), |
| 215 | + '重訓基礎課', |
| 216 | + '2024-11-25 14:00:00', |
| 217 | + '2024-11-25 16:00:00', |
| 218 | + 10, |
| 219 | + 'https://test-meeting.test.io' |
| 220 | +FROM "USER" |
| 221 | +WHERE "USER".email = 'lee2000@hexschooltest.io'; |
86 | 222 |
|
87 | 223 | -- ████████ █████ █ █████
|
88 | 224 | -- █ █ ██ █ █ █
|
|
0 commit comments