Previously, when using MySqlDataReader
, the
connection to the database was continually maintained unless
explicitly closed. It is also possible to work in a manner where a
connection is only established when needed. For example, in this
mode, a connection could be established to read a chunk of data,
the data could then be modified by the application as required. A
connection could then be reestablished only if and when the
application writes data back to the database. This decouples the
working data set from the database.
This decoupled mode of working with data is supported by MySQL Connector/NET. There are several parts involved in allowing this method to work:
Data Set. The Data Set is the area in which data is loaded to read or modify it. A
DataSet
object is instantiated, which can store multiple tables of data.Data Adapter. The Data Adapter is the interface between the Data Set and the database itself. The Data Adapter is responsible for efficiently managing connections to the database, opening and closing them as required. The Data Adapter is created by instantiating an object of the
MySqlDataAdapter
class. TheMySqlDataAdapter
object has two main methods:Fill
which reads data into the Data Set, andUpdate
, which writes data from the Data Set to the database.Command Builder. The Command Builder is a support object. The Command Builder works in conjunction with the Data Adapter. When a
MySqlDataAdapter
object is created, it is typically given an initial SELECT statement. From thisSELECT
statement the Command Builder can work out the correspondingINSERT
,UPDATE
andDELETE
statements that would be required to update the database. To create the Command Builder, an object of the classMySqlCommandBuilder
is created.
The remaining sections describe each of these classes in more detail.
A DataSet
object can be created simply, as
shown in the following code-snippet:
DataSet dsCountry;
...
dsCountry = new DataSet();
Although this creates the DataSet
object, it
has not yet filled it with data. For that, a Data Adapter is
required.
The MySqlDataAdapter
can be created as
illustrated by the following example:
MySqlDataAdapter daCountry;
...
string sql = "SELECT Code, Name, HeadOfState FROM Country WHERE Continent='North America'";
daCountry = new MySqlDataAdapter (sql, conn);
The MySqlDataAdapter
is given the SQL
specifying the data to work with.
Once the MySqlDataAdapter
has been created,
it is necessary to generate the additional statements required
for inserting, updating and deleting data. There are several
ways to do this, but in this tutorial you will see how this can
most easily be done with MySqlCommandBuilder
.
The following code snippet illustrates how this is done:
MySqlCommandBuilder cb = new MySqlCommandBuilder(daCountry);
The MySqlDataAdapter
object is passed as a
parameter to the command builder.
To do anything useful with the data from your database, you need
to load it into a Data Set. This is one of the jobs of the
MySqlDataAdapter
object, and is carried out
with its Fill
method. The following code
example illustrates this point.
DataSet dsCountry;
...
dsCountry = new DataSet();
...
daCountry.Fill(dsCountry, "Country");
The Fill
method is a
MySqlDataAdapter
method, and the Data Adapter
knows how to establish a connection with the database and
retrieve the required data, and then populate the Data Set when
the Fill
method is called. The second
parameter “Country” is the table in the Data Set to
update.
The data in the Data Set can now be manipulated by the
application as required. At some point, changes to data will
need to be written back to the database. This is achieved
through a MySqlDataAdapter
method, the
Update
method.
daCountry.Update(dsCountry, "Country");
Again, the Data Set and the table within the Data Set to update are specified.
The interactions between the DataSet
,
MySqlDataAdapter
and
MySqlCommandBuilder
classes can be a little
confusing, so their operation can perhaps be best illustrated by
working code.
In this example, data from the world
database
is read into a Data Grid View control. Here, the data can be
viewed and changed before clicking an update button. The update
button then activates code to write changes back to the
database. The code uses the principles explained previously. The
application was built using the Microsoft Visual Studio to place
and create the user interface controls, but the main code that
uses the key classes described previously is shown in the next
code example, and is portable.
using System;
using System.Collections.Generic;
using System.ComponentModel;
using System.Data;
using System.Drawing;
using System.Linq;
using System.Text;
using System.Windows.Forms;
using MySql.Data;
using MySql.Data.MySqlClient;
namespace WindowsFormsApplication5
{
public partial class Form1 : Form
{
MySqlDataAdapter daCountry;
DataSet dsCountry;
public Form1()
{
InitializeComponent();
}
private void Form1_Load(object sender, EventArgs e)
{
string connStr = "server=localhost;user=root;database=world;port=3306;password=******";
MySqlConnection conn = new MySqlConnection(connStr);
try
{
label2.Text = "Connecting to MySQL...";
string sql = "SELECT Code, Name, HeadOfState FROM Country WHERE Continent='North America'";
daCountry = new MySqlDataAdapter (sql, conn);
MySqlCommandBuilder cb = new MySqlCommandBuilder(daCountry);
dsCountry = new DataSet();
daCountry.Fill(dsCountry, "Country");
dataGridView1.DataSource = dsCountry;
dataGridView1.DataMember = "Country";
}
catch (Exception ex)
{
label2.Text = ex.ToString();
}
}
private void button1_Click(object sender, EventArgs e)
{
daCountry.Update(dsCountry, "Country");
label2.Text = "MySQL Database Updated!";
}
}
}
The following figure shows the application started. The World Database Application updated data in three columns: Code, Name, and HeadOfState.