List of commits:
Subject Hash Author Date (UTC)
Added first project. e851058cc58a9d47ada9970f8b914e798c7d2ce7 caubert 2021-01-27 19:57:12
Few typos. 45ba15cd03fab4388439b617c656f52b2ec96319 caubert 2021-01-26 20:08:24
Small fix in code. 7860e391d0bbe82336b8f05585f846e829d181b1 caubert 2021-01-26 18:55:17
Fixed various bugs. fa76c1e469a4263d7bb7da79532abd1eedcc49be caubert 2021-01-22 19:27:01
First quizz, and fix bug with code displayed. bc9b6bb097e30186805b02dc1cdc5de2d5feabe4 caubert 2021-01-22 19:21:54
Edited the preamble. 364e709107602e163ea9365f25ccf1f5a6bb1914 caubert 2021-01-11 16:00:07
Started to edit notes and add final exam from fall 2020. bb747e27ce08ce17e91913e947614e3057580995 caubert 2021-01-06 22:26:07
Integrated the include-link feature of pandoc-include-code. 3a8f9ededdaa1f05d526742f5d447aaa017e1d1b caubert 2021-01-04 22:52:18
Fixed citeproc. 0d90c7e60e4a4474fd7ded03bb6526ea63a57253 aubert@math.cnrs.fr 2020-12-27 21:33:48
(Finally) updated pandoc and pandoc-numbering. 127c1964a0732b49e14b46fdb0d3f8446e3892d0 aubert@math.cnrs.fr 2020-12-27 21:14:31
Fixed url in comments, avoid them being wrapped. 09a6a78479f24b5749605a4cb7136f8cfbf57d30 aubert@math.cnrs.fr 2020-12-18 18:55:50
Added comments on procedures from code f3e9c2abac41d5de1c7473867c4f688051dec928 aubert@math.cnrs.fr 2020-12-01 15:46:53
Updated mysql connector 228d86db5498aae94a4d162272fa03a84ae9c532 aubert@math.cnrs.fr 2020-12-01 15:09:46
Updated java beautifier 30f4a79f2d911cd0b6a24c31f968f0d23620965f aubert@math.cnrs.fr 2020-12-01 15:07:50
Worked on procedure example from java 998ea14119a5a3f88efc4b0a126177e85151e43d aubert@math.cnrs.fr 2020-12-01 15:06:47
Brief example of calling a procedure from a program. 1054c9d5c83fb956bdd0b8d884d5ce2c8a9a640e aubert@math.cnrs.fr 2020-11-30 19:00:45
Added solution to second exam d8f62ded96991885a96d561db587988d453a28c8 aubert@math.cnrs.fr 2020-11-05 20:35:50
Quick fix on testing semicolons. 7f48d88d2ed69213d803a7736df3d50330cfecd1 aubert@math.cnrs.fr 2020-11-03 14:14:06
Added simple example to test if semicolon are important in SQL querries. 98097fb11558c08bad630fb3351f99ceb6777de7 aubert@math.cnrs.fr 2020-11-03 14:11:22
Updated spots to https. a8daf1768395aa296bf0dd05783dd53c757d5d19 aubert@math.cnrs.fr 2020-10-05 16:18:44
Commit e851058cc58a9d47ada9970f8b914e798c7d2ce7 - Added first project.
Author: caubert
Author date (UTC): 2021-01-27 19:57
Committer name: caubert
Committer date (UTC): 2021-01-27 19:57
Parent(s): 45ba15cd03fab4388439b617c656f52b2ec96319
Signer:
Signing key:
Signing status: N
Tree: b0ada66549fdf2cda5d1e1590ab0ecd9b3ef27af
File Lines added Lines deleted
notes/code/sql/HW_AdvancedFK.sql 15 15
notes/code/sql/HW_CapstoneSol.sql 33 32
notes/code/sql/HW_Certificate.sql 31 29
notes/code/sql/HW_ConstraintsPart1.sql 1 1
notes/code/sql/HW_DBCoffee.sql 13 13
notes/code/sql/HW_Department.sql 1 1
notes/code/sql/HW_Faculty.sql 1 1
notes/code/sql/HW_ProcedureExamples.sql 4 4
notes/code/sql/HW_ProfExample.sql 2 2
notes/code/sql/HW_ResidencySol.sql 26 25
notes/code/sql/HW_ScientificResearchSol.sql 22 20
notes/code/sql/HW_SocialMedia.sql 9 9
notes/code/sql/HW_Storm.sql 27 23
notes/code/sql/HW_TriggerExample.sql 13 12
notes/code/sql/HW_Vaccine.sql 168 0
notes/code/sql/HW_Work.sql 30 30
File notes/code/sql/HW_AdvancedFK.sql changed (mode: 100644) (index 23b22d7..365746b)
... ... CREATE TABLE T2 (
19 19 B1 INT PRIMARY KEY, B1 INT PRIMARY KEY,
20 20 B2 INT, B2 INT,
21 21 -- We can create a "pair" of foreign key in one line, as -- We can create a "pair" of foreign key in one line, as
22 -- follows:
22 -- follows:
23 23 FOREIGN KEY (A1, A2) REFERENCES T1 (A1, A2), FOREIGN KEY (A1, A2) REFERENCES T1 (A1, A2),
24 24 -- We can create a foreign key that references the primary -- We can create a foreign key that references the primary
25 -- key of the table we are currently creating, and
26 -- name
27 -- it,
28 -- as follows:
25 -- key of the table we are currently creating, and
26 -- name
27 -- it,
28 -- as follows:
29 29 CONSTRAINT My_pk_to_T1 FOREIGN KEY (B2) REFERENCES T2 (B1) CONSTRAINT My_pk_to_T1 FOREIGN KEY (B2) REFERENCES T2 (B1)
30 30 ); );
31 31
32 32 -- The benefit of naming our fk constraint is that, if we -- The benefit of naming our fk constraint is that, if we
33 -- violate it, for instance with
34 -- INSERT INTO T2 VALUES (1, 1, 1, 3);
35 -- then the name of the constraint (here
36 -- would be displayed in the error message:
37 -- Cannot add or update a child row: a foreign key
38 -- constraint fails (`db_9_9837c1`.`t2`, CONSTRAINT
39 -- `My_pk_to_T1` FOREIGN KEY (`B2`) REFERENCES `t2`
40 -- end snippet advancedFK
33 -- violate it, for instance with
34 -- INSERT INTO T2 VALUES (1, 1, 1, 3);
35 -- then the name of the constraint (here
36 -- "My_pk_to_T1")
37 -- would be displayed in the error message:
38 -- Cannot add or update a child row: a foreign key
39 -- constraint fails (`db_9_9837c1`.`t2`, CONSTRAINT
40 -- `My_pk_to_T1` FOREIGN KEY (`B2`) REFERENCES `t2`
41 -- (`B1`))
42 -- end snippet advancedFK
File notes/code/sql/HW_CapstoneSol.sql changed (mode: 100644) (index 423d6b7..ddb9c00)
... ... Answer the following short questions based on the model implemented above.
123 123 You can simply answer "True" or "False", or justify your reasoning (e.g. with code). You can simply answer "True" or "False", or justify your reasoning (e.g. with code).
124 124 */ */
125 125 -- 1. Can a project uses multiple programming languages? -- 1. Can a project uses multiple programming languages?
126 -- Yes.
127 -- Yes.
128 -- Yes.
129 --6. Can we know who is working on a project
126 -- Yes.
127 -- 2. Can a student be the leader of multiple
128 -- projects?
129 -- Yes.
130 -- 3. Can multiple projects have the same code name?
131 -- Yes.
132 -- 4. Could Claude simply enter NULL for the value
133 -- of his pproject's code name, since he's undecided?
134 -- No.
135 -- 5. Can a project be created without project
136 -- leader?
137 -- No.
138 -- 6. Can we know who is working on a project
139 -- without being its leader?
140 -- No.
130 141 /* /*
131 142
132 143 II. Relational Model (6 pts.) II. Relational Model (6 pts.)
 
... ... Please, leave them uncommented, unless you can't write them correctly, in which
154 154 The first question is answered as an example. The first question is answered as an example.
155 155 */ */
156 156 -- 0. Write a command that list all the names of the -- 0. Write a command that list all the names of the
157 -- programming languages.
157 -- programming languages.
158 158 SELECT Name SELECT Name
159 159 FROM PROGRAMMING_LANGUAGE; FROM PROGRAMMING_LANGUAGE;
160 160
161 161 -- 1. Write a command that insert a new student in the -- 1. Write a command that insert a new student in the
162 -- STUDENT table.
163 -- (You should invent the values).
162 -- STUDENT table.
163 -- (You should invent the values).
164 164 INSERT INTO STUDENT INSERT INTO STUDENT
165 165 VALUES ( VALUES (
166 166 "Bob", "Bob",
 
... ... VALUES (
169 169 NULL); NULL);
170 170
171 171 -- 2. Write a command that updates the code name of the -- 2. Write a command that updates the code name of the
172 -- project ("Undecided", "9999999999999") to "VR in
173 -- ER".
172 174 UPDATE UPDATE
173 175 PROJECT PROJECT
174 176 SET CodeName = "VR in ER" SET CodeName = "VR in ER"
 
... ... WHERE CodeName = "Undecided"
178 178 AND Leader = "9999999999999"; AND Leader = "9999999999999";
179 179
180 180 -- 3. Write a command that updates the graduation year of the -- 3. Write a command that updates the graduation year of the
181 -- student whose id is "0987654321098" to 2024, and
182 -- the semester to "Fall".
181 183 UPDATE UPDATE
182 184 STUDENT STUDENT
183 185 SET GraduationYear = 2024, SET GraduationYear = 2024,
 
... ... SET GraduationYear = 2024,
187 187 WHERE id = "0987654321098"; WHERE id = "0987654321098";
188 188
189 189 -- 4. Write a command that changes the STUDENT table to make -- 4. Write a command that changes the STUDENT table to make
190 -- it impossible to enter NULL for the first name of
191 -- a student, without changing the primary key.
190 192 ALTER TABLE STUDENT MODIFY FName VARCHAR(50) NOT NULL; ALTER TABLE STUDENT MODIFY FName VARCHAR(50) NOT NULL;
191 193
192 194 -- 5. Write a command that changes the datatype of -- 5. Write a command that changes the datatype of
195 -- GraduationYear to SMALLINT.
193 196 ALTER TABLE STUDENT MODIFY GraduationYear SMALLINT; ALTER TABLE STUDENT MODIFY GraduationYear SMALLINT;
194 197
195 198 -- 6. Write a command that adds an attribute "ReleaseDate" to -- 6. Write a command that adds an attribute "ReleaseDate" to
199 -- the PROJECT table.
196 200 ALTER TABLE PROJECT ALTER TABLE PROJECT
197 201 ADD COLUMN ReleaseDate DATE; ADD COLUMN ReleaseDate DATE;
198 202
199 203 -- 6.bis If you managed to write the previous command -- 6.bis If you managed to write the previous command
204 -- correctly, write a command that sets the release
205 -- date of the project ("Brick Break", "0123456789100")
206 -- to
207 -- the 26th of November 2022.
200 208 UPDATE UPDATE
201 209 PROJECT PROJECT
202 210 SET ReleaseDate = DATE "20221126" SET ReleaseDate = DATE "20221126"
 
... ... WHERE CodeName = "Brick Break"
211 212 AND Leader = "0123456789100"; AND Leader = "0123456789100";
212 213
213 214 -- 7. Write a command that makes it impossible for a student -- 7. Write a command that makes it impossible for a student
215 -- to be the leader in more than one project
216 -- (This command should return an error)
217 -- ALTER TABLE PROJECT ADD UNIQUE (Leader);
File notes/code/sql/HW_Certificate.sql changed (mode: 100644) (index 8461e9e..86ff75c)
... ... SELECT CN
91 91 FROM CERTIFICATE; FROM CERTIFICATE;
92 92
93 93 -- (*.wikimedia.org | *.fsf.org | *.shadytest.org | -- (*.wikimedia.org | *.fsf.org | *.shadytest.org |
94 -- *.wikipedia.org)
95 -- The SN of the organizations whose CN contains
96 -- "Foundation"
94 -- *.wikipedia.org)
95 -- The SN of the organizations whose CN
96 -- contains
97 -- "Foundation"
97 98 SELECT SN SELECT SN
98 99 FROM ORGANIZATION FROM ORGANIZATION
99 100 WHERE CN LIKE "%Foundation%"; WHERE CN LIKE "%Foundation%";
100 101
101 102 -- (01 | 02) -- (01 | 02)
102 -- The CN and expiration date of all the
103 -- that
104 -- expired (assuming we are the 6th of December
103 -- The CN and expiration date of all the
104 -- certificates
105 -- that
106 -- expired (assuming we are the 6th of December
107 -- 2019).
105 108 SELECT CN, SELECT CN,
106 109 Valid_Until Valid_Until
107 110 FROM CERTIFICATE FROM CERTIFICATE
108 111 WHERE Valid_Until < DATE '20191206'; WHERE Valid_Until < DATE '20191206';
109 112
110 113 -- (*.fsf.org, 2019-10-10) -- (*.fsf.org, 2019-10-10)
111 -- The CN of the CA that are not trusted.
114 -- The CN of the CA that are not trusted.
112 115 SELECT CN SELECT CN
113 116 FROM CA FROM CA
114 117 WHERE Trusted IS NOT TRUE; WHERE Trusted IS NOT TRUE;
115 118
116 119 -- (Shady Corp. | NewComer Ltd.) -- (Shady Corp. | NewComer Ltd.)
117 -- The CN of the certificates that are signed by
118 -- that
119 -- is not trusted.
120 -- The CN of the certificates that are signed
121 -- by
122 -- a
123 -- CA
124 -- that
125 -- is not trusted.
120 126 SELECT CERTIFICATE.CN SELECT CERTIFICATE.CN
121 127 FROM CERTIFICATE, FROM CERTIFICATE,
122 128 CA CA
 
... ... WHERE Trusted IS NOT TRUE
128 130 AND CA.SN = CERTIFICATE.Issuer; AND CA.SN = CERTIFICATE.Issuer;
129 131
130 132 -- (Shady Corp. | NewComer Ltd.) -- (Shady Corp. | NewComer Ltd.)
131 -- The number of certificates signed by the CA
132 -- is
133 -- "Let's encrypt".
133 -- The number of certificates signed by the CA
134 -- whose
135 -- CN
136 -- is
137 -- "Let's encrypt".
134 138 SELECT COUNT(CERTIFICATE.SN) AS "Number of certificates signed SELECT COUNT(CERTIFICATE.SN) AS "Number of certificates signed
135 139 by Let's encrypt" by Let's encrypt"
136 140 FROM CERTIFICATE, FROM CERTIFICATE,
 
... ... WHERE CERTIFICATE.Issuer = CA.SN
141 143 AND CA.CN = "Let's encrypt"; AND CA.CN = "Let's encrypt";
142 144
143 145 -- (2) -- (2)
144 -- A table listing the CN of the organizations
145 -- with
146 -- the CN of their certificates.
146 -- A table listing the CN of the organizations
147 -- along
148 -- with
149 -- the CN of their certificates.
147 150 SELECT ORGANIZATION.CN AS Organization, SELECT ORGANIZATION.CN AS Organization,
148 151 CERTIFICATE.CN AS Certificate CERTIFICATE.CN AS Certificate
149 152 FROM ORGANIZATION, FROM ORGANIZATION,
 
... ... FROM ORGANIZATION,
152 154 WHERE CERTIFICATE.Org = ORGANIZATION.SN; WHERE CERTIFICATE.Org = ORGANIZATION.SN;
153 155
154 156 -- ( Wikimedia Foundation, *.wikimedia.org | Free Software -- ( Wikimedia Foundation, *.wikimedia.org | Free Software
155 -- Foundation, *.fsf.org | Free Software
156 -- *.shadytest.org | Wikimedia Foundation ,
157 -- *.wikipedia.org
158 -- )
157 -- Foundation, *.fsf.org | Free Software
158 -- Foundation
159 -- ,
160 -- *.shadytest.org | Wikimedia Foundation ,
161 -- *.wikipedia.org
162 -- )
159 163 /* /*
160 164 DELETE FROM CA WHERE SN = 'A'; DELETE FROM CA WHERE SN = 'A';
161 165 ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails (`HW_Certificate`.`CERTIFICATE`, CONSTRAINT `CERTIFICATE_ibfk_2` FOREIGN KEY (`Issuer`) REFERENCES `CA` (`SN`)) ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails (`HW_Certificate`.`CERTIFICATE`, CONSTRAINT `CERTIFICATE_ibfk_2` FOREIGN KEY (`Issuer`) REFERENCES `CA` (`SN`))
File notes/code/sql/HW_ConstraintsPart1.sql changed (mode: 100644) (index 522c00d..61bee27)
... ... CREATE TABLE HURRICANE (
10 10 WindSpeed INT DEFAULT 76 CHECK (WindSpeed > 74 AND WindSpeed INT DEFAULT 76 CHECK (WindSpeed > 74 AND
11 11 WindSpeed < 500), WindSpeed < 500),
12 12 -- 75mph is the minimum to be considered as a hurricane -- 75mph is the minimum to be considered as a hurricane
13 -- cf. https://www.hwn.org/resources/bws.html
13 -- cf. https://www.hwn.org/resources/bws.html
14 14 Above VARCHAR(25) Above VARCHAR(25)
15 15 ); );
16 16
File notes/code/sql/HW_DBCoffee.sql changed (mode: 100644) (index 4462200..0e4e696)
... ... VALUES (
125 125 3.00); 3.00);
126 126
127 127 -- The following statement raises an error. -- The following statement raises an error.
128 -- INSERT INTO PROVIDER
129 -- VALUES (NULL, "contact@localcof.com");
130 -- ERROR 1048 (23000) at line 68: Column 'Name'
131 -- be
132 -- null
128 -- INSERT INTO PROVIDER
129 -- VALUES (NULL, "contact@localcof.com");
130 -- ERROR 1048 (23000) at line 68: Column 'Name'
131 -- cannot
132 -- be
133 -- null
133 134 INSERT INTO SUPPLY INSERT INTO SUPPLY
134 135 VALUES ( VALUES (
135 136 "Johns & Co.", "Johns & Co.",
136 137 121); 121);
137 138
138 139 -- The following statement raises an error. -- The following statement raises an error.
139 -- -INSERT INTO SUPPLY
140 -- VALUES ("Coffee Unl.", 311, 221);
141 -- ERROR 1136 (21S01): Column count doesn't
142 -- count at row 1
143 -- Rest the changes:
140 -- -INSERT INTO SUPPLY
141 -- VALUES ("Coffee Unl.", 311, 221);
142 -- ERROR 1136 (21S01): Column count doesn't
143 -- match
144 -- value
145 -- count at row 1
146 -- Rest the changes:
144 147 ROLLBACK; ROLLBACK;
145 148
146 149 -- Question 3: -- Question 3:
File notes/code/sql/HW_Department.sql changed (mode: 100644) (index 3ed6152..e7dbf47)
5 5 DROP SCHEMA IF EXISTS HW_Department; DROP SCHEMA IF EXISTS HW_Department;
6 6
7 7 -- Carefull, we are dropping the schema HW_Department if it -- Carefull, we are dropping the schema HW_Department if it
8 -- exists already, and all the data in it.
8 -- exists already, and all the data in it.
9 9 CREATE SCHEMA HW_Department; CREATE SCHEMA HW_Department;
10 10
11 11 -- And then re-creating it. -- And then re-creating it.
File notes/code/sql/HW_Faculty.sql changed (mode: 100644) (index df9432e..5d2d505)
... ... VALUES (
68 68 '19940101', -- Or '940101', '1994-01-01', '94/01/01' '19940101', -- Or '940101', '1994-01-01', '94/01/01'
69 69 '090500', -- Or '09:05:00', '9:05:0', '9:5:0', '090500' '090500', -- Or '09:05:00', '9:05:0', '9:5:0', '090500'
70 70 -- Note also the existence of DATETIME, with 'YYYY-MM-DD -- Note also the existence of DATETIME, with 'YYYY-MM-DD
71 -- HH:MM:SS'
71 -- HH:MM:SS'
72 72 'Apple' -- This is not case-sensitive, oddly enough. 'Apple' -- This is not case-sensitive, oddly enough.
73 73 ); );
File notes/code/sql/HW_ProcedureExamples.sql changed (mode: 100644) (index b287790..ca7ec92)
... ... BEGIN
42 42 END; END;
43 43 $$ $$
44 44 -- This is the delimiter that marks the end of the procedure -- This is the delimiter that marks the end of the procedure
45 -- definition.
45 -- definition.
46 46 DELIMITER ; DELIMITER ;
47 47
48 48 -- Now, we want ";" to be the "natural" delimiter again. -- Now, we want ";" to be the "natural" delimiter again.
 
... ... DELIMITER ;
69 69 SHOW CREATE PROCEDURE STUDENTLOGIN; SHOW CREATE PROCEDURE STUDENTLOGIN;
70 70
71 71 -- This display information about the procedure just created. -- This display information about the procedure just created.
72 -- We can pass quite naturally an argument to
73 -- procedure.
72 -- We can pass quite naturally an argument to
73 -- our
74 -- procedure.
74 75 CALL STUDENTLOGIN ("Test A"); CALL STUDENTLOGIN ("Test A");
75 76
76 77 -- end snippet procedure-3 -- end snippet procedure-3
File notes/code/sql/HW_ProfExample.sql changed (mode: 100644) (index 297da89..9b1ef59)
... ... WHERE DEPARTMENT.Name = "Mathematics"
215 215 AND Department = Code; AND Department = Code;
216 216
217 217 -- end snippet select-project-join-1 -- end snippet select-project-join-1
218 -- start snippet select-project-join-2
218 -- start snippet select-project-join-2
219 219 SELECT Name SELECT Name
220 220 FROM STUDENT, FROM STUDENT,
221 221 GRADE GRADE
 
... ... WHERE Grade > 3.0
223 223 AND STUDENT.Login = GRADE.Login; AND STUDENT.Login = GRADE.Login;
224 224
225 225 -- end snippet select-project-join-2 -- end snippet select-project-join-2
226 -- start snippet select-project-join-3
226 -- start snippet select-project-join-3
227 227 SELECT PROF.Name SELECT PROF.Name
228 228 FROM PROF, FROM PROF,
229 229 DEPARTMENT, DEPARTMENT,
File notes/code/sql/HW_ResidencySol.sql changed (mode: 100644) (index b35d57c..ff1d077)
... ... VALUES (
75 75 the next question. the next question.
76 76 */ */
77 77 -- Exercise 4 -- Exercise 4
78 -- List the rows (i.e., P.2, H.1, or even
79 -- modified by the following statements:
78 -- List the rows (i.e., P.2, H.1, or even
79 -- “none”)
80 -- modified by the following statements:
80 81 START TRANSACTION; START TRANSACTION;
81 82
82 83 UPDATE UPDATE
 
... ... ROLLBACK;
106 106 START TRANSACTION; START TRANSACTION;
107 107
108 108 -- Commented, because it causes an error. -- Commented, because it causes an error.
109 -- DELETE FROM PERSON
110 -- WHERE Birthdate = DATE "1990-02-11";
111 -- None, because of the foreign key and the
112 -- integrity constraint.
113 -- ERROR 1451 (23000): Cannot delete or update a
114 -- row:
115 -- a foreign key constraint fails
116 -- (`HW_RESIDENCY_SOL`.`RESIDENCY`, CONSTRAINT
117 -- `RESIDENCY_ibfk_1` FOREIGN KEY (`Person`)
118 -- `PERSON` (`SSN`))
109 -- DELETE FROM PERSON
110 -- WHERE Birthdate = DATE "1990-02-11";
111 -- None, because of the foreign key and the
112 -- referential
113 -- integrity constraint.
114 -- ERROR 1451 (23000): Cannot delete or update
115 -- a
116 -- parent
117 -- row:
118 -- a foreign key constraint fails
119 -- (`HW_RESIDENCY_SOL`.`RESIDENCY`, CONSTRAINT
120 -- `RESIDENCY_ibfk_1` FOREIGN KEY (`Person`)
121 -- REFERENCES
122 -- `PERSON` (`SSN`))
119 123 ROLLBACK; ROLLBACK;
120 124
121 125 -- end snippet solution4 -- end snippet solution4
 
... ... SELECT Address
131 132 FROM HOUSE; FROM HOUSE;
132 133
133 134 -- … the SSN of the persons whose first name was not -- … the SSN of the persons whose first name was not
134 -- entered in the system (000-00-0000).
135 -- entered in the system (000-00-0000).
135 136 SELECT SSN SELECT SSN
136 137 FROM PERSON FROM PERSON
137 138 WHERE FName IS NULL; WHERE FName IS NULL;
 
... ... SELECT DISTINCT COLOR
141 142 FROM HOUSE; FROM HOUSE;
142 143
143 144 -- … the address of the residency of James Baldwin (123 -- … the address of the residency of James Baldwin (123
144 -- Main St.).
145 -- Main St.).
145 146 SELECT House SELECT House
146 147 FROM RESIDENCY, FROM RESIDENCY,
147 148 PERSON PERSON
 
... ... WHERE PERSON.Fname = "James"
150 151 AND PERSON.SSN = RESIDENCY.Person; AND PERSON.SSN = RESIDENCY.Person;
151 152
152 153 -- … the first name of the oldest person in the database -- … the first name of the oldest person in the database
153 -- (James).
154 -- (James).
154 155 SELECT FName SELECT FName
155 156 FROM PERSON FROM PERSON
156 157 WHERE Birthdate = ( WHERE Birthdate = (
 
... ... WHERE Birthdate = (
159 160 WHERE Birthdate IS NOT NULL); WHERE Birthdate IS NOT NULL);
160 161
161 162 -- … Michael Keal’s principal residency address (123 Main -- … Michael Keal’s principal residency address (123 Main
162 -- St.).
163 -- St.).
163 164 SELECT RESIDENCY.House SELECT RESIDENCY.House
164 165 FROM RESIDENCY, FROM RESIDENCY,
165 166 PERSON PERSON
 
... ... WHERE PERSON.FName = "Michael"
169 170 AND RESIDENCY.PrincipalResidence = TRUE; AND RESIDENCY.PrincipalResidence = TRUE;
170 171
171 172 -- … the (distinct) first and last names of the homeowners -- … the (distinct) first and last names of the homeowners
172 -- (Michael Keal, Mridula Warrier).
173 -- (Michael Keal, Mridula Warrier).
173 174 SELECT DISTINCT (PERSON.FName), SELECT DISTINCT (PERSON.FName),
174 175 PERSON.LName PERSON.LName
175 176 FROM PERSON, FROM PERSON,
 
... ... WHERE SSN IN ( SELECT DISTINCT (RESIDENCY.Person)
186 187 WHERE RESIDENCY.Status = "own"); WHERE RESIDENCY.Status = "own");
187 188
188 189 -- … the SSN of the persons that have the same principal -- … the SSN of the persons that have the same principal
189 -- residency as James Baldwin (000-00-0001).
190 -- residency as James Baldwin (000-00-0001).
190 191 SELECT RoomMate.Person SELECT RoomMate.Person
191 192 FROM RESIDENCY AS James, FROM RESIDENCY AS James,
192 193 RESIDENCY AS RoomMate, RESIDENCY AS RoomMate,
 
... ... WHERE PERSON.FName = "James"
202 203 START TRANSACTION; START TRANSACTION;
203 204
204 205 -- start snippet homonyms -- start snippet homonyms
205 -- If we have homonymns in our database, e.g.
206 -- If we have homonymns in our database, e.g.
206 207 INSERT INTO PERSON INSERT INTO PERSON
207 208 VALUES ( VALUES (
208 209 "A", "A",
 
... ... VALUES (
234 235 "own"); "own");
235 236
236 237 -- Then the query below fails, in the sense that it reports -- Then the query below fails, in the sense that it reports
237 -- the name "A, B" only once.
238 -- the name "A, B" only once.
238 239 SELECT DISTINCT (PERSON.FName), SELECT DISTINCT (PERSON.FName),
239 240 PERSON.LName PERSON.LName
240 241 FROM PERSON, FROM PERSON,
 
... ... WHERE RESIDENCY.Status = "own"
243 244 AND RESIDENCY.Person = PERSON.SSN; AND RESIDENCY.Person = PERSON.SSN;
244 245
245 246 -- A better (and not much more complicated) solution would -- A better (and not much more complicated) solution would
246 -- have been
247 -- have been
247 248 SELECT PERSON.FName, SELECT PERSON.FName,
248 249 PERSON.LName PERSON.LName
249 250 FROM PERSON FROM PERSON
File notes/code/sql/HW_ScientificResearchSol.sql changed (mode: 100644) (index 436dd4f..321817a)
... ... VALUES (
103 103 -- start snippet solution -- start snippet solution
104 104 /* code/sql/HW_ScientificResearchSol.sql */ /* code/sql/HW_ScientificResearchSol.sql */
105 105 -- List the rows affected (updated or deleted) by the -- List the rows affected (updated or deleted) by the
106 -- following commands.
107 -- If no rows are affected because the command would
108 -- would
109 -- violate the entity integrity constraint, the
110 -- referential
111 -- integrity constraint, or if there would be some other
112 -- kind
113 -- of error, please indicate it.
106 114 START TRANSACTION; START TRANSACTION;
107 115
108 116
 
... ... SET SSN = "000000001"
119 121 WHERE Name = "Claire"; WHERE Name = "Claire";
120 122 */ */
121 123 -- ERROR 1062 (23000) at line 106: Duplicate entry '1' for -- ERROR 1062 (23000) at line 106: Duplicate entry '1' for
124 -- key 'PRIMARY'
122 125 ROLLBACK; ROLLBACK;
123 126
124 127 START TRANSACTION; START TRANSACTION;
 
... ... DELETE FROM FUNDINGAGENCY
147 149 WHERE Name = "French-American Cultural Exchange"; WHERE Name = "French-American Cultural Exchange";
148 150 */ */
149 151 -- ERROR 1451 (23000): Cannot delete or update a parent row: -- ERROR 1451 (23000): Cannot delete or update a parent row:
152 -- a foreign key constraint fails
153 -- (`HW_SCIENTIFIC_RESEARCH`.`FUNDS`, CONSTRAINT
154 -- `FUNDS_ibfk_1` FOREIGN KEY (`Agency`) REFERENCES
155 -- `FUNDINGAGENCY` (`Name`) ON UPDATE CASCADE)
150 156 ROLLBACK; ROLLBACK;
151 157
152 158 -- List the name of the funding agencies created after 2000 -- List the name of the funding agencies created after 2000
159 -- ("French-American Cultural Exchange")
153 160 SELECT Name SELECT Name
154 161 FROM FUNDINGAGENCY FROM FUNDINGAGENCY
155 162 WHERE Creation >= 2000; WHERE Creation >= 2000;
156 163
157 164 -- List the code of the projects that contains the word -- List the code of the projects that contains the word
165 -- "Airplanes" ("AA", "BA")
158 166 SELECT CODE SELECT CODE
159 167 FROM PROJECT FROM PROJECT
160 168 WHERE Name LIKE ("%Airplanes%"); WHERE Name LIKE ("%Airplanes%");
161 169
162 170 -- List the number of hours scientists contributed to the -- List the number of hours scientists contributed to the
171 -- project "AA" (18)
163 172 SELECT SUM(Hours) SELECT SUM(Hours)
164 173 FROM CONTRIBUTESTO FROM CONTRIBUTESTO
165 174 WHERE Project = "AA"; WHERE Project = "AA";
166 175
167 176 -- List the code of the projects to which the scientist named -- List the code of the projects to which the scientist named
177 -- Sabine contributed ("AA", "BB")
168 178 SELECT Project SELECT Project
169 179 FROM CONTRIBUTESTO, FROM CONTRIBUTESTO,
170 180 SCIENTIST SCIENTIST
 
... ... WHERE SCIENTIST.Name = "Sabine"
180 182 AND SCIENTIST.SSN = CONTRIBUTESTO.Scientist; AND SCIENTIST.SSN = CONTRIBUTESTO.Scientist;
181 183
182 184 -- Give the name of the projects who benefited from federal -- Give the name of the projects who benefited from federal
185 -- funds ("Advancing Airplanes")
183 186 SELECT PROJECT.Name SELECT PROJECT.Name
184 187 FROM PROJECT, FROM PROJECT,
185 188 FUNDS, FUNDS,
 
... ... WHERE FUNDINGAGENCY.Type = "Federal"
190 192 AND FUNDS.Project = PROJECT.Code; AND FUNDS.Project = PROJECT.Code;
191 193
192 194 -- Give the name of the scientist who contributed to the same -- Give the name of the scientist who contributed to the same
195 -- project as Mike ("Sabine", "James")
193 196 SELECT DISTINCT (Fellow.Name) AS "Mike's fellow" SELECT DISTINCT (Fellow.Name) AS "Mike's fellow"
194 197 FROM SCIENTIST AS Mike, FROM SCIENTIST AS Mike,
195 198 SCIENTIST AS Fellow, SCIENTIST AS Fellow,
 
... ... WHERE Mike.Name = "Mike"
203 205 AND NOT Fellow.Name = "Mike"; AND NOT Fellow.Name = "Mike";
204 206
205 207 -- List the name of the projects that are not funded by an -- List the name of the projects that are not funded by an
208 -- agency ("Better Airplanes", "Better Buildings")
206 209 SELECT DISTINCT (PROJECT.Name) SELECT DISTINCT (PROJECT.Name)
207 210 FROM PROJECT, FROM PROJECT,
208 211 FUNDS FUNDS
 
... ... WHERE NOT PROJECT.Code IN (
212 214 FROM FUNDS); FROM FUNDS);
213 215
214 216 -- Give the name of the scientist who contributed the most -- Give the name of the scientist who contributed the most
217 -- (in terms of hours) to the project named "Advancing
218 -- Airplanes" (Sabine)
215 219 SELECT SCIENTIST.Name SELECT SCIENTIST.Name
216 220 FROM SCIENTIST, FROM SCIENTIST,
217 221 CONTRIBUTESTO CONTRIBUTESTO
File notes/code/sql/HW_SocialMedia.sql changed (mode: 100644) (index 8743579..64bca2e)
... ... VALUES (
75 75 DATE "2019-03-03"); DATE "2019-03-03");
76 76
77 77 -- The first entry means that 2 subscribed to 1, not the -- The first entry means that 2 subscribed to 1, not the
78 -- other way around.
79 -- And similarly for the other entries.
78 -- other way around.
79 -- And similarly for the other entries.
80 80 INSERT INTO VIDEO INSERT INTO VIDEO
81 81 VALUES ( VALUES (
82 82 10, 10,
 
... ... VALUES (
124 124 -- start snippet solution -- start snippet solution
125 125 /* code/sql/HW_SocialMedia.sql */ /* code/sql/HW_SocialMedia.sql */
126 126 -- … the title of all the videos ("My first video!", "My -- … the title of all the videos ("My first video!", "My
127 -- second video!", "My vacations").
127 -- second video!", "My vacations").
128 128 SELECT TITLE SELECT TITLE
129 129 FROM VIDEO; FROM VIDEO;
130 130
131 131 -- … the release date of the video whose title is "My first -- … the release date of the video whose title is "My first
132 -- video!" ("2020-02-02").
132 -- video!" ("2020-02-02").
133 133 SELECT Released SELECT Released
134 134 FROM VIDEO FROM VIDEO
135 135 WHERE Title = "My first video!"; WHERE Title = "My first video!";
136 136
137 137 -- … the ID of the account(s) where the "Name" attribute -- … the ID of the account(s) where the "Name" attribute
138 -- was not given ("2").
138 -- was not given ("2").
139 139 SELECT ID SELECT ID
140 140 FROM ACCOUNT FROM ACCOUNT
141 141 WHERE Name IS NULL; WHERE Name IS NULL;
142 142
143 143 -- … the ID of the videos whose title contains the word -- … the ID of the videos whose title contains the word
144 -- "video" ("10", "20").
144 -- "video" ("10", "20").
145 145 SELECT ID SELECT ID
146 146 FROM VIDEO FROM VIDEO
147 147 WHERE TITLE LIKE "%video%"; WHERE TITLE LIKE "%video%";
 
... ... FROM VIDEO
152 152 WHERE Title REGEXP 'video'; WHERE Title REGEXP 'video';
153 153
154 154 -- … the number of thumbs up for the video with title "My -- … the number of thumbs up for the video with title "My
155 -- vacations" ("1").
155 -- vacations" ("1").
156 156 SELECT COUNT(*) SELECT COUNT(*)
157 157 FROM THUMBS_UP, FROM THUMBS_UP,
158 158 VIDEO VIDEO
 
... ... ORDER BY Released ASC
180 180 LIMIT 1; LIMIT 1;
181 181
182 182 -- … the names of the accounts who gave a thumbs up to the -- … the names of the accounts who gave a thumbs up to the
183 -- video with id 30 ("Bob Ross").
183 -- video with id 30 ("Bob Ross").
184 184 SELECT Name SELECT Name
185 185 FROM ACCOUNT, FROM ACCOUNT,
186 186 THUMBS_UP THUMBS_UP
 
... ... WHERE THUMBS_UP.Video = 30
188 188 AND THUMBS_UP.Account = ACCOUNT.ID; AND THUMBS_UP.Account = ACCOUNT.ID;
189 189
190 190 -- … the ID of the account with the greatest number of -- … the ID of the account with the greatest number of
191 -- subscribers ("2").
191 -- subscribers ("2").
192 192 SELECT Subscribed SELECT Subscribed
193 193 FROM SUBSCRIBE FROM SUBSCRIBE
194 194 GROUP BY Subscribed GROUP BY Subscribed
File notes/code/sql/HW_Storm.sql changed (mode: 100644) (index ab28c40..dbb9929)
... ... VALUES (
36 36 "2017-08-17"); "2017-08-17");
37 37
38 38 -- In the following, the entry gets created, but date is -- In the following, the entry gets created, but date is
39 -- "corrected" to "2017-17-08"!
40 -- INSERT INTO STORM
41 -- VALUES ("Dummy", "Hurricane", 120,
42 -- The error message returned is
43 -- ERROR 1292 (22007) at line 34: Incorrect date
44 -- "2017-17-08" for column
45 -- at
46 -- row 1
47 -- In the following, we explicitely use "DATE",
48 -- since
49 -- the date is incorrect, nothing gets inserted.
50 -- INSERT INTO STORM
51 -- VALUES ("Dummy2", "Hurricane", 120, DATE
52 -- "2017-17-08");
53 -- ERROR 1525 (HY000) at line 40: Incorrect DATE
54 -- "2017-17-08"
55 -- The next one sets NULL for DATE.
39 -- "corrected" to "2017-17-08"!
40 -- INSERT INTO STORM
41 -- VALUES ("Dummy", "Hurricane", 120,
42 -- "2017-17-08");
43 -- The error message returned is
44 -- ERROR 1292 (22007) at line 34: Incorrect
45 -- date
46 -- value:
47 -- "2017-17-08" for column
48 -- `HW_STORM`.`STORM`.`Creation`
49 -- at
50 -- row 1
51 -- In the following, we explicitely use
52 -- "DATE",
53 -- and
54 -- since
55 -- the date is incorrect, nothing gets
56 -- inserted.
57 -- INSERT INTO STORM
58 -- VALUES ("Dummy2", "Hurricane", 120, DATE
59 -- "2017-17-08");
60 -- ERROR 1525 (HY000) at line 40: Incorrect
61 -- DATE
62 -- value:
63 -- "2017-17-08"
64 -- The next one sets NULL for DATE.
56 65 INSERT INTO STORM INSERT INTO STORM
57 66 VALUES ( VALUES (
58 67 "Irma", "Irma",
 
... ... VALUES (
86 90 NULL); NULL);
87 91
88 92 -- This instruction is not using the primary key, is that a -- This instruction is not using the primary key, is that a
89 -- problem?
93 -- problem?
90 94 UPDATE UPDATE
91 95 STATE STATE
92 96 SET Affected_by = "Harvey" SET Affected_by = "Harvey"
File notes/code/sql/HW_TriggerExample.sql changed (mode: 100644) (index 62f9ec9..4e8d8fb)
2 2 DROP SCHEMA IF EXISTS HW_TriggerExample; DROP SCHEMA IF EXISTS HW_TriggerExample;
3 3
4 4 -- To drop only a trigger, you can use -- To drop only a trigger, you can use
5 -- DROP TRIGGER IF EXISTS
6 -- HW_TriggerExample.NUMBER_OF_STUDENT_INC;
7 -- DROP TRIGGER IF EXISTS
8 -- HW_TriggerExample.NUMBER_OF_STUDENT_DEC;
5 -- DROP TRIGGER IF EXISTS
6 -- HW_TriggerExample.NUMBER_OF_STUDENT_INC;
7 -- DROP TRIGGER IF EXISTS
8 -- HW_TriggerExample.NUMBER_OF_STUDENT_DEC;
9 9 CREATE SCHEMA HW_TriggerExample; CREATE SCHEMA HW_TriggerExample;
10 10
11 11 USE HW_TriggerExample; USE HW_TriggerExample;
 
... ... CREATE TRIGGER STUDENT_AVERAGE
83 83 WHERE STUDENT.Login = NEW.Student; WHERE STUDENT.Login = NEW.Student;
84 84
85 85 -- The "NEW" keyword here refers to the "new" entry -- The "NEW" keyword here refers to the "new" entry
86 -- that is being inserted by the INSERT
87 -- triggering
88 -- the trigger.
89 -- end snippet trigger-3
86 -- that is being inserted by the INSERT
87 -- statement
88 -- triggering
89 -- the trigger.
90 -- end snippet trigger-3
90 91 INSERT INTO GRADE INSERT INTO GRADE
91 92 VALUES ( VALUES (
92 93 "A", "A",
 
... ... SELECT *
113 113 FROM STUDENT; FROM STUDENT;
114 114
115 115 -- Tada, all the averages have been computed! -- Tada, all the averages have been computed!
116 -- Note also that the student "C" does not have
117 -- average!
116 -- Note also that the student "C" does not
117 -- have
118 -- an
119 -- average!
File notes/code/sql/HW_Vaccine.sql added (mode: 100644) (index 0000000..91eb7cb)
1 /*
2 CSCI 3410 -- Project #1
3 Name: -- Fill here
4 Date: -- Fill here
5 */
6 /*
7 DO NOT EDIT BELOW
8 */
9 DROP SCHEMA IF EXISTS HW_Vaccine;
10
11 CREATE SCHEMA HW_Vaccine;
12
13 USE HW_Vaccine;
14
15 CREATE TABLE COMPANY (
16 Name VARCHAR(50) PRIMARY KEY,
17 Website VARCHAR(255) CHECK (Website LIKE "https://%")
18 );
19
20 CREATE TABLE DISEASE (
21 Name VARCHAR(50) PRIMARY KEY,
22 Communicable BOOL,
23 -- Whether the disease can be transmitted from a human to
24 -- another.
25 TYPE ENUM ("infectious", "deficiency", "hereditary")
26 );
27
28 CREATE TABLE VACCINE (
29 Name VARCHAR(50) PRIMARY KEY,
30 Manufacturer VARCHAR(50) NOT NULL,
31 FOREIGN KEY (Manufacturer) REFERENCES COMPANY (NAME) ON
32 UPDATE CASCADE
33 );
34
35 CREATE TABLE EFFICACY (
36 DiseaseName VARCHAR(50),
37 VaccineName VARCHAR(50),
38 Efficacy DECIMAl(5, 2),
39 PRIMARY KEY (DiseaseName, VaccineName),
40 FOREIGN KEY (DiseaseName) REFERENCES DISEASE (NAME),
41 FOREIGN KEY (VaccineName) REFERENCES VACCINE (NAME)
42 );
43
44 INSERT INTO COMPANY
45 VALUES (
46 "Moderna",
47 "https://www.modernatx.com/");
48
49 INSERT INTO DISEASE
50 VALUES (
51 "Coronavirus disease 2019",
52 TRUE,
53 "infectious");
54
55 INSERT INTO VACCINE
56 VALUES (
57 "mRNA-1273",
58 "Moderna");
59
60 INSERT INTO EFFICACY
61 VALUES (
62 "Coronavirus disease 2019",
63 "mRNA-1273",
64 94.1);
65
66
67 /*
68 START EDITING
69 */
70 /*
71
72 I. Short Questions (3 pts.)
73
74 Answer the following short questions. In our implementation…
75
76 1. … can two companies have exactly the same name?
77
78 2. … can two companies have the same website?
79
80 3. … can a company not have a website?
81
82 4. … can the same vaccine be manufactured by multiple companies?
83
84 5. … can a vaccine not have a manufacturer?
85
86 6. … can a disease being neither communicable nor not communicable?
87
88 7. … can the same vaccine have different efficacies for different diseases?
89 */
90 /*
91
92 II. Longer Questions (6 pts.)
93
94 Answer the following questions:
95
96 1. What does `CHECK (Website LIKE "https://*")` do?
97
98 2. Why did we picked the `DECIMAl(5,2)` datatype?
99
100 3. What is the benefit / are the benefits of having a separate EFFICACY table over having something like
101
102 CREATE TABLE VACCINE(
103 Name VARCHAR(50) PRIMARY KEY,
104 Manufacturer VARCHAR(50),
105 Disease VARCHAR(50),
106 Efficacy DECIMAl(5,2),
107 FOREIGN KEY (Manufacturer) REFERENCES COMPANY (Name)
108 );
109
110 ?
111 */
112 /*
113
114 III. Relational Model (6 pts.)
115
116 Draw the relational model corresponding to this code.
117 You can hand-draw it and join a scan or a picture, or simply hand me back a sheet.
118 */
119 /*
120
121 IV. Simple Commands (5 pts.)
122
123 Below, you are asked to write commands that perform various actions.
124 Please, leave them uncommented, unless
125 - you can not write them correctly, but want to share your attempt,
126 - it is specified that it should return an error.
127
128 The first question is answered as an example.
129 */
130 -- 0. Write a command that list the names of
131 -- all the diseases.
132 SELECT Name
133 FROM DISEASE;
134
135 -- 1. Write a command that insert "Pfizer" in the
136 -- COMPANY table (you can make up the website or look it)
137
138 -- 2. Write a command that insert the "Pfizer-BioNTech
139 -- COVID-19 Vaccine" in the VACCINE table, and a command
140 -- that store the efficacy of that vaccine against
141 -- the "Coronavirus disease 2019" disease
142 -- (you can make up the values or look them up).
143
144
145 -- 3. Write a command that updates the name of the
146 -- company "Moderna" to "Moderna, Inc." everywhere.
147
148
149 -- 4. Write a command that lists the name of all the
150 -- companies.
151
152
153 -- 5. Write a command that deletes the "Coronavirus disease
154 -- 2019" entry from the DISEASE table (if only!).
155
156
157 -- This command should return an error. Explain it and leave
158 -- the command commented.
159
160
161 -- 6. Write two commands: one that adds "physiological" to
162 -- the possible types of diseases, and one that inserts
163 -- a physiological disease in the DISEASE table.
164
165
166 -- 7 (difficult). Write a command that return the list of
167 -- all the companies that manufacture a
168 -- vaccine against "Coronavirus disease 2019".
File notes/code/sql/HW_Work.sql changed (mode: 100644) (index af49feb..ac59c97)
... ... VALUES (
100 100 So, "Successful insertion". So, "Successful insertion".
101 101 */ */
102 102 -- The following statement raises an error. -- The following statement raises an error.
103 -- INSERT INTO AUTHOR
104 -- VALUES ("Mary B.", "mb@fai.fr", NULL);
103 -- INSERT INTO AUTHOR
104 -- VALUES ("Mary B.", "mb@fai.fr", NULL);
105 105 /* /*
106 106 ERROR 1136 (21S01): Column count doesn't match value count at row 1 ERROR 1136 (21S01): Column count doesn't match value count at row 1
107 107 So, "Other kind of error". So, "Other kind of error".
108 108 */ */
109 109 -- The following statement raises an error. -- The following statement raises an error.
110 -- INSERT INTO WORK
111 -- VALUES ("My Life", "Claude A.");
110 -- INSERT INTO WORK
111 -- VALUES ("My Life", "Claude A.");
112 112 /* /*
113 113 ERROR 1452 (23000): Cannot add or update a child row: a foreign key constraint fails ERROR 1452 (23000): Cannot add or update a child row: a foreign key constraint fails
114 114 (`HW_EXAM_1`.`WORK`, CONSTRAINT `WORK_ibfk_1` FOREIGN KEY (`Author`) REFERENCES `AUTHOR` (`Name`) (`HW_EXAM_1`.`WORK`, CONSTRAINT `WORK_ibfk_1` FOREIGN KEY (`Author`) REFERENCES `AUTHOR` (`Name`)
 
... ... VALUES (
128 128 So, "Successful insertion". So, "Successful insertion".
129 129 */ */
130 130 -- The following statement raises an error. -- The following statement raises an error.
131 -- INSERT INTO AUTHOR
132 -- VALUES ("Virginia W.", "alt@isp.net");
131 -- INSERT INTO AUTHOR
132 -- VALUES ("Virginia W.", "alt@isp.net");
133 133 /* /*
134 134 ERROR 1062 (23000): Duplicate entry 'Virginia W.' for key 'PRIMARY' ERROR 1062 (23000): Duplicate entry 'Virginia W.' for key 'PRIMARY'
135 135 So, "Entity integrity constraint". So, "Entity integrity constraint".
 
... ... WHERE Title = "What to eat";
175 175 Does not change any row. Does not change any row.
176 176 */ */
177 177 -- The following statement raises an error. -- The following statement raises an error.
178 -- DELETE FROM AUTHOR
179 -- WHERE Name = "Virginia W.";
178 -- DELETE FROM AUTHOR
179 -- WHERE Name = "Virginia W.";
180 180 /* /*
181 181 ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails
182 182 (`HW_EXAM_1`.`BOOK`, CONSTRAINT `BOOK_ibfk_1` FOREIGN KEY (`Work`) REFERENCES `WORK` (`Title`) ON UPDATE CASCADE) (`HW_EXAM_1`.`BOOK`, CONSTRAINT `BOOK_ibfk_1` FOREIGN KEY (`Work`) REFERENCES `WORK` (`Title`) ON UPDATE CASCADE)
 
... ... WHERE Title = "What to eat";
185 185 ROLLBACK; ROLLBACK;
186 186
187 187 -- We go back to the previous state. -- We go back to the previous state.
188 -- You can now assume that there is more data
189 -- we
190 -- inserted, if that helps you. Write a command
191 -- selects
192 -- …
193 -- We insert some dummy values for this next
188 -- You can now assume that there is more data
189 -- than
190 -- what
191 -- we
192 -- inserted, if that helps you. Write a command
193 -- that
194 -- selects
195 -- …
196 -- We insert some dummy values for this next
197 -- part.
194 198 INSERT INTO WORK INSERT INTO WORK
195 199 VALUES ( VALUES (
196 200 "My Life", "My Life",
 
... ... SELECT Price
232 232 FROM EBOOK; FROM EBOOK;
233 233
234 234 -- … the (distinct) names of the authors who have authored -- … the (distinct) names of the authors who have authored
235 -- a piece of work.
235 -- a piece of work.
236 236 SELECT DISTINCT Author SELECT DISTINCT Author
237 237 FROM WORK; FROM WORK;
238 238
 
... ... SELECT MAX(Price)
258 258 FROM BOOK; FROM BOOK;
259 259
260 260 -- … the number of pieces of work written by the author -- … the number of pieces of work written by the author
261 -- whose name is “Virginia W.”.
261 -- whose name is “Virginia W.”.
262 262 SELECT COUNT(*) SELECT COUNT(*)
263 263 FROM WORK FROM WORK
264 264 WHERE WORK.Author = "Virginia W."; WHERE WORK.Author = "Virginia W.";
265 265
266 266 -- … the email of the author who wrote the piece of work -- … the email of the author who wrote the piece of work
267 -- called “My Life”.
267 -- called “My Life”.
268 268 SELECT Email SELECT Email
269 269 FROM AUTHOR, FROM AUTHOR,
270 270 WORK WORK
 
... ... WHERE WORK.Title = "My Life"
272 272 AND WORK.Author = AUTHOR.Name; AND WORK.Author = AUTHOR.Name;
273 273
274 274 -- the isbn(s) of the book containing a work written by the -- the isbn(s) of the book containing a work written by the
275 -- author whose email is "vw@isp.net".
275 -- author whose email is "vw@isp.net".
276 276 SELECT ISBN SELECT ISBN
277 277 FROM BOOK, FROM BOOK,
278 278 WORK, WORK,
 
... ... WHERE
300 300 they are both given the title "BANNED", which violates the unicity of value in primary keys. they are both given the title "BANNED", which violates the unicity of value in primary keys.
301 301 */ */
302 302 -- Write one or multiple commands that would delete the work -- Write one or multiple commands that would delete the work
303 -- whose title is “My Life”, as well as all
304 -- books
305 -- and ebooks versions of it.
306 -- The following statement raises an error.
307 -- DELETE FROM WORK
308 -- WHERE Title = "My Life";
303 -- whose title is “My Life”, as well as all
304 -- of
305 -- the
306 -- books
307 -- and ebooks versions of it.
308 -- The following statement raises an error.
309 -- DELETE FROM WORK
310 -- WHERE Title = "My Life";
309 311 /* /*
310 312 Fails Fails
311 313 ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails
Hints:
Before first commit, do not forget to setup your git environment:
git config --global user.name "your_name_here"
git config --global user.email "your@email_here"

Clone this repository using HTTP(S):
git clone https://rocketgit.com/user/caubert/CSCI_3410

Clone this repository using ssh (do not forget to upload a key first):
git clone ssh://rocketgit@ssh.rocketgit.com/user/caubert/CSCI_3410

Clone this repository using git:
git clone git://git.rocketgit.com/user/caubert/CSCI_3410

You are allowed to anonymously push to this repository.
This means that your pushed commits will automatically be transformed into a merge request:
... clone the repository ...
... make some changes and some commits ...
git push origin main