Chapter 11

JDBC

by Debasis Samanta


CONTENTS

Introduction

MySQL Basics and installation

  • SQL stands for Structured Query Language. It is a kind of language(mostly like English). SQL is undoubtedly the most popular and widely-used open source Database Management System (DBMS) language.
  • It is simple to set up and use.
  • SQL is mainly used to create a table, enter data into table, update records in a table and retrieving data from a table.
    NOTE: SQL is not a programming language like C, C++, Java, etc. SQL is not case sensitive.

    MySQL:

    MySQL is one of the most popular Database Management System (DBMS).
    MySQL is a database system used on the web.
    MySQL is a database system that runs on a server.
    MySQL is ideal for both small and large applications.
    MySQL is very fast, reliable, and easy to use.
    MySQL uses standard SQL.
    MySQL works on a number of platforms.
    MySQL is free to download and use.
    MySQL is developed, distributed, and supported by Oracle Corporation.
    MySQL is named after co-founder Monty Widenius's daughter: My
    

    MySQL Setup:

    1. Download: dev.mysql.com/downloads     -->      MySQL Community Server   -->      Archive Version (64/36 bit as per your OS)
    
    2. Extract the file in C:// drive.
    
    3. Rename the directory to 'mysql'
    
    4. Create the data folder in D:// drive. [D://data/] (Storing data in a different partition ensures data Backup)
    
    5. Create my.ini with the following details:
    		---------------------------------------------
    				[mysqld]
    
    				# installation directory
    				basedir="c:\mysql\"
    
    				# data directory
    				datadir="d:\data\"
    		--------------------------------------------
    
    
    6. Start command prompt and change directory to C://mysql/bin/
    
    7. Type the command: mysqld --console --initialize (Remember the password generated)
    			----------------------------
    			  TEMP PASS: 
    			----------------------------
    
    
    8. Open another command prompt and change directory to C://mysql/bin/
    
    9. Type the command: mysql -u root -p
    
    10. Enter the password from step 7.
    
    11. Type the command: ALTER USER 'root'@'localhost' IDENTIFIED BY 'root'; (Our new password for root user will be 'root')
    
    12. Type the command: EXIT (This will exit the console)
    
    13. Now start a new MySql console as in Step 9 with the password set in Step 11.
    
    That's It!
    
    

    MySQL Statements:
    CREATE:

    To begin with, the table creation command requires the following details-
    Name of the table
    Name of the fields
    Definitions for each field
    Syntax
    		CREATE TABLE table_name (
    			column_name1 column_type1,
    			column_name2 column_type2...);
    
    
    DESC:

    In practice, you use the DESC statement which is a shorthand of the DESCRIBE statement. These statements are used to view the structure, datatype, keys and constraints used in a table.

    Syntax
       DESC table_name;
    
    INSERT

    You can insert data into the existing MySQL table by using the mysql> prompt or by using any script like PHP or any programming language using proper drivers using the INSERT statement.

    Syntax
    	INSERT INTO table_name VALUES(Value1,Value2,..., Value n);
    
    UPDATE

    UPDATE statement is used to modify previously inserted data in a table.

    Syntax
    	UPDATE table_name SET 
    		ColName1=Value1,
    		ColName2=Value2,
    		,..., 
    		WHERE ColName1=Value1;
    
    SELECT

    SELECT statement is used to retrieve data from a table.

    Syntax
    	SELECT < colname 1>,< colname 2>,...,< colname p>
    	FROM table_name 
    	WHERE < Condition>;
    
    DELETE

    DELETE FROM statement is used to delete a record from any MySQL table.

    Syntax
    		DELETE FROM table_name 
    		WHERE < Condition>;
    
    DROP

    DROP TABLE statement is used to drop an existing MySQL table, but you need to be very careful while deleting any existing table because the data lost will not be recovered after deleting a table.

    Syntax
    		DROP TABLE table_name;
    

    Illustration 11.1				
    //Performing simple SQL operations in MySQL console (CREATE,INSERT,UPDATE,DROP etc)
    
    create DATABASE test;
    use test;
    
    create table JavaCourse(
    	Roll Integer primary key, 
    	Name Varchar(30), 
    	Marks Integer not null, 
    	Grade Varchar(2));
        
    desc JavaCourse;
    
    insert into JavaCourse values (01,'Debasish', 75, 'A');
    insert into JavaCourse values(02,'Nilanjan', 85, 'EX');
    insert into JavaCourse values(03,'Tauheed', 65, 'B');
    insert into JavaCourse values(04,'Priyabrata', 78, 'A');
    
    update JavaCourse set Name='Debasis' where Name='Debasish';   
    update JavaCourse set Marks=85, Grade='Ex' where Name='Debasis';
    
    select * from JavaCourse;
    
    select name, roll from JavaCourse;
    
    select * from JavaCourse where marks>80;
    
    select * from JavaCourse where name like ‘%jee%‘;
    
    select * from JavaCourse order by marks;
    
    delete from JavaCourse where marks < 66;
    
    delete from JavaCourse;
    
    drop table JavaCourse;
    
    

    JDBC: Java Database Connectivity

    JDBC is a standard Java API for handling database related activities. 
    
    In Java, there is a package java.sql having number of classes for database related programming.
    
    It includes java.sql.DriverManager class and two interfaces java.sql.Driver and java.sql.Connection.
    

    Illustration 11.2				
    // Downloading and extracting the latest version of JDBC driver
    
    Download link:
    
    https://dev.mysql.com/downloads/connector/j/
    
    
    Steps:
    
    	1. Extract the ZIP file.
    	2. Find the'JDBC MySQL Connector.jar' file and rename to 'mysql' for convinience.
    	3. Place the mysql.jar file along with any program using JDBC and use the following command during execution:
    				
    						java -cp mysql.jar;. 
    		
    
    Note: Compilation doesnot require the Classpath of JDBC driver.
    

    JDBC: Characteristics:

    JDBC is a SQL (Structured Query Language)-level API, which is very popular for RDBMS (Relational Database Management System).
    
    It is compatible with the most of the popular database management systems, namely OracleDB, MySQL, Sybase, Microsoft SQL, etc.
    
    It is simple and easy to implement.
    
    In this course, we shall refer to JDBC to connect to MySQL database server. 
    
    The approach is same to any other database.
    
    Note: 
    The JDBC driver for different database is different. But, as an end-user, we don’t have to bother about their implementation. 
    
    


    Relational database:

  • A relational database is a database that allows for queries which typically use Structured Query Language (SQL) to store and retrieve data.
  • A relational database stores information by means of tables. A table is referred to as a relation in the sense that it is a collection of objects of the same type (rows).
  • Examples: MS SQL Server, IBM DB2, Oracle, MySQL , etc.

    Why JDBC?

    Write once, run anywhere
       Multiple client and server platforms.
    
    Object-relational mapping
       Databases optimized for searching/indexing.
       Objects optimized for engineering/flexibility.
    
    Network independence
       Works across Internet Protocol.
    
    Database independence
       Java can access any database vendor.
    

    JDBC: Structure:

    JDBC is a SQL-level API. It means that the JDBC allows to construct SQL statements and embed them inside Java API calls.
    
    The JDBC API is an implementation to interact a particular database engine. This implementation is called JDBC Driver.

    Types of JDBC Drivers:

    JDBC Driver is a software component that enables Java application to interact with the database.

    There are 4 types of JDBC drivers:
    Type 1 : JDBC-ODBC bridge driver
    Type 2 : Native-API driver (partially Java driver)
    Type 3 : Network Protocol driver (fully Java driver)
    Type 4 : Thin driver (fully Java driver)
    

    JDBC: Type 1 JDBC-ODBC

    Type - I : JDBC-ODBC bridge driver
    The JDBC-ODBC bridge driver uses ODBC driver to connect to the database. The JDBC-ODBC bridge driver converts JDBC method calls into the ODBC function calls. This is now discouraged because of thin driver.


    Note: Oracle does not support the JDBC-ODBC Bridge from Java 8. Oracle recommends that you use JDBC drivers provided by the vendor of your database instead of the JDBC-ODBC Bridge.
    Advantages:
    
  • Easy to use.
  • Can be easily connected to any database.
  • Disadvantages:
  • Performance degraded because JDBC method call is converted into the ODBC function calls.
  • The ODBC driver needs to be installed on the client machine.
  • JDBC: Type 2 - Native-API

    Type - II : Native-API driver (partially Java driver)
    The native API driver uses the client-side libraries of the database. The driver converts JDBC method calls into native calls of the database API. It is not written entirely in java.

    Advantages:
    
  • Performance upgraded than JDBC-ODBC bridge driver.
  • Disadvantages:
  • The native driver needs to be installed on the each client machine.
  • The vendor client library needs to be installed on client machine.
  • JDBC: Type 3 - Network Protocol

    Type - III : Network Protocol driver (fully Java driver)
    The network protocol driver uses middleware (application server) that converts JDBC calls directly or indirectly into the vendor-specific database protocol. It is fully written in java.

    Advantages:
    
  • No client side library is required because of application server that can perform many tasks like auditing, load balancing, logging etc.
  • Disadvantages:
  • Network support is required on client machine.
  • Requires database-specific coding to be done in the middle tier.
  • Maintenance of Network Protocol driver becomes costly because it requires database-specific coding to be done in the middle tier.
  • JDBC: Type 4 - Thin Driver

    Type -IV : Thin driver (fully Java driver)
    The thin driver converts JDBC calls directly into the vendor-specific database protocol. That is why it is known as thin driver. It is fully written in Java language.

    Advantages:
    
  • Better performance than all other drivers.
  • No software is required at client side or server side.
  • Disadvantages:
  • Drivers depend on the database.

  • JDBC Architectures:

    JDBC Architecture : Two-tier

    JDBC Architecture : Three-tier

    Inside JDBC:

    JDBC steps

     Load a JDBC driver.
     Create connections.
     Connect to the data source.
     Execute SQL statement(s).
     Map the results to data structures.
    

    JDBC driver

    Acts as the gateway to a database.
    
    Not actually a Windows "driver", it is just a .jar file.
    
    For MySQL JDBC driver: 
                   mysql-connector-java-8.0.12-bin.jar (current)
    

    JDBC driver installation

    Download the driver, extract .jar file and add its path into your $CLASSPATH
    
    Linux: use command: 
         export CLASSPATH=$CLASSPATH::.
    
    Windows: Add the path of .jar file to system variable CLASSPATH 
    

    Connecting to Database:

    Common JDBC components

    Loading JDBC driver

    For MySql: 
          	Class.forName ("com.mysql.cj.jdbc.Driver").newInstance();
    
    For Oracle:  
           	Class.forName("oracle.jdbc.driver.OracleDriver").newInstance();
    
    For MS SQL Server :  
           Class.forName("com.microsoft.jdbc.sqlserver.SQLServerDriver").newInstance();
    

    Establishing connection

    Create a Connection object
    
    Use the DriverManager to grab a connection with the getConnection() method
    

    Three types of statements

    Executing SQL statements
    Create a statement object from the connection

    Useful methods in Statement class

    PrepareStatement : An example

    ResultSet

  • A ResultSet provides access to a table of data generated by executing a Statement.
  • Only one ResultSet per Statement can be open at once.
  • The table rows are retrieved in sequence.
  • A ResultSet maintains a cursor pointing to its current row of data.
  • The next() method moves the cursor to the next row.
  • you can't rewind.
  • Useful ResultSet methods

    Matching with Java and SQL data types

    Map the results to data structures

    JDBC exceptions
    SQLException is an Exception class which provides information on database access errors.


    Examples:

    Illustration 11.3				
    // Create JDBC connection to MySQL Database server
    
    import java.sql.*;
    public class Connect {
    	public static void main (String[] args) {
    		Connection conn = null;
    		try{
    			String userName = "root";
    			String password = "root";
    			String url = "jdbc:mysql://localhost:3306/test";
    			//Class.forName ("com.mysql.jdbc.Driver").newInstance (); // This is depricated
    			Class.forName ("com.mysql.cj.jdbc.Driver").newInstance ();// This is the newest driver
    			conn = DriverManager.getConnection (url, userName, password);
    			System.out.println ("Database connection established");
    		}
    		catch (Exception e) {
    			System.err.println ("Cannot connect to database server:"+e);
    		} finally {
    			if (conn != null) {
    				try {
    					conn.close ();
    					System.out.println ("Database connection terminated:"+e);
    				} catch (Exception e) { /* ignore close errors */ }
    			}     
    		} 
    	} 
    } 
    

    Illustration 11.4				
    // Create table in MySQL database using JDBC
    
    import java.sql.*;
    import java.sql.ResultSet;
    public class CreateTable{
    	public static void main (String[] args)   {
    		Connection conn = null;
    		Statement stmt = null; 
    		ResultSet rs = null;
    		String TableName;
    		try  {
    			String userName = "root";
    			String password = "root";
    			String url = "jdbc:mysql://localhost:3306/test";
    			Class.forName ("com.mysql.cj.jdbc.Driver").newInstance();
    			conn = DriverManager.getConnection (url, userName, password);
    			stmt = conn.createStatement();
    			//Creating table
    			stmt.execute("create table JavaCourse(Roll Integer primary key, Name Varchar(30), Marks Integer not null, Grade Varchar(2))");  
    		} catch (SQLException ex){
    			System.out.println("SQLException: " + ex.getMessage());
    			System.out.println("SQLState: " + ex.getSQLState());
    			System.out.println("VendorError: " + ex.getErrorCode());
    		}
    		catch (Exception e){
    			System.err.println ("Cannot connect to database server");
    		}
    		finally {
    			if (rs != null) {
    				try {
    					rs.close();
    				} catch (SQLException sqlEx) {}
    				rs = null;
    			}
    			if (stmt != null) {
    				try {
    					stmt.close();
    				} catch (SQLException sqlEx) {}
    				stmt = null; 
    			}
    			if (conn != null) {
    				try {
    					conn.close ();
    				} catch (Exception e) { /* Ignore code for closing errors */ }
    			}	   
    		} 
    	}
    }
    

    Illustration 11.6				
    // Insert data in MySQL database using JDBC
    
    import java.sql.*;
    import java.sql.ResultSet;
    public class InsertRecord{
    	public static void main (String[] args){
    		Connection conn = null;
    		Statement stmt = null; 
    		ResultSet rs = null;
    		String NameString, RollString, MarksString, GradeString;
    		
    		try{
    			String userName = "root";
    			String password = "root";
    			String url = "jdbc:mysql://localhost:3306/test";
    			Class.forName ("com.mysql.cj.jdbc.Driver").newInstance();
    			conn = DriverManager.getConnection (url, userName, password);                
    			stmt = conn.createStatement();  
    			stmt.execute("insert into JavaCourse values (01,'Debasis', 75, 'A')");
    			stmt.execute("insert into JavaCourse values(02,'Nilanjan', 85, 'EX')");
    			stmt.execute("insert into JavaCourse values(03,'Tauheed', 65, 'B')");
    			stmt.execute("insert into JavaCourse values(04,'Priyabrata', 78, 'A')");
    			} 
    		catch (SQLException ex){
    			// handle any errors
    			System.out.println("SQLException: " + ex.getMessage());
    			System.out.println("SQLState: " + ex.getSQLState());
    			System.out.println("VendorError: " + ex.getErrorCode());
    		}
    		catch (Exception e){
    			System.err.println ("Cannot connect to database server");
    		}
    		finally {
    			if (rs != null) {
    				try {
    					rs.close();
    				} catch (SQLException sqlEx) { } // ignore
    				rs = null;
    			}
    			if (stmt != null) {
    				try {
    					stmt.close();
    				} catch (SQLException sqlEx) { } // ignore
    				stmt = null;
    			}
    			if (conn != null) {
    				try {
    					conn.close ();// System.out.println ("Database connection terminated");
    				} catch (Exception e) { /* ignore close errors */ }
    			}
    		}
    	}
    }
    

    Illustration 11.7				
    // Update data in MySQL database using JDBC
    
    import java.sql.*;
    import java.sql.ResultSet;
    public class UpdateRecord{
    	public static void main (String[] args){
    		Connection conn = null;
    		Statement stmt = null; 
    		ResultSet rs = null;
    		String NameString, RollString, MarksString, GradeString;
    		try{
    			String userName = "root";
    			String password = "root";
    			String url = "jdbc:mysql://localhost:3306/test";
    			Class.forName ("com.mysql.cj.jdbc.Driver").newInstance();
    			conn = DriverManager.getConnection (url, userName, password);
    			stmt = conn.createStatement();
    			stmt.execute("update JavaCourse set Name='Debasis' where Name='Debasish'");
    			//stmt.execute("update JavaCourse set Marks=85, Grade='Ex' where Name='Debasis'");
    		}
    		catch (SQLException ex){
    			// handle any errors
    			System.out.println("SQLException: " + ex.getMessage());
    			System.out.println("SQLState: " + ex.getSQLState());
    			System.out.println("VendorError: " + ex.getErrorCode());
    		}
    		catch (Exception e){
    			System.err.println ("Cannot connect to database server");
    		} 
    		finally {
    			if (rs != null) {
    			try {
    				rs.close();
    				} catch (SQLException sqlEx) { } // ignore
    				rs = null;
    			}
    			if (stmt != null) {
    				try {
    					stmt.close();
    				} catch (SQLException sqlEx) { } // ignore
    				stmt = null;
    			}
    			if (conn != null) {
    				try {
    					conn.close ();
    				// System.out.println ("Database connection terminated");
    				} catch (Exception e) { /* ignore close errors */ }
    			}
    		} 
    	}
    }
    

    Illustration 11.8				
    // Delete table data in MySQL database using JDBC
    
    import java.sql.*;
    import java.sql.ResultSet;
    public class DeleteRecord{
    	public static void main (String[] args){
    		Connection conn = null;
    		Statement stmt = null; 
    		ResultSet rs = null;
    		String NameString, RollString, MarksString, GradeString;
    		try{
    			String userName = "root";
    			String password = "root";
    			String url = "jdbc:mysql://localhost:3306/test";
    			Class.forName ("com.mysql.cj.jdbc.Driver").newInstance();
    			conn = DriverManager.getConnection (url, userName, password);
    			stmt = conn.createStatement();  
    			stmt.execute("delete from JavaCourse where marks <66");
    			//stmt.execute("delete from JavaCourse");
    		}	
    		catch (SQLException ex){
    			// handle any errors
    			System.out.println("SQLException: " + ex.getMessage());
    			System.out.println("SQLState: " + ex.getSQLState());
    			System.out.println("VendorError: " + ex.getErrorCode());
    		}
    		catch (Exception e){
    			System.err.println ("Cannot connect to database server:"+e);
    		}
    		finally {
    			if (rs != null) {
    				try {
    					rs.close();
    				} catch (SQLException sqlEx) { } // ignore
    				rs = null;
    			}
    			if (stmt != null) {
    				try {
    					stmt.close();
    				} catch (SQLException sqlEx) { } // ignore
    				stmt = null;
    			}
    			if (conn != null) {
    				try {
    					conn.close ();
    				// System.out.println ("Database connection terminated");
    				}
    				catch (Exception e) { /* ignore close errors */ }
    			}
    		}
    	}
    }
    

    Illustration 11.9				
    // Drop a table in MySQL database using JDBC
    
    import java.sql.*;
    import java.sql.ResultSet;
    public class DropTable{
    	public static void main (String[] args){
    		Connection conn = null;
    		Statement stmt = null; 
    		ResultSet rs = null;
    		String NameString, RollString, MarksString, GradeString;
    		try{
    			String userName = "root";
    			String password = "root";
    			String url = "jdbc:mysql://localhost:3306/test";
    			Class.forName ("com.mysql.cj.jdbc.Driver").newInstance();
    			conn = DriverManager.getConnection (url, userName, password);
    			stmt = conn.createStatement();  
    			stmt.execute("drop table JavaCourse");
    		}	
    		catch (SQLException ex){
    			// handle any errors
    			System.out.println("SQLException: " + ex.getMessage());
    			System.out.println("SQLState: " + ex.getSQLState());
    			System.out.println("VendorError: " + ex.getErrorCode());
    		}
    		catch (Exception e){
    			System.err.println ("Cannot connect to database server:"+e);
    		}
    		finally {
    			if (rs != null) {
    				try {
    					rs.close();
    				} catch (SQLException sqlEx) { } // ignore
    				rs = null;
    			}
    			if (stmt != null) {
    				try {
    					stmt.close();
    				} catch (SQLException sqlEx) { } // ignore
    				stmt = null;
    			}
    			if (conn != null) {
    				try {
    					conn.close ();
    				// System.out.println ("Database connection terminated");
    				}
    				catch (Exception e) { /* ignore close errors */ }
    			}
    		}
    	}
    }
    

    Illustration 11.10				
    /*
    A program to select all data present in a table and calculate average marks
    */
    
    import java.sql.*;
    import java.sql.ResultSet;
    public class SelectRecord   {
    	public static void main (String[] args){
    		Connection conn = null;
    		Statement stmt = null; 
    		ResultSet rs = null;
    		int TotalMarks=0, Num_Student=0; 
    		float Avg_Marks;
    		String NameString, RollString, MarksString, GradeString;
    		try{
    			String userName = "root";
    			String password = "root";
    			String url = "jdbc:mysql://localhost:3306/test";
    			Class.forName ("com.mysql.cj.jdbc.Driver").newInstance();
    			conn = DriverManager.getConnection (url, userName, password);
    			stmt = conn.createStatement();  
    			stmt.execute("SELECT * FROM JavaCourse");
    			rs = stmt.getResultSet();
    			System.out.println("\n\n -------  Results  ---------\n");
    			while (rs.next()) {
    			NameString = rs.getString("Name");
    			RollString = rs.getString("Roll");
    			MarksString = rs.getString("Marks");
    			GradeString = rs.getString("Grade");	
    			TotalMarks = TotalMarks + Integer.parseInt(MarksString);
    			System.out.println("Name: = "+NameString+"\t\t"+"Roll: = "+RollString+"\t\t"+"Marks: = "+MarksString+"\t\t"+"Grade: = "+GradeString+"\n");
    			} //end while
    			rs.last();
    			Num_Student = rs.getRow();
    			Avg_Marks = TotalMarks / Num_Student; 
    			System.out.println("\n\n ------- AVERAGE Marks = "+Avg_Marks+"--------");
    		}
    		catch (SQLException ex){
    			// handle any errors
    			System.out.println("SQLException: " + ex.getMessage());
    			System.out.println("SQLState: " + ex.getSQLState());
    			System.out.println("VendorError: " + ex.getErrorCode());
    		}
    		catch (ArithmeticException e) {
    			System.out.println("Division by zero.");
    		} 
    		catch (Exception e) {
    			System.err.println ("Cannot connect to database server");
    		}
    		finally {
    			if (rs != null) {
    				try {
    					rs.close();
    				} catch (SQLException sqlEx) { } // ignore
    				rs = null;
    			}
    			if (conn != null) {
    				try {
    					conn.close ();
    				// System.out.println ("Database connection terminated");
    				}
    				catch (Exception e) { /* ignore close errors */ }
    			}
    		}
    	}
    } 
    

    Illustration 11.11				
    /*
    Create a table in MySQL DB using JDBC
    	- First show all the existing tables
    	- Insert the new table
    	- Show all the current tables 
    */
    import java.sql.*;
    import java.sql.ResultSet;
    public class CreateTable{
       public static void main (String[] args)   {
        Connection conn = null;
    	Statement stmt = null; 
    	ResultSet rs = null;
               String TableName;
               try  {
                    String userName = "root";
                    String password = "root";
                    String url = "jdbc:mysql://localhost:3306/test";
                    Class.forName ("com.mysql.cj.jdbc.Driver").newInstance();
                    conn = DriverManager.getConnection (url, userName, password);
    				stmt = conn.createStatement();
    				stmt.execute("show tables");
    			    rs = stmt.getResultSet();
    			    System.out.println("Result before creating the table");	
    			    while (rs.next()) {
    				   TableName = rs.getString("Tables_in_test");  // To create a table having name JavaCourse
    				   System.out.println("Table Name: = "+TableName+"\n");
    				}
    				stmt.execute("create table JavaCourse(Roll Integer primary key, Name Varchar(30), Marks Integer not null, Grade Varchar(2))");
    				stmt.execute("show tables");
    				rs = stmt.getResultSet();
    				System.out.println("Result after creating the table\n");
    		    	while (rs.next()) {
    		    		   TableName = rs.getString("Tables_in_test"); 
    		    		   System.out.println("Table Name: = "+TableName+"\n");
    		    	}  
    		    } catch (SQLException ex){
    		    		   System.out.println("SQLException: " + ex.getMessage());
    		    		   System.out.println("SQLState: " + ex.getSQLState());
    		    		   System.out.println("VendorError: " + ex.getErrorCode());
    		    }
    		    catch (Exception e){
    		    		   System.err.println ("Cannot connect to database server");
    		    }
                finally {
    				   if (rs != null) {
    					 try {
    						rs.close();
    					 } catch (SQLException sqlEx) {}
    						 rs = null;
    				   }
    				  if (stmt != null) {
    					  try {
    						  stmt.close();
    					  } catch (SQLException sqlEx) {}
    						  stmt = null; 
    				   }
    				  if (conn != null) {
    					try {
    						  conn.close ();
    						} catch (Exception e) { /* Ignore code for closing errors */ }
    				}			   
    		} 
       }
    }
    

    Illustration 11.12				
    /*
    Insert data in MySQL DB using JDBC
    	- First show all the existing data
    	- Insert the new data
    	- Show all the current data
    */
    import java.sql.*;
    import java.sql.ResultSet;
    public class InsertRecord{
    	public static void main (String[] args){
    		Connection conn = null;
    		Statement stmt = null; 
    		ResultSet rs = null;
    		String NameString, RollString, MarksString, GradeString;
    
    		try{
    			String userName = "root";
    			String password = "root";
    			String url = "jdbc:mysql://localhost:3306/test";
    			Class.forName ("com.mysql.cj.jdbc.Driver").newInstance();
    			conn = DriverManager.getConnection (url, userName, password);                
    			stmt = conn.createStatement();  
    			
    			stmt.execute("SELECT * FROM JavaCourse");
    			rs = stmt.getResultSet();
    			System.out.println("\n\n ------- Result Before Insert---------\n");
    			while (rs.next()) {
    			NameString = rs.getString("Name");
    			RollString = rs.getString("Roll");
    			MarksString = rs.getString("Marks");
    			GradeString = rs.getString("Grade");
    			System.out.println("Name: = "+NameString+"\t\t"+"Roll: = "+RollString+"\t\t"+"Marks: = "+MarksString+"\t\t"+"Grade: = "+GradeString+"\n");
    			} //end while
    			
    			stmt.execute("insert into JavaCourse values (01,'Debasish', 75, 'A')");
    			stmt.execute("insert into JavaCourse values(02,'Nilanjan', 85, 'EX')");
    			stmt.execute("insert into JavaCourse values(03,'Tauheed', 65, 'B')");
    			stmt.execute("insert into JavaCourse values(04,'Priyabrata', 78, 'A')");
    			
    			stmt.execute("SELECT * FROM JavaCourse");
    			rs = stmt.getResultSet();
    			System.out.println("\n\n ------- Result After Insert---------\n");
    			while (rs.next()) {
    			NameString = rs.getString("Name");
    			RollString = rs.getString("Roll");
    			MarksString = rs.getString("Marks");
    			GradeString = rs.getString("Grade");			 
    			System.out.println("Name: = "+NameString+"\t\t"+"Roll: ="+RollString+"\t\t"+"Marks: = "+MarksString+"\t\t"+"Grade: = "+GradeString+"\n");
    			} //end while
    		}
    		catch (SQLException ex){
    			// handle any errors
    			System.out.println("SQLException: " + ex.getMessage());
    			System.out.println("SQLState: " + ex.getSQLState());
    			System.out.println("VendorError: " + ex.getErrorCode());
    		}
    		catch (Exception e){
    			System.err.println ("Cannot connect to database server");
    		}
    		finally {
    			if (rs != null) {
    				try {
    					rs.close();
    				} catch (SQLException sqlEx) { } // ignore
    				rs = null;
    			}
    			if (stmt != null) {
    				try {
    					stmt.close();
    				} catch (SQLException sqlEx) { } // ignore
    				stmt = null;
    			}
    			if (conn != null) {
    				try {
    					conn.close ();// System.out.println ("Database connection terminated");
    				} catch (Exception e) { /* ignore close errors */ }
    			}
    		}
    	}
    }
    

    Illustration 11.13				
    /*
    Update data in MySQL DB using JDBC
    	- First show all the existing data
    	- Update the new data
    	- Show all the current data
    */
    import java.sql.*;
    import java.sql.ResultSet;
    public class UpdateRecord{
    	public static void main (String[] args){
    		Connection conn = null;
    		Statement stmt = null; 
    		ResultSet rs = null;
    		String NameString, RollString, MarksString, GradeString;
    		try{
    			String userName = "root";
    			String password = "root";
    			String url = "jdbc:mysql://localhost:3306/test";
    			Class.forName ("com.mysql.cj.jdbc.Driver").newInstance();
    			conn = DriverManager.getConnection (url, userName, password);
    			stmt = conn.createStatement();  
    			stmt.execute("SELECT * FROM JavaCourse");
    			rs = stmt.getResultSet();
    			System.out.println("\n\n ------- Result Before Update ---------\n");
    			while (rs.next()) {
    				NameString = rs.getString("Name");
    				RollString = rs.getString("Roll");
    				MarksString = rs.getString("Marks");
    				GradeString = rs.getString("Grade");				 
    				System.out.println("Name: = "+NameString+"\t\t"+"Roll: = "+RollString+"\t\t"+"Marks: = "+MarksString+"\t\t"+"Grade: = "+GradeString+"\n");
    			} //end while
    			// Update a row
    			stmt.execute("update JavaCourse set Marks=85, Grade='Ex' where Name='Debasish Kundu'");
    			stmt.execute("SELECT * FROM JavaCourse");
    			rs = stmt.getResultSet();
    			System.out.println("\n\n ------- Result After Update ---------\n");
    			while (rs.next()) {
    				NameString = rs.getString("Name");
    				RollString = rs.getString("Roll");
    				MarksString = rs.getString("Marks");
    				GradeString = rs.getString("Grade");				 
    				System.out.println("Name: = "+NameString+"\t\t"+"Roll: = "+RollString+"\t\t"+"Marks: = "+MarksString+"\t\t"+"Grade: = "+GradeString+"\n");
    			} //end while
    		}
    		catch (SQLException ex){
    			// handle any errors
    			System.out.println("SQLException: " + ex.getMessage());
    			System.out.println("SQLState: " + ex.getSQLState());
    			System.out.println("VendorError: " + ex.getErrorCode());
    		}
    		catch (Exception e){
    			System.err.println ("Cannot connect to database server");
    		} 
    		finally {
    			if (rs != null) {
    				try {
    					rs.close();
    				} catch (SQLException sqlEx) { } // ignore
    				rs = null;
    			}
    			if (stmt != null) {
    				try {
    					stmt.close();
    				} catch (SQLException sqlEx) { } // ignore
    				stmt = null;
    			}
    			if (conn != null) {
    				try {
    					conn.close ();
    				// System.out.println ("Database connection terminated");
    				}                catch (Exception e) { /* ignore close errors */ }
    			}
    		} 
    	}
    }
    

    Illustration 11.14				
    /*
    Delete table data in MySQL DB using JDBC
    	- First show all the existing data
    	- Delete the data
    	- Show all the currently present data 
    */
    import java.sql.*;
    import java.sql.ResultSet;
    public class DeleteRecord{
    	public static void main (String[] args){
    		Connection conn = null;
    		Statement stmt = null; 
    		ResultSet rs = null;
    		String NameString, RollString, MarksString, GradeString;
    		try{
    			String userName = "root";
    			String password = "root";
    			String url = "jdbc:mysql://localhost:3306/test";
    			Class.forName ("com.mysql.cj.jdbc.Driver").newInstance();
    			conn = DriverManager.getConnection (url, userName, password);
    			stmt = conn.createStatement();  
    			stmt.execute("SELECT * FROM JavaCourse");
    			rs = stmt.getResultSet();
    			System.out.println("\n\n ------- Result Before Update ---------\n");
    			while (rs.next()) {
    				NameString = rs.getString("Name");
    				RollString = rs.getString("Roll");
    				MarksString = rs.getString("Marks");
    				GradeString = rs.getString("Grade");				 
    				System.out.println("Name: = "+NameString+"\t\t"+"Roll: = "+RollString+"\t\t"+"Marks: = "+MarksString+"\t\t"+"Grade: = "+GradeString+"\n");
    			} //end while
    			
    			
    			// Delete data with marks less than value 66
    			stmt.execute("delete from JavaCourse where marks <66");
    			
    			
    			stmt.execute("SELECT * FROM JavaCourse");
    			rs = stmt.getResultSet();
    			System.out.println("\n\n ------- Result After Deletion ---------\n");
    			while (rs.next()) {
    				NameString = rs.getString("Name");
    				RollString = rs.getString("Roll");
    				MarksString = rs.getString("Marks");
    				GradeString = rs.getString("Grade");				 
    				System.out.println("Name: = "+NameString+"\t\t"+"Roll: = "+RollString+"\t\t"+"Marks: = "+MarksString+"\t\t"+"Grade: = "+GradeString+"\n");
    			} //end while
    		}
    		catch (SQLException ex){
    			// handle any errors
    			System.out.println("SQLException: " + ex.getMessage());
    			System.out.println("SQLState: " + ex.getSQLState());
    			System.out.println("VendorError: " + ex.getErrorCode());
    		}
    		catch (Exception e){
    			System.err.println ("Cannot connect to database server");
    		} 
    		finally {
    			if (rs != null) {
    				try {
    					rs.close();
    				} catch (SQLException sqlEx) { } // ignore
    				rs = null;
    			}
    			if (stmt != null) {
    				try {
    					stmt.close();
    				} catch (SQLException sqlEx) { } // ignore
    				stmt = null;
    			}
    			if (conn != null) {
    				try {
    					conn.close ();
    				// System.out.println ("Database connection terminated");
    				}                catch (Exception e) { /* ignore close errors */ }
    			}
    		} 
    	}
    }