320 lines
12 KiB
TeX
320 lines
12 KiB
TeX
|
\documentclass[全部作业]{subfiles}
|
|||
|
\input{mysubpreamble}
|
|||
|
|
|||
|
% 不知道为什么这里又变成不用framed才能不出现换页问题了
|
|||
|
% \BeforeBeginEnvironment{minted}{}
|
|||
|
% \AfterEndEnvironment{minted}{}
|
|||
|
% 这样好像不能替换掉原来的,那就只能把framed移动到需要的部分里了
|
|||
|
|
|||
|
|
|||
|
\begin{document}
|
|||
|
\setcounter{chapter}{6}
|
|||
|
\chapter{第七次作业}
|
|||
|
\begin{enumerate}
|
|||
|
\item \choice[1]{在MySQL中,存储过程和存储函数的主要区别在于:
|
|||
|
A
|
|||
|
存储过程可以返回单个值,而存储函数可以返回数据集
|
|||
|
|
|||
|
B
|
|||
|
存储函数必须指定返回值类型,而存储过程不需要
|
|||
|
|
|||
|
C
|
|||
|
存储过程可以包含DDL语句,而存储函数不可以
|
|||
|
|
|||
|
D
|
|||
|
存储过程可以使用CALL语句调用,而存储函数不能}{2}
|
|||
|
{\kaishu 怎么感觉第一题的B和C都对呢。}
|
|||
|
\item \choice[4]{在创建存储过程时,以下哪个参数类型是不允许的?
|
|||
|
A
|
|||
|
IN
|
|||
|
|
|||
|
B
|
|||
|
OUT
|
|||
|
|
|||
|
C
|
|||
|
INOUT
|
|||
|
|
|||
|
D
|
|||
|
ALL}{4}
|
|||
|
\item \choice[1]{ 以下哪个SQL语句用于创建一个存储过程,该过程接受一个整数类型的输入参数并返回一个包含单个整数值的输出参数?
|
|||
|
A
|
|||
|
\mintinline{SQL}|CREATE PROCEDURE my_procedure (IN num INT) BEGIN ... END;|
|
|||
|
|
|||
|
B
|
|||
|
\mintinline{SQL}|CREATE PROCEDURE my_procedure (OUT num INT) BEGIN ... END;|
|
|||
|
|
|||
|
C
|
|||
|
\mintinline{SQL}|CREATE FUNCTION my_function (IN num INT) RETURNS INT BEGIN ... END;|
|
|||
|
|
|||
|
D
|
|||
|
\mintinline{SQL}|CREATE PROCEDURE my_procedure (INOUT num INT) BEGIN ... END;|
|
|||
|
}{4}
|
|||
|
\item \choice[1]{以下哪个SQL语句正确地在存储过程中使用了IF语句?
|
|||
|
A
|
|||
|
\mintinline{SQL}{IF condition THEN BEGIN ... END;}
|
|||
|
|
|||
|
B
|
|||
|
\mintinline{SQL}{IF condition THEN BEGIN ... END IF;}
|
|||
|
|
|||
|
C
|
|||
|
\mintinline{SQL}{BEGIN IF condition THEN ... END;}
|
|||
|
|
|||
|
D
|
|||
|
\mintinline{SQL}{IF condition THEN ... END IF;}
|
|||
|
}{4}
|
|||
|
\item \choice[1]{以下哪个SQL查询将正确地返回每个部门的员工数量?
|
|||
|
A
|
|||
|
\mintinline{SQL}|SELECT Department, COUNT(*) FROM Employees GROUP BY Department;|
|
|||
|
|
|||
|
B
|
|||
|
\mintinline{SQL}|SELECT COUNT(*) FROM Employees GROUP BY Department; |
|
|||
|
|
|||
|
C
|
|||
|
\mintinline{SQL}|SELECT Department, COUNT(*) FROM Employees ORDER BY Department;|
|
|||
|
|
|||
|
D
|
|||
|
\mintinline{SQL}|SELECT Department FROM Employees GROUP BY Department;|
|
|||
|
}{1}
|
|||
|
\item \choice[1]{已知tm_employee表中具有默认约束df_adress,删除该约束的语句为
|
|||
|
A
|
|||
|
\mintinline{SQL}|alter table tm_employee drop constraint df_adress;|
|
|||
|
|
|||
|
B
|
|||
|
\mintinline{SQL}|alter table tm_employee remove constraint df_adress;|
|
|||
|
|
|||
|
C
|
|||
|
\mintinline{SQL}|alter table tm_employee delete constraint df_adress;|
|
|||
|
|
|||
|
D
|
|||
|
\mintinline{SQL}|remove constraint df_adress from talbe tm_employee;| % 这里的table在题目中就拼写成了talbe
|
|||
|
}{1}
|
|||
|
\questionandanswer[]{
|
|||
|
使用bank数据库,查询每个分行的员工总数以及该分行所有员工管理的客户数量。
|
|||
|
|
|||
|
示例:CUST_ID为10的客户的账户24,其OPEN_EMP_ID为16,则该客户是员工16管理的客户。
|
|||
|
}{}
|
|||
|
{\kaishu
|
|||
|
\begin{minted}{SQL}
|
|||
|
SELECT
|
|||
|
branch.NAME,
|
|||
|
COUNT( * ),
|
|||
|
sum( a.cust_num )
|
|||
|
FROM
|
|||
|
employee
|
|||
|
LEFT JOIN branch ON employee.ASSIGNED_BRANCH_ID = branch.BRANCH_ID
|
|||
|
LEFT JOIN ( SELECT OPEN_EMP_ID, COUNT( * ) as cust_num FROM account GROUP BY OPEN_EMP_ID ) as a on a.OPEN_EMP_ID = employee.EMP_ID
|
|||
|
GROUP BY
|
|||
|
BRANCH_ID;
|
|||
|
\end{minted}
|
|||
|
\csvstyle{every csv}{separator=tab}
|
|||
|
\begin{csv}
|
|||
|
NAME 员工总数 客户数量
|
|||
|
上海市总行 9 8
|
|||
|
建国支行 3 7
|
|||
|
南京分行 3 3
|
|||
|
杭州分行 3 6
|
|||
|
\end{csv}
|
|||
|
}
|
|||
|
\questionandanswer[]{
|
|||
|
使用bank数据库,找到每个分行的员工中直接下级员工最多的员工,输出字段包括员工id,全名,所属分行名,直接下级数量。
|
|||
|
|
|||
|
注意:直接下级指,如果员工A的SUPER_EMP_ID是B,那么A是B的直接下级员工。
|
|||
|
}{}
|
|||
|
{\kaishu
|
|||
|
\begin{minted}{SQL}
|
|||
|
-- 主要是要考虑可能出现多个相同的最大值(虽然这里没有),所以使用了三层嵌套子查询。
|
|||
|
SELECT
|
|||
|
employee.EMP_ID as 员工id,
|
|||
|
CONCAT( employee.LAST_NAME, employee.FIRST_NAME ) as 全名,
|
|||
|
branch.`NAME` as 所属分行名,
|
|||
|
( SELECT COUNT( * ) FROM employee as a WHERE a.SUPERIOR_EMP_ID = employee.EMP_ID ) as 直接下级数量
|
|||
|
FROM
|
|||
|
employee
|
|||
|
JOIN (
|
|||
|
SELECT
|
|||
|
ASSIGNED_BRANCH_ID,
|
|||
|
MAX( 直接下级数量 ) as 最大直接下级数量
|
|||
|
FROM
|
|||
|
( SELECT ASSIGNED_BRANCH_ID, ( SELECT count( * ) FROM employee as a WHERE a.SUPERIOR_EMP_ID = employee.EMP_ID ) as 直接下级数量 FROM employee ) as a
|
|||
|
GROUP BY
|
|||
|
a.ASSIGNED_BRANCH_ID
|
|||
|
) as b USING ( ASSIGNED_BRANCH_ID )
|
|||
|
LEFT JOIN branch ON employee.ASSIGNED_BRANCH_ID = branch.BRANCH_ID
|
|||
|
WHERE
|
|||
|
( SELECT COUNT( * ) FROM employee as a WHERE a.SUPERIOR_EMP_ID = employee.EMP_ID ) = 最大直接下级数量;
|
|||
|
-- 最外层好像不用group by 也能用having,但是会多出一列,还是直接where吧,但是where不能引用前面计算出来后用as命名的
|
|||
|
\end{minted}
|
|||
|
\csvstyle{every csv}{separator=tab}
|
|||
|
\begin{csv}
|
|||
|
员工id 全名 所属分行名 直接下级数量
|
|||
|
4 李易枫 上海市总行 5
|
|||
|
10 陈易 建国支行 2
|
|||
|
13 蒋琴琴 南京分行 2
|
|||
|
16 杨天宝 杭州分行 2
|
|||
|
\end{csv}
|
|||
|
}
|
|||
|
\questionandanswer[]{
|
|||
|
使用bank数据库,查询该银行每个部门的员工管理的账户中,余额最少的账户的类型,输出字段为部门名,账号产品类型,余额。
|
|||
|
}{}
|
|||
|
{\kaishu
|
|||
|
\begin{minted}{SQL}
|
|||
|
SELECT
|
|||
|
department.`NAME` as 部门名,
|
|||
|
product_type.`NAME` as 账号产品类型,
|
|||
|
account.AVAIL_BALANCE as 余额
|
|||
|
FROM
|
|||
|
( SELECT employee.DEPT_ID, MIN( AVAIL_BALANCE ) as min_balance FROM employee JOIN account ON employee.EMP_ID = account.OPEN_EMP_ID GROUP BY DEPT_ID ) as a
|
|||
|
JOIN employee USING ( DEPT_ID )
|
|||
|
JOIN account ON employee.EMP_ID = account.OPEN_EMP_ID
|
|||
|
left JOIN product USING ( PRODUCT_CD )
|
|||
|
LEFT JOIN product_type USING ( PRODUCT_TYPE_CD )
|
|||
|
LEFT JOIN department USING ( DEPT_ID )
|
|||
|
WHERE
|
|||
|
AVAIL_BALANCE = min_balance;
|
|||
|
\end{minted}
|
|||
|
\csvstyle{every csv}{separator=tab}
|
|||
|
\begin{csv}
|
|||
|
部门名 账号产品类型 余额
|
|||
|
营业部 存款 1057.7500
|
|||
|
营业部 存款 1057.7500
|
|||
|
综合管理部 存款 125.6700
|
|||
|
\end{csv}
|
|||
|
|
|||
|
先处理多个最值的情况,也有固定套路,先在子查询里查询出最值,运行一下看看没问题了,只保留聚合的键(DEPT_ID)以及最值(AVAIL_BALANCE),再join上原来的表(employee, account),并对最值使用where子句过滤(where AVAIL_BALANCE = min_balance),就完成了多个最值的处理。
|
|||
|
之后保留此表的信息,所以left join其他几个表,检查一下没问题了最后使用投影函数也就是select语句指定想要获取的列。
|
|||
|
}
|
|||
|
\questionandanswer[]{
|
|||
|
使用bank数据库,查询每个客户(包括个人和企业)的账户中,交易金额最高的单笔交易信息
|
|||
|
|
|||
|
要求:显示客户全名、账户ID、交易ID、交易金额和交易日期。
|
|||
|
}{}
|
|||
|
{\kaishu
|
|||
|
\begin{minted}{SQL}
|
|||
|
SELECT
|
|||
|
( CASE customer.CUST_TYPE_CD WHEN 'i' THEN CONCAT( individual.LAST_NAME, individual.FIRST_NAME ) ELSE business.`NAME` END ) as 客户全名,
|
|||
|
ACCOUNT_ID AS 账户ID,
|
|||
|
TXN_ID as 交易ID,
|
|||
|
AMOUNT as 交易金额,
|
|||
|
TXN_DATE as 交易日期
|
|||
|
FROM
|
|||
|
( SELECT CUST_ID, MAX( AMOUNT ) as max_amount FROM acc_transaction RIGHT JOIN account USING ( ACCOUNT_ID ) GROUP BY CUST_ID ) as a
|
|||
|
JOIN account USING ( CUST_ID )
|
|||
|
JOIN acc_transaction USING ( ACCOUNT_ID )
|
|||
|
LEFT JOIN customer USING ( CUST_ID )
|
|||
|
LEFT JOIN individual USING ( CUST_ID )
|
|||
|
LEFT JOIN business USING ( CUST_ID )
|
|||
|
WHERE
|
|||
|
AMOUNT = a.max_amount;
|
|||
|
\end{minted}
|
|||
|
\csvstyle{every csv}{separator=tab}
|
|||
|
\begin{csv}
|
|||
|
客户全名 账户ID 交易ID 交易金额 交易日期
|
|||
|
尤青 2 2 500000.0000 2011-01-15 00:00:00
|
|||
|
许文强 5 5 2000000.0000 2012-03-12 00:00:00
|
|||
|
何婕 8 14 650000.0000 2013-12-15 00:00:00
|
|||
|
吕东 11 3 650600.0000 2011-01-15 00:00:00
|
|||
|
施珊珊 13 19 340023.0000 2015-01-27 00:00:00
|
|||
|
张晓 14 9 3330000.0000 2013-08-24 00:00:00
|
|||
|
孔庆东 17 18 5000.0000 2015-01-12 00:00:00
|
|||
|
曹方 19 7 15000.0000 2012-05-23 00:00:00
|
|||
|
严匡 23 23 15000.0000 2015-06-30 00:00:00
|
|||
|
华东师范大学 25 11 503292.0000 2013-10-01 00:00:00
|
|||
|
阿里巴巴集团有限公司 27 21 119345.0000 2015-03-22 00:00:00
|
|||
|
上海汽车集团股份有限公司 28 16 30000.0000 2014-07-30 00:00:00
|
|||
|
南瑞集团有限公司 29 20 200000.0000 2015-02-22 00:00:00
|
|||
|
\end{csv}
|
|||
|
}
|
|||
|
\questionandanswer[]{
|
|||
|
使用university数据库,使用with子句进行递归查询,查询所有课程的所有先修课程列表(包含该课程)。
|
|||
|
|
|||
|
例如:BIO-301 课程的所有先修课程列表为 BIO-101,BIO-301。
|
|||
|
|
|||
|
注意:由于prereq表字段长度只有varchar(8),你可能需要使用CAST修改查询结果的类型。
|
|||
|
|
|||
|
注:university数据库在资料-上机材料中,其中数据库结构为university.sql,smallRelationsInsertFile.sql。
|
|||
|
|
|||
|
插入测试数据
|
|||
|
|
|||
|
insert into prereq values('FIN-201', 'HIS-351');
|
|||
|
|
|||
|
insert into prereq values('MU-199', 'FIN-201');
|
|||
|
|
|||
|
}{}
|
|||
|
{\kaishu
|
|||
|
\begin{minted}{SQL}
|
|||
|
INSERT INTO prereq VALUES('FIN-201', 'HIS-351');
|
|||
|
INSERT INTO prereq VALUES('MU-199', 'FIN-201');
|
|||
|
WITH recursive full_prereq_table as (
|
|||
|
( SELECT course.course_id, cast(course.course_id as VARCHAR(100)) as full_prereq_id FROM course WHERE not EXISTS ( SELECT course_id FROM prereq WHERE prereq.course_id = course.course_id ) ) UNION ALL
|
|||
|
( SELECT prereq.course_id, concat(full_prereq_table.full_prereq_id, ",", prereq.course_id) FROM prereq, full_prereq_table WHERE prereq_id = full_prereq_table.course_id )
|
|||
|
)
|
|||
|
SELECT * FROM full_prereq_table;
|
|||
|
\end{minted}
|
|||
|
\csvstyle{every csv}{separator=tab}
|
|||
|
\begin{csv}
|
|||
|
course_id full_prereq_id
|
|||
|
BIO-101 BIO-101
|
|||
|
CS-101 CS-101
|
|||
|
HIS-351 HIS-351
|
|||
|
PHY-101 PHY-101
|
|||
|
BIO-301 BIO-101,BIO-301
|
|||
|
BIO-399 BIO-101,BIO-399
|
|||
|
CS-190 CS-101,CS-190
|
|||
|
CS-315 CS-101,CS-315
|
|||
|
CS-319 CS-101,CS-319
|
|||
|
CS-347 CS-101,CS-347
|
|||
|
EE-181 PHY-101,EE-181
|
|||
|
FIN-201 HIS-351,FIN-201
|
|||
|
MU-199 HIS-351,FIN-201,MU-199
|
|||
|
\end{csv}
|
|||
|
}
|
|||
|
\questionandanswer[]{
|
|||
|
使用university数据库,使用函数迭代查询某课程的所有先修课程列表(包含该课程),函数输入为一个代表课程id的字符串,输出为该课程的所有先修课程列表。
|
|||
|
|
|||
|
例如:BIO-301 课程的所有先修课程列表为 BIO-101,BIO-301。
|
|||
|
|
|||
|
插入测试数据
|
|||
|
|
|||
|
insert into prereq values('FIN-201', 'HIS-351');
|
|||
|
|
|||
|
insert into prereq values('MU-199', 'FIN-201');
|
|||
|
|
|||
|
}{}
|
|||
|
{\kaishu
|
|||
|
\begin{minted}{SQL}
|
|||
|
DROP FUNCTION IF EXISTS get_prereq_courses;
|
|||
|
|
|||
|
CREATE FUNCTION get_prereq_courses(base_course_id VARCHAR(8)) RETURNS VARCHAR(100)
|
|||
|
BEGIN
|
|||
|
DECLARE result VARCHAR(100);
|
|||
|
DECLARE child_temp VARCHAR(100);
|
|||
|
SET result = '';
|
|||
|
SET child_temp = base_course_id;
|
|||
|
WHILE child_temp is NOT NULL DO
|
|||
|
IF result = '' THEN
|
|||
|
SET result = child_temp;
|
|||
|
ELSE
|
|||
|
SET result = CONCAT(child_temp, ',', result);
|
|||
|
END IF;
|
|||
|
SELECT GROUP_CONCAT(prereq_id) INTO child_temp FROM prereq WHERE FIND_IN_SET(course_id,child_temp) > 0;
|
|||
|
END WHILE;
|
|||
|
RETURN result;
|
|||
|
END;
|
|||
|
|
|||
|
SELECT get_prereq_courses('BIO-301');
|
|||
|
\end{minted}
|
|||
|
\csvstyle{every csv}{separator=tab}
|
|||
|
\begin{csv}
|
|||
|
get_prereq_courses('BIO-301')
|
|||
|
BIO-101,BIO-301
|
|||
|
\end{csv}
|
|||
|
\begin{minted}{SQL}
|
|||
|
SELECT get_prereq_courses('MU-199');
|
|||
|
\end{minted}
|
|||
|
\begin{csv}
|
|||
|
get_prereq_courses('MU-199')
|
|||
|
HIS-351,FIN-201,MU-199
|
|||
|
\end{csv}
|
|||
|
}
|
|||
|
\end{enumerate}
|
|||
|
\end{document}
|