File notes/code/sql/HW_ScientificResearch.sql added (mode: 100644) (index 0000000..408fa6e) |
|
1 |
|
/* code/sql/HW_SCIENTIFIC_RESEARCH.sql */ |
|
2 |
|
|
|
3 |
|
|
|
4 |
|
DROP SCHEMA IF EXISTS HW_SCIENTIFIC_RESEARCH; |
|
5 |
|
CREATE SCHEMA HW_SCIENTIFIC_RESEARCH; |
|
6 |
|
USE HW_SCIENTIFIC_RESEARCH; |
|
7 |
|
|
|
8 |
|
|
|
9 |
|
CREATE TABLE SCIENTIST ( |
|
10 |
|
SSN INT PRIMARY KEY, |
|
11 |
|
Name VARCHAR(30) NOT NULL |
|
12 |
|
); |
|
13 |
|
|
|
14 |
|
CREATE TABLE PROJECT ( |
|
15 |
|
Code CHAR(4) PRIMARY KEY, |
|
16 |
|
Name VARCHAR(150) NOT NULL |
|
17 |
|
); |
|
18 |
|
|
|
19 |
|
CREATE TABLE CONTRIBUTESTO ( |
|
20 |
|
Scientist INT, |
|
21 |
|
Project CHAR(4), |
|
22 |
|
Hours INT NOT NULL CHECK (Hours > 0), |
|
23 |
|
PRIMARY KEY (Scientist, Project), |
|
24 |
|
FOREIGN KEY (Scientist) REFERENCES SCIENTIST(SSN), |
|
25 |
|
FOREIGN KEY (Project) REFERENCES PROJECT(Code) |
|
26 |
|
ON DELETE CASCADE |
|
27 |
|
ON UPDATE CASCADE |
|
28 |
|
); |
|
29 |
|
|
|
30 |
|
CREATE TABLE FUNDINGAGENCY ( |
|
31 |
|
Name VARCHAR(150) PRIMARY KEY, |
|
32 |
|
Type ENUM("State", "Federal", "Foundation"), |
|
33 |
|
Creation YEAR |
|
34 |
|
); |
|
35 |
|
|
|
36 |
|
CREATE TABLE FUNDS ( |
|
37 |
|
Agency VARCHAR(150), |
|
38 |
|
Project CHAR(4), |
|
39 |
|
Amount DECIMAL(12, 2), |
|
40 |
|
FOREIGN KEY (Agency) REFERENCES FUNDINGAGENCY(Name) |
|
41 |
|
ON UPDATE CASCADE |
|
42 |
|
ON DELETE RESTRICT, |
|
43 |
|
FOREIGN KEY (Project) REFERENCES PROJECT(Code) |
|
44 |
|
); |
|
45 |
|
|
|
46 |
|
|
|
47 |
|
INSERT INTO SCIENTIST VALUES |
|
48 |
|
("000000000", "Mike"), -- S.1 |
|
49 |
|
("000000001", "Sabine"), -- S.2 |
|
50 |
|
("000000002", "James"), -- S.3 |
|
51 |
|
("000000003", "Emily"), -- S.4 |
|
52 |
|
("000000004", "Claire"); -- S.5 |
|
53 |
|
|
|
54 |
|
INSERT INTO PROJECT VALUES |
|
55 |
|
("AA", "Advancing Airplanes"), -- P.1 |
|
56 |
|
("BA", "Better Airplanes"), -- P.2 |
|
57 |
|
("BB", "Better Buildings"), -- P.3 |
|
58 |
|
("CC", "Creative Creation"); -- P.4 |
|
59 |
|
|
|
60 |
|
INSERT INTO CONTRIBUTESTO VALUES |
|
61 |
|
("000000001", "AA", 12), -- C.1 |
|
62 |
|
("000000001", "BB", 10), -- C.2 |
|
63 |
|
("000000002", "AA", 5), -- C.3 |
|
64 |
|
("000000003", "BA", 3), -- C.4 |
|
65 |
|
("000000000", "BB", 1), -- C.5 |
|
66 |
|
("000000000", "AA", 1); -- C.6 |
|
67 |
|
|
|
68 |
|
INSERT INTO FUNDINGAGENCY VALUES |
|
69 |
|
("National Science Foundation", "Federal", 1950), -- FA.1 |
|
70 |
|
("French-American Cultural Exchange", "Foundation", 2017); -- FA.2 |
|
71 |
|
|
|
72 |
|
INSERT INTO FUNDS VALUES |
|
73 |
|
("National Science Foundation", "AA", 100000), -- F.1 |
|
74 |
|
("French-American Cultural Exchange", "CC", 10000); -- F.2 |
|
75 |
|
|
|
76 |
|
-- List the name of the funding agencies created after 2000 ("French-American Cultural Exchange") |
|
77 |
|
SELECT Name FROM FUNDINGAGENCY WHERE Creation >= 2000; |
|
78 |
|
|
|
79 |
|
-- List the code of the projects that contains the word "Airplanes" ("AA", "BA") |
|
80 |
|
SELECT CODE FROM PROJECT WHERE Name LIKE ("%Airplanes%"); |
|
81 |
|
|
|
82 |
|
-- List the number of hours scientists contributed to the project "AA" (18) |
|
83 |
|
SELECT SUM(Hours) FROM CONTRIBUTESTO WHERE Project = "AA"; |
|
84 |
|
|
|
85 |
|
-- List the code of the projects to which the scientist named Sabine contributed ("AA", "BB") |
|
86 |
|
SELECT Project FROM CONTRIBUTESTO, SCIENTIST WHERE SCIENTIST.Name = "Sabine" AND SCIENTIST.SSN = CONTRIBUTESTO.Scientist; |
|
87 |
|
|
|
88 |
|
-- Give the name of the projects who benefited from federal funds ("Advancing Airplanes") |
|
89 |
|
SELECT PROJECT.Name FROM PROJECT, FUNDS, FUNDINGAGENCY WHERE FUNDINGAGENCY.Type = "Federal" AND FUNDINGAGENCY.Name = FUNDS.Agency AND FUNDS.Project = PROJECT.Code; |
|
90 |
|
|
|
91 |
|
-- Give the name of the scientist who contributed to the same project as Mike ("Sabine", "James") |
|
92 |
|
SELECT DISTINCT(Fellow.Name) AS "Mike's fellow" FROM SCIENTIST AS Mike, SCIENTIST AS Fellow, CONTRIBUTESTO AS A, CONTRIBUTESTO AS B WHERE Mike.Name = "Mike" AND Mike.SSN = A.Scientist AND A.Project = B.Project AND B.Scientist = Fellow.SSN AND NOT Fellow.Name = "Mike"; |
|
93 |
|
|
|
94 |
|
-- List the name of the projects that are not funded by an agency ("Better Airplanes", "Better Buildings") |
|
95 |
|
SELECT DISTINCT(PROJECT.Name) FROM PROJECT, FUNDS WHERE NOT PROJECT.Code IN (SELECT FUNDS.Project FROM FUNDS); |
|
96 |
|
|
|
97 |
|
-- Give the name of the scientist who contributed the most (in terms of hours) to the project named "Advancing Airplanes" (Sabine) |
|
98 |
|
SELECT SCIENTIST.Name FROM SCIENTIST, CONTRIBUTESTO WHERE CONTRIBUTESTO.Hours >= (SELECT MAX(Hours) FROM CONTRIBUTESTO, PROJECT WHERE PROJECT.Name = "Advancing Airplanes" AND PROJECT.Code = CONTRIBUTESTO.Project) AND CONTRIBUTESTO.Scientist = SCIENTIST.SSN; |
|
99 |
|
|
|
100 |
|
|
|
101 |
|
-- List the rows affected (updated or deleted) by the following commands. |
|
102 |
|
-- If no rows are affected because the command would would violate the entity integrity constraint, the referential integrity constraint, or if there would be some other kind of error, please indicate it. |
|
103 |
|
|
|
104 |
|
|
|
105 |
|
START TRANSACTION; |
|
106 |
|
UPDATE SCIENTIST SET SSN = "000000001" WHERE Name = "Claire"; |
|
107 |
|
-- ERROR 1062 (23000) at line 106: Duplicate entry '1' for key 'PRIMARY' |
|
108 |
|
ROLLBACK; |
|
109 |
|
|
|
110 |
|
|
|
111 |
|
START TRANSACTION; |
|
112 |
|
UPDATE FUNDINGAGENCY SET Name = "NSF" WHERE Name = "National Science Foundation"; |
|
113 |
|
SELECT * FROM FUNDINGAGENCY; -- FA. 1 |
|
114 |
|
SELECT * FROM FUNDS; -- F.1 |
|
115 |
|
ROLLBACK; |
|
116 |
|
|
|
117 |
|
|
|
118 |
|
START TRANSACTION; |
|
119 |
|
DELETE FROM FUNDINGAGENCY WHERE Name = "French-American Cultural Exchange"; |
|
120 |
|
-- ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails (`HW_SCIENTIFIC_RESEARCH`.`FUNDS`, CONSTRAINT `FUNDS_ibfk_1` FOREIGN KEY (`Agency`) REFERENCES `FUNDINGAGENCY` (`Name`) ON UPDATE CASCADE) |
|
121 |
|
ROLLBACK; |
|
122 |
|
|
|
123 |
|
|