CREATE TABLE departments
(
Id INTEGER PRIMARY KEY NOT NULL, -- 部门ID
Name varchar(100), -- 部门名称
Budget FLOAT -- 部门预算
);
CREATE TABLE employees
(
SSN INTEGER PRIMARY KEY NOT NULL,
Name varchar(100) NOT NULL,
LastName varchar(100) NOT NULL,
Department INTEGER NOT NULL,
CONSTRAINT fk_Departments_Code FOREIGN KEY (Department)
REFERENCES Departments (Id)
);
INSERT INTO departments
VALUES (14, 'IT', 65000),
(37, '财务', 15000),
(59, '人力资源', 240000),
(77, '研发', 55000);
INSERT INTO Employees
VALUES ('123234877', 'Michael', 'Rogers', 14),
('152934485', 'Anand', 'Manikutty', 14),
('222364883', 'Carol', 'Smith', 37),
('326587417', 'Joe', 'Stevens', 37),
('332154719', 'Mary-Anne', 'Foster', 14),
('332569843', 'George', 'O''Donnell', 77),
('546523478', 'John', 'Doe', 59),
('631231482', 'David', 'Smith', 77),
('654873219', 'Zacary', 'Efron', 59),
('745685214', 'Eric', 'Goldsmith', 59),
('845657245', 'Elizabeth', 'Doe', 14),
('845657246', 'Kumar', 'Swamy', 14);
Smith
的员工的所有数据Smith
或Doe
的员工的所有数据14
中工作的员工的所有数据37
或部门77
中工作的员工的所有数据S
开头的员工的所有数据60,000
的部门工作的员工的姓名和姓氏Quality Assurance
的新部门,预算为40,000
美元,部门代码为11
,在该部门添加一名名为Mary Moore
的员工,SSN为847-21-9811
10%
60,000
的部门工作的员工select lastname
from employees;
select distinct lastname
from employees;
Smith
的员工的所有数据select *
from employees
where lastname = 'Smith';
Smith
或Doe
的员工的所有数据/* With OR */
SELECT *
FROM Employees
WHERE LastName = 'Smith'
OR LastName = 'Doe';
/* With IN */
SELECT *
FROM Employees
WHERE LastName IN ('Smith', 'Doe');
14
中工作的员工的所有数据select *
from employees
where department = 14;
37
或部门77
中工作的员工的所有数据/* With OR */
select *
from employees
where department = 37
or department = 77;
/* With IN */
select *
from employees
where department in (37, 77);
S
开头的员工的所有数据SELECT *
FROM Employees
WHERE LastName LIKE 'S%';
select sum(budget)
from departments;
select department, count(*)
from employees
group by department;
SELECT SSN, E.Name AS Name_E, LastName, D.Name AS Name_D, Department, id, Budget
FROM Employees E
INNER JOIN Departments D
ON E.Department = D.id;
/* Without labels */
SELECT Employees.Name, LastName, Departments.Name AS DepartmentsName, Budget
FROM Employees
INNER JOIN Departments
ON Employees.Department = Departments.ID;
/* With labels */
SELECT E.Name, LastName, D.Name AS DepartmentsName, Budget
FROM Employees E
INNER JOIN Departments D
ON E.Department = D.ID;
60,000
的部门工作的员工的姓名和姓氏/* Without subquery */
SELECT Employees.Name, LastName
FROM Employees
INNER JOIN Departments
ON Employees.Department = Departments.id
AND Departments.Budget > 60000;
/* With subquery */
SELECT Name, LastName
FROM Employees
WHERE Department IN
(SELECT id FROM Departments WHERE Budget > 60000);
SELECT *
FROM Departments
WHERE Budget >
(
SELECT AVG(Budget)
FROM Departments
);
/* With subquery */
SELECT Name
FROM Departments
WHERE id IN
(
SELECT Department
FROM Employees
GROUP BY Department
HAVING COUNT(*) > 2
);
/* With UNION. This assumes that no two departments have the same name */
SELECT Departments.Name
FROM Employees
INNER JOIN Departments
ON Department = id
GROUP BY Departments.Name
HAVING COUNT(*) > 2;
select name, lastname
from employees
where department = (
select id
from departments
order by budget
limit 1 offset 1);
Quality Assurance
的新部门,预算为40,000
美元,部门代码为11
,在该部门添加一名名为Mary Moore
的员工,SSN为847-21-9811
INSERT INTO Departments
VALUES (11, 'Quality Assurance', 40000);
INSERT INTO Employees
VALUES ('847219811', 'Mary', 'Moore', 11);
10%
UPDATE Departments
SET Budget = Budget * 0.9;
UPDATE Employees
SET Department = 14
WHERE Department = 77;
DELETE
FROM Employees
WHERE Department = 14;
60,000
的部门工作的员工DELETE
FROM Employees
WHERE Department IN
(
SELECT id
FROM Departments
WHERE Budget >= 60000
);
DELETE
FROM Employees;