diff --git a/.prettierignore b/.prettierignore index 3de7bc75f9981..ea62a4d14aa91 100644 --- a/.prettierignore +++ b/.prettierignore @@ -27,4 +27,6 @@ node_modules/ /solution/1700-1799/1767.Find the Subtasks That Did Not Execute/Solution.sql /solution/2100-2199/2118.Build the Equation/Solution.sql /solution/2100-2199/2153.The Number of Passengers in Each Bus II/Solution.sql -/solution/2200-2299/2205.The Number of Users That Are Eligible for Discount/Solution.sql \ No newline at end of file +/solution/2200-2299/2205.The Number of Users That Are Eligible for Discount/Solution.sql +/solution/2200-2299/2252.Dynamic Pivoting of a Table/Solution.sql +/solution/2200-2299/2253.Dynamic Unpivoting of a Table/Solution.sql \ No newline at end of file diff --git a/solution/0100-0199/0175.Combine Two Tables/README.md b/solution/0100-0199/0175.Combine Two Tables/README.md index 4adb80649d275..1b22ecd086223 100644 --- a/solution/0100-0199/0175.Combine Two Tables/README.md +++ b/solution/0100-0199/0175.Combine Two Tables/README.md @@ -80,20 +80,18 @@ addressId = 1 包含了 personId = 2 的地址信息。 **方法一:左连接** +我们可以使用左连接,将 `Person` 表左连接 `Address` 表,连接条件为 `Person.personId = Address.personId`,这样就可以得到每个人的姓、名、城市和州。如果 `personId` 的地址不在 `Address` 表中,则报告为空 `null`。 + ### **SQL** ```sql # Write your MySQL query statement below -SELECT - firstName, - lastName, - city, - state +SELECT firstName, lastName, city, state FROM - Person AS p - LEFT JOIN Address AS a ON p.personId = a.personId; + Person + LEFT JOIN Address USING (personId); ``` diff --git a/solution/0100-0199/0175.Combine Two Tables/README_EN.md b/solution/0100-0199/0175.Combine Two Tables/README_EN.md index 19f8a7091cd2e..a55a1b4693ba5 100644 --- a/solution/0100-0199/0175.Combine Two Tables/README_EN.md +++ b/solution/0100-0199/0175.Combine Two Tables/README_EN.md @@ -82,14 +82,10 @@ addressId = 1 contains information about the address of personId = 2. ```sql # Write your MySQL query statement below -SELECT - firstName, - lastName, - city, - state +SELECT firstName, lastName, city, state FROM - Person AS p - LEFT JOIN Address AS a ON p.personId = a.personId; + Person + LEFT JOIN Address USING (personId); ``` diff --git a/solution/0100-0199/0175.Combine Two Tables/Solution.sql b/solution/0100-0199/0175.Combine Two Tables/Solution.sql index fb13df4f0aadf..616d34acc4f54 100644 --- a/solution/0100-0199/0175.Combine Two Tables/Solution.sql +++ b/solution/0100-0199/0175.Combine Two Tables/Solution.sql @@ -1,9 +1,5 @@ # Write your MySQL query statement below -SELECT - firstName, - lastName, - city, - state +SELECT firstName, lastName, city, state FROM - Person AS p - LEFT JOIN Address AS a ON p.personId = a.personId; + Person + LEFT JOIN Address USING (personId); diff --git a/solution/0100-0199/0176.Second Highest Salary/README.md b/solution/0100-0199/0176.Second Highest Salary/README.md index 7cc20933a3ed7..24f765ff93e15 100644 --- a/solution/0100-0199/0176.Second Highest Salary/README.md +++ b/solution/0100-0199/0176.Second Highest Salary/README.md @@ -73,12 +73,22 @@ Employee 表: +**方法一:使用 LIMIT 语句和子查询** + +我们可以按照薪水降序排列,然后使用 `LIMIT` 语句来获取第二高的薪水,如果不存在第二高的薪水,那么就返回 `null`。 + +**方法二:使用 MAX() 函数和子查询** + +使用 `MAX()` 函数,从小于 `MAX()` 的 Salary 中挑选最大值 `MAX()` 即可。 + +**方法三:使用 IFNULL() 和窗口函数** + +我们也可以先通过 `dense_rank()` 函数计算出每个员工的薪水排名,然后再筛选出排名为 $2$ 的员工即可,如果不存在第二高的薪水,那么就返回 `null`。 + ### **SQL** -解法 1:使用 LIMIT 语句和子查询。 - ```sql # Write your MySQL query statement below SELECT @@ -90,8 +100,6 @@ SELECT ) AS SecondHighestSalary; ``` -解法 2:使用 `MAX()` 函数,从小于 `MAX()` 的 Salary 中挑选最大值 `MAX()` 即可。 - ```sql # Write your MySQL query statement below SELECT MAX(Salary) AS SecondHighestSalary @@ -103,4 +111,20 @@ WHERE ); ``` +```sql +# Write your MySQL query statement below +WITH + S AS ( + SELECT salary, dense_rank() OVER (ORDER BY salary DESC) AS rk + FROM Employee + ) +SELECT + ifnull( + SELECT salary + FROM S + WHERE rk = 2 + LIMIT 1, NULL + ) AS SecondHighestSalary; +``` + diff --git a/solution/0100-0199/0176.Second Highest Salary/README_EN.md b/solution/0100-0199/0176.Second Highest Salary/README_EN.md index 8cff2ebdee79c..176810b1ca9ee 100644 --- a/solution/0100-0199/0176.Second Highest Salary/README_EN.md +++ b/solution/0100-0199/0176.Second Highest Salary/README_EN.md @@ -64,12 +64,16 @@ Employee table: ## Solutions +**Solution 1: Use Sub Query and LIMIT** + +**Solution 2: Use `MAX()` function** + +**Solution 3: Use `IFNULL()` and window function** + ### **SQL** -Solution 1: Use Sub Query and LIMIT. - ```sql # Write your MySQL query statement below SELECT @@ -81,8 +85,6 @@ SELECT ) AS SecondHighestSalary; ``` -Solution 2: Use `MAX()` function. - ```sql # Write your MySQL query statement below SELECT MAX(Salary) AS SecondHighestSalary @@ -94,4 +96,20 @@ WHERE ); ``` +```sql +# Write your MySQL query statement below +WITH + S AS ( + SELECT salary, dense_rank() OVER (ORDER BY salary DESC) AS rk + FROM Employee + ) +SELECT + ifnull( + SELECT salary + FROM S + WHERE rk = 2 + LIMIT 1, NULL + ) AS SecondHighestSalary; +``` + diff --git a/solution/0100-0199/0180.Consecutive Numbers/README.md b/solution/0100-0199/0180.Consecutive Numbers/README.md index 0c7f73999b7ae..8a106d9453f8f 100644 --- a/solution/0100-0199/0180.Consecutive Numbers/README.md +++ b/solution/0100-0199/0180.Consecutive Numbers/README.md @@ -60,26 +60,23 @@ Result 表: ### **SQL** -```sql -SELECT DISTINCT (Num) AS ConsecutiveNums -FROM Logs AS Curr -WHERE - Num = (SELECT Num FROM Logs WHERE id = Curr.id - 1) - AND Num = (SELECT Num FROM Logs WHERE id = Curr.id - 2); -``` - ```sql # Write your MySQL query statement below -SELECT DISTINCT l1.num AS ConsecutiveNums -FROM - logs AS l1, - logs AS l2, - logs AS l3 -WHERE - l1.id = l2.id - 1 - AND l2.id = l3.id - 1 - AND l1.num = l2.num - AND l2.num = l3.num; +WITH + t AS ( + SELECT + *, + CASE + WHEN (lag(num) OVER (ORDER BY id)) = num THEN 0 + ELSE 1 + END AS mark + FROM Logs + ), + p AS (SELECT num, sum(mark) OVER (ORDER BY id) AS gid FROM t) +SELECT DISTINCT num AS ConsecutiveNums +FROM p +GROUP BY gid +HAVING count(1) >= 3; ``` diff --git a/solution/0100-0199/0180.Consecutive Numbers/README_EN.md b/solution/0100-0199/0180.Consecutive Numbers/README_EN.md index 808a175844c8a..91b7aac65956d 100644 --- a/solution/0100-0199/0180.Consecutive Numbers/README_EN.md +++ b/solution/0100-0199/0180.Consecutive Numbers/README_EN.md @@ -57,26 +57,23 @@ Logs table: ### **SQL** -```sql -SELECT DISTINCT (Num) AS ConsecutiveNums -FROM Logs AS Curr -WHERE - Num = (SELECT Num FROM Logs WHERE id = Curr.id - 1) - AND Num = (SELECT Num FROM Logs WHERE id = Curr.id - 2); -``` - ```sql # Write your MySQL query statement below -SELECT DISTINCT l1.num AS ConsecutiveNums -FROM - logs AS l1, - logs AS l2, - logs AS l3 -WHERE - l1.id = l2.id - 1 - AND l2.id = l3.id - 1 - AND l1.num = l2.num - AND l2.num = l3.num; +WITH + t AS ( + SELECT + *, + CASE + WHEN (lag(num) OVER (ORDER BY id)) = num THEN 0 + ELSE 1 + END AS mark + FROM Logs + ), + p AS (SELECT num, sum(mark) OVER (ORDER BY id) AS gid FROM t) +SELECT DISTINCT num AS ConsecutiveNums +FROM p +GROUP BY gid +HAVING count(1) >= 3; ``` diff --git a/solution/0100-0199/0180.Consecutive Numbers/Solution.sql b/solution/0100-0199/0180.Consecutive Numbers/Solution.sql index d3525c6c51572..c87a60edfe835 100644 --- a/solution/0100-0199/0180.Consecutive Numbers/Solution.sql +++ b/solution/0100-0199/0180.Consecutive Numbers/Solution.sql @@ -1,5 +1,16 @@ -SELECT DISTINCT (Num) AS ConsecutiveNums -FROM Logs AS Curr -WHERE - Num = (SELECT Num FROM Logs WHERE id = Curr.id - 1) - AND Num = (SELECT Num FROM Logs WHERE id = Curr.id - 2); +# Write your MySQL query statement below +WITH + t AS ( + SELECT + *, + CASE + WHEN (lag(num) OVER (ORDER BY id)) = num THEN 0 + ELSE 1 + END AS mark + FROM Logs + ), + p AS (SELECT num, sum(mark) OVER (ORDER BY id) AS gid FROM t) +SELECT DISTINCT num AS ConsecutiveNums +FROM p +GROUP BY gid +HAVING count(1) >= 3; diff --git a/solution/2200-2299/2252.Dynamic Pivoting of a Table/README.md b/solution/2200-2299/2252.Dynamic Pivoting of a Table/README.md index 2448f5c753235..28e45396ef672 100644 --- a/solution/2200-2299/2252.Dynamic Pivoting of a Table/README.md +++ b/solution/2200-2299/2252.Dynamic Pivoting of a Table/README.md @@ -76,7 +76,23 @@ Products 表: ```sql - +CREATE PROCEDURE PivotProducts() +BEGIN + # Write your MySQL query statement below. + SET group_concat_max_len = 5000; + SELECT GROUP_CONCAT(DISTINCT 'MAX(CASE WHEN store = \'', + store, + '\' THEN price ELSE NULL END) AS ', + store + ORDER BY store) INTO @sql + FROM Products; + SET @sql = CONCAT('SELECT product_id, ', + @sql, + ' FROM Products GROUP BY product_id'); + PREPARE stmt FROM @sql; + EXECUTE stmt; + DEALLOCATE PREPARE stmt; +END ``` diff --git a/solution/2200-2299/2252.Dynamic Pivoting of a Table/README_EN.md b/solution/2200-2299/2252.Dynamic Pivoting of a Table/README_EN.md index 2fed3ca27fb09..13a6239cbaab4 100644 --- a/solution/2200-2299/2252.Dynamic Pivoting of a Table/README_EN.md +++ b/solution/2200-2299/2252.Dynamic Pivoting of a Table/README_EN.md @@ -70,7 +70,23 @@ For product 3, the price is 1000 in Shop and 1900 in Souq. It is not sold in the ### **SQL** ```sql - +CREATE PROCEDURE PivotProducts() +BEGIN + # Write your MySQL query statement below. + SET group_concat_max_len = 5000; + SELECT GROUP_CONCAT(DISTINCT 'MAX(CASE WHEN store = \'', + store, + '\' THEN price ELSE NULL END) AS ', + store + ORDER BY store) INTO @sql + FROM Products; + SET @sql = CONCAT('SELECT product_id, ', + @sql, + ' FROM Products GROUP BY product_id'); + PREPARE stmt FROM @sql; + EXECUTE stmt; + DEALLOCATE PREPARE stmt; +END ``` diff --git a/solution/2200-2299/2252.Dynamic Pivoting of a Table/Solution.sql b/solution/2200-2299/2252.Dynamic Pivoting of a Table/Solution.sql new file mode 100644 index 0000000000000..f79841c8b9283 --- /dev/null +++ b/solution/2200-2299/2252.Dynamic Pivoting of a Table/Solution.sql @@ -0,0 +1,17 @@ +CREATE PROCEDURE PivotProducts() +BEGIN + # Write your MySQL query statement below. + SET group_concat_max_len = 5000; + SELECT GROUP_CONCAT(DISTINCT 'MAX(CASE WHEN store = \'', + store, + '\' THEN price ELSE NULL END) AS ', + store + ORDER BY store) INTO @sql + FROM Products; + SET @sql = CONCAT('SELECT product_id, ', + @sql, + ' FROM Products GROUP BY product_id'); + PREPARE stmt FROM @sql; + EXECUTE stmt; + DEALLOCATE PREPARE stmt; +END \ No newline at end of file diff --git a/solution/2200-2299/2253.Dynamic Unpivoting of a Table/README.md b/solution/2200-2299/2253.Dynamic Unpivoting of a Table/README.md index 59d110199b714..2219d4ccba404 100644 --- a/solution/2200-2299/2253.Dynamic Unpivoting of a Table/README.md +++ b/solution/2200-2299/2253.Dynamic Unpivoting of a Table/README.md @@ -79,7 +79,33 @@ Products 表: ```sql - +CREATE PROCEDURE UnpivotProducts() +BEGIN + # Write your MySQL query statement below. + SET group_concat_max_len = 5000; + WITH + t AS ( + SELECT column_name + FROM information_schema.columns + WHERE + table_schema = DATABASE() + AND table_name = 'Products' + AND column_name != 'product_id' + ) + SELECT + GROUP_CONCAT( + 'SELECT product_id, \'', + column_name, + '\' store, ', + column_name, + ' price FROM Products WHERE ', + column_name, + ' IS NOT NULL' SEPARATOR ' UNION ' + ) INTO @sql from t; + PREPARE stmt FROM @sql; + EXECUTE stmt; + DEALLOCATE PREPARE stmt; +END; ``` diff --git a/solution/2200-2299/2253.Dynamic Unpivoting of a Table/README_EN.md b/solution/2200-2299/2253.Dynamic Unpivoting of a Table/README_EN.md index fa69137a63e02..7b0c972e2caef 100644 --- a/solution/2200-2299/2253.Dynamic Unpivoting of a Table/README_EN.md +++ b/solution/2200-2299/2253.Dynamic Unpivoting of a Table/README_EN.md @@ -73,7 +73,33 @@ Product 3 is sold in Shop and Souq with prices of 1000 and 1900. ### **SQL** ```sql - +CREATE PROCEDURE UnpivotProducts() +BEGIN + # Write your MySQL query statement below. + SET group_concat_max_len = 5000; + WITH + t AS ( + SELECT column_name + FROM information_schema.columns + WHERE + table_schema = DATABASE() + AND table_name = 'Products' + AND column_name != 'product_id' + ) + SELECT + GROUP_CONCAT( + 'SELECT product_id, \'', + column_name, + '\' store, ', + column_name, + ' price FROM Products WHERE ', + column_name, + ' IS NOT NULL' SEPARATOR ' UNION ' + ) INTO @sql from t; + PREPARE stmt FROM @sql; + EXECUTE stmt; + DEALLOCATE PREPARE stmt; +END; ``` diff --git a/solution/2200-2299/2253.Dynamic Unpivoting of a Table/Solution.sql b/solution/2200-2299/2253.Dynamic Unpivoting of a Table/Solution.sql new file mode 100644 index 0000000000000..80a919a2c2e84 --- /dev/null +++ b/solution/2200-2299/2253.Dynamic Unpivoting of a Table/Solution.sql @@ -0,0 +1,27 @@ +CREATE PROCEDURE UnpivotProducts() +BEGIN + # Write your MySQL query statement below. + SET group_concat_max_len = 5000; + WITH + t AS ( + SELECT column_name + FROM information_schema.columns + WHERE + table_schema = DATABASE() + AND table_name = 'Products' + AND column_name != 'product_id' + ) + SELECT + GROUP_CONCAT( + 'SELECT product_id, \'', + column_name, + '\' store, ', + column_name, + ' price FROM Products WHERE ', + column_name, + ' IS NOT NULL' SEPARATOR ' UNION ' + ) INTO @sql from t; + PREPARE stmt FROM @sql; + EXECUTE stmt; + DEALLOCATE PREPARE stmt; +END;