一个查询语句嵌套在另外一个查询语句中

需求:谁的工资比 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 e2.`salary` > e1.`salary`
AND e1.last_name = 'Abel';

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

称谓的规范:外查询(或主查询)、内查询(或子查询)

注意:

  • 子查询(内查询)在主查询之前一次执行完成
  • 子查询的结果被主查询(外查询)使用
    • 子查询包含在括号内
    • 将子查询放在 比较条件的右侧
    • 单行操作符对应单行子查询,多行操作符对应多行子查询

1. 子查询的分类

角度1:从内查询返回的结果的条目数 单行子查询 vs 多行子查询

角度2:内查询是否被执行多次 相关子查询 vs 不相关子查询

比如:相关子查询的需求:查询工资大于本部门平均工资的员工信息 不相关子查询的需求:查询工资大于本公司平均工资的员工信息

2. 单行子查询

题目:查询工资大于149号员工工资的员工的信息
SELECT employee_id,last_name,salary
FROM employees
WHERE salary > (
		SELECT salary
		FROM employees
		WHERE employee_id = 149
		);

题目:返回job_id与141号员工相同,salary比143号员工多的员工姓名,job_id和工资
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
		);


题目:返回公司工资最少的员工的last_name,job_id和salary

SELECT last_name,job_id,salary
FROM employees
WHERE salary = (
		SELECT MIN(salary)
		FROM employees
		);

题目:查询与141号员工的manager_id和department_id相同的其他员工
的employee_id,manager_id,department_id。
方式1:
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;

方式2:了解
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;

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

SELECT department_id,MIN(salary)
FROM employees
WHERE department_id IS NOT NULL
GROUP BY department_id
HAVING MIN(salary) > (
			SELECT MIN(salary)
			FROM employees
			WHERE department_id = 110
		     );

题目:显式员工的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;

4.2 子查询中的空值问题
SELECT last_name, job_id
FROM   employees
WHERE  job_id =
                (SELECT job_id
                 FROM   employees
                 WHERE  last_name = 'Haas');
                 
4.3 非法使用子查询
错误:Subquery returns more than 1 row
SELECT employee_id, last_name
FROM   employees
WHERE  salary =
                (SELECT   MIN(salary)
                 FROM     employees
                 GROUP BY department_id);

3. 多行子查询

内查询返回多行数据

3.1 多行比较操作符

操作符含义
IN等于列表中的任意一个
ANY需要和单行比较操作符一起使用,和子查询返回的某一个值比较
ALL需要和单行比较操作符一起使用,和子查询返回的所有值比较
SOME是 ANY的别名,作用相同,常用 ANY
IN:
SELECT employee_id,last_name
FROM employees
WHERE salary IN (
				SELECT MIN(salary)
				FROM employees
				GROUP BY department_id
);

ANY:
返回其他job_id 中比 job_id 为 `IT_PROG` 部门任一工资低的员工的员工号、姓名、job_id 以及 salary

SELECT employee_id,last_name,job_id,salary
FROM employee
WHERE job_id <> 'IT_PROG'
AND salary < ANY (
					SELECT salary
					FROM employees
					WHERE job_id = 'IT_PROG'
);

ALL:
返回其他job_id 中比 job_id 为 `IT_PROG` 部门所有工资低的员工的员工号、姓名、job_id 以及 salary
SELECT employee_id,last_name,job_id,salary
FROM employee
WHERE job_id <> 'IT_PROG'
AND salary < ALL (
					SELECT salary
					FROM employees
					WHERE job_id = 'IT_PROG'
);

查询平均工资最低的部门 id
MySQL中聚合函数不可嵌套使用

SELECT AVG(salary) avg_sal
FROM employees
GROUP BY department_id

SELECT MIN(avg_sal)
FROM (
	SELECT AVG(salary) avg_sal
	FROM employees
	GROUP BY department_id
	) dept_avg_sal

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 
					)

空值问题
SELECT last_name
FROM employees
WHERE employee_id NOT IN (
						SELECT manager_id
						FROM employees
);
当 子查询中 有 NULL 值时,会无法查询出结果
正确:
SELECT last_name
FROM employees
WHERE employee_id NOT IN (
						SELECT manager_id
						FROM employees
						WHERE MANAGER_id is NOT NULL
);

4.相关子查询


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

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

每次查询都需要执行一次子查询语句

不相关子查询:
查询员工中工资大于公司平均工资的员工的last_name,salary 和 department_id
SELECT last_name,salary,department_id
FROM employees
WHERE salary >(
					SELECT AVG(salary)
					FROM employees
);

相关子查询:
查询员工中工资大于本部门平均工资的员工的last_name,salary 和 department_id
方式一:使用相关子查询
SELECT last_name,salary,department_id
FROM employees e1
WHERE salary > (
					SELECT AVG(salary)
					FROM employees e2
					WHERE department_id = e1.`department_id`
);
方式二:在 FROM 中声明子查询
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


查询员工的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`
) ASC;

结论:在 SELECT 中,GROUP BY 和 LIMIT 不可使用 子查询语句

SELECT ....
FROM ...
JOIN ...   ON ...
WHERE ...(不包含聚合函数的过滤条件)
GROUP BY ...
HAVING ... (包含聚合函数的过滤条件)
ORDER BY ...(ASC/DESC)
LIMIT .
若employees表中employee_id与job_history表中employee_id相同的数目不小于2,
输出这些相同 id 的员工的employee_id,last_name和其job_id

SELECT *
FROM job_history;

SELECT employee_id,last_name,job_id
FROM employees
WHERE 2 <= (
			SELECT COUNT(*)
			FROM job_history j
			WHERE e.`employee_id` = j.`employee_id`
)

4.1 EXISTS 与 NOT EXISTS 关键字

  • 相关子查询通常也会和 EXISTS操作符一起来使用,用来检查在子查询中是否存在满足条件的行。
  • 如果在子查询中不存在满足条件的行:
    • 条件返回 FALSE
    • 继续在子查询中查找
  • 如果在子查询中存在满足条件的行:
    • 不在子查询中继续查找
    • 条件返回 TRUE
  • NOT EXISTS关键字表示如果不存在某种条件,则返回TRUE,否则返回FALSE。
查询公司管理者的employee_id,last_name,job_id,department_id信息
方式一:自连接
SELECT DISTINCT mgr.employee_id,mgr.last_name,mgr.job_id,mgr.department_id
FROM employees emp JOIN employees mgr
ON emp.manager_id = mgr.employee_id

方式二:子查询
SELECT employee_id,last_name,job_id,department_id
FROM employees
WHERE employee_id IN (
					SELECT DISTINCT manager_id
					FROM employees
)

方式三:使用 EXISTS
SELECT employee_id,last_name,job_id,department_id
FROM employees e1
WHERE EXISTS (
			SELECT * 
			FROM employees e2
			WHERE e1.`employee_id` = e2.`manager_id`
)

4.2 相关更新

UPDATE table1 alias1
SET column = (SELECT expression
				FROM table2 alias2
				WHERE alias1.column = alias2.column);

使用相关子查询依据一个表中的数据更新另一个表的数据。

在employees中增加一个department_name字段,数据为员工对应的部门名称
# 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);

4.3 相关删除

DELETE FROM table1 alias1
WHERE column operator (SELECT expression
						FROM table2 alias2
						WHERE alias1.column = alias2.column);

使用相关子查询依据一个表中的数据删除另一个表的数据。

题目:删除表employees中,其与emp_history表皆有的数据
DELETE FROM employees e
WHERE employee_id in(
					SELECT employee_id
					FROM emp_history
					WHERE employee_id = e.employee_id);

自连接比子查询的效率高

谁的工资比Abel的高?
方式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 中都对自连接处理进行了优化。

文章作者: 临川
版权声明: 本站所有文章除特别声明外,均采用 CC BY-NC-SA 4.0 许可协议。转载请注明来自 临川羡鱼
MySQL MySQL
喜欢就支持一下吧