1. 1. MySQL基础-子查询
    1. 1.1. 一、子查询的引入
    2. 1.2. 二、子查询的分类
    3. 1.3. 三、单行子查询
      1. 1.3.1. 1.单行比较操作符
      2. 1.3.2. 2.代码示例
      3. 1.3.3. 3.HAVING中的子查询
      4. 1.3.4. 4.CASE中的子查询
      5. 1.3.5. 5.非法使用子查询
    4. 1.4. 四、多行子查询
      1. 1.4.1. 1.多行比较操作符
      2. 1.4.2. 2.代码示例
      3. 1.4.3. 3.空值问题
    5. 1.5. 五、相关子查询
      1. 1.5.1. 1.代码示例
      2. 1.5.2. 2.相关更新
      3. 1.5.3. 3.相关删除
    6. 1.6. 六、性能思考
    7. 1.7. 七、课后练习
      1. 1.7.0.0.1. 1.查询和Zlotkey相同部门的员工姓名和工资
      2. 1.7.0.0.2. 2.查询工资比公司平均工资高的员工的员工号,姓名和工资
      3. 1.7.0.0.3. 3.选择工资大于所有job_id = ‘SA_MAN’ 的员工的工资的员工的last_name, job_id, salary
      4. 1.7.0.0.4. 4.查询和姓名中包含字母u的员工在相同部门的员工的员工号和姓名
      5. 1.7.0.0.5. 5.查询在部门的location_id为1700的部门工作的员工的员工号
      6. 1.7.0.0.6. 6.查询管理者是King的员工姓名和工资
      7. 1.7.0.0.7. 7.查询工资最低的员工信息 (last_name, salary)
      8. 1.7.0.0.8. 8.查询平均工资最低的部门信息
      9. 1.7.0.0.9. 9.查询平均工资最低的部门信息和该部门的平均工资 (相关子查询)
      10. 1.7.0.0.10. 10.查询平均工资最高的job信息
      11. 1.7.0.0.11. 11.查询平均工资高于公司平均工资的部门有哪些
      12. 1.7.0.0.12. 12.查询出公司中所有manager的详细信息
      13. 1.7.0.0.13. 13.各个部门中,最高工资中最低的那个部门的最低工资是多少
      14. 1.7.0.0.14. 14.查询平均工资最高的部门的manager的详细信息:last_name, department_id, email, salary
      15. 1.7.0.0.15. 15.查询部门的部门号,其中不包括job_id是”ST_CLERK”的部门号
      16. 1.7.0.0.16. 16.选择所有没有管理者的员工的last_name
      17. 1.7.0.0.17. 17.查询员工号、姓名、雇用时间、工资,其中员工的管理者为 ‘De Haan’
      18. 1.7.0.0.18. 18.查询各部门中工资比本部门平均工资高的员工的员工号,姓名和工资(相关子查询)
      19. 1.7.0.0.19. 19.查询每个部门下的部门人数大于5的部门名称(相关子查询)
      20. 1.7.0.0.20. 20.查询每个国家下的部门个数大于2的国家编号(相关子查询)

MySQL基础-子查询

MySQL基础-子查询

一、子查询的引入

子查询指一个查询语句嵌套在另一个查询语句内部的查询,这个特性从 MySQL4.1 开始引入。 SQL 中子查询的使用大大增强了 SELECT 查询的能力,因为很多时候查询需要从结果集中获取数据,或者需要从同一个表中先计算得出一个数据结果,然后与这个数据结果(可能是某个标量,也可能是某个集合)进行比较。

image-20231012161358022

现有的一些解决方式:

1
2
3
4
5
6
7
8
9
10
11
12
13
#方式一:存在两次Web服务器与数据库服务器的网络访问延迟
SELECT salary
FROM employees
WHERE last_name = 'Abel';

SELECT last_name, salary
FROM employees
WHERE salary > 11000;

#方式二:自连接
SELECT e2.last_name,e2.salary
FROM employees e1
JOIN employees e2 ON e1.last_name = 'Abel' AND e1.`salary` < e2.`salary`

采用子查询的解决方案:

1
2
3
4
5
6
7
8
#方式二:子查询
SELECT last_name, salary
FROM employees
WHERE salary > (
SELECT salary
FROM employees
WHERE last_name = 'Abel'
);

注意事项:

  • 子查询要包含在括号内
  • 将子查询放在比较条件的右侧,可读写较强
  • 单行操作符对应单行子查询,多行操作符对应多行子查询

二、子查询的分类

我们按子查询的结果返回一条还是多条记录,将子查询分为单行子查询多行子查询。我们按子查询是否被执行多次,将子查询划分为相关子查询不相关子查询

子查询从数据表中查询了数据结果,如果这个数据结果只执行一次,然后这个数据结果作为主查询的条件进行执行,那么这样的子查询叫做不相关子查询。同样,如果子查询需要执行多次,即采用循环的方式,先从外部查询开始,每次都将主查询的字段传入子查询进行查询,然后再将结果反馈给外部,这种嵌套的执行方式就称为相关子查询。

三、单行子查询

1.单行比较操作符

操作符 含义
= equal to
> greater than
>= greater than or equal to
< less than
<= less than or equal to
<> not equal to

2.代码示例

==题目:查询工资大于149号员工工资的员工的信息==

1
2
3
4
5
6
SELECT last_name
FROM employees
WHERE salary > (
SELECT salary
FROM employees
WHERE employee_id=149);

==题目:返回job_id与141号员工相同,salary比143号员工多的员工姓名、job_id和salary==

1
2
3
4
5
6
7
8
9
10
11
12
SELECT last_name, job_id, salary
FROM employees
WHERE job_id = (
SELECT job_id
FROM employees
WHERE employee_id = 141
)
AND salary > (
SELECT salary
FROM employees
WHERE employee_id = 143
);

==题目:查询与141号员工的manager_id和department_id相同的其他员工的employee_id, manager_id,department_id==

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
# 实现方式一:不成对比较
SELECT employee_id, manager_id, department_id
FROM employees
WHERE manager_id = (
SELECT manager_id
FROM employees
WHERE employee_id = 141
)
AND department_id = (
SELECT department_id
FROM employees
WHERE employee_id = 141
)
AND employee_id <> 141;

# 实现方式二:成对比较
SELECT employee_id, manager_id, department_id
FROM employees
WHERE (manager_id, department_id) = (
SELECT manager_id, department_id
FROM employees
WHERE employee_id = 141
)
AND employee_id <> 141;

3.HAVING中的子查询

==题目:查询最低工资大于50号部门最低工资的部门id和其最低工资==

1
2
3
4
5
6
7
8
SELECT department_id, MIN(salary)
FROM employees
GROUP BY department_id
HAVING MIN(salary) > (
SELECT MIN(salary)
FROM employees
WHERE department_id = 50
);

4.CASE中的子查询

==题目:显示员工的employee_id,last_name和location。其中,若员工department_id与location_id为1800的department_id相同,则location为’Canada’,其余则为’USA’。==

1
2
3
4
5
SELECT employee_id, last_name, (CASE department_id
WHEN (SELECT department_id FROM departments WHERE location_id = 1800)
THEN 'Canada'
ELSE 'USA' END) AS "location"
FROM employees;

5.非法使用子查询

1
2
3
4
5
6
7
8
# 错误的原因:多行子查询使用单行比较符
SELECT employee_id, last_name
FROM employees
WHERE salary = (
SELECT MIN(salary)
FROM employees
GROUP BY department_id
);

四、多行子查询

1.多行比较操作符

操作符 含义
IN 等于列表中的任意一个
ANY 需要和单行比较操作符一起使用,和子查询返回的某一个值比较
ALL 需要和单行比较操作符一起使用,和子查询返回的所有值比较
SOME 实际上是ANY的别名,作用相同,一般常使用ANY

2.代码示例

==题目:返回其它job_id中比job_id为‘IT_PROG’部门任一工资低的员工的员工号、姓名、job_id 以及salary==

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
SELECT employee_id, last_name, job_id, salary
FROM employees
WHERE job_id <> 'IT_PROG'
AND salary < ANY(
SELECT salary
FROM employees
WHERE job_id = 'IT_PROG'
);
# 等价的写法:
SELECT employee_id, last_name, job_id, salary
FROM employees
WHERE job_id <> 'IT_PROG'
AND salary < (
SELECT MAX(salary)
FROM employees
WHERE job_id = 'IT_PROG'
);

==题目:查询平均工资最低的部门id==

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
#方式1
SELECT department_id
FROM employees
GROUP BY department_id
HAVING AVG(salary) = (
SELECT MIN(avg_sal)
FROM (
SELECT AVG(salary) AS "avg_sal"
FROM employees
GROUP BY department_id
) t_dept_avg_sal
);

#方式2
SELECT department_id
FROM employees
GROUP BY department_id
HAVING AVG(salary) <= ALL(
SELECT AVG(salary) AS "avg_sal"
FROM employees
GROUP BY department_id
);

3.空值问题

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
# 找出所有的管理者:
SELECT last_name
FROM employees
WHERE employee_id IN (
SELECT manager_id
FROM employees
);

# 找出所有的非管理者:
SELECT last_name
FROM employees
WHERE employee_id NOT IN (
SELECT manager_id
FROM employees
WHERE manager_id IS NOT NULL
);

# 找出所有的非管理者(错误写法):
SELECT last_name
FROM employees
WHERE employee_id NOT IN (
SELECT manager_id
FROM employees
);

上面的子查询里面内部查询的结果集可能包含NULL,使用IN操作符比较时类似于OR的串联操作,因此包含NULL不影响结果;使用NOT IN操作符类似于AND的串联操作,因此一旦出现NULL则结果必为空集。

五、相关子查询

如果子查询的执行依赖于外部查询,通常情况下都是因为子查询中的表用到了外部的表,并进行了条件关联,因此每执行一次外部查询,子查询都要重新计算一次,这样的子查询就称之为关联子查询

相关子查询按照一行接一行的顺序执行,主查询的每一行都执行一次子查询。

image-20231012171402820

1.代码示例

==题目:查询员工中工资大于本部门平均工资的员工的last_name,salary和其department_id==

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
# 方式一:在WHERE中声明子查询
SELECT e1.last_name, e1.salary, e1.department
FROM employees e1
WHERE e1.salary > (
SELECT AVG(e2.salary)
FROM employees e2
WHERE e2.department_id = e1.department_id
);
# 方式二:在FROM中声明子查询
SELECT e.last_name, e.salary, e.department_id
FROM employees e, (
SELECT department_id, AVG(salary) AS "avg_sal"
FROM employees
GROUP BY department_id) t_dept_avg_sal
WHERE e.department_id = t_dept_avg_sal.department_id
AND e.salary > t_dept_avg_salary.avg_sal;

==题目:查询员工的id,salary,按照department_name排序==

1
2
3
4
5
6
7
SELECT e.employee_id, e.salary
FROM employees e
ORDER BY (
SELECT d.department_name
FROM departments d
WHERE e.`department_id` = d.`department_id`
);

==题目:若employees表中employee_id与job_history表中employee_id相同的数目不小于2,输出这些相同id的员工的employee_id,last_name和其job_id==

1
2
3
4
5
6
SELECT e.employee_id, e.last_name, e.job_id
FROM employees e
WHERE 2 <= (SELECT COUNT(*)
FROM job_history j
WHERE j.employee_id = e.employee_id
);

==题目:查询公司管理者的employee_id,last_name,job_id,department_id信息==

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
# 方式一:EXISTS
SELECT e1.employee_id, e1.last_name, e1.job_id, e1.department_id
FROM employees e1
WHERE EXISTS (
SELECT *
FROM employees e2
WHERE e2.manager_id = e1.employee_id
);

# 方式二:自连接
SELECT DISTINCT e1.employee_id, e1.last_name, e1.job_id, e1.department_id
FROM employees e1 JOIN employees e2
ON e1.employee_id = e2.manager_id;

# 方式三:IN
SELECT employee_id, last_name, job_id, department_id
WHERE employee_id IN (
SELECT DISTINCT manager_id
FROM employees
);

==题目:查询departments表中,不存在于employees表中的部门的department_id和department_name==

1
2
3
4
5
6
7
8
9
10
11
12
13
14
# 方式一:右连接
SELECT d.department_id, d.department_name
FROM departments e RIGHT JOIN departments d
ON e.`department_id` = d.`department_id`
WHERE e.`department_id` IS NULL;

# 方式二:NOT EXISTS
SELECT d.department_id, d.department_name
FROM departments d
WHERE NOT EXISTS (
SELECT *
FROM employees e
WHERE d.`department_id` = e.`department_id`
);

2.相关更新

==题目:在employees中增加一个department_name字段,数据为员工对应的部门名称==

1
2
3
4
5
6
7
8
9
10
11
# 1
ALTER TABLE employees
ADD(department_name VARCHAR2(14));

# 2
UPDATE employees e
SET department_name = (
SELECT department_name
FROM departments d
WHERE e.department_id = d.department_id
);

3.相关删除

==题目:删除表employees中,其与emp_history表皆有的数据==

1
2
3
4
5
6
DELETE FROM employees e
WHERE employee_id IN (
SELECT employee_id
FROM emp_history
WHERE employee_id = e.employee_id
);

六、性能思考

==问题:谁的工资比Abel的高?==

解答:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
#方式1:自连接
SELECT e2.last_name,e2.salary
FROM employees e1,employees e2
WHERE e1.last_name = 'Abel'
AND e1.`salary` < e2.`salary`;

#方式2:子查询
SELECT last_name,salary
FROM employees
WHERE salary > (
SELECT salary
FROM employees
WHERE last_name = 'Abel'
);

==问题:以上两种方式有好坏之分吗?==

解答:自连接方式好!题目中可以使用子查询,也可以使用自连接。一般情况建议使用自连接,因为在许多 DBMS 的处理过程中,对于自连接的处理速度要比子查询快得多。 可以这样理解:子查询实际上是通过未知表进行查询后的条件判断,而自连接是通过已知的自身数据表进行条件判断,因此在大部分 DBMS 中都对自连接处理进行了优化。

七、课后练习

1.查询和Zlotkey相同部门的员工姓名和工资
1
2
3
4
5
6
7
SELECT last_name, salary
FROM employees
WHERE department_id = (
SELECT department_id
FROM employees
WHERE last_name = 'Zlotkey'
);
2.查询工资比公司平均工资高的员工的员工号,姓名和工资
1
2
3
4
5
6
SELECT employee_id, last_name, salary
FROM employees
WHERE salary > (
SELECT AVG(salary)
FROM employees
);
3.选择工资大于所有job_id = ‘SA_MAN’ 的员工的工资的员工的last_name, job_id, salary
1
2
3
4
5
6
7
SELECT last_name, job_id, salary
FROM employees
WHERE salary > ALL (
SELECT salary
FROM employees
WHERE job_id = 'SA_MAN'
);
4.查询和姓名中包含字母u的员工在相同部门的员工的员工号和姓名
1
2
3
4
5
6
7
SELECT employee_id, last_name
FROM employees
WHERE department_id IN (
SELECT DISTINCT department_id
FROM employees
WHERE last_name LIKE '%u%'
);
5.查询在部门的location_id为1700的部门工作的员工的员工号
1
2
3
4
5
6
7
SELECT employee_id
FROM employees
WHERE department_id IN (
SELECT department_id
FROM departments
WHERE location_id = 1700
);
6.查询管理者是King的员工姓名和工资

image-20231012173916372

1
2
3
4
5
6
7
SELECT last_name, salary
FROM employees
WHERE manage_id IN (
SELECT employee_id
FROM employees
WHERE last_name = 'King'
);
7.查询工资最低的员工信息 (last_name, salary)
1
2
3
4
5
6
SELECT last_name, salary
FROM employees
WHERE salary = (
SELECT MIN(salary)
FROM employees
);
8.查询平均工资最低的部门信息
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
# 方式一
SELECT *
FROM departments
WHERE department_id = (
SELECT department_id
FROM employees
GROUP BY department_id
HAVING AVG(salary) = (
SELECT MIN(avg_sal)
FROM (
SELECT AVG(salary) avg_sal
FROM employees
GROUP BY department_id
) t_dept_avg_sal
)
);

# 方式二
SELECT *
FROM departments
WHERE department_id = (
SELECT department_id
FROM employees
GROUP BY department_id
HAVING AVG(salary) <= ALL (
SELECT AVG(salary) avg_sal
FROM employees
GROUP BY department_id
)
);

# 方式三: LIMIT
SELECT *
FROM departments
WHERE department_id IN (
SELECT department_id
FROM employees
GROUP BY department_id
HAVING AVG(salary) = (
SELECT AVG(salary) avg_sal
FROM employees
GROUP BY department_id
ORDER BY avg_sal ASC
LIMIT 0,1
)
);

# 方式四
SELECT d.*
FROM departments d, (
SELECT department_id, AVG(salary) avg_sal
FROM employees
GROUP BY department_id
ORDER BY avg_sal ASC
LIMIT 0,1
) t_dept_avg_sal
WHERE d.`department_id` = t_dept_avg_sal.`department_id`;
9.查询平均工资最低的部门信息和该部门的平均工资 (相关子查询)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
# 方式一:相关子查询
SELECT d.*, (SELECT AVG(salary) FROM employees WHERE department_id = d.`department_id`) avg_sal
FROM departments d, (
SELECT department_id, AVG(salary) avg_sal
FROM employees
GROUP BY department_id
ORDER BY avg_sal ASC
LIMIT 0,1
) t_dept_avg_sal
WHERE d.`department_id` = t_dept_avg_sal.`department_id`;

#方式二:不相关子查询
SELECT d.*, t_dept_avg_sal.avg_sal avg_sal
FROM departments d, (
SELECT department_id, AVG(salary) avg_sal
FROM employees
GROUP BY department_id
ORDER BY avg_sal ASC
LIMIT 0,1
) t_dept_avg_sal
WHERE d.`department_id` = t_dept_avg_sal.`department_id`;
10.查询平均工资最高的job信息
1
2
3
4
5
6
7
8
9
10
11
SELECT *
FROM jobs
WHERE job_id = (
SELECT job_id
FROM employees
GROUP BY job_id
HAVING AVG(salary) >= ALL(
SELECT AVG(salary)
FROM employees
GROUP BY job_id)
);
11.查询平均工资高于公司平均工资的部门有哪些
1
2
3
4
5
6
7
8
SELECT depatment_id
FROM employees
WHERE department_id IS NOT NULL
GROUP BY department_id
HAVING AVG(salary) > (
SELECT AVG(salary)
FROM employees
);
12.查询出公司中所有manager的详细信息
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
# 方式1:自连接
SELECT DISTINCT manager.employee_id, manager.last_name
FROM employees emp, employees manager
WHERE emp.`manager_id` = manager.`employee_id`;

SELECT DISTINCT manager.employee_id, manager.last_name
FROM employees emp JOIN employees manager
ON emp.`manager_id` = manager.`employee_id`;

# 方式2:子查询
SELECT employee_id, last_name
FROM employees
WHERE employee_id IN (
SELECT DISTINCT manager_id
FROM employees
);

# 方式3EXISTS
SELECT manager.employee_id, manager.last_name
FROM employees manager
WHERE EXISTS (
SELECT *
FROM employees emp
WHERE manager.`employee_id` = emp.`manager_id`
);
13.各个部门中,最高工资中最低的那个部门的最低工资是多少
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
# 方式一:
SELECT MIN(salary)
FROM employees
WHERE department_id = (
SELECT department_id
FROM employees
GROUP BY department_id
HAVING MAX(salary) = (
SELECT MIN(max_sal)
FROM (
SELECT MAX(salary) max_sal
FROM employees
GROUP BY department_id
) t_dept_max_sal
)
);

# 方式二:
SELECT MIN(salary)
FROM employees
WHERE department_id = (
SELECT department_id
FROM employees
GROUP BY department_id
HAVING MAX(salary) <= ALL (
SELECT MAX(salary)
FROM employees
GROUP BY department_id
)
);

# 方式三:
SELECT MIN(salary)
FROM employees
WHERE department_id = (
SELECT department_id
FROM employees
GROUP BY department_id
HAVING MAX(salary) = (
SELECT MAX(salary) max_sal
FROM employees
GROUP BY department_id
ORDER BY max_sal ASC
LIMIT 0,1
)
);

# 方式四:
SELECT MIN(e.salary)
FROM employees e, (
SELECT department_id, MAX(salary) max_sal
FROM employees
GROUP BY department_id
ORDER BY max_sal ASC
LIMIT 0,1
) t_dept_max_sal
WHERE e.`department_id` = t_dept_max_sal.`department_id`;
14.查询平均工资最高的部门的manager的详细信息:last_name, department_id, email, salary
1
2
3
4
5
6
7
8
9
10
SELECT * 
FROM employees
WHERE employee_id = (SELECT d.manager_id
FROM departments d
JOIN (SELECT department_id, AVG(salary) AS "avg_sal"
FROM employees
WHERE department_id IS NOT NULL
GROUP BY department_id
ORDER BY avg_sal
LIMIT 1) t_dept_avg_sal ON d.department_id = t_dept_avg_sal.department_id);
15.查询部门的部门号,其中不包括job_id是”ST_CLERK”的部门号
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
SELECT department_id
FROM departments
WHERE department_id NOT IN (
SELECT DISTINCT department_id
FROM employees
WHERE job_id = `ST_CLERK`
);

SELECT d.department_id
FROM department d
WHERE NOT EXISTS (
SELECT *
FROM employees e
WHERE d.`department_id` = e.`department_id`
AND e.`job_id` = 'ST_CLERK'
);
16.选择所有没有管理者的员工的last_name
1
2
3
4
5
6
7
8
9
10
11
SELECT last_name
FROM employees
WHERE manager_id IS NULL;

SELECT emp.last_name
FROM employees emp
WHERE NOT EXISTS (
SELECT *
FROM employees mgr
WHERE emp.`manager_id` = mgr.`employee_id`
);
17.查询员工号、姓名、雇用时间、工资,其中员工的管理者为 ‘De Haan’
1
2
3
4
5
6
7
SELECT employee_id, last_name, hire_date, salary
FROM employee
WHERE manager_id IN (
SELECT manager_id
FROM employee
WHERE last_name = 'De Haan'
);
18.查询各部门中工资比本部门平均工资高的员工的员工号,姓名和工资(相关子查询)
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
SELECT e1.department_id, e1.last_name, e1.salary
FROM employees e1
WHERE e1.salary > (
SELECT AVG(salary)
FROM employees e2
WHERE e2.`department_id` = e1.`department_id`
);

SELECT e.last_name, e.salary, e.department_id
FROM employees e, (
SELECT department_id, AVG(salary) avg_sal
FROM employees
GROUP BY department_id
) t_dept_avg_sal
WHERE e.`department_id` = t_dept_avg_sal.`department_id`
AND e.`salary` > t_dept_avg_sal.`avg_sal`;
19.查询每个部门下的部门人数大于5的部门名称(相关子查询)
1
2
3
4
5
6
7
SELECT d.department_name
FROM departments d
WHERE 5 < (
SELECT COUNT(*)
FROM employees e
WHERE d.`department_id` = e.`department_id`
);
20.查询每个国家下的部门个数大于2的国家编号(相关子查询)
1
2
3
4
5
6
7
SELECT country_id
FROM locations l
WHERE 2 < (
SELECT COUNT(*)
FROM department d
WHERE l.`location_id` = d.`location_id`
);