List of commits:
Subject Hash Author Date (UTC)
Add files via upload 101413087f21fa91a122027b83935f567a154575 poonamveeral 2020-04-02 15:18:46
Add files via upload 4b23b55a1a74e30626ffb0908597a02b8c05c1ba poonamveeral 2020-04-02 15:17:53
Add files via upload 7de4d7172002df5784c6585a382de55f35d909a8 poonamveeral 2020-04-02 15:17:30
Add files via upload e7780bd581399dcc09a61771e79515b4e5eff1c2 poonamveeral 2020-04-02 15:16:37
Initial commit 19b3cf0fb56429d4c4b5aabb08367390540246d5 Poonam Veeral 2020-04-02 15:09:01
Commit 101413087f21fa91a122027b83935f567a154575 - Add files via upload
Author: poonamveeral
Author date (UTC): 2020-04-02 15:18
Committer name: GitHub
Committer date (UTC): 2020-04-02 15:18
Parent(s): 4b23b55a1a74e30626ffb0908597a02b8c05c1ba
Signer:
Signing key: 4AEE18F83AFDEB23
Signing status: E
Tree: 23200cdd7965fdc4b3d3e41b9713fa7d5ee58fa4
File Lines added Lines deleted
notes/code/java/AdvancedProg.java 252 0
notes/code/java/FirstProg.java 47 0
notes/code/java/FirstProgBis.java 33 0
notes/code/java/GuestProgram.java 41 0
notes/code/java/GuestProgram_Solution.java 91 0
notes/code/java/InsecureProgram.java 40 0
notes/code/java/MongoTest.java 63 0
notes/code/java/ProgWithErrors.java 37 0
notes/code/java/ProgWithErrorsPatched.java 38 0
notes/code/java/ScrollingProgram.java 121 0
notes/code/java/SimpleInjection_1.java 47 0
notes/code/java/SimpleInjection_2.java 50 0
notes/code/java/SimpleInjection_3.java 50 0
notes/code/java/TestForNull.java 30 0
notes/code/sql/HW_Avg.sql 14 0
notes/code/sql/HW_Certificate.sql 113 0
notes/code/sql/HW_Computer.sql 42 0
notes/code/sql/HW_ComputerVariation.sql 35 0
notes/code/sql/HW_ConstraintsPart1.sql 18 0
notes/code/sql/HW_DBCoffee.sql 134 0
notes/code/sql/HW_Department.sql 94 0
notes/code/sql/HW_EBookshop.sql 23 0
notes/code/sql/HW_FKtest.sql 16 0
notes/code/sql/HW_Faculty.sql 69 0
notes/code/sql/HW_HelloWorld.sql 3 0
notes/code/sql/HW_Lecture.sql 87 0
notes/code/sql/HW_PKtest.sql 11 0
notes/code/sql/HW_Person.sql 40 0
notes/code/sql/HW_ProcedureExamples.sql 60 0
notes/code/sql/HW_SimpleBook.sql 48 0
notes/code/sql/HW_Train.sql 63 0
notes/code/sql/HW_TriggerExample.sql 97 0
notes/code/sql/HW_Work.sql 57 0
notes/code/sql/HW_WorkSol.sql 138 0
notes/code/xml/Customers.xml 45 0
notes/code/xml/NSF_Award.xml 52 0
notes/code/xml/Shiporder.xml 23 0
File notes/code/java/AdvancedProg.java added (mode: 100644) (index 0000000..11b8bb7)
1 // code/java/AdvancedProg.java
2
3 /*
4 * This is a long program, introducing:
5 * I. How to pass options when connecting to the database,
6 * II. How to create a table,
7 * III. How to insert values,
8 * IV. How to use prepared statements,
9 * V. How to read backward and write in ResultSets.
10 *
11 * If you want to run this program multiple times, you have to either:
12 * 1. Comment first statement of II. Creating a table
13 * 2. Change the name of the schema, from HW_DBPROG to whatever you want
14 * 3. Drop the DVD table: connect to your database, and then enter
15 * USE HW_DBPROG; DROP TABLE DVD;
16 * Or do it from within your program!
17 *
18 * If you use option 1, you will keep inserting tuples in your table: cleaning it with DELETE
19 * FROM DVD; can help. You can do it from within the program!
20 */
21 import java.sql.*;
22
23 public class AdvancedProg {
24 public static void main(String[] args) {
25 try (
26
27 // I. Passing options to the dababse
28
29 Connection conn =
30 DriverManager.getConnection(
31 "jdbc:mysql://localhost:3306/HW_DBPROG"
32 + "?user=testuser"
33 + "&password=password"
34 + "&allowMultiQueries=true"
35 + "&createDatabaseIfNotExist=true"
36 + "&useSSL=true");
37
38 /*
39 * Read about other options at
40 * https://dev.mysql.com/doc/connector-j/5.1/en/connector-j-reference-configuration-properties.html
41 * https://jdbc.postgresql.org/documentation/head/connect.html
42 */
43
44 Statement stmt = conn.createStatement(); ) {
45
46 // II. Creating a table
47
48 stmt.execute(
49 "CREATE TABLE DVD ("
50 + "Title CHAR(25) PRIMARY KEY, "
51 + "Minutes INTEGER, "
52 + "Price DOUBLE)");
53
54 /*
55 * If we were to execute
56 * SHOW TABLES
57 * directly in the MySQL interpreter, this would display at the screen
58 *
59 * +--------------------------+
60 * | Tables_in_HW_NewDataBase |
61 * +--------------------------+
62 * | DVD |
63 * +--------------------------+
64 *
65 * But here, to access this information, we will use the connection's metadata.
66 */
67
68 DatabaseMetaData md = conn.getMetaData();
69 // DatabaseMetaData is a class used to get information about the database: the driver, the
70 // user, the versions, etc.
71
72 ResultSet rs = md.getTables(null, null, "%", null);
73
74 /*
75 * You can read at
76 * https://docs.oracle.com/javase/7/docs/api/java/sql/DatabaseMetaData.html#getTables(java.lang.String,%20java.lang.String,%20java.lang.String,%20java.lang.String[])
77 * the full specification of this method.
78 * All you need to know, for now, is that the third parameter is
79 * String tableNamePattern,
80 * i.e., what must match the table name as it is stored in the database
81 * Here, by using the wildcard "%", we select all the table names.
82 * We can then iterate over the ResultSet as usual:
83 */
84
85 while (rs.next()) {
86 System.out.println(
87 rs.getString(3)); // In the ResultSet returned by getTables, 3 is the TABLE_NAME.
88 }
89
90 // III. Inserting values
91
92 String sqlStatement = "INSERT INTO DVD VALUES ('Gone With The Wind', 221, 3);";
93 int rowsAffected = stmt.executeUpdate(sqlStatement);
94 System.out.print(sqlStatement + " changed " + rowsAffected + " row(s).\n");
95
96 // Batch Insertion
97
98 String insert1 = "INSERT INTO DVD VALUES ('Aa', 129, 0.2)";
99 String insert2 = "INSERT INTO DVD VALUES ('Bb', 129, 0.2)";
100 String insert3 = "INSERT INTO DVD VALUES ('Cc', 129, 0.2)";
101 String insert4 = "INSERT INTO DVD VALUES ('DD', 129, 0.2)";
102
103 /*
104 * Method 1: Using executeUpdate, if the option allowMultiQueries=true was passed in the url given to getConnection
105 * and your DBMS supports it.
106 */
107 stmt.executeUpdate(insert1 + ";" + insert2);
108
109 // Method 2: Using the addBatch and executeBatch methods
110 stmt.addBatch(insert3);
111 stmt.addBatch(insert4);
112 stmt.executeBatch();
113
114 // IV. Prepared Statements
115
116 // Example 1
117 sqlStatement =
118 "SELECT title FROM DVD WHERE Price <= ?"; // We have a string with an empty slot,
119 // represented by "?".
120 PreparedStatement ps =
121 conn.prepareStatement(
122 sqlStatement); // We create a PreparedStatement object, using that string with an
123 // empty slot.
124 /*
125 * Note that once the object is created, we cannot change the content of the query, beside instantiating the slot.
126 * cf. e.g. the discussion at <https://stackoverflow.com/q/25902881/>.
127 */
128 double maxprice = 0.5;
129 ps.setDouble(
130 1, maxprice); // This statement says "Fill the first slot with the value of maxprice".
131 ResultSet result =
132 ps.executeQuery(); // And then we can execute the query, and display the results:
133
134 System.out.printf("For %.2f you can get:\n", maxprice);
135
136 while (result.next()) {
137 System.out.printf("\t %s \n", result.getString(1));
138 }
139
140 // Example 2
141 sqlStatement =
142 "INSERT INTO DVD VALUES (?, ?, ?)"; // Now, our string has 3 empty slots, and it is an
143 // INSERT statement.
144 PreparedStatement preparedStatement = conn.prepareStatement(sqlStatement);
145
146 preparedStatement.setString(1, "The Great Dictator");
147 preparedStatement.setInt(2, 124);
148 preparedStatement.setDouble(3, 5.4);
149
150 rowsAffected =
151 preparedStatement
152 .executeUpdate(); // You can check "by hand" that this statement was correctly
153 // executed.
154 System.out.print(preparedStatement.toString() + " changed " + rowsAffected + " row(s).\n");
155
156 // If we try to mess things up, i.e., provide wrong datatypes:
157 preparedStatement.setString(1, "The Great Dictator");
158 preparedStatement.setString(2, "The Great Dictator");
159 preparedStatement.setString(3, "The Great Dictator");
160
161 /*
162 * Java compiler will be ok, but we'll have an error at execution time when executing the query. You can uncomment the line below to see for yourself.
163 * rowsAffected = preparedStatement.executeUpdate();
164 */
165
166 // Of course, we can use prepared statement inside loops.
167 for (int i = 1; i < 5; i++) {
168 preparedStatement.setString(1, "Saw " + i);
169 preparedStatement.setInt(2, 100);
170 preparedStatement.setDouble(3, .5);
171 preparedStatement.executeUpdate();
172 }
173
174 // V. Reading backward and writing in ResultSets
175
176 // To read backward and write in ResultSets, you need to have a statement with certain
177 // options:
178
179 Statement stmtNew =
180 conn.createStatement(ResultSet.TYPE_SCROLL_SENSITIVE, ResultSet.CONCUR_UPDATABLE);
181
182 /*
183 * Those options change two things about the ResultSet we obtain using this statement
184 *
185 * The first argument is the scrolling level:
186 * TYPE_FORWARD_ONLY = default.
187 * TYPE_SCROLL_INSENSITIVE = can scroll, but updates don't impact result set.
188 * TYPE_SCROLL_SENSITIVE = can scroll, update impact result set.
189 *
190 * The second argument is the concurrency level:
191 * CONCUR_READ_ONLY: default.
192 * CONCUR_UPDATABLE: we can change the database without issuing SQL statement.
193 */
194
195 // Reading backward
196
197 sqlStatement = "SELECT title FROM DVD WHERE Price < 1;";
198 result = stmtNew.executeQuery(sqlStatement);
199
200 System.out.println("For $1, you can get:");
201
202 if (result.last()) { // We can jump to the end of the ResultSet
203 System.out.print(result.getString("Title") + " ");
204 }
205
206 System.out.print("and also, (in reverse order)");
207
208 while (result.previous()) { // Now we can scroll back!
209 System.out.print(result.getString("Title") + " ");
210 }
211
212 /*
213 * Other methods to navigate in ResultSet:
214 * first()
215 * last()
216 * next()
217 * previous()
218 * relative(x) : move cursor x times (positive = forward, negative = backward)
219 * absolute(x): move to the row number x. 1 is the first.
220 */
221
222 // Changing the values
223
224 System.out.print("\n\nLet us apply a 50% discount. Currently, the prices are:\n");
225
226 sqlStatement = "SELECT title, price FROM DVD;";
227 result = stmtNew.executeQuery(sqlStatement);
228 while (result.next()) {
229 System.out.printf("%20s \t $%3.2f\n", result.getString("title"), result.getDouble("price"));
230 }
231
232 result.absolute(0); // We need to scroll back!
233
234 while (result.next()) {
235 double current = result.getDouble("price");
236 result.updateDouble("price", (current * 0.5));
237 result.updateRow();
238 }
239 System.out.print("\n\nAfter update, the prices are:\n");
240
241 result.absolute(0); // We need to scroll back!
242
243 while (result.next()) {
244 System.out.printf("%20s \t $%3.2f\n", result.getString("title"), result.getDouble("price"));
245 }
246
247 conn.close();
248 } catch (SQLException ex) {
249 ex.printStackTrace();
250 }
251 }
252 }
File notes/code/java/FirstProg.java added (mode: 100644) (index 0000000..8d680f0)
1 // code/java/FirstProg.java
2
3 import java.sql.*;
4
5 public class FirstProg {
6 public static void main(String[] args) {
7 try (Connection conn =
8 DriverManager.getConnection(
9 "jdbc:mysql://localhost:3306/HW_EBOOKSHOP", "testuser", "password");
10 /*
11 * If at execution time you receive an error that starts with
12 * "java.sql.SQLException: The server time zone value 'EDT' is unrecognized or
13 * represents more than one time zone. You must configure either the server ..."
14 * add ?serverTimezone=UTC at the end of the previous string,
15 * i.e., replace the previous lines of code with:
16 * Connection conn = DriverManager.getConnection("jdbc:mysql://localhost:3306/HW_EBOOKSHOP?serverTimezone=UTC", "testuser","password");
17 * cf. for instance https://stackoverflow.com/q/26515700
18 * Or, change your server's configuration, cf.
19 * https://stackoverflow.com/a/44720416
20 */
21 Statement stmt = conn.createStatement(); ) {
22 String strSelect = "SELECT title, price, qty FROM BOOKS WHERE qty > 40";
23 System.out.print("The SQL query is: " + strSelect + "\n");
24 ResultSet rset = stmt.executeQuery(strSelect);
25
26 System.out.println("The records selected are:");
27 int rowCount = 0;
28 String title;
29 double price;
30 int qty;
31
32 while (rset.next()) {
33 title = rset.getString("title");
34 price = rset.getDouble("price");
35 qty = rset.getInt("qty");
36 System.out.println(title + ", " + price + ", " + qty);
37 rowCount++;
38 }
39
40 System.out.println("Total number of records = " + rowCount);
41 conn.close();
42
43 } catch (SQLException ex) {
44 ex.printStackTrace();
45 }
46 }
47 }
File notes/code/java/FirstProgBis.java added (mode: 100644) (index 0000000..27c2126)
1 import java.sql.*;
2
3 public class FirstProgBis {
4 public static void main(String[] args) {
5 try (Connection conn =
6 DriverManager.getConnection(
7 "jdbc:mysql://localhost:3306/HW_EBOOKSHOP", "testuser", "password");
8 Statement stmt = conn.createStatement(); ) {
9 // start snippet alternate
10 // code/java/FirstProgBis.java
11 String strSelect = "SELECT * FROM BOOKS";
12 ResultSet rset = stmt.executeQuery(strSelect);
13
14 System.out.println("The records selected are:");
15
16 ResultSetMetaData rsmd = rset.getMetaData();
17 int columnsNumber = rsmd.getColumnCount();
18 String columnValue;
19 while (rset.next()) {
20 for (int i = 1; i <= columnsNumber; i++) {
21 if (i > 1) System.out.print(", ");
22 columnValue = rset.getString(i);
23 System.out.print(columnValue + " " + rsmd.getColumnName(i));
24 }
25 System.out.println();
26 // end snippet alternate
27 }
28 conn.close();
29 } catch (SQLException ex) {
30 ex.printStackTrace();
31 }
32 }
33 }
File notes/code/java/GuestProgram.java added (mode: 100644) (index 0000000..e549239)
1 // code/java/GuestProgram.java
2
3 import java.sql.*;
4 import java.util.Scanner; // Importing a java API to read from the keyboard.
5
6 // This first part is "standard". Just note that we allow multiple statements.
7
8 public class GuestProgram {
9 public static void main(String[] args) {
10 try (Connection conn =
11 DriverManager.getConnection(
12 "jdbc:mysql://localhost:3306/?user=testuser&password=password"
13 + "&allowMultiQueries=true");
14 Statement stmt = conn.createStatement(); ) {
15 // We create a schema, use it, create two tables, and insert a value in the second one.
16 stmt.execute(
17 "CREATE SCHEMA HW_GUEST_PROGRAM;"
18 + "USE HW_GUEST_PROGRAM;"
19 + "CREATE TABLE GUEST("
20 + "Id INT PRIMARY KEY,"
21 + "Name VARCHAR(30),"
22 + "Confirmed BOOL"
23 + ");"
24 + "CREATE TABLE BLACKLIST("
25 + "Name VARCHAR(30)"
26 + ");"
27 + "INSERT INTO BLACKLIST VALUES (\"Marcus Hells\");");
28
29 /*
30 * INSERT HERE Solution to exercises 1, 2 and 3.
31 * Tip for Exercise 1, this solves the first item.
32 */
33 System.out.print("How many guests do you have?\n");
34 Scanner key = new Scanner(System.in);
35 int guest_total = key.nextInt();
36
37 } catch (SQLException ex) {
38 ex.printStackTrace();
39 }
40 }
41 }
File notes/code/java/GuestProgram_Solution.java added (mode: 100644) (index 0000000..01b15cb)
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/java/InsecureProgram.java added (mode: 100644) (index 0000000..1e56215)
1 // code/java/InsecureProgram.java
2
3 import java.sql.*;
4 import java.util.Scanner;
5
6 public class InsecureProgram {
7 public static void main(String[] args) {
8 try (Connection conn =
9 DriverManager.getConnection(
10 "jdbc:mysql://localhost:3306/?user=testuser&password=password");
11 Statement stmt = conn.createStatement(); ) {
12
13 stmt.addBatch("DROP SCHEMA IF EXISTS HW_InsecureProgram");
14 stmt.addBatch("CREATE SCHEMA HW_InsecureProgram");
15 stmt.addBatch("USE HW_InsecureProgram");
16 stmt.addBatch("CREATE TABLE DISK(Title VARCHAR(30), Price DOUBLE)");
17 stmt.addBatch("CREATE TABLE BOOK(Title VARCHAR(30), Price DOUBLE)");
18 stmt.addBatch("CREATE TABLE VINYL(Title VARCHAR(30), Price DOUBLE)");
19 stmt.addBatch("INSERT INTO DISK VALUES('test', 12)");
20 stmt.addBatch("INSERT INTO DISK VALUES('Hidden', NULL)");
21 stmt.executeBatch();
22
23 Scanner key = new Scanner(System.in);
24 System.out.print(
25 "Do you want to browse the table containing DISK, BOOK or VINYL? (please enter exactly the table name)?\n");
26 String table = key.nextLine();
27 System.out.print("How much money do you have?\n");
28 String max = key.nextLine();
29 ResultSet rst =
30 stmt.executeQuery("SELECT Title FROM " + table + " WHERE PRICE <= " + max + ";");
31 System.out.printf("Here are the %s you can afford with %s: \n", table, max);
32 while (rst.next()) {
33 System.out.printf("\t- %s \n", rst.getString(1));
34 }
35
36 } catch (SQLException ex) {
37 ex.printStackTrace();
38 }
39 }
40 }
File notes/code/java/MongoTest.java added (mode: 100644) (index 0000000..5e5af51)
1 // code/java/MongoTest.java
2
3 /*
4 * javac -cp .:mongo-java-driver-3.7.0-rc0.jar MongoTest.java
5 * java -cp .:mongo-java-driver-3.7.0-rc0.jar MongoTest
6 */
7
8 import com.mongodb.MongoClient;
9 import com.mongodb.client.MongoCollection;
10 import com.mongodb.client.MongoDatabase;
11 import java.util.ArrayList;
12 import java.util.Arrays;
13 import java.util.List;
14 import org.bson.Document;
15
16 public class MongoTest {
17 public static void main(String[] args) {
18
19 /*
20 * MongoClientURI connectionString = new MongoClientURI("mongodb://localhost:27017");
21 * MongoClient mongoClient = new MongoClient(connectionString);
22 */
23 MongoClient mongoClient = new MongoClient();
24
25 MongoDatabase database =
26 mongoClient.getDatabase(
27 "mydb"); // Creates the database if it doesn't exist, when we add documents to it.
28
29 MongoCollection<Document> collection = database.getCollection("test");
30
31 /*
32 * To create a document, we use the Document class: https://mongodb.github.io/mongo-java-driver/3.4/driver/getting-started/quick-start/
33 * We want to insert the following document:
34
35 * {
36 * "name" : "MongoDB",
37 * "type" : "database",
38 * "count" : 1,
39 * "versions": [ "v3.2", "v3.0", "v2.6" ],
40 * "info" : { "level" : "easy", "used" : "yes" }
41 * }
42
43 * Remember that the order does not matter.
44 */
45
46 Document doc = new Document("name", "MongoDB");
47 doc.append("type", "database");
48 doc.append("count", 1);
49 doc.append("versions", Arrays.asList("v3.2", "v3.0", "v2.6"));
50 doc.append("info", new Document("level", "easy").append("used", "yes"));
51
52 collection.insertOne(doc);
53
54 List<Document> documents = new ArrayList<Document>();
55 for (int i = 0; i < 10; i++) {
56 documents.add(new Document("i", i));
57 }
58
59 collection.insertMany(documents);
60
61 System.out.println(collection.count());
62 }
63 }
File notes/code/java/ProgWithErrors.java added (mode: 100644) (index 0000000..5a66f9d)
1 // code/java/ProgWithErrors.java
2
3 import java.sql.*;
4
5 public class ProgWithErrors {
6 public static void main(String[] args) {
7 try (Connection conn =
8 DriverManager.getConnection(
9 "jdbc:mysql://localhost:3306/" + "HW_TestDB?user=testuser&password=password");
10 Statement stmt = conn.createStatement(); ) {
11
12 // Errors after this point.
13
14 String strSelect = "SELECT title FROM DISKS WHERE qty > 40;";
15 ResultSet rset = stmt.executeUpdate(strSelect);
16
17 System.out.println("The records selected are: (listed last first):");
18 rset.last();
19
20 while (rset.previous()) {
21 String title = rset.getDouble("title");
22 System.out.println(title + "\n");
23 }
24
25 String sss = "SELECT title FROM DISKS WHERE Price <= ?";
26 PreparedStatement ps = conn.prepareStatement(sss);
27 ResultSet result = ps.executeQuery();
28
29 conn.close();
30
31 // Errors before this point.
32
33 } catch (SQLException ex) {
34 ex.printStackTrace();
35 }
36 }
37 }
File notes/code/java/ProgWithErrorsPatched.java added (mode: 100644) (index 0000000..b08c4d5)
1 // code/java/ProgWithErrorsPatched.java
2
3 import java.sql.*;
4
5 public class ProgWithErrorsPatched {
6 public static void main(String[] args) {
7 try (Connection conn =
8 DriverManager.getConnection(
9 "jdbc:mysql://localhost:3306/" + "HW_TestDB?user=testuser&password=password");
10 Statement stmt = conn.createStatement(); ) {
11
12 // Errors after this point.
13
14 String strSelect = "SELECT title FROM DISKS WHERE qty > 40;";
15 ResultSet rset = stmt.executeQuery(strSelect); // Error 1
16
17 System.out.println("The records selected are: (listed last first):");
18 rset.last();
19
20 do { // Error 2
21 String title = rset.getString("title"); // Error 3
22 System.out.println(title); // Not an error, but we probably don't need two new lines.
23 } while (rset.previous()); // Error 2 bis
24
25 String sss = "SELECT title FROM DISKS WHERE Price <= ?";
26 PreparedStatement ps = conn.prepareStatement(sss);
27 ps.setInt(1, 10); // Error 4
28 ResultSet result = ps.executeQuery();
29
30 conn.close();
31
32 // Errors before this point.
33
34 } catch (SQLException ex) {
35 ex.printStackTrace();
36 }
37 }
38 }
File notes/code/java/ScrollingProgram.java added (mode: 100644) (index 0000000..cef4b62)
1 // code/java/ScrollingProgram.java
2
3 import java.sql.*;
4
5 public class ScrollingProgram {
6 public static void main(String[] args) {
7 try (Connection conn =
8 DriverManager.getConnection(
9 "jdbc:mysql://localhost:3306/"
10 // We connect to the database, not to a particular schema.
11 + "?user=testuser"
12 + "&password=password"
13 + "&allowMultiQueries=true"
14
15 /*
16 * We want to allow multiple statements
17 * to be shipped in one execute() call.
18 */
19
20 );
21 Statement stmt =
22 conn.createStatement(ResultSet.TYPE_SCROLL_SENSITIVE, ResultSet.CONCUR_READ_ONLY);
23 /*
24 * Finally, we want to be able to move back and forth in our
25 * ResultSets. This implies that we have to also chose if the
26 * ResultSets will be updatable or not: we chose to have them
27 * to be "read-only".
28 */
29 ) {
30
31 /*
32 * Before you ask: no, there are no "simple" way of
33 * constructing a string over multiple lines,
34 * besides concatenating them,
35 * cf. e.g. https://stackoverflow.com/q/878573
36 */
37
38 stmt.execute(
39 "DROP SCHEMA IF EXISTS HW_SCROLLABLE_DEMO;"
40 +
41 /*
42 * We drop the schema we want to use if it already exists.
43 * (This allows to execute the same program multiple times.)
44 */
45
46 "CREATE SCHEMA HW_SCROLLABLE_DEMO;"
47 + "USE HW_SCROLLABLE_DEMO;"
48 +
49 // We create and use the schema.
50 "CREATE TABLE TEST("
51 + " Id INT"
52 + ");"
53 // The schema contains only one very simple table.
54 );
55 /*
56 * We can execute all those queries at once
57 * because we passed the "allowMultiQueries=true"
58 * token when we created the Connection object.
59 */
60
61 // Let us insert some dummy values in this dummy table:
62 for (int i = 0; i < 10; i++) stmt.addBatch("INSERT INTO TEST VALUES (" + i + ")");
63 /*
64 * no ";" in the statements that we add
65 * to the batch!
66 */
67 stmt.executeBatch();
68 // We execute the 10 statements that were loaded at once.
69
70 // Now, let us write a simple query, and navigate in the result:
71
72 ResultSet rs = stmt.executeQuery("SELECT * FROM TEST");
73 /*
74 * We select all the tuples in the table.
75 * If we were to execute this instruction on the
76 * command-line interface, we would get:
77
78 * MariaDB [HW_SCROLLABLE_DEMO]> SELECT * FROM TEST;
79 * +----+
80 * | Id |
81 * +----+
82 * | 0 |
83 * | 1 |
84 * | 2 |
85 * | 3 |
86 * | 4 |
87 * | 5 |
88 * | 6 |
89 * | 7 |
90 * | 8 |
91 * | 9 |
92 * +----+
93 * 10 rows in set (0.001 sec)
94 */
95
96 // We can "jump" to the 8th result in the set:
97 rs.absolute(8);
98 System.out.printf("%-22s %s %d.\n", "After absolute(8),", "we are at Id", rs.getInt(1));
99 /* Note that this would display "7" since the
100 * 8th result contains the value 7 (sql starts
101 * counting at 1.
102 */
103
104 // We can move back 1 item:
105 rs.relative(-1);
106 System.out.printf("%-22s %s %d.\n", "After relative(-1),", "we are at Id", rs.getInt(1));
107
108 // We can move to the last item:
109 rs.last();
110 System.out.printf("%-22s %s %d.\n", "After last(),", "we are at Id", rs.getInt(1));
111
112 // We can move to the first item:
113 rs.first();
114 System.out.printf("%-22s %s %d.\n", "After first(),", "we are at Id", rs.getInt(1));
115
116 conn.close();
117 } catch (SQLException ex) {
118 ex.printStackTrace();
119 }
120 }
121 }
File notes/code/java/SimpleInjection_1.java added (mode: 100644) (index 0000000..de1b474)
1 // code/java/SimpleInjection_1.java
2
3 import java.sql.*;
4 import java.util.Scanner; // Importing a java API to read from the keyboard.
5
6 public class SimpleInjection_1 {
7 public static void main(String[] args) {
8 try (Connection conn =
9 DriverManager.getConnection(
10 "jdbc:mysql://localhost:3306/?user=testuser&password=password"
11 + "&allowMultiQueries=true");
12 Statement stmt =
13 conn.createStatement(ResultSet.TYPE_SCROLL_SENSITIVE, ResultSet.CONCUR_READ_ONLY); ) {
14 stmt.addBatch("DROP SCHEMA IF EXISTS HW_SIMPLE_INJECTION_1");
15 stmt.addBatch("CREATE SCHEMA HW_SIMPLE_INJECTION_1");
16 stmt.addBatch("USE HW_SIMPLE_INJECTION_1");
17 stmt.addBatch("CREATE TABLE SECRETVIP(Name VARCHAR(30))");
18 stmt.addBatch("INSERT INTO SECRETVIP VALUES (\"Marcus Hells\")");
19 stmt.executeBatch();
20
21 Scanner key = new Scanner(System.in);
22
23 System.out.print(
24 "\n\nTo test the program, enter\n"
25 + "\t• \"Marcus Hells\" (without the quotes) to confirm that guessing correctly triggers the correct result,\n"
26 + "\t• \"n' OR '1' = '1\" (without the double quotes (\")) to perform an SQL injection.\n"
27 + "\t• anything else to confirm that guessing correctly triggers the correct result,\n");
28
29 while (true) {
30 System.out.print("\n\nType the name of someone who may be the secret VIP.\n");
31
32 String entered = key.nextLine();
33
34 ResultSet rset =
35 stmt.executeQuery("SELECT * FROM SECRETVIP WHERE Name ='" + entered + "';");
36 if (rset.next()) {
37 System.out.print("Yes," + rset.getString(1) + " is our secret VIP!\n");
38 } else {
39 System.out.print("Nope, \"" + entered + "\" is not our secret VIP.\n");
40 }
41 }
42
43 } catch (SQLException ex) {
44 ex.printStackTrace();
45 }
46 }
47 }
File notes/code/java/SimpleInjection_2.java added (mode: 100644) (index 0000000..1446b7d)
1 // code/java/SimpleInjection_2.java
2
3 import java.sql.*;
4 import java.util.Scanner; // Importing a java API to read from the keyboard.
5
6 public class SimpleInjection_2 {
7 public static void main(String[] args) {
8 try (Connection conn =
9 DriverManager.getConnection(
10 "jdbc:mysql://localhost:3306/?user=testuser&password=password"
11 + "&allowMultiQueries=true");
12 Statement stmt =
13 conn.createStatement(ResultSet.TYPE_SCROLL_SENSITIVE, ResultSet.CONCUR_READ_ONLY); ) {
14 stmt.addBatch("DROP SCHEMA IF EXISTS HW_SIMPLE_INJECTION_2");
15 stmt.addBatch("CREATE SCHEMA HW_SIMPLE_INJECTION_2");
16 stmt.addBatch("USE HW_SIMPLE_INJECTION_2");
17 stmt.addBatch("CREATE TABLE SECRETVIP(Name VARCHAR(30))");
18 stmt.addBatch("INSERT INTO SECRETVIP VALUES (\"Marcus Hells\")");
19 stmt.executeBatch();
20
21 Scanner key = new Scanner(System.in);
22
23 System.out.print(
24 "\n\nTo test the program, enter\n"
25 + "\t• \"Marcus Hells\" (without the quotes) to confirm that guessing correctly triggers the correct result,\n"
26 + "\t• \"nope'; DROP SCHEMA HW_SIMPLE_INJECTION_2;\" (without the double quotes (\")) to perform an SQL injection.\n"
27 + "\t• anything else to confirm that guessing correctly triggers the correct result,\n");
28
29 while (true) {
30 System.out.print("\n\nType the name of someone who may be the secret VIP.\n");
31
32 String entered = key.nextLine();
33
34 stmt.execute("SELECT * FROM SECRETVIP WHERE Name ='" + entered + "';");
35 ResultSet rst = stmt.getResultSet();
36
37 boolean found = rst.first();
38
39 if (found) {
40 System.out.print("Yes, you found it!\n");
41 } else {
42 System.out.print("Nope, " + entered + " is not our secret VIP.\n");
43 }
44 }
45
46 } catch (SQLException ex) {
47 ex.printStackTrace();
48 }
49 }
50 }
File notes/code/java/SimpleInjection_3.java added (mode: 100644) (index 0000000..950b652)
1 // code/java/SimpleInjection_3.java
2
3 import java.sql.*;
4 import java.util.Scanner; // Importing a java API to read from the keyboard.
5
6 public class SimpleInjection_3 {
7 public static void main(String[] args) {
8 try (Connection conn =
9 DriverManager.getConnection(
10 "jdbc:mysql://localhost:3306/?user=testuser&password=password"
11 + "&allowMultiQueries=true");
12 Statement stmt =
13 conn.createStatement(ResultSet.TYPE_SCROLL_SENSITIVE, ResultSet.CONCUR_READ_ONLY); ) {
14 stmt.addBatch("DROP SCHEMA IF EXISTS HW_SIMPLE_INJECTION_3");
15 stmt.addBatch("CREATE SCHEMA HW_SIMPLE_INJECTION_3");
16 stmt.addBatch("USE HW_SIMPLE_INJECTION_3");
17 stmt.addBatch("CREATE TABLE SECRETVIP(Name VARCHAR(30))");
18 stmt.addBatch("INSERT INTO SECRETVIP VALUES (\"Marcus Hells\")");
19 stmt.executeBatch();
20
21 Scanner key = new Scanner(System.in);
22
23 System.out.print(
24 "\n\nTo test the program, enter\n"
25 + "\t• \"Marcus Hells\" (without the quotes) to confirm that guessing correctly triggers the correct result,\n"
26 + "\t• anything else to confirm that guessing correctly triggers the correct result.\n\n"
27 + "This program uses prepared statement, and as such is extremely good at preventing SQL injections.\n\n");
28
29 PreparedStatement ps = conn.prepareStatement("SELECT * FROM SECRETVIP WHERE Name = ?;");
30
31 while (true) {
32 System.out.print("\n\nType the name of someone who may be the secret VIP.\n");
33
34 String entered = key.nextLine();
35
36 ps.setString(1, entered);
37 ResultSet rset = ps.executeQuery();
38
39 if (rset.next()) {
40 System.out.print("Yes, " + rset.getString(1) + "is our secret VIP!\n");
41 } else {
42 System.out.print("Nope, " + entered + " is not our secret VIP.\n");
43 }
44 }
45
46 } catch (SQLException ex) {
47 ex.printStackTrace();
48 }
49 }
50 }
File notes/code/java/TestForNull.java added (mode: 100644) (index 0000000..4cbe034)
1 // code/java/TestForNull.java
2
3 import java.sql.*;
4
5 public class TestForNull {
6 public static void main(String[] args) {
7 try (Connection conn =
8 DriverManager.getConnection(
9 "jdbc:mysql://localhost:3306/HW_DBPROG?user=testuser&password=password&createDatabaseIfNotExist=true&serverTimezone=UTC");
10 Statement stmt = conn.createStatement(); ) {
11 stmt.execute("CREATE TABLE Test (" + "A CHAR(25), " + "B INTEGER, " + "C DOUBLE)");
12
13 String strAdd = "INSERT INTO Test VALUES (NULL, NULL, NULL);";
14 int number_of_row_changed = stmt.executeUpdate(strAdd);
15 System.out.print("This last query changed " + number_of_row_changed + " row(s).\n");
16
17 ResultSet result = stmt.executeQuery("SELECT * FROM Test");
18
19 if (result.next()) {
20 System.out.print(result.getString(1) + " " + result.getDouble(2) + " " + result.getInt(3));
21 if (result.getString(1) == null) {
22 System.out.print("\nAnd null for CHAR in SQL is null for String in Java.\n");
23 }
24 }
25 conn.close();
26 } catch (SQLException ex) {
27 ex.printStackTrace();
28 }
29 }
30 }
File notes/code/sql/HW_Avg.sql added (mode: 100644) (index 0000000..7250e6a)
1 /* code/sql/HW_Avg.sql */
2
3 DROP SCHEMA IF EXISTS HW_Avg;
4 CREATE SCHEMA HW_Avg;
5 USE HW_AVG;
6
7 CREATE TABLE TEST(
8 Test INT
9 );
10
11 INSERT INTO TEST VALUES (null), (0), (10);
12
13 SELECT AVG(Test) FROM TEST;
14 -- Returns 5.0
File notes/code/sql/HW_Certificate.sql added (mode: 100644) (index 0000000..f25bb70)
1 /* code/sql/HW_Certificate.sql */
2
3 DROP SCHEMA IF EXISTS HW_Certificate;
4 CREATE SCHEMA HW_Certificate;
5 USE HW_Certificate;
6
7 /*
8 SN = Serial Number
9 CN = Common Name
10 CA = Certificate Authority
11 */
12
13 CREATE TABLE ORGANIZATION(
14 SN VARCHAR(30) PRIMARY KEY,
15 CN VARCHAR(30)
16 );
17
18 CREATE TABLE CA(
19 SN VARCHAR(30) PRIMARY KEY,
20 CN VARCHAR(30),
21 Trusted BOOL
22 );
23 CREATE TABLE CERTIFICATE(
24 SN VARCHAR(30) PRIMARY KEY,
25 CN Varchar(30) NOT NULL,
26 Org VARCHAR(30) NOT NULL,
27 Issuer VARCHAR(30),
28 Valid_Since DATE,
29 Valid_Until DATE,
30 FOREIGN KEY (Org)
31 REFERENCES ORGANIZATION(SN)
32 ON DELETE CASCADE,
33 FOREIGN KEY (Issuer)
34 REFERENCES CA(SN)
35 );
36
37 INSERT INTO ORGANIZATION VALUES
38 ('01', 'Wikimedia Foundation'),
39 ('02', 'Free Software Foundation');
40
41 INSERT INTO CA VALUES
42 ('A', "Let's Encrypt", true),
43 ('B', 'Shady Corp.', false),
44 ('C', 'NewComer Ltd.', NULL);
45
46 INSERT INTO CERTIFICATE VALUES
47 ('a', '*.wikimedia.org', '01', 'A', 20180101, 20200101),
48 ('b', '*.fsf.org', '02', 'A', 20180101, 20191010),
49 ('c', '*.shadytest.org', '02', 'B', 20190101, 20200101),
50 ('d', '*.wikipedia.org', '01', 'C', 20200101, 20220101);
51
52 -- CN of all certificates.
53 SELECT CN FROM CERTIFICATE;
54 -- (*.wikimedia.org | *.fsf.org | *.shadytest.org | *.wikipedia.org)
55
56 -- The SN of the organizations whose CN contains "Foundation"
57 SELECT SN FROM ORGANIZATION WHERE CN LIKE "%Foundation%";
58 -- (01 | 02)
59
60 -- The CN and expiration date of all the certificates that expired (assuming we are the 6th of December 2019).
61 SELECT CN, Valid_Until FROM CERTIFICATE WHERE Valid_Until < DATE'20191206';
62 -- (*.fsf.org, 2019-10-10)
63
64 -- The CN of the CA that are not trusted.
65 SELECT CN FROM CA WHERE Trusted IS NOT TRUE;
66 -- (Shady Corp. | NewComer Ltd.)
67
68 -- The CN of the certificates that are signed by a CA that is not trusted.
69 SELECT CERTIFICATE.CN FROM CERTIFICATE, CA
70 WHERE Trusted IS NOT TRUE
71 AND CA.SN = CERTIFICATE.Issuer;
72 -- (Shady Corp. | NewComer Ltd.)
73
74 -- The number of certificates signed by the CA whose CN is "Let's encrypt".
75 SELECT COUNT(CERTIFICATE.SN) AS "Number of certificates signed by Let's encrypt"
76 FROM CERTIFICATE, CA
77 WHERE CERTIFICATE.Issuer = CA.SN
78 AND CA.CN = "Let's encrypt";
79 -- (2)
80
81 -- A table listing the CN of the organizations along with the CN of their certificates.
82 SELECT ORGANIZATION.CN AS Organization, CERTIFICATE.CN AS Certificate
83 FROM ORGANIZATION, CERTIFICATE WHERE
84 CERTIFICATE.Org = ORGANIZATION.SN;
85 -- ( Wikimedia Foundation, *.wikimedia.org | Free Software Foundation, *.fsf.org | Free Software Foundation , *.shadytest.org | Wikimedia Foundation , *.wikipedia.org )
86
87
88 /*
89 DELETE FROM CA WHERE SN = 'A';
90 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`))
91
92 => Rejected, because an entry in CERTIFICATE references this tuple (referential integrity constraint).
93
94 UPDATE ORGANIZATION SET CN = "FSF" WHERE SN = '02';
95 Query OK, 1 row affected (0.008 sec)
96 Rows matched: 1 Changed: 1 Warnings: 0
97
98 => Ok, change
99 ('02', 'Free Software Foundation');
100 into
101 ('02', 'FSF');
102 in ORGANIZATION
103
104 MariaDB [HW_Certificate]> UPDATE ORGANIZATION SET SN = "01" WHERE SN = '02';
105 ERROR 1451 (23000): Cannot delete or update a parent row: a foreign key constraint fails (`HW_Certificate`.`CERTIFICATE`, CONSTRAINT `CERTIFICATE_ibfk_1` FOREIGN KEY (`Org`) REFERENCES `ORGANIZATION` (`SN`) ON DELETE CASCADE)
106
107 => Rejected, because an entry in CERTIFICATE references this tuple (referential integrity constraint).
108 This query would have been rejected even if this tuple was not referenced, since it would have violated the entity integrity constraint.
109
110 DELETE FROM ORGANIZATION;
111
112 => Deletes all the content of organization and of certificate.
113 */
File notes/code/sql/HW_Computer.sql added (mode: 100644) (index 0000000..3c9846b)
1 /* code/sql/HW_Computer.sql */
2
3 DROP SCHEMA IF EXISTS HW_Computer;
4 CREATE SCHEMA HW_Computer;
5 USE HW_Computer;
6
7
8 CREATE TABLE COMPUTER(
9 ID VARCHAR(20) PRIMARY KEY,
10 Model VARCHAR(20)
11 );
12
13 CREATE TABLE PRINTER(
14 ID VARCHAR(20) PRIMARY KEY,
15 Model VARCHAR(20)
16 );
17
18 CREATE TABLE CONNEXION(
19 Computer VARCHAR(20),
20 Printer VARCHAR(20),
21 PRIMARY KEY(Computer, Printer),
22 FOREIGN KEY (Computer) REFERENCES COMPUTER(ID),
23 FOREIGN KEY (Printer) REFERENCES PRINTER(ID)
24 );
25
26 INSERT INTO COMPUTER VALUES
27 ('A', 'DELL A'),
28 ('B', 'HP X'),
29 ('C', 'ZEPTO D'),
30 ('D', 'MAC Y');
31
32 INSERT INTO PRINTER VALUES
33 ('12', 'HP-140'),
34 ('13', 'HP-139'),
35 ('14', 'HP-140'),
36 ('15', 'HP-139');
37
38 INSERT INTO CONNEXION VALUES
39 ('A', '12'),
40 ('A', '13'),
41 ('B', '13'),
42 ('C', '14');
File notes/code/sql/HW_ComputerVariation.sql added (mode: 100644) (index 0000000..2fd8f37)
1 /* code/sql/HW_ComputerVariation.sql */
2
3
4 DROP SCHEMA IF EXISTS HW_ComputerVariation;
5 CREATE SCHEMA HW_ComputerVariation;
6 USE HW_ComputerVariation;
7
8 CREATE TABLE COMPUTER(
9 ID VARCHAR(20) PRIMARY KEY,
10 Model VARCHAR(20)
11 );
12 CREATE TABLE PERIPHERAL(
13 ID VARCHAR(20) PRIMARY KEY,
14 Model VARCHAR(20),
15 Type ENUM('mouse', 'keyboard',
16 'screen', 'printer')
17 );
18 CREATE TABLE CONNEXION(
19 Computer VARCHAR(20),
20 Peripheral VARCHAR(20),
21 PRIMARY KEY(Computer, Peripheral),
22 FOREIGN KEY (Computer)
23 REFERENCES COMPUTER(ID),
24 FOREIGN KEY (Peripheral)
25 REFERENCES PERIPHERAL(ID)
26 );
27 INSERT INTO COMPUTER VALUES
28 ('A', 'Apple IIc Plus'),
29 ('B', 'Commodore SX-64');
30 INSERT INTO PERIPHERAL VALUES
31 ('12', 'Trendcom Model', 'printer'),
32 ('14', 'TP-10 Thermal Matrix', 'printer'),
33 ('15', 'IBM Selectric', 'keyboard');
34 INSERT INTO CONNEXION VALUES
35 ('A', '12'), ('B', '14'), ('A', '15');
File notes/code/sql/HW_ConstraintsPart1.sql added (mode: 100644) (index 0000000..f82d2ce)
1 /* code/sql/HW_ConstraintsPart1.sql */
2
3 DROP SCHEMA IF EXISTS HW_ConstraintsPart1;
4 CREATE SCHEMA HW_ConstraintsPart1;
5 USE HW_ConstraintsPart1;
6
7 CREATE TABLE HURRICANE(
8 Name VARCHAR(25) PRIMARY KEY,
9 WindSpeed INT DEFAULT 76 CHECK (WindSpeed > 74 AND WindSpeed < 500),
10 -- 75mph is the minimum to be considered as a hurricane
11 -- cf. https://www.hwn.org/resources/bws.html
12 Above VARCHAR(25)
13 );
14
15 CREATE TABLE STATE(
16 Name VARCHAR(25) UNIQUE,
17 Postal_abbr CHAR(2) NOT NULL
18 );
File notes/code/sql/HW_DBCoffee.sql added (mode: 100644) (index 0000000..ae51f65)
1 /* code/sql/HW_DBCoffee.sql */
2
3 /*
4 * Setting up the data
5 */
6
7 DROP SCHEMA IF EXISTS HW_DBCoffee;
8 CREATE SCHEMA HW_DBCoffee;
9 USE HW_DBCoffee;
10
11 CREATE TABLE COFFEE(
12 Ref VARCHAR(30) PRIMARY KEY,
13 Origin VARCHAR(30),
14 TypeOfRoast VARCHAR(30),
15 PricePerPound DOUBLE
16 );
17 CREATE TABLE CUSTOMER(
18 CardNo VARCHAR(30) PRIMARY KEY,
19 Name VARCHAR(30),
20 Email VARCHAR(30),
21 FavCoffee VARCHAR(30),
22 FOREIGN KEY (FavCoffee) REFERENCES COFFEE(Ref) ON UPDATE CASCADE ON DELETE CASCADE
23 );
24 CREATE TABLE PROVIDER(
25 Name VARCHAR(30) PRIMARY KEY,
26 Email VARCHAR(30)
27 );
28 CREATE TABLE SUPPLY(
29 Provider VARCHAR(30),
30 Coffee VARCHAR(30),
31 PRIMARY KEY (Provider, Coffee),
32 FOREIGN KEY (Provider) REFERENCES PROVIDER(Name) ON UPDATE CASCADE ON DELETE CASCADE,
33 FOREIGN KEY (Coffee) REFERENCES COFFEE(Ref) ON UPDATE CASCADE ON DELETE CASCADE
34 );
35 INSERT INTO COFFEE VALUES
36 (001, 'Brazil', 'Light', 8.9),
37 (121, 'Bolivia', 'Dark', 7.5),
38 (311, 'Brazil', 'Medium', 9.0),
39 (221, 'Sumatra', 'Dark', 10.25);
40 INSERT INTO CUSTOMER VALUES
41 (001, 'Bob Hill', 'b.hill@sip.net', 221),
42 (002, 'Ana Swamp', 'swampa@nca.edu', 311),
43 (003, 'Mary Sea', 'brig@gsu.gov', 121),
44 (004, 'Pat Mount', 'pmount@fai.fr', 121);
45 INSERT INTO PROVIDER VALUES
46 ('Coffee Unl.', 'bob@cofunl.com'),
47 ('Coffee Exp.', 'pat@coffeex.dk'),
48 ('Johns & Co.', NULL);
49 INSERT INTO SUPPLY VALUES
50 ('Coffee Unl.', 001),
51 ('Coffee Unl.', 121),
52 ('Coffee Exp.', 311),
53 ('Johns & Co.', 221);
54
55 -- Question 2:
56 START TRANSACTION;
57
58 INSERT INTO CUSTOMER VALUES(005, Bob Hill, NULL, 001);
59
60 INSERT INTO COFFEE VALUES(002, "Peru", "Decaf", 3.00);
61
62 INSERT INTO PROVIDER VALUES(NULL, "contact@localcof.com"); -- ERROR 1048 (23000): Column 'Name' cannot be null
63
64 INSERT INTO SUPPLY VALUES("Johns & Co.", 121);
65
66 INSERT INTO SUPPLY VALUES("Coffee Unl.", 311, 221); -- ERROR 1136 (21S01): Column count doesn't match value count at row 1
67
68 --COMMIT;
69 -- Rest the changes:
70 ROLLBACK;
71
72 -- Question 3:
73
74 START TRANSACTION;
75 UPDATE CUSTOMER SET FavCoffee = 001 WHERE CardNo = 001; -- Rows matched: 1 Changed: 1 Warnings: 0
76 SELECT * FROM CUSTOMER;
77 ROLLBACK;
78
79 START TRANSACTION;
80 UPDATE COFFEE SET TypeOfRoast = 'Decaf' WHERE Origin = 'Brazil'; -- Rows matched: 2 Changed: 2 Warnings: 0
81 SELECT * FROM COFFEE;
82 ROLLBACK;
83
84 START TRANSACTION;
85 UPDATE PROVIDER SET Name = 'Coffee Unlimited' WHERE Name = 'Coffee Unl.'; -- Rows matched: 1 Changed: 1 Warnings: 0
86 SELECT * FROM PROVIDER;
87 SELECT * FROM SUPPLY;
88 ROLLBACK;
89
90 START TRANSACTION;
91 UPDATE COFFEE SET PricePerPound = 10.00 WHERE PricePerPound > 10.00; -- Rows matched: 1 Changed: 1 Warnings: 0
92 SELECT * FROM COFFEE;
93 ROLLBACK;
94
95 -- Question 4:
96
97 START TRANSACTION;
98 DELETE FROM CUSTOMER WHERE Name LIKE '%S%'; -- Query OK, 2 rows affected (0.01 sec)
99 SELECT * FROM CUSTOMER;
100 ROLLBACK;
101
102 START TRANSACTION;
103 DELETE FROM COFFEE WHERE Ref = 001; -- Query OK, 1 row affected (0.00 sec)
104 SELECT * FROM COFFEE;
105 SELECT * FROM SUPPLY;
106 ROLLBACK;
107
108 START TRANSACTION;
109 DELETE FROM SUPPLY WHERE Provider = 'Coffee Unl.' AND Coffee = '001'; -- Query OK, 1 row affected (0.00 sec)
110 SELECT* FROM SUPPLY;
111 ROLLBACK;
112
113 START TRANSACTION;
114 DELETE FROM PROVIDER WHERE Name = 'Johns & Co.'; -- Query OK, 1 row affected (0.00 sec)
115 SELECT * FROM PROVIDER;
116 SELECT * FROM SUPPLY;
117 ROLLBACK;
118
119 -- Question 5:
120
121 -- 1.
122 SELECT Origin FROM COFFEE WHERE TypeOfRoast = 'Dark';
123
124 -- 2.
125 SELECT FavCoffee FROM CUSTOMER WHERE Name LIKE 'Bob%';
126
127 -- 3.
128 SELECT Name FROM PROVIDER WHERE Email IS NULL;
129
130 -- 4.
131 SELECT COUNT(*) FROM SUPPLY WHERE Provider = 'Johns & Co.';
132
133 -- 5.
134 SELECT Provider FROM COFFEE, SUPPLY WHERE TypeOfRoast = 'Dark' AND Coffee = Ref;
File notes/code/sql/HW_Department.sql added (mode: 100644) (index 0000000..a226776)
1 /* code/sql/HW_Department.sql */
2
3 /*
4 Preamble:
5 The following is in case you want to run your program on your installation:
6 */
7
8 DROP SCHEMA IF EXISTS HW_Department;
9 -- Carefull, we are dropping the schema HW_Department if it exists already, and all the data in it.
10 CREATE SCHEMA HW_Department;
11 -- And then re-creating it.
12 USE HW_Department;
13
14 /*
15 End of the preamble.
16 */
17
18
19 CREATE TABLE DEPARTMENT(
20 ID INT PRIMARY KEY,
21 Name VARCHAR(30)
22 );
23
24 CREATE TABLE EMPLOYEE(
25 ID INT PRIMARY KEY,
26 Name VARCHAR(30),
27 Hired DATE,
28 Department INT,
29 FOREIGN KEY (Department)
30 REFERENCES DEPARTMENT(ID)
31 );
32
33 INSERT INTO DEPARTMENT VALUES
34 (1, "Storage"),
35 (2, "Hardware");
36
37 INSERT INTO EMPLOYEE VALUES
38 (1, "Bob", 20100101, 1),
39 (2, "Samantha", 20150101, 1),
40 (3, "Mark", 20050101, 2),
41 (4, "Karen", NULL, 1),
42 (5, "Jocelyn", 20100101, 1);
43
44 SELECT EMPLOYEE.Name
45 FROM EMPLOYEE, DEPARTMENT
46 WHERE DEPARTMENT.Name = "Storage"
47 AND EMPLOYEE.Department = DEPARTMENT.ID;
48
49 /*
50 Will return:
51 Bob
52 Samantha
53 Karen
54 Jocelyn
55 and not Mark, since that employee works in a differente department.
56 */
57
58 SELECT Name
59 FROM EMPLOYEE
60 WHERE Hired <= ALL (
61 SELECT Hired
62 FROM EMPLOYEE
63 WHERE Hired IS NOT NULL
64 );
65
66 /*
67 Will return
68 Mark
69 since he has the smallest hiring date,
70 excluding Karen (whose hiring date is
71 unknown).
72 */
73
74 SELECT EMPLOYEE.Name
75 FROM EMPLOYEE, DEPARTMENT
76 WHERE Hired <= ALL (
77 SELECT Hired
78 FROM EMPLOYEE
79 WHERE Hired IS NOT NULL
80 AND DEPARTMENT.Name = "Storage"
81 AND EMPLOYEE.Department = DEPARTMENT.ID
82 )
83 AND DEPARTMENT.Name = "Storage"
84 AND EMPLOYEE.Department = DEPARTMENT.ID;
85
86 /*
87 Will return
88 Bob
89 Jocelyn
90 since those are the two employees of the
91 department whose name is Storage that have
92 the smallest hiring date among the
93 employee of the department whose name is storage.
94 */
File notes/code/sql/HW_EBookshop.sql added (mode: 100644) (index 0000000..b579df0)
1 /* code/sql/HW_EBookshop.sql */
2
3 DROP SCHEMA IF EXISTS HW_EBookshop;
4 CREATE DATABASE HW_EBookshop;
5 USE HW_EBookshop;
6
7 CREATE TABLE BOOKS (
8 ID INT PRIMARY KEY,
9 title VARCHAR(50),
10 author VARCHAR(50),
11 price DECIMAL(10, 2),
12 qty INT
13 );
14
15 /* Cf. https://en.wikipedia.org/wiki/List_of_best-selling_books */
16
17 INSERT INTO BOOKS VALUES (1, 'The Communist Manifesto', 'Karl Marx and Friedrich Engels', 11.11, 11);
18 INSERT INTO BOOKS VALUES (2, 'Don Quixote', 'Miguel de Cervantes', 22.22, 22);
19 INSERT INTO BOOKS VALUES (3, 'A Tale of Two Cities', 'Charles Dickens', 33.33, 33);
20 INSERT INTO BOOKS VALUES (4, 'The Lord of the Rings', 'J. R. R. Tolkien', 44.44, 44);
21 INSERT INTO BOOKS VALUES (5, 'Le Petit Prince', 'Antoine de Saint-Exupéry', 55.55, 55);
22
23 SELECT * FROM BOOKS;
File notes/code/sql/HW_FKtest.sql added (mode: 100644) (index 0000000..531798e)
1 /* code/sql/HW_FK_test.sql */
2
3 DROP SCHEMA IF EXISTS HW_FKtest;
4
5 CREATE SCHEMA HW_FKtest;
6
7 USE HW_FKtest;
8
9 CREATE TABLE TARGET(
10 Test VARCHAR(15) PRIMARY KEY
11 );
12
13 CREATE TABLE SOURCE(
14 Test VARCHAR(25),
15 FOREIGN KEY (Test) REFERENCES TARGET(Test)
16 );
File notes/code/sql/HW_Faculty.sql added (mode: 100644) (index 0000000..1f0b7fe)
1 /* code/sql/HW_Faculty.sql */
2
3 -- We first drop the schema if it already exists:
4 DROP SCHEMA IF EXISTS HW_Faculty;
5
6 -- Then we create the schema:
7 CREATE SCHEMA HW_Faculty;
8
9 /*
10 Or we could have use the syntax:
11
12 CREATE DATABASE HW_FACUTLY;
13
14 */
15
16 -- Now, let us create a table in it:
17 CREATE TABLE HW_Faculty.PROF(
18 Fname VARCHAR(15),
19 -- No String!
20 -- The value "15" vas picked randomly, any value below 255 would
21 -- more or less do the same. Note that declaring extremely large
22 -- values without using them can impact the performance of
23 -- your database, cf. for instance https://dba.stackexchange.com/a/162117/
24 Room INT,
25 -- shorthad for INTEGER, are also available: SMALLINT, FLOAT, REAL, DEC
26 -- The "REAL" datatype is like the "DOUBLE" datatype of C# (they are actually synonyms in SQL):
27 -- more precise than the "FLOAT" datatype, but not as exact as the "NUMERIC" datatype.
28 -- cf. https://dev.mysql.com/doc/refman/8.0/en/numeric-types.html
29 Title CHAR(3),
30 -- fixed-length string, padded with blanks if needed
31 Tenured BIT(1),
32 Nice BOOLEAN,
33 -- True / False (= 0) / Unknown
34 Hiring DATE,
35 -- The DATE is always supposed to be entered in a YEAR/MONTH/DAY variation.
36 -- To tune the way it will be displayed, you can use the "DATE_FORMAT" function
37 -- (cf. https://dev.mysql.com/doc/refman/8.0/en/date-and-time-functions.html#function_date-format),
38 -- but you can enter those values only using the "standard" literals
39 -- (cf. https://dev.mysql.com/doc/refman/8.0/en/date-and-time-literals.html )
40 Last_seen TIME,
41 FavoriteFruit ENUM('apple', 'orange', 'pear'),
42 PRIMARY KEY(Fname, Hiring)
43 );
44
45 /*
46 Or, instead of using the fully qualified name HW_Faculty.PROF,
47 we could have done:
48
49 USE HW_Faculty;
50 CREATE TABLE PROF(…)
51
52 */
53
54 -- Let us use this schema, from now on.
55 USE HW_Faculty;
56
57 -- Let us insert some "Dummy" value in our table:
58 INSERT INTO PROF VALUES
59 (
60 "Clément", -- Or 'Clément'.
61 290,
62 'PhD',
63 0,
64 NULL,
65 '19940101', -- Or '940101', '1994-01-01', '94/01/01'
66 '090500', -- Or '09:05:00', '9:05:0', '9:5:0', '090500'
67 -- Note also the existence of DATETIME, with 'YYYY-MM-DD HH:MM:SS'
68 'Apple' -- This is not case-sensitive, oddly enough.
69 );
File notes/code/sql/HW_HelloWorld.sql added (mode: 100644) (index 0000000..55b1104)
1 /* code/sql/HW_HelloWorld.sql */
2
3 SELECT "Hello World!";
File notes/code/sql/HW_Lecture.sql added (mode: 100644) (index 0000000..4005d10)
1 /* code/sql/HW_Lecture.sql */
2
3 -- Question 2
4 CREATE TABLE HW_Lecture(
5 Name VARCHAR(25),
6 Instructor VARCHAR(25),
7 Year YEAR(4),
8 Code CHAR(5),
9 PRIMARY KEY(Year, Code),
10 FOREIGN KEY (Instructor) REFERENCES PROF(Login)
11 );
12
13 INSERT INTO HW_Lecture VALUES
14 ('Intro to CS', 'caubert', 2017, '1304'),
15 ('Intro to Algebra', 'perdos', 2017, '1405'),
16 ('Intro to Cyber', 'aturing', 2017, '1234');
17
18 -- This representation can not handle the following situations:
19 -- - If multiple instructors teach the same class,
20 -- - If the HW_Lecture is taught more than once a year (either because it is taught in the Fall, Spring and Summer, or if multiple sections are offered at the same time),
21 -- - If a HW_Lecture is cross-listed, then some duplication of information will be needed.
22
23
24 -- Question 3
25 ALTER TABLE GRADE
26 ADD COLUMN LectureCode CHAR(5),
27 ADD COLUMN LectureYear YEAR(4);
28
29 DESCRIBE GRADE;
30
31 SELECT * FROM GRADE;
32
33 ALTER TABLE GRADE
34 ADD FOREIGN KEY (LectureYear, LectureCode)
35 REFERENCES HW_Lecture(Year, Code);
36
37 -- The values for LectureCode and LectureYear are set to NULL in all the tuples.
38
39 -- Question 4
40 UPDATE GRADE SET LectureCode = '1304', LectureYear = 2017
41 WHERE Login = 'jrakesh'
42 AND Grade = '2.85';
43
44 UPDATE GRADE SET LectureCode = '1405', LectureYear = 2017
45 WHERE Login = 'svlatka'
46 OR (Login = 'jrakesh' AND Grade = '3.85');
47
48 UPDATE GRADE SET LectureCode = '1234', LectureYear = 2017
49 WHERE Login = 'aalyx'
50 OR Login = 'cjoella';
51
52 -- Question 6
53 SELECT Login, Grade
54 FROM GRADE
55 WHERE Lecturecode='1304'
56 AND LectureYear = '2017';
57
58 SELECT DISTINCT Instructor
59 FROM HW_Lecture
60 WHERE Year = 2017;
61
62 SELECT Name, Grade
63 FROM STUDENT, GRADE
64 WHERE GRADE.LectureCode = 1405
65 AND STUDENT.Login = GRADE.Login;
66
67 SELECT Year
68 FROM HW_Lecture
69 WHERE Code = '1234';
70
71 SELECT Name
72 FROM HW_Lecture
73 WHERE Year IN
74 (SELECT Year
75 FROM HW_Lecture
76 WHERE CODE = '1234');
77
78 SELECT B.name
79 FROM STUDENT AS A, STUDENT AS B
80 WHERE A.Name = 'Ava Alyx'
81 AND A.Registered > B.Registered;
82
83 SELECT COUNT(DISTINCT PROF.Name) AS 'Head Teaching This Year'
84 FROM HW_Lecture, DEPARTMENT, PROF
85 WHERE Year = 2017
86 AND Instructor = Head
87 AND Head = PROF.Login;
File notes/code/sql/HW_PKtest.sql added (mode: 100644) (index 0000000..178a35a)
1 /* code/sql/HW_PKtest.sql */
2
3 DROP SCHEMA IF EXISTS HW_PKtest;
4 CREATE SCHEMA HW_PKtest;
5 USE HW_PKtest;
6
7 CREATE TABLE TEST(
8 A INT,
9 B INT,
10 PRIMARY KEY (A,B)
11 );
File notes/code/sql/HW_Person.sql added (mode: 100644) (index 0000000..ccd8d15)
1 /* code/sql/HW_Person.sql */
2
3 DROP SCHEMA IF EXISTS HW_Person;
4 CREATE SCHEMA HW_Person;
5 USE HW_Person;
6
7 CREATE TABLE PERSON(
8 ID VARCHAR(25) PRIMARY KEY,
9 Name VARCHAR(25),
10 Street VARCHAR(25),
11 City VARCHAR(25),
12 Seat VARCHAR(25),
13 Position VARCHAR(25)
14 );
15
16 CREATE TABLE CAR(
17 Vin VARCHAR(25) PRIMARY KEY,
18 Make VARCHAR(25),
19 Model VARCHAR(25),
20 Year DATE,
21 Driver VARCHAR(25),
22 FOREIGN KEY (Driver) REFERENCES PERSON(ID)
23 ON UPDATE CASCADE
24 );
25
26 ALTER TABLE PERSON ADD FOREIGN KEY (Seat) REFERENCES car(Vin);
27
28 CREATE TABLE CAR_INSURANCE(
29 Policy_number VARCHAR(25) PRIMARY KEY,
30 Company_name VARCHAR(25),
31 Insured_car VARCHAR(25),
32 FOREIGN KEY (Insured_car) REFERENCES CAR(Vin)
33 );
34
35 CREATE TABLE PHONE(
36 ID VARCHAR(25),
37 Number VARCHAR(25),
38 FOREIGN KEY (ID) REFERENCES PERSON(ID),
39 PRIMARY KEY (ID, number)
40 );
File notes/code/sql/HW_ProcedureExamples.sql added (mode: 100644) (index 0000000..a21c07e)
1 /* code/sql/HW_ProcedureExamples.sql */
2
3 DROP SCHEMA IF EXISTS HW_ProcedureExamples;
4 CREATE SCHEMA HW_ProcedureExamples;
5 USE HW_ProcedureExamples;
6
7 /*
8 A "procedure" is a serie of statements stored in a schema,
9 that can easily be executed repeatedly.
10 https://dev.mysql.com/doc/refman/8.0/en/create-procedure.html
11 https://mariadb.com/kb/en/library/create-procedure/
12 */
13
14
15 CREATE TABLE STUDENT(
16 Login INT PRIMARY KEY,
17 Name VARCHAR(30),
18 Major VARCHAR(30),
19 Email VARCHAR(30)
20 );
21
22 INSERT INTO STUDENT VALUES (123, "Test A", "CS", "a@a.edu"),
23 (124, "Test B", "IT", "b@a.edu"),
24 (125, "Test C", "CYBR", "c@a.edu");
25
26 DELIMITER // -- This tells mysql not to mistake the ; below for the end of the procedure definition.
27 -- We temporarily alter the language, and make the delimiter being //.
28 -- $$ is often used too, and the documentation, at https://dev.mysql.com/doc/refman/8.0/en/stored-programs-defining.html, reads:
29 -- " You can redefine the delimiter to a string other than //,
30 -- " and the delimiter can consist of a single character or multiple characters.
31 -- " You should avoid the use of the backslash (\) character because that is the escape character for MySQL.
32 -- I am assuming that using the minus sign twice is also a poor choice.
33 CREATE PROCEDURE STUDENTLIST()
34 BEGIN
35 SELECT * FROM STUDENT; -- This ";" is not the end of the procedure definition!
36 END;
37 // -- This is the delimiter that marks the end of the procedure definition.
38 DELIMITER ; -- Now, we want ";" to be the "natural" delimiter again.
39
40 CALL STUDENTLIST();
41
42 /*
43 As the "()" suggests, a procedure can take
44 argument(s).
45 */
46
47
48 DELIMITER //
49 CREATE PROCEDURE STUDENTLOGIN(NameP VARCHAR(30))
50 BEGIN
51 SELECT Login
52 FROM STUDENT WHERE NameP = Name;
53 END;
54 //
55 DELIMITER ;
56
57 SHOW CREATE PROCEDURE STUDENTLOGIN; -- You can ask the system to give you information
58 -- About the procedure you just created.
59
60 CALL STUDENTLOGIN("Test A"); -- We can pass quite naturally an argument to our procedure.
File notes/code/sql/HW_SimpleBook.sql added (mode: 100644) (index 0000000..3540649)
1 /* code/sql/HW_SimpleBook.sql */
2
3 DROP SCHEMA IF EXISTS HW_SimpleBook;
4 CREATE SCHEMA HW_SimpleBook;
5 USE HW_SimpleBook;
6
7 CREATE TABLE AUTHOR(
8 FName VARCHAR(30),
9 LName VARCHAR(30),
10 Id INT PRIMARY KEY
11 );
12
13 CREATE TABLE PUBLISHER(
14 Name VARCHAR(30),
15 City VARCHAR(30),
16 PRIMARY KEY (Name, City)
17 );
18
19
20 CREATE TABLE BOOK(
21 Title VARCHAR(30),
22 Pages INT,
23 Published DATE,
24 PublisherName VARCHAR(30),
25 PublisherCity VARCHAR(30),
26 FOREIGN KEY (PublisherName, PublisherCity)
27 REFERENCES PUBLISHER(Name, City),
28 Author INT,
29 FOREIGN KEY (Author)
30 REFERENCES AUTHOR(Id),
31 PRIMARY KEY (Title, Published)
32 );
33
34 INSERT INTO AUTHOR VALUES
35 ("Virginia", "Wolve", 01),
36 ("Paul", "Bryant", 02),
37 ("Samantha", "Carey", 03);
38
39 INSERT INTO PUBLISHER VALUES
40 ("Gallimard", "Paris"),
41 ("Gallimard", "New-York"),
42 ("Jobs Pub.", "New-York");
43
44 INSERT INTO BOOK VALUES
45 ("What to eat", 213, DATE'20170219', "Gallimard", "Paris", 01),
46 ("Where to live", 120, DATE'20130212', "Gallimard", "New-York", 02),
47 ("My Life, I", 100, DATE'18790220', "Gallimard", "Paris", 03),
48 ("My Life, II", 100, DATE'18790219', "Jobs Pub.", "New-York", 03);
File notes/code/sql/HW_Train.sql added (mode: 100644) (index 0000000..4776ecf)
1 /* code/sql/TRAIN.sql */
2
3 -- Question 1:
4
5 CREATE TABLE HW_Train(
6 Id VARCHAR(30) PRIMARY KEY, -- This line was changed.
7 Model VARCHAR(30),
8 ConstructionYear YEAR(4)
9 );
10
11 -- Question 2 :
12
13 CREATE TABLE CONDUCTOR(
14 Id VARCHAR(20),
15 Name VARCHAR(20),
16 ExperienceLevel VARCHAR(20)
17 );
18
19 ALTER TABLE CONDUCTOR
20 ADD PRIMARY KEY (Id);
21
22 -- Question 3
23
24 CREATE TABLE ASSIGNED_TO(
25 TrainId VARCHAR(20),
26 ConductorId VARCHAR(20),
27 Day DATE,
28 PRIMARY KEY(TrainId, ConductorId),
29 FOREIGN KEY (TrainId) REFERENCES TRAIN(Id), -- This line was changed
30 FOREIGN KEY (ConductorId) REFERENCES CONDUCTOR(Id) -- This line was changed
31 );
32
33 -- Question 4:
34
35 /*
36 * We insert more than one tuple, to make
37 * the SELECT statements that follow easier
38 * to test and debug.
39 */
40
41 INSERT INTO TRAIN VALUES ('K-13', 'SurfLiner', 2019), ('K-12', 'Regina', 2015);
42 INSERT INTO CONDUCTOR VALUES ('GP1029', 'Bill', 'Junior'), ('GP1030', 'Sandrine', 'Junior');
43 INSERT INTO ASSIGNED_TO VALUES ('K-13', 'GP1029', DATE'2015/12/14'), ('K-12', 'GP1030', '20120909');
44
45 -- Question 5:
46
47 UPDATE CONDUCTOR SET ExperienceLevel = 'Senior' WHERE Id = 'GP1029';
48
49 -- Question 6:
50 -- 1.
51 SELECT Id FROM TRAIN;
52
53 -- 2.
54 SELECT Name FROM CONDUCTOR WHERE ExperienceLevel = 'Senior';
55
56 -- 3.
57 SELECT ConstructionYear FROM TRAIN WHERE Model='SurfLiner' OR Model='Regina';
58
59 --4.
60 SELECT ConductorId FROM ASSIGNED_TO WHERE TrainId = 'K-13' AND Day='2015/12/14';
61
62 --5.
63 SELECT Model FROM TRAIN, ASSIGNED_TO WHERE ConductorID = 'GP1029' AND TrainId = TRAIN.ID;
File notes/code/sql/HW_TriggerExample.sql added (mode: 100644) (index 0000000..9cea482)
1 /* code/sql/HW_TriggerExample.sql */
2
3 DROP SCHEMA IF EXISTS HW_TriggerExample;
4 CREATE SCHEMA HW_TriggerExample;
5 USE HW_TriggerExample;
6
7 CREATE TABLE STUDENT(
8 Login VARCHAR(30) PRIMARY KEY,
9 Average Float
10 );
11
12
13 SET @number_of_student = 0;
14
15 /*
16 SQL supports some primitive form of variables.
17 cf.
18 https://dev.mysql.com/doc/refman/8.0/en/user-variables.html
19 https://mariadb.com/kb/en/library/user-defined-variables/
20 There is no "clear" form of type
21 https://dev.mysql.com/doc/refman/8.0/en/user-variables.html
22 reads:
23 " In addition, the default result type of a variable is based on
24 " its type at the beginning of the statement. This may have unintended
25 " effects if a variable holds a value of one type at the beginning of a
26 " statement in which it is also assigned a new value of a different type.
27
28 " To avoid problems with this behavior, either do not assign a value to
29 " and read the value of the same variable within a single statement, or else
30 " set the variable to 0, 0.0, or '' to define its type before you use it.
31
32 In other words, mysql just "guess" the type of your value and go with it.
33 */
34
35 /*
36 We can create a trigger to count the number
37 of times something was inserted in our STUDENT
38 table.
39 */
40
41 CREATE TRIGGER NUMBER_OF_STUDENT
42 AFTER INSERT ON STUDENT
43 FOR EACH ROW SET @number_of_student = @number_of_student + 1;
44 -- As far as I know, this is the only way to increment a variable.
45
46 INSERT INTO STUDENT(Login) VALUES ("A"), ("B"), ("C"), ("D");
47
48 SELECT COUNT(*) FROM STUDENT; -- We now have four value inserted in the table.
49 SELECT @number_of_student AS 'Total number of student'; -- And the counter knows it.
50
51 /*
52 We should not forget to update our counter
53 when a student is removed from our table!
54 */
55
56 CREATE TRIGGER NUMBER_OF_STUDENT
57 AFTER DELETE ON STUDENT
58 FOR EACH ROW SET @number_of_student = @number_of_student - 1;
59
60 DELETE FROM STUDENT WHERE Login = "D" || Login = "E";
61
62 SELECT COUNT(*) FROM STUDENT; -- Note that our previous query deleted only one student.
63 SELECT @number_of_student AS 'Total number of student'; -- And the counter knows it.
64
65 /*
66 Let us now create a table for each individal grade,
67 and a trigger to calculate the average for us.
68 Note that the trigger will need to manipulate two tables
69 at the same time.
70 */
71
72 CREATE TABLE GRADE(
73 Student VARCHAR(30),
74 Exam VARCHAR(30),
75 Grade INT,
76 PRIMARY KEY(Student, Exam),
77 FOREIGN KEY (Student) REFERENCES STUDENT(Login)
78 );
79
80 CREATE TRIGGER STUDENT_AVERAGE
81 AFTER INSERT ON GRADE
82 FOR EACH ROW -- Woh, a whole query inside our trigger!
83 UPDATE STUDENT
84 SET STUDENT.Average =
85 (SELECT AVG(Grade) FROM GRADE WHERE GRADE.Student = STUDENT.Login)
86 WHERE STUDENT.Login = NEW.Student; -- The "NEW" keyword here refers to the "new" entry
87 -- that is being inserted by the INSERT statement triggering the trigger.
88
89 INSERT INTO GRADE VALUES
90 ("A", "Exam 1", 50),
91 ("A", "Exam 2", 40),
92 ("B", "Exam 1", 80),
93 ("B", "Exam 2", 100);
94
95 SELECT * FROM GRADE;
96 SELECT * FROM STUDENT; -- Tada, all the averages have been computed!
97 -- Note also that the student "C" does not have an average!
File notes/code/sql/HW_Work.sql added (mode: 100644) (index 0000000..eabfe01)
1 /* code/sql/HW_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/HW_WorkSol.sql added (mode: 100644) (index 0000000..7f202fd)
1 /* code/sql/HW_WorkSol.sql */
2
3 /*
4 For this code to work, you need to execute
5 the code in
6 code/sql/HW_WORK.sql
7 first.
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/code/xml/Customers.xml added (mode: 100644) (index 0000000..97c07a1)
1 <?xml version="1.0" encoding="UTF-8"?>
2 <!-- code/xml/Customers.xml -->
3 <Customers>
4 <Customers>
5 <Customer Name="Pamela Zave" ID="C001">
6 <Orders>
7 <Order Date="2012-07-04T00:00:00" ID="10248">
8 <Product Quantity="5" ID="10">
9 <Description>A Box of Cereal</Description>
10 <Brand>Cereal Company</Brand>
11 <Price>$3</Price>
12 </Product>
13 <Product Quantity="10" ID="43">
14 <Description>A Box of Matches</Description>
15 <Brand>Match Ltd</Brand>
16 <Price>$1.20</Price>
17 <Caution>Not suitable for children</Caution>
18 </Product>
19 </Order>
20 </Orders>
21 <Address>123 Main St., Augusta, GA, 30904</Address>
22 </Customer>
23 <Customer Name="Nancy Lynch" ID="C002">
24 <Orders>
25 <Order Date="2011-07-04T00:00:00" ID="10245">
26 <Product Quantity="3" ID="10">
27 <Description>A Box of Cereal</Description>
28 <Brand>Cereal Company</Brand>
29 <Price>$3</Price>
30 </Product>
31 <Product Quantity="1" ID="5">
32 <Description>A Cup</Description>
33 <Brand>Cup Company</Brand>
34 <Price>$2</Price>
35 <Material>Stoneware</Material>
36 </Product>
37 </Order>
38 </Orders>
39 <Address> Address line 5, 6, 7</Address>
40 </Customer>
41 <Customer Name="Shafi Goldwasser" ID="C003">
42 <Address>345 Second St., Augusta, GA, 30904</Address>
43 </Customer>
44 </Customers>
45 </Customers>
File notes/code/xml/NSF_Award.xml added (mode: 100644) (index 0000000..53e1534)
1 <?xml version="1.0" encoding="UTF-8"?>
2 <!-- code/xml/NSF_Award.xml -->
3
4 <rootTag>
5 <Award>
6 <AwardTitle>CAREER: Advances in Graph Learning and Inference</AwardTitle>
7 <AwardEffectiveDate>11/01/2019</AwardEffectiveDate>
8 <AwardExpirationDate>01/31/2023</AwardExpirationDate>
9 <AwardAmount>105091</AwardAmount>
10 <Organization>
11 <Code>05010000</Code>
12 <Directorate>
13 <Abbreviation>CSE</Abbreviation>
14 <LongName>Direct For Computer &amp; Info Scie &amp; Enginr</LongName>
15 </Directorate>
16 <Division>
17 <Abbreviation>CCF</Abbreviation>
18 <LongName>Division of Computing and Communication Foundations</LongName>
19 </Division>
20 </Organization>
21 <ProgramOfficer>
22 <SignBlockName>Phillip Regalia</SignBlockName>
23 </ProgramOfficer>
24 <AwardID>2005804</AwardID>
25 <Investigator>
26 <FirstName>Patrick</FirstName>
27 <LastName>Hopkins</LastName>
28 <EmailAddress>phopkins@virginia.edu</EmailAddress>
29 <StartDate>11/22/2019</StartDate>
30 <EndDate />
31 <RoleCode>Co-Principal Investigator</RoleCode>
32 </Investigator>
33 <Investigator>
34 <FirstName>Jon</FirstName>
35 <LastName>Ihlefeld</LastName>
36 <EmailAddress>jfi4n@virginia.edu</EmailAddress>
37 <StartDate>11/22/2019</StartDate>
38 <EndDate />
39 <RoleCode>Principal Investigator</RoleCode>
40 </Investigator>
41 <Institution>
42 <Name>University of Virginia Main Campus</Name>
43 <CityName>CHARLOTTESVILLE</CityName>
44 <ZipCode>229044195</ZipCode>
45 <PhoneNumber>4349244270</PhoneNumber>
46 <StreetAddress>P.O. BOX 400195</StreetAddress>
47 <CountryName>United States</CountryName>
48 <StateName>Virginia</StateName>
49 <StateCode>VA</StateCode>
50 </Institution>
51 </Award>
52 </rootTag>
File notes/code/xml/Shiporder.xml added (mode: 100644) (index 0000000..7abb3bc)
1 <?xml version="1.0" encoding="UTF-8"?>
2 <!-- code/xml/Shiporder.xml -->
3
4 <shiporder orderid="889923">
5 <orderperson>John Smith</orderperson>
6 <shipto>
7 <name>Ola Nordmann</name>
8 <address>Langgt 23</address>
9 <city>4000 Stavanger</city>
10 <country>Norway</country>
11 </shipto>
12 <item>
13 <title>Empire Burlesque</title>
14 <note>Special Edition</note>
15 <quantity>1</quantity>
16 <price>10.90</price>
17 </item>
18 <item>
19 <title>Hide your heart</title>
20 <quantity>1</quantity>
21 <price>9.90</price>
22 </item>
23 </shiporder>
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