This section illustrates how to work with stored procedures.
Putting database-intensive operations into stored procedures lets
you define an API for your database application. You can reuse
this API across multiple applications and multiple programming
languages. This technique avoids duplicating database code, saving
time and effort when you make updates due to schema changes, tune
the performance of queries, or add new database operations for
logging, security, and so on. Before working through this
tutorial, familiarize yourself with the
CREATE PROCEDURE
and
CREATE FUNCTION
statements that
create different kinds of stored routines.
For the purposes of this tutorial, you will create a simple stored
procedure to see how it can be called from MySQL Connector/NET. In the MySQL
Client program, connect to the world
database
and enter the following stored procedure:
DELIMITER //
CREATE PROCEDURE country_hos
(IN con CHAR(20))
BEGIN
SELECT Name, HeadOfState FROM Country
WHERE Continent = con;
END //
DELIMITER ;
Test that the stored procedure works as expected by typing the following into the mysql command interpreter:
CALL country_hos('Europe');
The stored routine takes a single parameter, which is the continent to restrict your search to.
Having confirmed that the stored procedure is present and correct, you can see how to access it from Connector/NET.
Calling a stored procedure from your Connector/NET application is similar
to techniques you have seen earlier in this tutorial. A
MySqlCommand
object is created, but rather than
taking an SQL query as a parameter, it takes the name of the
stored procedure to call. Set the MySqlCommand
object to the type of stored procedure, as shown by the following
code snippet:
string rtn = "country_hos";
MySqlCommand cmd = new MySqlCommand(rtn, conn);
cmd.CommandType = CommandType.StoredProcedure;
In this case, the stored procedure requires you to pass a parameter. This can be achieved using the techniques seen in the previous section on parameters, Section 6.1.4, “Working with Parameters”, as shown in the following code snippet:
cmd.Parameters.AddWithValue("@con", "Europe");
The value of the parameter @con
could more
realistically have come from a user input control, but for
simplicity it is set as a static string in this example.
At this point, everything is set up and you can call the routine
using techniques also learned in earlier sections. In this case,
the ExecuteReader
method of the
MySqlCommand
object is used.
The following code shows the complete stored procedure example.
using System;
using System.Data;
using MySql.Data;
using MySql.Data.MySqlClient;
public class Tutorial6
{
public static void Main()
{
string connStr = "server=localhost;user=root;database=world;port=3306;password=******";
MySqlConnection conn = new MySqlConnection(connStr);
try
{
Console.WriteLine("Connecting to MySQL...");
conn.Open();
string rtn = "country_hos";
MySqlCommand cmd = new MySqlCommand(rtn, conn);
cmd.CommandType = CommandType.StoredProcedure;
cmd.Parameters.AddWithValue("@con", "Europe");
MySqlDataReader rdr = cmd.ExecuteReader();
while (rdr.Read())
{
Console.WriteLine(rdr[0] + " --- " + rdr[1]);
}
rdr.Close();
}
catch (Exception ex)
{
Console.WriteLine(ex.ToString());
}
conn.Close();
Console.WriteLine("Done.");
}
}
In this section, you have seen how to call a stored procedure from Connector/NET. For the moment, this concludes our introductory tutorial on programming with Connector/NET.