List of commits:
Subject Hash Author Date (UTC)
Added the first exam of Fall 2019 694ee6905435d3ace98fac02a1d9a158ec0dc205 aubert@math.cnrs.fr 2019-09-24 19:00:32
Adding a link to the Known_Bugs for an example of TOC that follows the scrolling d48fae1dfe47f40ea7fe93c283d424741b694303 aubert@math.cnrs.fr 2019-09-19 19:30:11
Fixing css and bug descrition. 7af0904a2d3356988d3661aef8b4f8b61d84660a aubert@math.cnrs.fr 2019-09-17 17:04:38
Some notes about the bugs with css. a68fe8d8974ee19a585e9c9b77519a918d3795ee aubert@math.cnrs.fr 2019-09-17 16:58:10
Adding some bugs to the report. 50e2dc7eca8e2dcd20e8f9e06eba76e54bd52114 aubert@math.cnrs.fr 2019-09-17 16:20:58
Added quizz 2 a57781924233353363e5cc9b8d6b7d88a0a735b6 aubert@math.cnrs.fr 2019-09-17 12:45:36
Adding quiz #2, correcting a few typo in SQL chapter. 16e6aee0be154245b472c77fb2d6a486dd07ef38 aubert@math.cnrs.fr 2019-09-16 19:58:53
Quick changes in the first SQL part: check is actually taken into account! b62ed769ef0ebd96ea91e3053246e142b73d524c aubert@math.cnrs.fr 2019-09-09 16:26:17
Added quiz #1 of Fall 2019, plus minor corrections. a5498523b05cb246ce58b05a8951b833a0b0e699 aubert@math.cnrs.fr 2019-08-29 16:23:07
Adding a figure for a quizz, and a possible bug to the list. 6e83297ccb9678296993e605b2f35d0b13a97523 aubert@math.cnrs.fr 2019-08-27 16:20:35
Changed the monospace font, updated instructions to install mariaDB. 3dc6162733e0a373205012869c1ee068ef3e5c91 aubert@math.cnrs.fr 2019-08-16 18:56:37
Few patches to prepare for Fall 2019. 545561b3d47dfe9bff2436f8f2b7e32572cd808a aubert@math.cnrs.fr 2019-08-07 17:12:26
Editing the cycle of design picture 9bd1c3190a71202b88011b831161cf9d6a365237 aubert@math.cnrs.fr 2019-08-07 16:13:03
Test c742ba7590d59e2941f9fa197c9d009d5c642e76 au 2019-07-31 23:56:14
Minor fix in Known bugs and contrib. 19f3adfa1f88e6d12e94868f4eab0b5838d05eb6 aubert@math.cnrs.fr 2019-07-29 20:51:14
Commit 2ed1a8532cbdae46d3feb99cf52f23f2afa144ec aubert@math.cnrs.fr 2019-07-29 19:01:36
Adding the final to the notes. 0e8848a3e67ec49bab5b767e25d6099fd218e417 aubert@math.cnrs.fr 2019-05-20 14:44:54
Added the solution to one of the problem from Exam #2. 625545a335c5dc7b7303355088a3abba999fdf40 aubert@math.cnrs.fr 2019-05-06 16:59:50
Added a solution to one of the problem of Exam #2, and added the last quiz. 4e0ee25d509412e5e455d9ad4c98f7aad8c5a354 aubert@math.cnrs.fr 2019-04-19 15:14:10
A few glitches in the first java programs patched, added the alternative version to the source. 48611244d21515269bae041dc2535b7e08fb5877 aubert@math.cnrs.fr 2019-04-04 22:05:03
Commit 694ee6905435d3ace98fac02a1d9a158ec0dc205 - Added the first exam of Fall 2019
Author: aubert@math.cnrs.fr
Author date (UTC): 2019-09-24 19:00
Committer name: aubert@math.cnrs.fr
Committer date (UTC): 2019-09-24 19:00
Parent(s): d48fae1dfe47f40ea7fe93c283d424741b694303
Signing key:
Tree: ae9ba0c2ca47cfc78a5e114823635ca31e0bef6c
File Lines added Lines deleted
notes/code/sql/WORK.sql 57 0
notes/code/sql/WORK_SOL.sql 138 0
notes/fig/rel_mod/UNIVERSITIES.tex 50 0
notes/fig/rel_mod/WORK.tex 48 0
notes/lectures_notes.md 136 9
File notes/code/sql/WORK.sql added (mode: 100644) (index 0000000..a7f5c61)
1 /* code/sql/WORK.sql */
2
3 DROP SCHEMA IF EXISTS HW_WORK;
4 CREATE SCHEMA HW_WORK;
5 USE HW_WORK;
6
7 CREATE TABLE AUTHOR(
8 Name VARCHAR(30) PRIMARY KEY,
9 Email VARCHAR(30)
10 );
11
12 CREATE TABLE WORK(
13 Title VARCHAR(30) PRIMARY KEY,
14 Author VARCHAR(30),
15 FOREIGN KEY (Author)
16 REFERENCES AUTHOR(Name)
17 ON DELETE CASCADE
18 ON UPDATE CASCADE
19 );
20
21
22 CREATE TABLE BOOK(
23 ISBN INT PRIMARY KEY,
24 Work VARCHAR(30),
25 Published DATE,
26 Price DECIMAL(10, 2),
27 FOREIGN KEY (Work)
28 REFERENCES WORK(Title)
29 ON DELETE RESTRICT
30 ON UPDATE CASCADE
31 );
32
33 CREATE TABLE EBOOK(
34 ISBN INT PRIMARY KEY,
35 Work VARCHAR(30),
36 Published DATE,
37 Price DECIMAL(10, 2),
38 FOREIGN KEY (Work)
39 REFERENCES WORK(Title)
40 ON DELETE RESTRICT
41 ON UPDATE CASCADE
42 );
43
44 INSERT INTO AUTHOR VALUES
45 ("Virginia W.", "vw@isp.net"), -- A.1
46 ("Paul B.", "pb@isp.net"), -- A.2
47 ("Samantha T.", "st@fai.fr") -- A.3
48 ;
49 INSERT INTO WORK VALUES
50 ("What to eat", "Virginia W.") -- W.1
51 ;
52 INSERT INTO BOOK VALUES
53 (15155627, "What to eat", DATE'20170219', 12.89) -- B.1
54 ;
55 INSERT INTO EBOOK VALUES
56 (15155628, "What to eat", DATE'20170215', 9.89) -- E.1
57 ;
File notes/code/sql/WORK_SOL.sql added (mode: 100644) (index 0000000..ed5df5b)
1 /* code/sql/WORK_SOL.sql */
2
3 -- For this code to work, you need to execute
4 -- the code in
5 -- code/sql/WORK.sql
6 -- first.
7
8
9
10 /*
11 *
12 * Determine if the following insertion statements would violate the the Entity integrity constraint, the Referential integrity constraint, if there would be some Other kind of error, or if it would result in uccessful insertion.
13 *
14 */
15
16 START TRANSACTION; -- We don't want to perform the actual insertions.
17
18 INSERT INTO EBOOK VALUES(0, NULL, 20180101, 0);
19 -- Query OK, 1 row affected (0.003 sec)
20 -- So, "Successful insertion".
21
22 INSERT INTO AUTHOR VALUES("Mary B.", "mb@fai.fr", NULL);
23 -- ERROR 1136 (21S01): Column count doesn't match value count at row 1
24 -- So, "Other kind of error".
25
26 INSERT INTO WORK VALUES("My Life", "Claude A.");
27 -- ERROR 1452 (23000): Cannot add or update a child row: a foreign key constraint fails (`HW_EXAM_1`.`WORK`, CONSTRAINT `WORK_ibfk_1` FOREIGN KEY (`Author`) REFERENCES `AUTHOR` (`Name`) ON DELETE CASCADE ON UPDATE CASCADE)
28 -- So, "Referential integrity constraint"
29
30 INSERT INTO BOOK VALUES(00000000, NULL, DATE'20001225', 90.9);
31 -- Query OK, 1 row affected (0.000 sec)
32 -- So, "Successful insertion".
33
34 INSERT INTO AUTHOR VALUES("Virginia W.", "alt@isp.net");
35 -- ERROR 1062 (23000): Duplicate entry 'Virginia W.' for key 'PRIMARY'
36 -- So, "Entity integrity constraint".
37
38 ROLLBACK; -- We go back to the previous state.
39
40
41
42
43 /*
44 *
45 * List the rows (i.e., A.2, W.1, etc.) modified by the following statements (be careful about the conditions on foreign keys!):
46 *
47 */
48
49
50 START TRANSACTION; -- We don't want to perform the following operations.
51
52 UPDATE AUTHOR SET Email = 'Deprecated' WHERE Email LIKE '%isp.net';
53 -- Query OK, 2 rows affected (0.010 sec)
54 -- Rows matched: 2 Changed: 2 Warnings: 0
55 -- This changed A.1 and A.2
56
57 UPDATE WORK SET Title = "How to eat" WHERE Title = "What to eat";
58 -- Rows matched: 1 Changed: 1 Warnings: 0
59 -- SQL returns only the number of row changed in the WORK table,
60 -- but other rows have been changed as well.
61 -- This changed W.1, B.1, E.1.
62
63 DELETE FROM WORK;
64 -- ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails (`HW_EXAM_1`.`BOOK`, CONSTRAINT `BOOK_ibfk_1` FOREIGN KEY (`Work`) REFERENCES `WORK` (`Title`) ON UPDATE CASCADE)
65 -- Does not change any row.
66
67 DELETE FROM AUTHOR WHERE Name = "Virginia W.";
68 -- ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails (`HW_EXAM_1`.`BOOK`, CONSTRAINT `BOOK_ibfk_1` FOREIGN KEY (`Work`) REFERENCES `WORK` (`Title`) ON UPDATE CASCADE)
69 -- Does not change any row.
70
71 ROLLBACK; -- We go back to the previous state.
72
73 /*
74 *
75 * You can now assume that there is more data than what we inserted, if that helps you. Write a command that selects …
76 *
77 */
78
79 -- We insert some dummy values for this next part.
80 INSERT INTO WORK VALUES("My Life", "Paul B."), ("What to eat, 2", "Virginia W.");
81 INSERT INTO BOOK VALUES(15355627, "My Life", DATE'20180219', 15.00), (12912912, "What to eat, 2", DATE'20200101', 13);
82 INSERT INTO EBOOK VALUES(15150628, "My Life", DATE'20190215', 10.89), (42912912, "What to eat, 2", DATE'20200115', 12);
83
84 -- … the price of all the ebooks.
85 SELECT Price FROM EBOOK;
86
87 -- … the (distinct) names of the authors who have authored a piece of work.
88 SELECT DISTINCT Author FROM WORK;
89
90 -- … the name of the authors using fai.fr for their email.
91 SELECT Name FROM AUTHOR WHERE Email LIKE '%fai.fr';
92
93 -- … the price of the ebooks published after 2018.
94 SELECT Price FROM BOOK WHERE Published >= 20180101;
95 -- Note that
96 -- SELECT Price FROM BOOK WHERE Published > 2018;
97 -- would return all the prices, along with a warning:
98 -- Incorrect datetime value: '2018'
99
100 -- … the price of the most expensive book.
101 SELECT MAX(Price) FROM BOOK;
102
103 -- … the number of pieces of work written by the author whose name is “Virginia W.”.
104 SELECT COUNT(*) FROM WORK WHERE WORK.Author = "Virginia W.";
105
106 -- … the email of the author who wrote the piece of work called “My Life”.
107 SELECT Email FROM AUTHOR, WORK WHERE WORK.Title = "My Life" AND WORK.Author = AUTHOR.Name;
108
109 -- the isbn(s) of the book containing a work written by the author whose email is "vw@isp.net".
110 SELECT ISBN FROM BOOK, WORK, AUTHOR WHERE AUTHOR.Email = "vw@isp.net" AND WORK.Author = AUTHOR.Name AND BOOK.Work = WORK.Title;
111
112 /*
113 *
114 * Write a command that updates the title of all the pieces of work written by the author whose name is “Virginia W. to”BANNED". Is there any reason for this command to be rejected by the system? If yes, explain which one.
115 *
116 */
117
118 UPDATE WORK SET Title = "BANNED" WHERE Author = "Virginia W.";
119 -- Does not give an error with the that we currently have.
120 -- However, since "Title" is the primary key in the WORK table, if Virginia W. had authored two pieces of work or more, then this command would give an error.
121
122 /*
123 *
124 * Write one or multiple commands that would delete the work whose title is “My Life”, as well as all of the books and ebooks versions of it.
125 *
126 */
127
128 DELETE FROM WORK WHERE Title = "My Life";
129 -- Fails
130 -- ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails (`HW_EXAM_1`.`BOOK`, CONSTRAINT `BOOK_ibfk_1` FOREIGN KEY (`Work`) REFERENCES `WORK` (`Title`) ON UPDATE CASCADE)
131 -- We have to first delete the corresponding publications:
132
133 DELETE FROM BOOK WHERE Work = "My Life";
134 DELETE FROM EBOOK WHERE Work = "My Life";
135 -- And then we can delete the work:
136 DELETE FROM WORK WHERE Title = "My Life";
137 -- And, no, we cannot delete "simply" from multiple tables in one command.
138 -- Some workaround exists, cf. https://stackoverflow.com/q/1233451/ .
File notes/fig/rel_mod/UNIVERSITIES.tex added (mode: 100644) (index 0000000..507c594)
1 \documentclass[border=20pt]{standalone}
2 \input{template.def}
3
4 % UNIVERSITY (Name (PK), Website)
5 % CAMPUS (Address (PK), University (FK to UNIVERSITY.Name))
6 % DEPARTMENT (Code (PK), Contact, CreationDate, University (FK to UNIVERSITY.Name))
7 % COURSE (Name (PK), CreditHours)
8 % OFFERING (Department (PK, FK to DEPARTMENT.Name), Course (PK, FK to COURSE.Name), Code)
9
10 \Frame(0,0){1}[UNIVERSITY]{
11 Name/PK,
12 Website/A};
13
14 \Frame(0,-2.5){2}[DEPARTMENT]{
15 Code/PK,
16 Contact/A,
17 CreationDate/A,
18 University/A};
19
20 \Frame(8,0){3}[CAMPUS]{
21 Address/PK,
22 University/A};
23
24 \Frame(8,-2.5){4}[OFFERING]{
25 Department/PK,
26 Course/PK,
27 Code/A};
28
29 \Frame(8,-5){5}[COURSE]{
30 Name/PK,
31 CreditHours/A};
32
33 \draw[FK] % From CAMPUS.University to UNIVERSITY.Name
34 (Name1)++(0.15,0) -- ++(0,-.45) coordinate (inter)
35 -- (University3 |- inter) --++(0, 0.55);
36
37 \draw[FK] % From DEPARTMENT.University to UNIVERSITY.Name
38 (Name1) -- ++(0,-.55) -- ++(6, 0.0) -- ++(0, -2.35)
39 coordinate (inter) -- (University2|- inter) --++(0, 0.5);
40
41 \draw[FK] % From OFFERING.Department to DEPARTMENT.Code
42 (Code2) -- ++(0,-.55)
43 coordinate (inter) -- (Department4|- inter) --++(0, 0.55);
44
45 \draw[FK] % From OFFERING.Department to COURSE.Name
46 (Name5) -- ++(0,-.55) -- ++(3, 0.0) -- ++(0, 2.55)
47 coordinate (inter) -- (Course4|- inter) --++(0, 0.5);
48
49 \end{tikzpicture}
50 \end{document}
File notes/fig/rel_mod/WORK.tex added (mode: 100644) (index 0000000..3d45399)
1 \documentclass[border=20pt]{standalone}
2 \input{template.def}
3
4
5 % WORK(Title (PK), Author (FK to AUTHOR.Name))
6 % AUTHOR(Name (PK), Email)
7 % BOOK(ISBN (PK), Work (FK to WORK.Title), Published, Price)
8 % EBOOK(ISBN (PK), Work (FK to WORK.Title), Published, Price)
9
10 \Frame(0,0){1}[WORK]{
11 Title/PK,
12 Author/A};
13
14 \Frame(0,-2.5){2}[BOOK]{
15 ISBN/PK,
16 Work/A,
17 Published/A,
18 Price/A};
19
20 \Frame(10,0){3}[AUTHOR]{
21 Name/PK,
22 Email/A};
23
24 \Frame(10,-2.5){4}[BOOK]{
25 ISBN/PK,
26 Work/A,
27 Published/A,
28 Price/A};
29
30 \draw[FK] % From WORK.Author to AUTHOR.Name
31 (Name3)++(-0.2,0) -- ++(0,-.55) coordinate (inter)
32 -- (Author1 |- inter) --++(0, 0.65);
33
34 \draw[FK] % From BOOK.Work to WORK.Title
35 (Title1)++(0.3,0) -- ++(0,-0.8) --++(-1, 0)
36 --++(0, -2.3)
37 coordinate (inter)
38 -- (Work2 |- inter) --++(0, 0.7);
39
40 \draw[FK] % From EBOOK.Work to WORK.Title
41 (Title1)++(-0.1,0) -- ++(0,-0.5) --++(-1.5, 0)
42 --++(0, -3)
43 coordinate (inter)
44 -- (Work4 |- inter) --++(0, 1.1);
45
46
47 \end{tikzpicture}
48 \end{document}
File notes/lectures_notes.md changed (mode: 100644) (index 533eb31..bf8d878)
... ... marks the (usual) separation between two lectures.
87 87
88 88 To give you a sense of what you will be asked to do during the exams, please find below a description of the exams given previous semesters. To give you a sense of what you will be asked to do during the exams, please find below a description of the exams given previous semesters.
89 89
90 ### Fall 2017 {-}
90 ### Spring 2018 {-}
91 91
92 92 - Exam #1:^[This exam was probably a bit too long, but students managed it pretty well.] - Exam #1:^[This exam was probably a bit too long, but students managed it pretty well.]
93 93 - Six small exercises (@exercise:programdataindependence, @exercise:schemastate, @exercise:entityintegrity, @exercise:sqldatatype, @exercise:explainsql and @exercise:explainfk) - Six small exercises (@exercise:programdataindependence, @exercise:schemastate, @exercise:entityintegrity, @exercise:sqldatatype, @exercise:explainsql and @exercise:explainfk)
 
... ... To give you a sense of what you will be asked to do during the exams, please fin
108 108 - [%D %n (%T)](#problem:book) - [%D %n (%T)](#problem:book)
109 109 - [%D %n (%T)](#problem:consultation) - [%D %n (%T)](#problem:consultation)
110 110
111 ### Spring 2018 {-}
111 ### Fall 2018 {-}
112 112
113 113 - Exam #1: - Exam #1:
114 114 - [%D %n (%T)](#problem:cinema), except that I gave some of the relations and attributes, to help getting started with the problem. - [%D %n (%T)](#problem:cinema), except that I gave some of the relations and attributes, to help getting started with the problem.
 
... ... To give you a sense of what you will be asked to do during the exams, please fin
128 128 - A variation on [%D %n (%T)](#problem:BusinessToEr) - A variation on [%D %n (%T)](#problem:BusinessToEr)
129 129 - A variation on [%D %n (%T)](#problem:UMLtoRELDriver): students were asked to draw the ER diagram for that schema. - A variation on [%D %n (%T)](#problem:UMLtoRELDriver): students were asked to draw the ER diagram for that schema.
130 130
131 ### Fall 2019 {-}
131 ### Spring 2019 {-}
132 132
133 133 - Exam #1: - Exam #1:
134 134 - [%D %n (%T)](#problem:sqlBooks) - [%D %n (%T)](#problem:sqlBooks)
 
... ... To give you a sense of what you will be asked to do during the exams, please fin
147 147 - [%D %n (%T)](#problem:library_network) - [%D %n (%T)](#problem:library_network)
148 148 - Five exercises from the [Database Application](#databases-applications) chapter. - Five exercises from the [Database Application](#databases-applications) chapter.
149 149
150
150
151 ### Fall 2019 {-}
152
153 - Exam #1:
154 - [%D %n (%T)](#problem:sqlWorks)
155 - Three exercises (@exercise:defaultForeign, @exercise:truthTableAnd but for the `OR` operator, and @exercise:NullMeaning)
156 - [%D %n (%T)](#problem:rel_model_universities)
157
158
151 159 ## Typesetting and Acknowledgments {-} ## Typesetting and Acknowledgments {-}
152 160
153 161 The source code for those notes is hosted at [rocketgit](https://rocketgit.com/user/caubert/CSCI_3410), typeset in markdown, and then compiled using [pandoc](http://pandoc.org/) and multiple filters ([pandoc-numbering](https://github.com/chdemko/pandoc-numbering), [pandoc-citeproc](https://github.com/jgm/pandoc-citeproc), [pandoc-include-code](https://github.com/owickstrom/pandoc-include-code)). The source code for those notes is hosted at [rocketgit](https://rocketgit.com/user/caubert/CSCI_3410), typeset in markdown, and then compiled using [pandoc](http://pandoc.org/) and multiple filters ([pandoc-numbering](https://github.com/chdemko/pandoc-numbering), [pandoc-citeproc](https://github.com/jgm/pandoc-citeproc), [pandoc-include-code](https://github.com/owickstrom/pandoc-include-code)).
 
... ... Problem (Relational model for a cinema company) +.#cinema
1083 1091 - Furthermore, each theater has a set of auditoriums. Each auditorium has a unique number, and seating capacity. - Furthermore, each theater has a set of auditoriums. Each auditorium has a unique number, and seating capacity.
1084 1092 - Each theater can schedule movies at show-times. Each show-time has a unique id, a start time, and is for a specific movie, at a theater auditorium. - Each theater can schedule movies at show-times. Each show-time has a unique id, a start time, and is for a specific movie, at a theater auditorium.
1085 1093 - The company sells tickets for scheduled show-times. Each ticket has a unique ticket id, and a price. - The company sells tickets for scheduled show-times. Each ticket has a unique ticket id, and a price.
1086
1087 1094 --- ---
1088 1095
1089 1096 Problem (Relational model for bills) +.#rel_model_bills Problem (Relational model for bills) +.#rel_model_bills
 
... ... Problem (Relational model for bills) +.#rel_model_bills
1095 1102 - You also want to record the name of the Speaker, Majority Leader, Minority Leader, Majority Whip, and Minority Whip, which are all members of the house. - You also want to record the name of the Speaker, Majority Leader, Minority Leader, Majority Whip, and Minority Whip, which are all members of the house.
1096 1103 - Finally, for each bill, you want to record the vote of every member of the house. - Finally, for each bill, you want to record the vote of every member of the house.
1097 1104
1105 ---
1106
1107 Problem (Relational model for universities) +.#rel_model_universities
1108 ~
1109
1110 Propose a relational model for the following situation:
1111
1112 - You want to store information about multiple universities. A university has multiple departments, a name and a website.
1113 - Each department offers multiple courses. A course has a name, one (or multiple, when it is cross-listed) code, a number of credit hours.
1114 - A campus has a name, an address, and belong to one university.
1115 - A department has a contact address, a date of creation and a (unique) code.
1116
1098 1117 ## Solution to Selected Problems {-} ## Solution to Selected Problems {-}
1099 1118
1100 1119 Solution to @problem:cinema Solution to @problem:cinema
 
... ... Solution to @problem:rel_model_bills
1128 1147
1129 1148 For simplicity, we added an `Id` to our `MEMBER` and `BILL` relations. Note that having a "role" in the `MEMBER` relation to store the information about speaker, etc., would be extremely inefficient, since we would add an attribute to the ~435 members that would be `NULL` in ~430 of them. For simplicity, we added an `Id` to our `MEMBER` and `BILL` relations. Note that having a "role" in the `MEMBER` relation to store the information about speaker, etc., would be extremely inefficient, since we would add an attribute to the ~435 members that would be `NULL` in ~430 of them.
1130 1149
1150 ---
1151
1152 Solution to @problem:rel_model_universities
1153
1154 ~
1155
1156 A possible solution follows.
1157 The part that is the hardest to accomodate is the fact that a course can have multiple codes.
1158 We are reading here "cross-listed" as "a course that is offered under more than one departmental heading and can receive different codes (e.g., CSCI XXXX and AIST YYYY)".
1159
1160 ![
1161 UNIVERSITY (Name (PK), Website)
1162 CAMPUS (Address (PK), University (FK to UNIVERSITY.Name))
1163 DEPARTMENT (Code (PK), Contact, CreationDate, University (FK to UNIVERSITY.Name))
1164 COURSE (Name (PK), CreditHours)
1165 OFFERING (Department (PK, FK to DEPARTMENT.Name), Course (PK, FK to COURSE.Name), Code)
1166 ](fig/rel_mod/UNIVERSITIES)
1167 \
1168
1169
1131 1170 # The SQL Programming Language # The SQL Programming Language
1132 1171
1133 1172 ## Resources {-} ## Resources {-}
 
... ... Exercise +.#
2471 2510
2472 2511 : If you want that every time a referenced row is delted, all the refering rows are deleted as well, what mechanism should you use? : If you want that every time a referenced row is delted, all the refering rows are deleted as well, what mechanism should you use?
2473 2512
2513 Exercise +.#defaultForeign
2514
2515 : By default, does the foreign key restrict, cascade, or set null on update? Can you justify this choice?
2516
2474 2517 Exercise +.# Exercise +.#
2475 2518
2476 2519 : If a database designer is using the `ON UPDATE SET NULL` for a foreign key, what mechanism is (s)he implementing (i.e., describe how the database will react a certain operation)? : If a database designer is using the `ON UPDATE SET NULL` for a foreign key, what mechanism is (s)he implementing (i.e., describe how the database will react a certain operation)?
 
... ... Exercise +.#
2576 2619
2577 2620 : Can an `UPDATE` statement have a `WHERE` condition using an attribute that isn't the primary key? If no, justify, if yes, tell what could happen. : Can an `UPDATE` statement have a `WHERE` condition using an attribute that isn't the primary key? If no, justify, if yes, tell what could happen.
2578 2621
2579 Exercise +.#
2622 Exercise +.#NullMeaning
2580 2623
2581 : What are the possible meanings or interpretations for a `NULL` value?
2624 : Give the three possible meaning of the `NULL` value, and an example for each of them.
2582 2625
2583 2626 Exercise +.# Exercise +.#
2584 2627 ~ ~
 
... ... Solution +.#
2720 2763
2721 2764 Solution +.# Solution +.#
2722 2765
2766 : By default, the foreign key restricts updates. This prevents unwanted update of information: if an update needs to be propagated, then it needs to be "acknowledged" and done explicitely.
2767
2768 Solution +.#
2769
2723 2770 : If the referenced row is updated, then the attribute of the referencing rows are set to `NULL`{.sqlmysql}. : If the referenced row is updated, then the attribute of the referencing rows are set to `NULL`{.sqlmysql}.
2724 2771
2725 2772 Solution +.# Solution +.#
 
... ... Solution +.#
2800 2847
2801 2848 Solution +.# Solution +.#
2802 2849
2803 : Unknown value, unavailable / withheld, N/A.
2850 : Unknown value ("Will it rain tomorrow?"), unavailable / withheld ("What is the phone number of Harry Belafonte?"), N/A ("What is the email address of Abraham Lincoln?").
2804 2851
2805 2852 Solution +.# Solution +.#
2806 2853 ~ ~
 
... ... Solution +.#
2822 2869 - `FALSE AND UNKNOWN`{.sqlmysql} → `FALSE`{.sqlmysql} - `FALSE AND UNKNOWN`{.sqlmysql} → `FALSE`{.sqlmysql}
2823 2870 - The other cases can be deduced by symmetry. - The other cases can be deduced by symmetry.
2824 2871
2825 For a more compact presentation, refer to [the three-valued truth table"](#truth-tables).
2872 For a more compact presentation, refer to [the three-valued truth table](#truth-tables).
2826 2873
2827 2874 Solution +.# Solution +.#
2828 2875
 
... ... Problem (A simple database for books) +.#sqlBooks
3413 3460 #. Draw the relational model of the database you created (i.e., including all the relations given in the code and the one you added). #. Draw the relational model of the database you created (i.e., including all the relations given in the code and the one you added).
3414 3461 #. Discuss two limitations of the model and how to improve it. #. Discuss two limitations of the model and how to improve it.
3415 3462
3463
3464 ---
3465
3466 Problem (A simple database for published pieces of work) +.#sqlWorks
3467 ~
3468
3469 Consider the following code:
3470
3471 ```{.sqlmysql .numberLines include=code/sql/WORK.sql}
3472 ```
3473
3474 You should assume that
3475
3476 #. Every statement respects SQL's syntax (there's no "a semi-colon is missing" trap).
3477 #. None of the commands in the rest of this problem are actually executed, you are asked to answer "what if" questions.
3478
3479 Also, note that each row inserted between line 39 and 50 is given a name in comment (`A.1`, `A.2`, `A.3`, `W.1`, etc.).
3480
3481 - Draw the relational model corresponding to this series of commands.
3482 - Determine if the following insertion statements would violate the the Entity integrity constraint, the Referential integrity constraint, if there would be some Other kind of error, or if it would result in \textbf{S}uccessful insertion.
3483
3484 ~~~{.sqlmysql .numberLines}
3485 INSERT INTO EBOOK VALUES (0, NULL, 20180101, 0);
3486 INSERT INTO AUTHOR VALUES("Mary B.", "mb@fai.fr", NULL);
3487 INSERT INTO WORK VALUES("My Life", "Claude A.");
3488 INSERT INTO BOOK VALUES(00000000, NULL, DATE'20001225', 90.9);
3489 INSERT INTO AUTHOR VALUES("Virginia W.", "alt@isp.net");
3490 ~~~
3491
3492 - List the rows (i.e., A.2, W.1, etc.) modified by the following statements (be careful about the conditions on foreign keys!):
3493
3494 ~~~{.sqlmysql .numberLines}
3495 UPDATE AUTHOR SET Email = 'Deprecated' WHERE Email LIKE '%isp.net';
3496 UPDATE WORK SET Title = "How to eat" WHERE Title = "What to eat";
3497 DELETE FROM WORK;
3498 DELETE FROM AUTHOR WHERE Name = "Virginia W.";
3499 ~~~
3500
3501 - You can now assume that there is more data than what we inserted, if that helps you. Write a command that selects …
3502 - … the price of all the ebooks.
3503 - … the (distinct) names of the authors who have authored a piece of work.
3504 - … the name of the authors using fai.fr for their email.
3505 - … the price of the ebooks published after 2018.
3506 - … the price of the most expensive book.
3507 - … the number of pieces of work written by the author whose name is "Virginia W.".
3508 - … the email of the author who wrote the piece of work called "My Life".
3509 - … the isbn(s) of the book containing a work written by the author whose email is "vw@isp.net".
3510
3511 - Write a command that updates the title of all the pieces of work written by the author whose name is "Virginia W. to "BANNED".
3512 Is there any reason for this command to be rejected by the system?
3513 If yes, explain which one.
3514 - Write one or multiple commands that would delete the work whose title is "My Life", as well as all of the books and ebooks versions of it.
3515 - Discuss two limitations of the model and how to improve it.
3516
3416 3517 ## Solution to Selected Problems {-} ## Solution to Selected Problems {-}
3417 3518
3418 3519
 
... ... Solution to [%D %n (%T)](#problem:sqlBooks)
3861 3962 - The choice of the primary key for the `BOOK` relation: two books with the same title cannot be published on the same day, and that is a serious limitation. Using a primary key like ISBN would be much more appropriate. - The choice of the primary key for the `BOOK` relation: two books with the same title cannot be published on the same day, and that is a serious limitation. Using a primary key like ISBN would be much more appropriate.
3862 3963 - The impossibility to deal with books written by multiple authors or published by multiple publishers. We could address this by having two separate tables, `IS_THE_AUTHOR_OF` and `PUBLISHED_BY`, that "maps" book's ISBN with author's or editor's primary key. - The impossibility to deal with books written by multiple authors or published by multiple publishers. We could address this by having two separate tables, `IS_THE_AUTHOR_OF` and `PUBLISHED_BY`, that "maps" book's ISBN with author's or editor's primary key.
3863 3964
3965 ---
3966
3967 Solution to [%D %n (%T)](#problem:sqlWorks)
3968 ~ The relational model for this code is:
3969
3970 ![
3971 WORK(Title (PK), Author (FK to AUTHOR.Name))
3972 AUTHOR(Name (PK), Email)
3973 BOOK(ISBN (PK), Work (FK to WORK.Title), Published, Price)
3974 EBOOK(ISBN (PK), Work (FK to WORK.Title), Published, Price)
3975 ](fig/rel_mod/WORK)
3976 \
3977
3978 The solution to the next questions can be read from the following code:
3979
3980
3981 ```{.sqlmysql .numberLines include=code/sql/WORK_SOL.sql}
3982 ```
3983
3984 Finally, to answer the last question, we could list, among the possible limitations:
3985
3986 - Having the name or the title as a primary key (in the AUTHOR and WORK tables) is not a good idea: we cannot have two authors with the same name, or two pieces of work with the same title!
3987 - If all the attributes in the BOOK and the EBOOK tables are going to be the same, then we should probably have only one table, called e.g. PUBLICATION, with a boolean to indicate whenever the publication is numeric or on paper.
3988 - Having a mix of "ON DELETE CASCADE" and "ON DELETE RESTRICT" is not really justified, and makes the tables harder to use. We should have the same update policy on both tables.
3989
3990
3864 3991 # Designing a Good Database # Designing a Good Database
3865 3992
3866 3993 ## Resources {-} ## Resources {-}
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