子查询
首先需要创建表
Mysql 基础表SQL https://songzixian.com/mysql/1792.html
1. 需求分析与问题解决
1.1 实际问题
题目:谁的工资比Abel高?
#方式一:
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,employees e2
WHERE e1.last_name = 'Abel'
AND e1.`salary` < e2.`salary`
#方式三:子查询
SELECT last_name,salary
FROM employees
WHERE salary > (
SELECT salary
FROM employees
WHERE last_name = 'Abel'
);
1.2 子查询的基本使用
- 子查询(内查询)在主查询之前一次执行完成。
- 子查询的结果被主查询(外查询)使用 。
注意事项
- 子查询要包含在括号内
- 将子查询放在比较条件的右侧
- 单行操作符对应单行子查询,多行操作符对应多行子查询
1.3 子查询的分类
分类方式1:
我们按内查询的结果返回一条还是多条记录,将子查询分为单行子查询
、多行子查询
。
分类方式2:
我们按内查询是否被执行多次,将子查询划分为相关(或关联)子查询
和不相关(或非关联)子查询
。
2. 单行子查询
2.1 单行比较操作符
操作符 | 含义 |
---|---|
= | equal to |
> | greater than |
>= | greater than or equal to |
< | less than |
<= | less than or equal to |
<> | not equal to |
2.2 代码示例
题目:返回公司工资最少的员工的last_name,job_id和salary
SELECT last_name, job_id, salary
FROM employees
WHERE salary = (
SELECT MIN(salary)
FROM employees
);
2.3 HAVING 中的子查询
题目:查询最低工资大于50号部门最低工资的部门id和其最低工资
SELECT department_id, MIN(salary)
FROM employees
GROUP BY department_id
HAVING MIN(salary) > (
SELECT MIN(salary)
FROM employees
WHERE department_id = 50
);
2.4 CASE中的子查询
题目:显示员工的employee_id,last_name和location。其中,若员工department_id与location_id为1800的department_id相同,则location为’Canada’,其余则为’USA’。
SELECT employee_id, last_name, (
CASE department_id
WHEN (
SELECT department_id
FROM departments
WHERE location_id = 1800
) THEN 'Canada' ELSE 'USA' END
) location
FROM employees;
2.5 子查询中的空值问题
mysql> SELECT last_name, job_id
-> FROM employees
-> WHERE job_id = (
-> SELECT job_id
-> FROM employees
-> WHERE last_name = 'Haas'
-> );
Empty set (0.01 sec)
子查询不返回任何行
2.6 非法使用子查询
mysql> SELECT employee_id, last_name
-> FROM employees
-> WHERE salary = ( # 多行子查询使用单行比较符
-> SELECT MIN(salary)
-> FROM employees
-> GROUP BY department_id
-> );
ERROR 1242 (21000): Subquery returns more than 1 row
3. 多行子查询
3.1 多行比较操作符
操作符 | 含义 |
---|---|
IN | 等于列表中的任意一个 |
ANY | 需要和单行比较操作符一起使用,和子查询返回的某一个值比较 |
ALL | 需要和单行比较操作符一起使用,和子查询返回的所有值比较 |
SOME | 实际上是ANY的别名,作用相同,一般常使用ANY |
3.2 代码示例
题目:查询平均工资最低的部门id
#方式1:
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
) dept_avg_sal
);
#方式2:
SELECT department_id
FROM employees
GROUP BY department_id
HAVING AVG(salary) <= ALL (
SELECT AVG(salary) avg_sal
FROM employees
GROUP BY department_id
);
MySQL中聚合函数是不能嵌套使用的。
3.3 空值问题
mysql> SELECT last_name
-> FROM employees
-> WHERE employee_id NOT IN (
-> SELECT manager_id
-> FROM employees
-> );
Empty set (0.01 sec)
4. 相关子查询
4.1 相关子查询执行流程
如果子查询的执行依赖于外部查询,通常情况下都是因为子查询中的表用到了外部的表,并进行了条件关联,因此每执行一次外部查询,子查询都要重新计算一次,这样的子查询就称之为关联子查询
。
4.2 代码示例
题目:查询员工中工资大于本部门平均工资的员工的last_name,salary和其department_id
方式一:相关子查询
SELECT last_name, salary, department_id
FROM employees e
WHERE salary > (
SELECT AVG(salary)
FROM employees
WHERE department_id = e.department_id
);
方式二:在 FROM 中使用子查询
SELECT last_name,salary,e1.department_id
FROM employees e1,(
SELECT department_id,AVG(salary) dept_avg_sal
FROM employees
GROUP BY department_id
) e2
WHERE e1.`department_id` = e2.department_id
AND e2.dept_avg_sal < e1.`salary`;
在ORDER BY 中使用子查询:
题目:查询员工的id,salary,按照department_name排序
SELECT employee_id,salary
FROM employees e
ORDER BY (
SELECT department_name
FROM departments d
WHERE e.`department_id` = d.`department_id`
);
结论:在SELECT中,除了GROUP BY 和 LIMIT之外,其他位置都可以声明子查询!
4.3 EXISTS与NOT EXISTS关键字
- 关联子查询通常也会和 EXISTS操作符一起来使用,用来检查在子查询中是否存在满足条件的行。
如果在子查询中不存在满足条件的行:
- 条件返回 FALSE
- 继续在子查询中查找
如果在子查询中存在满足条件的行:
- 不在子查询中继续查找
- 条件返回 TRUE
- NOT EXISTS关键字表示如果不存在某种条件,则返回TRUE,否则返回FALSE。
题目:查询公司管理者的employee_id,last_name,job_id,department_id信息
方式一:
SELECT employee_id, last_name, job_id, 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
WHERE e1.employee_id = e2.manager_id;
方式三:
SELECT employee_id,last_name,job_id,department_id
FROM employees
WHERE employee_id IN (
SELECT DISTINCT manager_id
FROM employees
);
题目:查询departments表中,不存在于employees表中的部门的department_id和department_name
SELECT department_id,department_name
FROM departments d
WHERE NOT EXISTS (
SELECT *
FROM employees e
WHERE d.`department_id` = e.`department_id`
);
题目中可以使用子查询,也可以使用自连接。一般情况建议你使用自连接,因为在许多 DBMS 的处理过程中,对于自连接的处理速度要比子查询快得多。