List of commits:
Subject Hash Author Date (UTC)
Adding a problem and its solution, in the SQL chapter. d5bfcbb949a6acac68156a8b37d6f8d23375b1cb aubert@math.cnrs.fr 2019-02-19 19:53:27
Adding second quiz, and fixing some exercises and problems in Chapter 3. 062c9b46fad52848efbf61e08c91103c0bae4127 aubert@math.cnrs.fr 2019-02-06 20:04:16
Clarification on SQL constraints. 70e26a02aa344cc1bf009a089623be6baac79ba7 aubert@math.cnrs.fr 2019-01-29 22:46:26
Adding some minor SQL remarks + code for HW_FACULTY. 1d1b74302d29fb63c3c2bacca30533283f720997 aubert@math.cnrs.fr 2019-01-25 17:24:16
fixing small typo. 0feeb8df61e05d6d0990120628303cf31108f100 aubert@math.cnrs.fr 2019-01-22 18:23:34
Quick fix + adding macOS install instructions. ea3063e4e9225c8ce66838c8bfddb9a34aadacf8 aubert@math.cnrs.fr 2019-01-16 15:59:38
Fixing a few typos and adding a drawing. b335800d4129c8e29763a6c1d564243d485fa51b aubert@math.cnrs.fr 2019-01-15 19:03:38
Fixing first homework 3eeb05a78235274a330c780f4f26b5fed1a01aef aubert@math.cnrs.fr 2019-01-08 19:50:29
Added content of various exam, fixed intro, added references, solutions, fixed types. a8e9d2d4856133d68d882403cde42dfcc2f5cc69 aubert@math.cnrs.fr 2019-01-07 16:47:02
Cleaning files and makefile 7605a6530505ad69042413dd995d77f1814c2f30 au 2018-12-24 14:25:31
Fixed margin for PDF, added a couple of SVG images, fixed some problems, added some code. eb83d9f07d738df7ab2515b768d6165a3b7e5ca3 au 2018-12-24 02:28:36
Working on rel_mod for Prof_Department_Extended. 2b1eff83797fbda620189f014043d648c884e887 au 2018-12-23 22:38:07
Working on FD and various figures. 8fd7f8322e70ae252596aa9cb88918ac40d5aa84 au 2018-12-23 20:25:19
Added first drawing for fd. 2a0e4fc716d91c23c81346a0e3b568f7132284c9 au 2018-12-23 05:23:29
Cleaned latex code. 1cf04e85915d24fc0208b407eb0166803b2369cf au 2018-12-23 04:27:41
Working on drawing for functional dependencies. 7dc167021630c00be25881877c0921adbc87f482 au 2018-12-23 04:20:33
Working on style for functional dependencies graph. 029c32395ba1110ad2af980e248848e0877040d7 au 2018-12-23 00:17:54
Working on template for FD. 091bb061b6fea06f440e97a4c9ac0f69b4ea1392 au 2018-12-22 20:57:00
Started to work on Functional Dep. 2123fbafc3b8258184ad745d8f23521a3f477d0e au 2018-12-22 18:53:20
Fixing a couple of problem, adding some more correct figures. ef44b65f45fba2bd9a653b639287d872b9f7471d au 2018-12-22 04:27:34
Commit d5bfcbb949a6acac68156a8b37d6f8d23375b1cb - Adding a problem and its solution, in the SQL chapter.
Author: aubert@math.cnrs.fr
Author date (UTC): 2019-02-19 19:53
Committer name: aubert@math.cnrs.fr
Committer date (UTC): 2019-02-19 19:53
Parent(s): 062c9b46fad52848efbf61e08c91103c0bae4127
Signer:
Signing key:
Signing status: N
Tree: 1e68e966837fb5ab31d0dde904d87e753a1f25ec
File Lines added Lines deleted
notes/code/sql/SIMPLE_BOOK.sql 54 0
notes/lectures_notes.md 145 0
File notes/code/sql/SIMPLE_BOOK.sql added (mode: 100644) (index 0000000..0855f02)
1 /*
2
3 code/sql/SIMPLE_BOOK.sql
4
5 The following is in case you want to run your program on your installation:
6
7 -- DROP SCHEMA HW_SIMPLE_BOOK;
8 CREATE SCHEMA HW_SIMPLE_BOOK;
9 USE HW_SIMPLE_BOOK;
10
11 */
12
13 CREATE TABLE AUTHOR(
14 FName VARCHAR(30),
15 LName VARCHAR(30),
16 Id INT PRIMARY KEY
17 );
18
19 CREATE TABLE PUBLISHER(
20 Name VARCHAR(30),
21 City VARCHAR(30),
22 PRIMARY KEY (Name, City)
23 );
24
25
26 CREATE TABLE BOOK(
27 Title VARCHAR(30),
28 Pages INT,
29 Published DATE,
30 PublisherName VARCHAR(30),
31 PublisherCity VARCHAR(30),
32 FOREIGN KEY (PublisherName, PublisherCity)
33 REFERENCES PUBLISHER(Name, City),
34 Author INT,
35 FOREIGN KEY (Author)
36 REFERENCES AUTHOR(Id),
37 PRIMARY KEY (Title, Published)
38 );
39
40 INSERT INTO AUTHOR VALUES
41 ("Virginia", "Wolve", 01),
42 ("Paul", "Bryant", 02),
43 ("Samantha", "Carey", 03);
44
45 INSERT INTO PUBLISHER VALUES
46 ("Gallimard", "Paris"),
47 ("Gallimard", "New-York"),
48 ("Jobs Pub.", "New-York");
49
50 INSERT INTO BOOK VALUES
51 ("What to eat", 213, DATE'20170219', "Gallimard", "Paris", 01),
52 ("Where to live", 120, DATE'20130212', "Gallimard", "New-York", 02),
53 ("My Life, I", 100, DATE'18790220', "Gallimard", "Paris", 03),
54 ("My Life, II", 100, DATE'18790219', "Jobs Pub.", "New-York", 03);
File notes/lectures_notes.md changed (mode: 100644) (index 8791dee..c352277)
... ... Problem (Improving a role-playing game) +.#roleplaying
3060 3060
3061 3061 Can you provide a *relational model* (no need to write the `SQL` code, but remember to indicate the primary and foreign keys) that would solve all of your friend's troubles? Can you provide a *relational model* (no need to write the `SQL` code, but remember to indicate the primary and foreign keys) that would solve all of your friend's troubles?
3062 3062
3063
3064 Problem (A simple database for books) +.#sqlBooks
3065 ~
3066
3067 Consider the following code:
3068
3069 ```{.sqlmysql .numberLines include=code/sql/SIMPLE_BOOK.sql}
3070 ```
3071
3072 The values inserted in the database will guide some examples, but you should assume there is more data than what we inserted.
3073 In this long problem, you will be asked to write commands to select, update, delete, insert data, and to enhance the model.
3074
3075 #. Write a command that selects…
3076
3077 #. the title of all the books.
3078 #. the (distinct) name of the publishers.
3079 #. the title and publication date of the books published since January 31, 2012.
3080 #. the first and last names of the authors published by Gallimard (no matter the city).
3081 #. the first and last names of the authors who were not published by an editor in New-York.
3082 #. the id of the authors who published a book whose name starts with "Where".
3083 #. the total number of pages in the database.
3084 #. the number of pages in the longest book written by the author whose last name is "Wolve".
3085 #. the title of the books published in the XIXth century.
3086
3087 #. Write a command that updates the title of all the books written by the author whose id is $1$ to "BANNED". Is there any reason for this command to be rejected by the system? If yes, explain which one.
3088 #. Write one or multiple commands that would delete the author whose id is $3$, and all the book written by that author. Make sure you don't violate any foreign key constraint.
3089 #. Write a command that would create a table used to record the awards granted to authors for particular books. You should assume that each award has its own name, is awarded every year, and that it is awarded to an author for a particular book. Pick appropriate attributes, datatypes^[You can use the `DATE`{.sqlmysql} datatype to store a year.], primary as well as foreign keys, and avoid above all redundancy.
3090 #. Draw the relational model of the database you created (i.e., including all the relations given in the code and the one you added).
3091 #. Discuss two limitations of the model and how to improve it.
3092
3063 3093 ## Solution to Selected Problems {-} ## Solution to Selected Problems {-}
3064 3094
3065 3095 Solution to [%D %n (%T)](#problem:address) Solution to [%D %n (%T)](#problem:address)
 
... ... Solution to [%D %n (%T)](#problem:roleplaying)
3356 3386 ](fig/rel_mod/RPG) ](fig/rel_mod/RPG)
3357 3387 \ \
3358 3388
3389 Solution to [%D %n (%T)](#problem:sqlBooks)
3390 ~
3391
3392 @problem:sqlBooks -- Solution to Q. -.#
3393 ~ Here are possible ways of getting the required information:
3394
3395 - The title of all the books:
3396
3397 ~~~{.sqlmysql}
3398 SELECT Title FROM BOOK;
3399 ~~~
3400 - The (distinct) name of the publishers.
3401
3402 ~~~{.sqlmysql}
3403 SELECT DISTINCT Name FROM PUBLISHER;
3404 ~~~
3405
3406 - The title and publication date of the books published since January 31, 2012.
3407
3408 ~~~{.sqlmysql}
3409 SELECT Title, Published FROM BOOK
3410 WHERE Published > DATE'20120131';
3411 ~~~
3412
3413 - The first and last names of the authors published by Gallimard (no matter the city).
3414
3415 ~~~{.sqlmysql}
3416 SELECT FName, LName FROM AUTHOR, BOOK
3417 WHERE PublisherName = "Gallimard"
3418 AND Author = Id;
3419 ~~~
3420
3421 - The first and last names of the authors who were not published by an editor in New-York.
3422
3423 ~~~{.sqlmysql}
3424 SELECT FName, LName FROM AUTHOR, BOOK
3425 WHERE NOT PublisherCity= "New-York"
3426 AND Author = Id;
3427 ~~~
3428
3429 - The id of the authors who published a book whose name starts with "Where".
3430
3431 ~~~{.sqlmysql}
3432 SELECT Author FROM BOOK
3433 WHERE Title LIKE 'Where%';
3434 ~~~
3435
3436 - The total number of pages in the database.
3437
3438 ~~~{.sqlmysql}
3439 SELECT SUM(Pages) FROM BOOK;
3440 ~~~
3441
3442 - The number of pages in the longest book written by the author whose last name is "Wolve".
3443
3444 ~~~{.sqlmysql}
3445 SELECT MAX(PAGES) FROM BOOK, AUTHOR
3446 WHERE LName = "Wolve"
3447 AND Author = Id;
3448 ~~~
3449
3450 - The title of the books published in the XIXth century.
3451
3452 ~~~{.sqlmysql}
3453 SELECT Title FROM BOOK
3454 WHERE Published >= DATE'18010101'
3455 AND Published <= DATE'19001231';
3456 ~~~
3457
3458 @problem:sqlBooks -- Solution to Q. -.#
3459 ~ We can use the following command:
3460
3461 ~~~{.sqlmysql}
3462 UPDATE BOOK SET Title = "BANNED"
3463 WHERE Author = 3;
3464 ~~~
3465
3466 But, as the pair (title, publication date) is the primary key in the `BOOK` table, if the author whose id is $3$ has published more than one book at a particular date, then our update will be rejected, as applying it would result in violating the entity integrity constraint.
3467
3468 @problem:sqlBooks -- Solution to Q. -.#
3469 ~ To delete the required rows, we can use:
3470
3471 ~~~{.sqlmysql}
3472 DELETE FROM BOOK WHERE Author = 3;
3473 DELETE FROM AUTHOR WHERE Id = 3;
3474 ~~~
3475
3476 Note that trying to delete the rows in the `AUTHOR` table before deleting the rows in the `BOOK` table could cause a referential integrity violation, since some of the books would be "authorless".
3477
3478 @problem:sqlBooks -- Solution to Q. -.#
3479 ~ We could design that table as follows:
3480
3481 ~~~{.sqlmysql}
3482 CREATE TABLE AWARD(
3483 Name VARCHAR(30),
3484 Year DATE,
3485 BookTitle VARCHAR(30),
3486 BookPubDate DATE,
3487 FOREIGN KEY (BookTitle, BookPubDate)
3488 REFERENCES BOOK(Title, Published),
3489 PRIMARY KEY (Name, Year)
3490 );
3491 ~~~
3492
3493 Note that there is no need to store the name of the author in that relation: this information can be recovered by looking in the `BOOK` table for the name of the author of the awarded book.
3494
3495 @problem:sqlBooks -- Solution to Q. -.#
3496 ~ Drawing added soon.
3497
3498 @problem:sqlBooks -- Solution to Q. -.#
3499 ~ Two of the flaws that come to mind are:
3500
3501 - 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.
3502 - 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.
3503
3359 3504 # Designing a Good Database # Designing a Good Database
3360 3505
3361 3506 ## 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