List of commits:
Subject Hash Author Date (UTC)
Re-vamping the advanced java part. bc34886513772e6920a153752267149ef89d9a70 aubert@math.cnrs.fr 2020-04-13 18:25:23
Deleted Workflow file, since it is now in CONTRIb. 194d0e9f227b1f56f893a010247417268552b9e4 aubert@math.cnrs.fr 2020-04-13 14:45:21
SQL/XML indentation and comments 618fca553f0ffa355ca330e90e9adeeeb42c586d guest 2020-04-13 00:09:03
Cleaning 29f4f08496934561d3fdfbc46ea2393714cf1662 aubert@math.cnrs.fr 2020-04-10 21:21:37
Changing end-of-line tyes. b9efef4052a41d6444c7e3c173859f32b98f32b8 aubert@math.cnrs.fr 2020-04-10 19:54:21
Changes to ease merging. 77a481a4534bb0594e9fba45457450b14a7834b9 aubert@math.cnrs.fr 2020-04-10 19:51:38
? 556cbef3895848adcc86cf97120b03f8dbc047ea aubert@math.cnrs.fr 2020-04-10 18:41:38
Update Naming Convention.md 8c4884331492385f759784da347ac0b5c79b41a3 Poonam Veeral 2020-04-10 15:51:39
Update Naming Convention.md 2d8a1085f6f801da7ec69842fbd62cf5b2e9d056 Poonam Veeral 2020-04-09 16:37:10
Update Naming Convention.md fd3a77024bdb825a905d5a4913d3e97642336a16 Poonam Veeral 2020-04-09 16:35:01
Update Naming Convention.md 1017cd664b47b82f8f2689a1f295d8948e193eff Poonam Veeral 2020-04-09 16:33:59
Update Naming Convention.md 522d6f2f656e4d96db8e5bc81e626c6ba51b5a09 Poonam Veeral 2020-04-09 16:31:06
Update Naming Convention.md 24cde6ec7174b70496a62d0b1dd3d0c955513a84 Poonam Veeral 2020-04-09 16:30:10
Update Naming Convention.md 606049c713b804956cc4f3c9a2700887125dc3e3 Poonam Veeral 2020-04-09 16:29:16
Update Naming Convention.md e2d70be8c8cf05c10be7194f5a86ad84a71dcba2 Poonam Veeral 2020-04-09 16:27:09
Update Naming Convention.md b297f088e45d4cab3bca47272eb5d7d283997815 poonamveeral 2020-04-09 16:16:43
Update Naming Convention.md 562ba67f4338884279c312eddf7fd1688d314da3 Poonam Veeral 2020-04-09 16:16:01
Update Naming Convention.md fa669e84e04edadb029e834caedf56223b897fe0 Poonam Veeral 2020-04-09 16:09:31
Update Naming Convention.md 12eb5e6aea619c56222817878567db2e23aacc41 Poonam Veeral 2020-04-09 16:05:26
Update Naming Convention.md d39a8ec969e2d9023dfa75e39aadd537ef3c79e3 Poonam Veeral 2020-04-09 16:02:16
Commit bc34886513772e6920a153752267149ef89d9a70 - Re-vamping the advanced java part.
Author: aubert@math.cnrs.fr
Author date (UTC): 2020-04-13 18:25
Committer name: aubert@math.cnrs.fr
Committer date (UTC): 2020-04-13 18:25
Parent(s): e2493d042e48d24e0a512c38d5941ff8b6530f98
Signer:
Signing key:
Signing status: N
Tree: 3c49c07f75047995af6352df3dcabce890eae230
File Lines added Lines deleted
notes/code/java/AdvancedProg.java 61 105
notes/code/java/ListPrice.java 1 1
notes/code/sql/HW_Department.sql 34 5
notes/lectures_notes.md 131 27
notes/temp.md 11 11
File notes/code/java/AdvancedProg.java changed (mode: 100644) (index 8d98e44..3607f03)
3 3 /* /*
4 4 * This is a long program, introducing: * This is a long program, introducing:
5 5 * I. How to pass options when connecting to the database, * I. How to pass options when connecting to the database,
6 * II. How to create a table,
6 * II. How to create a table and read its meta-data,
7 7 * III. How to insert values, * III. How to insert values,
8 8 * IV. How to use prepared statements, * IV. How to use prepared statements,
9 9 * V. How to read backward and write in ResultSets. * V. How to read backward and write in ResultSets.
10 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!
11 * To be able to execute this program multiple times, the schema is dropped and re-created.
17 12 * *
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 13 */ */
14
21 15 import java.sql.*; import java.sql.*;
22 16
23 17 public class AdvancedProg { public class AdvancedProg {
 
... ... public class AdvancedProg {
26 20
27 21 // I. Passing options to the dababse // I. Passing options to the dababse
28 22
23 // start snippet passing-options
29 24 Connection conn = Connection conn =
30 25 DriverManager.getConnection( DriverManager.getConnection(
31 26 "jdbc:mysql://localhost:3306/HW_DBPROG" "jdbc:mysql://localhost:3306/HW_DBPROG"
 
... ... public class AdvancedProg {
34 29 + "&allowMultiQueries=true" + "&allowMultiQueries=true"
35 30 + "&createDatabaseIfNotExist=true" + "&createDatabaseIfNotExist=true"
36 31 + "&useSSL=true"); + "&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 */
32 // end snippet passing-options
43 33
44 34 Statement stmt = conn.createStatement(); ) { Statement stmt = conn.createStatement(); ) {
35 /*
36 * Below, we drop the schema and re-create it to allow multiple execution of the
37 * program. You can ignore this part if you want.
38 */
39
40 stmt.execute(
41 "DROP SCHEMA IF EXISTS HW_DBPROG;" + "CREATE SCHEMA HW_DBPROG;" + "USE HW_DBPROG;");
45 42
46 // II. Creating a table
43 // II. Creating a table and reading its meta-data
47 44
45 // start snippet table-creation
48 46 stmt.execute( stmt.execute(
49 47 "CREATE TABLE DVD (" "CREATE TABLE DVD ("
50 48 + "Title CHAR(25) PRIMARY KEY, " + "Title CHAR(25) PRIMARY KEY, "
51 49 + "Minutes INTEGER, " + "Minutes INTEGER, "
52 50 + "Price DOUBLE)"); + "Price DOUBLE)");
51 // end snippet table-creation
53 52
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
53 // start snippet table-metadata-1
68 54 DatabaseMetaData md = conn.getMetaData(); 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 55
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 */
56 ResultSet rs = md.getTables("HW_DBPROG", null, "%", null);
57 // end snippet table-metadata-1
84 58
59 // start snippet table-metadata-2
85 60 while (rs.next()) { while (rs.next()) {
86 System.out.println(
87 rs.getString(3)); // In the ResultSet returned by getTables, 3 is the TABLE_NAME.
61 System.out.println(rs.getString(3));
88 62 } }
63 // end snippet table-metadata-2
89 64
90 65 // III. Inserting values // III. Inserting values
91 66
67 // start snippet inserting-1
92 68 String sqlStatement = "INSERT INTO DVD VALUES ('Gone With The Wind', 221, 3);"; String sqlStatement = "INSERT INTO DVD VALUES ('Gone With The Wind', 221, 3);";
93 69 int rowsAffected = stmt.executeUpdate(sqlStatement); int rowsAffected = stmt.executeUpdate(sqlStatement);
94 70 System.out.print(sqlStatement + " changed " + rowsAffected + " row(s).\n"); System.out.print(sqlStatement + " changed " + rowsAffected + " row(s).\n");
71 // end snippet inserting-1
95 72
96 // Batch Insertion
97
73 // start snippet inserting-2
98 74 String insert1 = "INSERT INTO DVD VALUES ('Aa', 129, 0.2)"; String insert1 = "INSERT INTO DVD VALUES ('Aa', 129, 0.2)";
99 75 String insert2 = "INSERT INTO DVD VALUES ('Bb', 129, 0.2)"; 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 76
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 77 stmt.executeUpdate(insert1 + ";" + insert2); stmt.executeUpdate(insert1 + ";" + insert2);
78 // end snippet inserting-2
108 79
109 // Method 2: Using the addBatch and executeBatch methods
80 // start snippet inserting-3
81 String insert3 = "INSERT INTO DVD VALUES ('Cc', 129, 0.2)";
82 String insert4 = "INSERT INTO DVD VALUES ('DD', 129, 0.2)";
110 83 stmt.addBatch(insert3); stmt.addBatch(insert3);
111 84 stmt.addBatch(insert4); stmt.addBatch(insert4);
112 85 stmt.executeBatch(); stmt.executeBatch();
86 // end snippet inserting-3
113 87
114 88 // IV. Prepared Statements // IV. Prepared Statements
115 89
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.
90 // start snippet prepared-queries-1
91 /*
92 * We create a string with an empty slot,
93 * represented by "?".
94 */
95 sqlStatement = "SELECT title FROM DVD WHERE Price <= ?";
96 /*
97 * We create a PreparedStatement object, using that string with an
98 * empty slot.
99 */
100 PreparedStatement ps = conn.prepareStatement(sqlStatement);
101
124 102 /* /*
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/>.
103 * Then, we "fill" the first slot with the value of a variable.
127 104 */ */
128 105 double maxprice = 0.5; 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:
106 ps.setDouble(1, maxprice);
107 /*
108 * Finally, we can execute the query, and display the results.
109 */
110 ResultSet result = ps.executeQuery();
133 111
134 112 System.out.printf("For %.2f you can get:\n", maxprice); System.out.printf("For %.2f you can get:\n", maxprice);
135 113
136 114 while (result.next()) { while (result.next()) {
137 115 System.out.printf("\t %s \n", result.getString(1)); System.out.printf("\t %s \n", result.getString(1));
138 116 } }
117 // end snippet prepared-queries-1
139 118
140 // Example 2
119 // start snippet prepared-queries-2
141 120 sqlStatement = sqlStatement =
142 121 "INSERT INTO DVD VALUES (?, ?, ?)"; // Now, our string has 3 empty slots, and it is an "INSERT INTO DVD VALUES (?, ?, ?)"; // Now, our string has 3 empty slots, and it is an
143 122 // INSERT statement. // INSERT statement.
 
... ... public class AdvancedProg {
153 132 // executed. // executed.
154 133 System.out.print(preparedStatement.toString() + " changed " + rowsAffected + " row(s).\n"); System.out.print(preparedStatement.toString() + " changed " + rowsAffected + " row(s).\n");
155 134
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");
135 // end snippet prepared-queries-2
160 136
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 */
137 // start snippet prepared-queries-3
138 preparedStatement.setString(1, "The Great Dictator");
139 preparedStatement.setString(2, "Not-an-integer");
140 preparedStatement.setString(3, "Not-a-double");
141 // This command will make your program crash.
142 // rowsAffected = preparedStatement.executeUpdate();
143 // end snippet prepared-queries-3
165 144
166 // Of course, we can use prepared statement inside loops.
145 // start snippet prepared-queries-4
167 146 for (int i = 1; i < 5; i++) { for (int i = 1; i < 5; i++) {
168 147 preparedStatement.setString(1, "Saw " + i); preparedStatement.setString(1, "Saw " + i);
169 148 preparedStatement.setInt(2, 100); preparedStatement.setInt(2, 100);
170 149 preparedStatement.setDouble(3, .5); preparedStatement.setDouble(3, .5);
171 150 preparedStatement.executeUpdate(); preparedStatement.executeUpdate();
172 151 } }
152 // end snippet prepared-queries-4
173 153
174 154 // V. Reading backward and writing in ResultSets // V. Reading backward and writing in ResultSets
175 155
176 // To read backward and write in ResultSets, you need to have a statement with certain
177 // options:
178
156 // start snippet new-statement-1
179 157 Statement stmtNew = Statement stmtNew =
180 158 conn.createStatement(ResultSet.TYPE_SCROLL_SENSITIVE, ResultSet.CONCUR_UPDATABLE); 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 */
159 // end snippet new-statement-1
194 160
195 161 // Reading backward // Reading backward
196 162
 
... ... public class AdvancedProg {
209 175 System.out.print(result.getString("Title") + " "); System.out.print(result.getString("Title") + " ");
210 176 } }
211 177
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 178 // Changing the values // Changing the values
223 179
224 180 System.out.print("\n\nLet us apply a 50% discount. Currently, the prices are:\n"); System.out.print("\n\nLet us apply a 50% discount. Currently, the prices are:\n");
File notes/code/java/ListPrice.java changed (mode: 100644) (index 7b1e868..1ec00e5)
1 /* code/java/ListPrice.java */
1 // code/java/ListPrice.java
2 2
3 3 import java.sql.*; import java.sql.*;
4 4 import java.util.Scanner; // Importing a java API to read from the keyboard. import java.util.Scanner; // Importing a java API to read from the keyboard.
File notes/code/sql/HW_Department.sql changed (mode: 100644) (index a226776..1e2f77a)
1 /* code/sql/HW_Department.sql */
2
3 1 /* /*
4 2 Preamble: Preamble:
5 3 The following is in case you want to run your program on your installation: The following is in case you want to run your program on your installation:
 
... ... USE HW_Department;
15 13 End of the preamble. End of the preamble.
16 14 */ */
17 15
16 -- start snippet statement
17 /* code/sql/HW_Department.sql */
18
18 19
19 20 CREATE TABLE DEPARTMENT( CREATE TABLE DEPARTMENT(
20 21 ID INT PRIMARY KEY, ID INT PRIMARY KEY,
 
... ... INSERT INTO EMPLOYEE VALUES
40 41 (3, "Mark", 20050101, 2), (3, "Mark", 20050101, 2),
41 42 (4, "Karen", NULL, 1), (4, "Karen", NULL, 1),
42 43 (5, "Jocelyn", 20100101, 1); (5, "Jocelyn", 20100101, 1);
44 -- end snippet statement
45
46
47 /*
48 *
49 *
50 * Below are the solution, but think about it first!
51 *
52 *
53 *
54 */
55
43 56
57
58
59
60
61
62
63
64
65
66
67 -- start snippet solution1
44 68 SELECT EMPLOYEE.Name SELECT EMPLOYEE.Name
45 69 FROM EMPLOYEE, DEPARTMENT FROM EMPLOYEE, DEPARTMENT
46 70 WHERE DEPARTMENT.Name = "Storage" WHERE DEPARTMENT.Name = "Storage"
47 71 AND EMPLOYEE.Department = DEPARTMENT.ID; AND EMPLOYEE.Department = DEPARTMENT.ID;
48
72 -- end snippet solution1
73
49 74 /* /*
50 75 Will return: Will return:
51 76 Bob Bob
 
... ... Jocelyn
55 80 and not Mark, since that employee works in a differente department. and not Mark, since that employee works in a differente department.
56 81 */ */
57 82
83 -- start snippet solution2
58 84 SELECT Name SELECT Name
59 85 FROM EMPLOYEE FROM EMPLOYEE
60 86 WHERE Hired <= ALL ( WHERE Hired <= ALL (
 
... ... WHERE Hired <= ALL (
62 88 FROM EMPLOYEE FROM EMPLOYEE
63 89 WHERE Hired IS NOT NULL WHERE Hired IS NOT NULL
64 90 ); );
65
91 -- end snippet solution2
92
66 93 /* /*
67 94 Will return Will return
68 95 Mark Mark
 
... ... excluding Karen (whose hiring date is
71 98 unknown). unknown).
72 99 */ */
73 100
101 -- start snippet solution3
74 102 SELECT EMPLOYEE.Name SELECT EMPLOYEE.Name
75 103 FROM EMPLOYEE, DEPARTMENT FROM EMPLOYEE, DEPARTMENT
76 104 WHERE Hired <= ALL ( WHERE Hired <= ALL (
 
... ... WHERE Hired <= ALL (
82 110 ) )
83 111 AND DEPARTMENT.Name = "Storage" AND DEPARTMENT.Name = "Storage"
84 112 AND EMPLOYEE.Department = DEPARTMENT.ID; AND EMPLOYEE.Department = DEPARTMENT.ID;
85
113 -- end snippet solution3
114
86 115 /* /*
87 116 Will return Will return
88 117 Bob Bob
File notes/lectures_notes.md changed (mode: 100644) (index b59451b..dfcc6c0)
... ... Solution to [%D %n (%T)](#problem:reverseeng)
7568 7568 - <http://spots.augusta.edu/caubert/teaching/general/java/> - <http://spots.augusta.edu/caubert/teaching/general/java/>
7569 7569 - If you experience troubles, <https://www.ntu.edu.sg/home/ehchua/programming/howto/ErrorMessages.html#JDBCErrors> might be a good read. - If you experience troubles, <https://www.ntu.edu.sg/home/ehchua/programming/howto/ErrorMessages.html#JDBCErrors> might be a good read.
7570 7570 - [@Textbook6, 13.3.2] or [@Textbook7, Chapter 10] is a condensed, but good read. - [@Textbook6, 13.3.2] or [@Textbook7, Chapter 10] is a condensed, but good read.
7571 - Many textbook on Java includes a part on Databases, cf. for instance [Gaddis2014, Chapter 16].
7571 - Many textbook on Java includes a part on Databases, cf. for instance [@Gaddis2014, Chapter 16].
7572 7572
7573 7573 ## Overview ## Overview
7574 7574
 
... ... Take the time to make sure you have the same result on your installation, and th
7773 7773
7774 7774 If you were to replace the body of `try` in the previous program with If you were to replace the body of `try` in the previous program with
7775 7775
7776 ```{.java .numberLines include=code/java/FirstProgBis.java snippet=alternate}
7776 ```{.java .numberLines dedent=6 include=code/java/FirstProgBis.java snippet=alternate}
7777 7777 ``` ```
7778 7778
7779 7779 You would obtain: You would obtain:
 
... ... For more details, consult <https://docs.oracle.com/javase/7/docs/api/java/sql/St
7838 7838 ## A Second Program ## A Second Program
7839 7839
7840 7840 The program in [%D %n (%T)](#problem:Advanced_java) uses the modifications discussed below. The program in [%D %n (%T)](#problem:Advanced_java) uses the modifications discussed below.
7841 Please refer to it once you are done with this section.
7841 7842
7842 7843 ### Passing Options ### Passing Options
7843 7844
7844 7845 We can pass options when connecting to the database: We can pass options when connecting to the database:
7845 7846
7846 ```{.java}
7847 Connection conn = DriverManager.getConnection("jdbc:mysql://localhost:3306/HW_DBPROG"
7848 + "?user=testuser"
7849 + "&password=password"
7850 + "&allowMultiQueries=true"
7851 + "&createDatabaseIfNotExist=true"
7852 + "&useSSL=true");
7847 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=passing-options}
7853 7848 ``` ```
7854 7849
7855 `allowMultiQueries` allows to pass multiple queries with one `executeUpdate` statement, and `createDatabaseIfNotExist` is about schema, actually.
7850 On top of `user` and `password` (which are self-explanatory), setting `allowMultiQueries` to `true` allows to pass multiple queries with one `executeUpdate` statement, and `createDatabaseIfNotExist` creates the _schema_ passed in the `url` if it does not already exists.
7851
7852 You can read about other options at <https://dev.mysql.com/doc/connector-j/5.1/en/connector-j-reference-configuration-properties.html> or <https://jdbc.postgresql.org/documentation/head/connect.html>.
7856 7853
7857 7854 ### Creating a Table ### Creating a Table
7858 7855
7859 7856 We can create a table with the method `stmt.execute`. We can create a table with the method `stmt.execute`.
7860 We can use the `getMetaData()` of the `DatabaseMetaData` to obtain information about the tables.
7857 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=table-creation}
7858 ```
7859
7860 If we were to execute `SHOW TABLES;` after this `execute` instruction directly in the MySQL interpreter, this would display at the screen:
7861
7862 ```{.plain}
7863 +---------------------+
7864 | Tables_in_HW_DBPROG |
7865 +---------------------+
7866 | DVD |
7867 +---------------------+
7868 ```
7869
7870 But here, to access this information, we will use the connection's metadata.
7871 The `DatabaseMetaData` is a class used to get information about the database: the driver, the user, the versions, etc.
7872 We can use the `getMetaData()` method of this class to obtain information about the schema we just created:
7873
7874 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=table-metadata-1 }
7875 ```
7876
7877 The first parameter of `getMetaData()` is the schema's name, as you probably guessed, and the the third parameter is `String tableNamePattern`, i.e., what must match the table name stored in the database to be selected.
7878 Here, by using the wildcard `%`, we select all the table names (which is only "DVD" at this point).
7879
7880 The `getMetaData()` method returns a `ResultSet` (here named `rs`), where `3` is the `TABLE_NAME`.
7881 We can now iterate over this `rs` object to list all the elements in it, as we would with any `ResultSet` object:
7882
7883
7884 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=table-metadata-2 }
7885 ```
7886
7887 You can read at <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[])> the full specification of this method.
7888
7861 7889
7862 7890 ### Inserting Values ### Inserting Values
7863 7891
7864 Use `stmt.executeUpdate` (multiple insertion possible if `allowMultiQueries` was set to true, cf. <https://stackoverflow.com/a/10804730/>).
7892 To insert values in our table, we can use `stmt.executeUpdate`:
7865 7893
7866 Another way of batch processing statements:
7894 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=inserting-1 }
7895 ```
7867 7896
7868 ```{.java}
7869 stmt.addBatch(insert3);
7870 stmt.addBatch(insert4);
7871 stmt.executeBatch();
7897 Note that the `executeUpdate` returns an integer, the number of rows changed.
7898 We can even use this method to perform multiple insertions at the same time, if `allowMultiQueries` was set to true, cf. <https://stackoverflow.com/a/10804730/>:
7899
7900 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=inserting-2 }
7901 ```
7902
7903 Another way of "batch processing" statements (i.e., of executing multiple insertions at the same time) is to use `addBatch` (that "loads" statements in the `statement` object) and `executeBatch()` (that execute all the statement loaded):
7904
7905 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=inserting-3 }
7872 7906 ``` ```
7873 7907
7874 Note that `executeBatch` may be used "for updating, inserting, or deleting a row; and it may also contain DDL statements such as `CREATE TABLE` and `DROP TABLE`. It cannot, however, contain a statement that would produce a ResultSet object, such as a `SELECT statement`", cf. <https://docs.oracle.com/javase/tutorial/jdbc/basics/retrieving.html#batch_updates>.
7908 Note that the database is not sollicited until the `executeBatch` method is called: we simply loaded the instruction in the program, and connect to the database only once, with all the instructions, when this `executeBatch()` instruction is met.
7909
7910 Note also that `executeBatch` may be used, per <https://docs.oracle.com/javase/tutorial/jdbc/basics/retrieving.html#batch_updates>:
7911
7912 > for updating, inserting, or deleting a row; and it may also contain DDL statements such as `CREATE TABLE` and `DROP TABLE`. It cannot, however, contain a statement that would produce a `ResultSet` object, such as a `SELECT statement`.
7913
7875 7914 Also, the name suggests that it should be possible to fetch the `SQL` instructions from a file and load them in your `Java` program, but there is actually no easy way to do this, c.f. <https://stackoverflow.com/q/2071682/>. Also, the name suggests that it should be possible to fetch the `SQL` instructions from a file and load them in your `Java` program, but there is actually no easy way to do this, c.f. <https://stackoverflow.com/q/2071682/>.
7876 7915
7877 7916 ### Prepared Statements ### Prepared Statements
7878 7917
7879 "A query with a slot": parsed and stored on the database, but not executed.
7880 When the program gives values, it is executed.
7918 A prepared statement is "a query with a slot": it is a query that takes one or multiple parameters, is parsed and stored on the database, but not executed.
7919 It is only _after_ the value of the slot(s) are fixed by the program that this query can be executed.
7920 The program can re-use the same prepared statement with multile (different) values multiple times.
7881 7921
7882 7922 Compared to executing `SQL` statements directly, prepared statements have three main advantages: Compared to executing `SQL` statements directly, prepared statements have three main advantages:
7883 7923
7884 - Reduces parsing time (one time VS as many time as values)
7885 - Minimize bandwidth (send only the parameters, and not the whole query)
7886 - Protect against `SQL` injections
7924 - They reduce parsing time (we store the prepared statement only once, VS as many time as there are values),
7925 - They minimize bandwidth usage (once the prepared statement is sent, the server needs only the parameters, and not the whole query again),
7926 - They protect against `SQL` injections (cf. [A Bit About Security](#a-bit-about-security)).
7927
7928 Let us look at a first example:
7929
7930 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=prepared-queries-1}
7931 ```
7932
7933 Note that once the `ps` `PreparedStatement` object is created, we cannot change the content of the query, beside instantiating the slot.
7934 cf. e.g. the discussion at <https://stackoverflow.com/q/25902881/>.
7935
7936 As we said earlier, a prepared statement can have multiple "slots", as we can see in that second example:
7937
7938
7939 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=prepared-queries-2}
7940 ```
7941
7942 Where we stored the integer value returned by `executeUpdate` and displayed the the prepared statement using the`toString` method.
7943
7944 If we try to mess things up, i.e., provide wrong datatypes:
7945
7946 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=prepared-queries-3}
7947 ```
7948 Java compiler will be ok, but we'll have an error at execution time when executing the query.
7949
7950 Executing `rowsAffected = preparedStatement.executeUpdate();`{.java} would return an error containing
7951
7952 ```{.plain}
7953 com.mysql.cj.jdbc.exceptions.MysqlDataTruncation: Data truncation: Incorrect integer value: 'Not-an-integer' for column `HW_DBPROG`.`DVD`.`Minutes` at row 1
7954 ```
7955
7956 since `"Not-an-integer"` is not … a valid integer!
7957
7958 Of course, prepared statements are particularly convenient when you want to automate some tasks or repeat them multiple times, as you write the query only once, and then re-use it.
7959 For instance, inserting the whole "Saw" franchise can be made into a loop:
7960
7961 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=prepared-queries-4}
7962 ```
7887 7963
7888 7964 ### More Complex Statement Objects ### More Complex Statement Objects
7889 7965
7890 When you create the `Statement` objects, you can give two arguments to the `createStatement` method.
7891 The first one will indicate whenever you can scroll in the `ResultSets` objects that will be created using this `Statement` object.
7892 The second indicates whenever you can update the values "from" the `ResultSet` directly.
7966 When you create the `Statement` objects, you can give two arguments to the `createStatement` method:
7967
7968 ```{.java .numberLines dedent=6 include=code/java/AdvancedProg.java snippet=new-statement-1}
7969 ```
7970
7971 Those options change two things about the ResultSet we obtain using this statement
7972 The first argument indicates whenever you can scroll (go forward _and_ backward) in the `ResultSets` objects that will be created using this `Statement` object:
7973
7974 - `TYPE_FORWARD_ONLY` is the default (you can only move forward).
7975 - `TYPE_SCROLL_INSENSITIVE` means that you can scroll, but that updates don't impact result set.
7976 - `TYPE_SCROLL_SENSITIVE` means that you can scroll, and that updates impact result set.
7977
7978 Allowing to go in both direction extends the methods one can use in the `ResultSet` class: now, to scrool through the results, one can use:
7893 7979
7894 The method is documented at <https://docs.oracle.com/javase/7/docs/api/java/sql/Connection.html#createStatement(int,%20int)>, you can find below a simple example of "scrollable" `ResultSet`:
7980 - `first()`
7981 - `last()`
7982 - `next()`
7983 - `previous()`
7984 - `relative(x)` : move cursor x times (positive = forward, negative = backward)
7985 - `absolute(x)`: move to the row number x, where $1$ is the first.
7986
7987 The second argument is the concurrency level, it indicates whenever you can update the values into the `ResultSet` directly.
7988
7989 - `CONCUR_READ_ONLY` is the default.
7990 - `CONCUR_UPDATABLE` means that we can change the database without issuing SQL statement.
7991
7992 In other terms, manipulting the `ResultSet` object will _directly_ impact the data stored in the database if we set the second parameter to `CONCUR_UPDATABLE`.
7993
7994 This `createStatement` method is documented at <https://docs.oracle.com/javase/7/docs/api/java/sql/Connection.html#createStatement(int,%20int)>.
7995
7996 You can find below a simple example of "scrollable" `ResultSet`:
7895 7997
7896 7998
7897 7999 ```{.java .numberLines include=code/java/ScrollingProgram.java} ```{.java .numberLines include=code/java/ScrollingProgram.java}
7898 8000 ``` ```
7899 8001
8002 You can also have a look at the end of `code/java/AdvancedProg.java`, which creates a second `Statement` object is created and used.
8003
7900 8004 ## Exercises {-} ## Exercises {-}
7901 8005
7902 8006 Exercise +.# Exercise +.#
File notes/temp.md changed (mode: 100644) (index 041caa5..0bec618)
... ... pandoc-numbering:
30 30 format-link-title: '%D %n (%T), p. %p' format-link-title: '%D %n (%T), p. %p'
31 31 --- ---
32 32
33 Solution to [%D %n (%T)](#problem:DepartmentSelect)
33 34
34 Exercise +.#
35 35 ~ ~
36
37 For each of the following notion, indicate if they are usually an attribute of NoSQL or of "traditional" `SQL`:
38
39 |||||
40 |-------:|:-------------:|---|---|---|
41 ~ | Schema First | Distributed | Relational | Scalable | Immediate Consistency
42 NoSQL |   |   |   |   |
43 `SQL` |   |   |   |   |
44
45 <!-- Bug with table -->
36
37 #.
38 ```{.sqlmysql .numberLines include=code/sql/HW_Department.sql snippet=solution1}
39 ```
40 #.
41 ```{.sqlmysql .numberLines include=code/sql/HW_Department.sql snippet=solution2}
42 ```
43 #.
44 ```{.sqlmysql .numberLines include=code/sql/HW_Department.sql snippet=solution3}
45 ```
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