List of commits:
Subject Hash Author Date (UTC)
update 6fd8bae9a3068318513bb261f79a0a07d3c87f17 Poonam Veeral 2020-04-08 15:37:39
Update lectures_notes.md be9ca4670f042e27dfd60082cf0b081401dc072d poonamveeral 2020-04-08 14:29:08
Rename Print.tex to print.tex 8a2253b100e8fb661c03e410e61c87e6e0dd768a poonamveeral 2020-04-08 13:45:56
Rename alt_Not_03.tex to alt_not_03.tex ab653337fe4266a333d22178c33bd5d5c3ca3613 poonamveeral 2020-04-08 13:37:09
Rename alt_Not_02.tex to alt_not_02.tex a79c527d3aa97f29fa835406eb2fd6bfca80e616 poonamveeral 2020-04-08 13:36:52
Rename alt_Not_01.tex to alt_not_01.tex ce6ec02b5543682869d3dd782576e6a7c27cf5b5 poonamveeral 2020-04-08 13:36:36
Update lectures_notes.md 3d3106fe10b24fcccedbdcc6c20c1d7a4c3e0801 poonamveeral 2020-04-08 13:31:56
Rename book_Exo.tex to book_exo.tex 2fc98bb8f1b8dc8793fe1d9eaae4babeff760624 poonamveeral 2020-04-08 13:25:08
updated a080901830e9ef778e099d2cbf06d37af41e880e Poonam Veeral 2020-04-08 13:15:26
er updated 69bb6e5cfd8f31c5347d8b6b6e9e3a4e5ef6580c Poonam Veeral 2020-04-08 12:51:37
er deleted 3543da66bdd8adff409cf79707fb11584b490f67 Poonam Veeral 2020-04-08 12:41:23
fd updated 0a92b326fdc2fea4cd908c6ca4d14b2d635e1728 Poonam Veeral 2020-04-08 12:40:47
fd deleted 8ba0a92ca38f25f6bb10b68d27e0cfb5b8719a3f Poonam Veeral 2020-04-08 12:36:42
misc updated 37bac44c663e91e07d28a76031aef855907e097d Poonam Veeral 2020-04-08 12:36:01
misc deleted 3a5c7e6b44694169109a1fb71e2f23508708dd67 Poonam Veeral 2020-04-08 12:35:23
rel_mod updated d20af615ee586d57e85b873f28174870cf33d574 Poonam Veeral 2020-04-08 12:34:37
deleted dc4debbc6caa6857438051f3591b692186878392 Poonam Veeral 2020-04-08 12:33:42
rel_mod updated e75e40028412899276f36b55ddf8856d47e1b1dc Poonam Veeral 2020-04-08 12:31:58
uml updated 66ee8ea267cb09112b0eae2b106936f81caa1d79 Poonam Veeral 2020-04-08 12:25:06
uml folder deleted 219c795f28525733c62e7cfffecc9339295c492e Poonam Veeral 2020-04-08 12:22:59
Commit 6fd8bae9a3068318513bb261f79a0a07d3c87f17 - update
Author: Poonam Veeral
Author date (UTC): 2020-04-08 15:37
Committer name: Poonam Veeral
Committer date (UTC): 2020-04-08 15:37
Parent(s): be9ca4670f042e27dfd60082cf0b081401dc072d
Signer:
Signing key:
Signing status: N
Tree: c1bd3b457b7098521ec59daae55df742e537f9ff
File Lines added Lines deleted
notes/code/java/GuestProgramSolution.java 91 91
notes/code/sql/HW_DefaultTest.sql 18 0
notes/code/sql/HW_Residency.sql 43 0
notes/code/sql/HW_ResidencySol.sql 174 0
notes/code/sql/HW_TextbookAuthored.sql 44 0
notes/code/sql/HW_TextbookAuthoredSol.sql 224 0
File notes/code/java/GuestProgramSolution.java renamed from notes/code/java/GuestProgram_Solution.java (similarity 97%) (mode: 100644) (index 01b15cb..0fb99ce)
1 // code/java/GuestProgram_Solution.java
2
3 import java.sql.*;
4 import java.util.Scanner; // Importing a java API to read from the keyboard.
5
6 /*
7 * This first part is "standard". Just note that we allow multiple statements and that
8 * the ResultsSet we will construct with our conn objects will be scrollables.
9 */
10
11 public class GuestProgram_Solution {
12 public static void main(String[] args) {
13 try (Connection conn =
14 DriverManager.getConnection(
15 "jdbc:mysql://localhost:3306/?user=testuser&password=password&allowMultiQueries=true");
16 Statement stmt =
17 conn.createStatement(ResultSet.TYPE_SCROLL_SENSITIVE, ResultSet.CONCUR_READ_ONLY); ) {
18 stmt.execute(
19 "DROP SCHEMA IF EXISTS HW_GUEST_PROGRAM;"
20 + "CREATE SCHEMA HW_GUEST_PROGRAM;"
21 + "USE HW_GUEST_PROGRAM;"
22 + "CREATE TABLE GUEST("
23 + "Id INT PRIMARY KEY,"
24 + "Name VARCHAR(30),"
25 + "Confirmed BOOL"
26 + ");"
27 + "CREATE TABLE BLACKLIST("
28 + "Name VARCHAR(30)"
29 + ");"
30 + "INSERT INTO BLACKLIST VALUES (\"Marcus Hells\");");
31
32 System.out.print("How many guests do you have?\n");
33 Scanner key = new Scanner(System.in);
34 int guest_total = key.nextInt();
35
36 key.nextLine(); // "Hack" to flush the buffer. Please ignore.
37
38 // EXERCISE 1
39 int guest_id;
40 String guest_name;
41 int counter = 0;
42
43 // Solution A
44 while (counter < guest_total) {
45 System.out.print("Enter name of guest " + (counter + 1) + ".\n");
46 guest_name = key.nextLine();
47 stmt.addBatch("INSERT INTO GUEST VALUES (" + counter + ", \"" + guest_name + "\", NULL)");
48 counter++;
49 }
50 stmt.executeBatch();
51
52 // Solution B
53 /*
54 * PreparedStatement ps = conn.prepareStatement("INSERT INTO GUEST VALUES(?, ?, NULL);");
55 * while (counter < guest_total) {
56 * System.out.print("Enter name of guest " + (counter + 1) + ".\n");
57 * guest_name = key.nextLine();
58 * ps.setInt(1, counter);
59 * ps.setString(2, guest_name);
60 * ps.executeUpdate();
61 * counter++;
62 * }
63 */
64 // Needed to test our solution to the following two exercises.
65 stmt.execute("INSERT INTO GUEST VALUES (-1, \"Marcus Hells\", true);");
66 stmt.execute("INSERT INTO GUEST VALUES (-2, \"Marcus Hells\", false);");
67
68 // EXERCISE 2
69 ResultSet rset =
70 stmt.executeQuery(
71 "SELECT * FROM GUEST, BLACKLIST WHERE GUEST.Name = BLACKLIST.Name AND GUEST.Confirmed = true");
72 if (rset.next()) {
73 System.out.print(
74 "Oh no, (at least) one of the guest from the black list confirmed their presence!\nThe name of the first one is "
75 + rset.getString(2)
76 + ".\n");
77 }
78
79 // EXERCISE 3
80 System.out.print(
81 "Do you want to remove all the guests that are on the black list and confirmed their presence? Enter \"Y\" for yes, anything else for no.\n");
82 if (key.nextLine().equals("Y")) {
83 stmt.execute(
84 "DELETE FROM GUEST WHERE NAME IN (SELECT NAME FROM BLACKLIST) AND Confirmed = true;");
85 }
86
87 } catch (SQLException ex) {
88 ex.printStackTrace();
89 }
90 }
91 }
1 // code/java/GuestProgram_Solution.java
2
3 import java.sql.*;
4 import java.util.Scanner; // Importing a java API to read from the keyboard.
5
6 /*
7 * This first part is "standard". Just note that we allow multiple statements and that
8 * the ResultsSet we will construct with our conn objects will be scrollables.
9 */
10
11 public class GuestProgram_Solution {
12 public static void main(String[] args) {
13 try (Connection conn =
14 DriverManager.getConnection(
15 "jdbc:mysql://localhost:3306/?user=testuser&password=password&allowMultiQueries=true");
16 Statement stmt =
17 conn.createStatement(ResultSet.TYPE_SCROLL_SENSITIVE, ResultSet.CONCUR_READ_ONLY); ) {
18 stmt.execute(
19 "DROP SCHEMA IF EXISTS HW_GUEST_PROGRAM;"
20 + "CREATE SCHEMA HW_GUEST_PROGRAM;"
21 + "USE HW_GUEST_PROGRAM;"
22 + "CREATE TABLE GUEST("
23 + "Id INT PRIMARY KEY,"
24 + "Name VARCHAR(30),"
25 + "Confirmed BOOL"
26 + ");"
27 + "CREATE TABLE BLACKLIST("
28 + "Name VARCHAR(30)"
29 + ");"
30 + "INSERT INTO BLACKLIST VALUES (\"Marcus Hells\");");
31
32 System.out.print("How many guests do you have?\n");
33 Scanner key = new Scanner(System.in);
34 int guest_total = key.nextInt();
35
36 key.nextLine(); // "Hack" to flush the buffer. Please ignore.
37
38 // EXERCISE 1
39 int guest_id;
40 String guest_name;
41 int counter = 0;
42
43 // Solution A
44 while (counter < guest_total) {
45 System.out.print("Enter name of guest " + (counter + 1) + ".\n");
46 guest_name = key.nextLine();
47 stmt.addBatch("INSERT INTO GUEST VALUES (" + counter + ", \"" + guest_name + "\", NULL)");
48 counter++;
49 }
50 stmt.executeBatch();
51
52 // Solution B
53 /*
54 * PreparedStatement ps = conn.prepareStatement("INSERT INTO GUEST VALUES(?, ?, NULL);");
55 * while (counter < guest_total) {
56 * System.out.print("Enter name of guest " + (counter + 1) + ".\n");
57 * guest_name = key.nextLine();
58 * ps.setInt(1, counter);
59 * ps.setString(2, guest_name);
60 * ps.executeUpdate();
61 * counter++;
62 * }
63 */
64 // Needed to test our solution to the following two exercises.
65 stmt.execute("INSERT INTO GUEST VALUES (-1, \"Marcus Hells\", true);");
66 stmt.execute("INSERT INTO GUEST VALUES (-2, \"Marcus Hells\", false);");
67
68 // EXERCISE 2
69 ResultSet rset =
70 stmt.executeQuery(
71 "SELECT * FROM GUEST, BLACKLIST WHERE GUEST.Name = BLACKLIST.Name AND GUEST.Confirmed = true");
72 if (rset.next()) {
73 System.out.print(
74 "Oh no, (at least) one of the guest from the black list confirmed their presence!\nThe name of the first one is "
75 + rset.getString(2)
76 + ".\n");
77 }
78
79 // EXERCISE 3
80 System.out.print(
81 "Do you want to remove all the guests that are on the black list and confirmed their presence? Enter \"Y\" for yes, anything else for no.\n");
82 if (key.nextLine().equals("Y")) {
83 stmt.execute(
84 "DELETE FROM GUEST WHERE NAME IN (SELECT NAME FROM BLACKLIST) AND Confirmed = true;");
85 }
86
87 } catch (SQLException ex) {
88 ex.printStackTrace();
89 }
90 }
91 }
File notes/code/sql/HW_DefaultTest.sql added (mode: 100644) (index 0000000..aab0b6d)
1 /* code/sql/HW_DEFAULT_test.sql */
2
3 DROP SCHEMA IF EXISTS HW_DEFAULT_test;
4 CREATE SCHEMA HW_DEFAULT_test;
5 USE HW_DEFAULT_test;
6
7 CREATE TABLE TEST(
8 TestA VARCHAR(15),
9 TestB INT,
10 TestC FLOAT,
11 TestD BOOLEAN,
12 TestE BIT(1),
13 TestF DATE
14 );
15
16 INSERT INTO TEST VALUES (DEFAULT, DEFAULT, DEFAULT, DEFAULT, DEFAULT, DEFAULT);
17
18 SELECT * FROM TEST;
File notes/code/sql/HW_Residency.sql added (mode: 100644) (index 0000000..2bbfcd4)
1 /* code/sql/HW_RESIDENCY.sql */
2
3 DROP SCHEMA IF EXISTS HW_RESIDENCY;
4 CREATE SCHEMA HW_RESIDENCY;
5 USE HW_RESIDENCY;
6
7 CREATE TABLE PERSON(
8 FName VARCHAR(40),
9 LName VARCHAR(40),
10 SSN VARCHAR(11) PRIMARY KEY,
11 Birthdate DATE
12 );
13
14 CREATE TABLE HOUSE(
15 Address VARCHAR(40) PRIMARY KEY,
16 Color ENUM("blue", "white", "green")
17 );
18
19 CREATE TABLE RESIDENCY(
20 Person VARCHAR(11),
21 House VARCHAR(40),
22 PrincipalResidence BOOLEAN,
23 Status ENUM("own", "rent", "squat", "other"),
24 FOREIGN KEY (Person) REFERENCES PERSON(SSN),
25 FOREIGN KEY (House) REFERENCES HOUSE(Address) ON DELETE CASCADE
26 );
27
28 INSERT INTO PERSON VALUES
29 (NULL, "Doe", "000-00-0000", NULL), -- P.1
30 ("Michael", "Keal", "000-00-0001", DATE"1983-02-11"), -- P.2
31 ("James", "Baldwin", "000-00-0002", DATE"1967-01-01"), -- P.3
32 ("Mridula", "Warrier", "000-00-0003", DATE"1990-02-11"); -- P.4
33
34 INSERT INTO HOUSE VALUES
35 ("123 Main St.", "blue"), -- H.1
36 ("456 Second St.", "white"), -- H.2
37 ("11 Third St.", "blue"); -- H.3
38
39 INSERT INTO RESIDENCY VALUES
40 ("000-00-0001", "123 Main St.", TRUE, "own"), -- R.1
41 ("000-00-0001", "456 Second St.", FALSE, "own"), -- R.2
42 ("000-00-0002", "123 Main St.", TRUE, "rent"), -- R.3
43 ("000-00-0003", "456 Second St.", TRUE, "own"); -- R.4
File notes/code/sql/HW_ResidencySol.sql added (mode: 100644) (index 0000000..dd70ffd)
1 /* code/sql/ HW_RESIDENCY_SOL.sql */
2
3 DROP SCHEMA IF EXISTS HW_RESIDENCY_SOL;
4 CREATE SCHEMA HW_RESIDENCY_SOL;
5 USE HW_RESIDENCY_SOL;
6
7 CREATE TABLE PERSON(
8 FName VARCHAR(40),
9 LName VARCHAR(40),
10 SSN VARCHAR(11) PRIMARY KEY,
11 Birthdate DATE
12 );
13
14 CREATE TABLE HOUSE(
15 Address VARCHAR(40) PRIMARY KEY,
16 Color ENUM("blue", "white", "green")
17 );
18
19 CREATE TABLE RESIDENCY(
20 Person VARCHAR(11),
21 House VARCHAR(40),
22 PrincipalResidence BOOLEAN,
23 Status ENUM("own", "rent", "squat", "other"),
24 FOREIGN KEY (Person) REFERENCES PERSON(SSN),
25 FOREIGN KEY (House) REFERENCES HOUSE(Address) ON DELETE CASCADE
26 );
27
28 INSERT INTO PERSON VALUES
29 (NULL, "Doe", "000-00-0000", NULL), -- P.1
30 ("Michael", "Keal", "000-00-0001", DATE"1983-02-11"), -- P.2
31 ("James", "Baldwin", "000-00-0002", DATE"1967-01-01"), -- P.3
32 ("Mridula", "Warrier", "000-00-0003", DATE"1990-02-11"); -- P.4
33
34 INSERT INTO HOUSE VALUES
35 ("123 Main St.", "blue"), -- H.1
36 ("456 Second St.", "white"), -- H.2
37 ("11 Third St.", "blue"); -- H.3
38
39 INSERT INTO RESIDENCY VALUES
40 ("000-00-0001", "123 Main St.", TRUE, "own"), -- R.1
41 ("000-00-0001", "456 Second St.", FALSE, "own"), -- R.2
42 ("000-00-0002", "123 Main St.", TRUE, "rent"), -- R.3
43 ("000-00-0003", "456 Second St.", TRUE, "own"); -- R.4
44
45 -- start snippet solution4
46
47 /*
48 In the following we use transactions
49 to be able to simulate the "what if"
50 aspect of the questions: we will not
51 commit the changes we are testing,
52 and roll back on them before moving to
53 the next question.
54 */
55
56 -- Exercise 4
57 -- List the rows (i.e., P.2, H.1, or even “none”) modified by the following statements:
58
59 START TRANSACTION;
60 UPDATE HOUSE SET COLOR = "green";
61 -- H.1, H.2 and H.3
62 ROLLBACK;
63
64 START TRANSACTION;
65 DELETE FROM RESIDENCY WHERE House LIKE "1%";
66 -- R.1,and R.3
67 ROLLBACK;
68
69 START TRANSACTION;
70 DELETE FROM HOUSE WHERE Address = "456 Second St.";
71 -- H.2, R.2 and R.4 (because of the foreign key).
72 ROLLBACK;
73
74 START TRANSACTION;
75 DELETE FROM PERSON WHERE Birthdate=DATE"1990-02-11";
76 -- None, because of the foreign key and the referential integrity constraint.
77 -- ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails (`HW_RESIDENCY_SOL`.`RESIDENCY`, CONSTRAINT `RESIDENCY_ibfk_1` FOREIGN KEY (`Person`) REFERENCES `PERSON` (`SSN`))
78 ROLLBACK;
79
80 -- end snippet solution4
81
82 -- start snippet solution5
83 -- Exercise 5
84 -- Write a query that selects …
85
86 -- … the addresses of the houses in the system (11 Third St., 123 Main St., 456 Second St.).
87 SELECT Address FROM HOUSE;
88
89 -- … the SSN of the persons whose first name was not entered in the system (000-00-0000).
90 SELECT SSN FROM PERSON WHERE FName IS NULL;
91
92 -- … all the different colors of houses (white, blue).
93 SELECT DISTINCT COLOR FROM HOUSE;
94
95 -- … the address of the residency of James Baldwin (123 Main St.).
96 SELECT House
97 FROM RESIDENCY, PERSON
98 WHERE PERSON.Fname = "James"
99 AND PERSON.LName = "Baldwin"
100 AND PERSON.SSN = RESIDENCY.Person;
101
102 -- … the first name of the oldest person in the database (James).
103 SELECT FName
104 FROM PERSON
105 WHERE Birthdate = (
106 SELECT MIN(Birthdate) FROM PERSON WHERE Birthdate IS NOT NULL
107 );
108
109 -- … Michael Keal’s principal residency address (123 Main St.).
110 SELECT RESIDENCY.House
111 FROM RESIDENCY, PERSON
112 WHERE PERSON.FName = "Michael"
113 AND PERSON.LName = "Keal"
114 AND PERSON.SSN = RESIDENCY.Person
115 AND RESIDENCY.PrincipalResidence = TRUE;
116
117 -- … the (distinct) first and last names of the homeowners (Michael Keal, Mridula Warrier).
118 SELECT DISTINCT (PERSON.FName), PERSON.LName
119 FROM PERSON, RESIDENCY
120 WHERE RESIDENCY.Status = "own"
121 AND RESIDENCY.Person = PERSON.SSN;
122 -- cf comment at snippet homonyms
123
124 SELECT PERSON.FName, PERSON.LName
125 FROM PERSON
126 WHERE SSN IN (SELECT DISTINCT(RESIDENCY.Person) FROM RESIDENCY WHERE RESIDENCY.Status = "own");
127
128
129 -- … the SSN of the persons that have the same principal residency as James Baldwin (000-00-0001).
130 SELECT RoomMate.Person
131 FROM RESIDENCY AS James, RESIDENCY AS RoomMate, PERSON
132 WHERE PERSON.FName = "James"
133 AND PERSON.LName = "Baldwin"
134 AND PERSON.SSN = James.Person
135 AND James.House = RoomMate.House
136 AND NOT James.Person = RoomMate.Person
137 AND RoomMate.PrincipalResidence = TRUE;
138
139 -- end snippet solution5
140
141 START TRANSACTION;
142 -- start snippet homonyms
143 -- If we have homonymns in our database, e.g.
144
145 INSERT INTO PERSON VALUES
146 ("A", "B", "000-00-0010", NULL),
147 ("A", "B", "000-00-0011", NULL);
148
149 INSERT INTO HOUSE VALUES
150 ("H", NULL); -- H.3
151
152 INSERT INTO RESIDENCY VALUES
153 ("000-00-0010", "H", TRUE, "own"),
154 ("000-00-0011", "H", TRUE, "own");
155
156 -- Then the query below fails, in the sense that it
157 -- reports the name "A, B" only once.
158
159 SELECT DISTINCT (PERSON.FName), PERSON.LName
160 FROM PERSON, RESIDENCY
161 WHERE RESIDENCY.Status = "own"
162 AND RESIDENCY.Person = PERSON.SSN;
163
164 -- A better (and not much more complicated)
165 -- solution would have been
166
167 SELECT PERSON.FName, PERSON.LName
168 FROM PERSON
169 WHERE SSN IN
170 (SELECT DISTINCT(RESIDENCY.Person)
171 FROM RESIDENCY
172 WHERE RESIDENCY.Status = "own");
173 -- end snippet homonyms
174 ROLLBACK;
File notes/code/sql/HW_TextbookAuthored.sql added (mode: 100644) (index 0000000..8b4e4b8)
1 /* code/sql/HW_TEXTBOOK_AUTHORED.sql */
2
3 DROP SCHEMA IF EXISTS HW_TEXTBOOK_AUTHORED;
4 CREATE SCHEMA HW_TEXTBOOK_AUTHORED;
5 USE HW_TEXTBOOK_AUTHORED;
6
7 CREATE TABLE TEXTBOOK(
8 Title VARCHAR(50),
9 ISBN CHAR(13) PRIMARY KEY,
10 Price DECIMAL(10,2)
11 );
12
13 CREATE TABLE AUTHOR(
14 LName VARCHAR(30),
15 FName VARCHAR(30),
16 Email VARCHAR(30),
17 PRIMARY KEY(Lname, Fname)
18 );
19
20 CREATE TABLE AUTHORED(
21 Book CHAR(13),
22 FOREIGN KEY (Book)
23 REFERENCES TEXTBOOK(ISBN),
24 AuthorLName VARCHAR(30),
25 AuthorFName VARCHAR(30),
26 FOREIGN KEY (AuthorLName, AuthorFName)
27 REFERENCES AUTHOR(LName, Fname)
28 );
29
30 INSERT INTO TEXTBOOK VALUES
31 ('Starting Out with Java: Early Objects',
32 9780133776744,
33 30.00),
34 ('NoSQL for Mere Mortals',
35 9780134023212,
36 47.99);
37
38 INSERT INTO AUTHOR VALUES
39 ('Sullivan', 'Dan', NULL),
40 ('Gaddis', 'Tony', NULL);
41
42 INSERT INTO AUTHORED VALUES
43 (9780134023212, 'Sullivan', 'Dan'),
44 (9780133776744, 'Gaddis', 'Tony');
File notes/code/sql/HW_TextbookAuthoredSol.sql added (mode: 100644) (index 0000000..0e0655e)
1 /*
2 DO **NOT** EDIT THE CODE BELOW
3 */
4
5 DROP SCHEMA IF EXISTS HW_PROJECT1;
6 CREATE SCHEMA HW_PROJECT1;
7 USE HW_PROJECT1;
8
9 CREATE TABLE TEXTBOOK(
10 Title VARCHAR(50),
11 ISBN CHAR(13) PRIMARY KEY,
12 Price DECIMAL(10,2)
13 );
14
15 CREATE TABLE AUTHOR(
16 LName VARCHAR(30),
17 FName VARCHAR(30),
18 Email VARCHAR(30),
19 PRIMARY KEY(Lname, Fname)
20 );
21
22 -- The meaning of this table is that
23 -- a tuple <I, L, F> means that the
24 -- author whose last name is L and whose
25 -- first name is F wrote the textbook
26 -- whose ISBN is I.
27
28 CREATE TABLE AUTHORED(
29 Book CHAR(13),
30 FOREIGN KEY (Book)
31 REFERENCES TEXTBOOK(ISBN),
32 AuthorLName VARCHAR(30),
33 AuthorFName VARCHAR(30),
34 FOREIGN KEY (AuthorLName, AuthorFName)
35 REFERENCES AUTHOR(LName, Fname)
36 );
37
38 INSERT INTO TEXTBOOK VALUES
39 ('Starting Out with Java: Early Objects',
40 9780133776744,
41 30.00),
42 ('NoSQL for Mere Mortals',
43 9780134023212,
44 47.99);
45
46 INSERT INTO AUTHOR VALUES
47 ('Sullivan', 'Dan', NULL),
48 ('Gaddis', 'Tony', NULL);
49
50 INSERT INTO AUTHORED VALUES
51 (9780134023212, 'Sullivan', 'Dan'),
52 (9780133776744, 'Gaddis', 'Tony');
53
54 /*
55 START EDITING
56 */
57
58 -- start snippet solution
59
60 /* code/sql/HW_TEXTBOOK_AUTHORED_SOL.sql */
61
62 -- EXERCISE 1
63
64 -- Write a command that updates the email address of 'Gaddis', 'Tony'
65 -- to "tgaddis@pearson.com"
66
67 UPDATE AUTHOR SET Email = "tgaddis@pearson.com"
68 WHERE LName = 'Gaddis' AND FName = 'Tony';
69
70 -- You can use
71 -- SELECT * FROM AUTHOR;
72 -- to check that the modification took place.
73
74
75 -- EXERCISE 2
76
77 -- Write a command that inserts the textbook of your choice in the
78 -- TEXTBOOK table. No value should be NULL, but you can invent
79 -- the values.
80
81 INSERT INTO TEXTBOOK VALUES ('Fundamentals of Database Systems', 9780133970777, 165.89);
82
83 -- You can use
84 -- SELECT * FROM TEXTBOOK;
85 -- to check that the insertion was correctly made.
86
87
88 -- EXERCISE 3
89
90 -- Write a command that makes 'Gaddis', 'Tony' the author of the
91 -- textbook you just added to our database.
92
93 INSERT INTO AUTHORED VALUES(9780133970777, 'Gaddis', 'Tony');
94
95 -- You can use
96 -- SELECT * FROM AUTHORED;
97 -- to check that the insertion was correctly made.
98
99
100 -- EXERCISE 4
101
102 -- Write a command that makes "0.01" becomes the
103 -- default value for the Price attribute of the
104 -- TEXTBOOK relation.
105
106 ALTER TABLE TEXTBOOK ALTER COLUMN Price SET DEFAULT 0.01;
107
108 -- You can use
109 -- DESCRIBE TEXTBOOK;
110 -- to check that the Price attribute now has a default
111 -- value.
112
113
114 -- EXERCISE 5
115
116 -- Write a command that insert a textbook of
117 -- your choice in the TEXTBOOK table, with the
118 -- price set to the default value.
119
120 INSERT INTO TEXTBOOK VALUES('Proof Theory', 9780486490731, DEFAULT);
121
122 -- You can use
123 -- SELECT * FROM TEXTBOOK;
124 -- to check that the insertion was correctly made.
125
126
127 -- EXERCISE 6
128
129 -- Write a command that creates a table called EDITOR
130 -- with 3 attributes, "Name", "Address" and "Website".
131 -- The "Name" attribute should be the primary key.
132 -- Then, insert two tuples in the EDITOR table, one
133 -- should have the "Name" attribute set to "Pearson".
134
135 CREATE TABLE EDITOR(
136 Name VARCHAR(30)
137 PRIMARY KEY,
138 Address VARCHAR(255),
139 Website VARCHAR(100)
140 );
141
142 INSERT INTO EDITOR VALUES
143 ('Pearson', NULL, 'http://pearsoned.com/'),
144 ('Dover', NULL, 'https://store.doverpublications.com/');
145
146 -- You can use
147 -- DESCRIBE EDITOR;
148 -- to check that the table was actually created, and
149 -- SELECT * FROM EDITOR;
150 -- to check that the values were inserted.
151
152
153 -- EXERCISE 7
154
155 -- Write a command that creates a table called PUBLISHED
156 -- with 2 attributes, "Editor", and "Textbook".
157 -- The "Editor" attribute should references the EDITOR
158 -- table, and the "Textbook" attribute should reference
159 -- the TEXTBOOK table.
160
161 CREATE TABLE PUBLISHED(
162 Editor VARCHAR(30),
163 FOREIGN KEY (Editor)
164 REFERENCES EDITOR(Name),
165 Textbook CHAR(13),
166 FOREIGN KEY (Textbook)
167 REFERENCES TEXTBOOK(ISBN)
168 );
169
170 -- You can use
171 -- DESCRIBE PUBLISHED;
172 -- to check that the table was actually created.
173
174
175 -- EXERCISE 8
176
177 -- Write a command that makes "Pearson" the editor of
178 -- the textbook whose ISBN is 9780133776744.
179
180 INSERT INTO PUBLISHED VALUES ("Pearson", 9780133776744);
181
182 -- You can use
183 -- SELECT * FROM PUBLISHED;
184 -- to check that the table was actually created.
185
186
187 -- EXERCISE 9
188
189 -- Answer the following short questions. In our model,
190 -- as it is, …
191
192 -- can an author have authored more than one textbook?
193 -- Yes.
194
195 -- can a textbook have more than one author?
196 -- Yes.
197
198 -- can a textbook without ISBN be inserted in the
199 -- TEXTBOOK relation?
200 -- No, unless you create a "dummy" (fake) value for it,
201 -- like 0000000000000, but this value can be used only
202 -- once, since ISBN is the primary key.
203
204 -- can the price of a textbook be negative?
205 -- Yes. We can actually test it:
206 -- INSERT INTO TEXTBOOK VALUES ("Test", 0000000000000, -1);
207
208 -- can two author have the same first and last name?
209 -- No. The query
210 -- INSERT INTO AUTHOR VALUES ('Smith', 'Bob', NULL), ('Smith', 'Bob', NULL);
211 -- returns
212 -- ERROR 1062 (23000): Duplicate entry 'Smith-Bob' for key 'PRIMARY'
213
214 -- can two textbooks have the same title?
215 -- Yes, as long as they have different ISBN. The command
216 -- INSERT INTO TEXTBOOK VALUES ("Test", 0000000000001, NULL), ("Test", 0000000000002, NULL);
217 -- is processed just fine.
218
219 -- can two editiors have the same address?
220 -- Yes. The command
221 -- INSERT INTO EDITOR VALUES ("Test 1", "123 Main St.", NULL), ("Test 2", "123 Main St.", NULL);
222 -- is processed just fine.
223
224 -- end snippet solution
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