dotConnect for MySQL Documentation
In This Topic
    Using Parameters
    In This Topic

    dotConnect for MySQL enhances SQL handling capabilities with usage of parameters in SQL queries. You can make execution of a query or stored procedure very flexible using several simple techniques. This article describes some basics you must be acquainted with when working with parameters in dotConnect for MySQL, as well as parameters synchronization and some nuances related to usage of stored procedures.

    The article consists of following sections:

    Parameters basics

    In general, a parameter is a placeholder for a variable that contains some value of some type when executing a general-purpose query, or arguments and return values when a stored procedure is executed. Parameter is represented by MySql.MySqlParameter class. All parameters that take part in query execution constitute a collection that can be accessed through MySqlCommand.Parameters property.

    MySQL supports two kinds of parameters: named and unnamed.

    Unnamed parameters can be specified as '?' character. The following query

        INSERT INTO dept (deptno, dname, loc) VALUES (?, ?, ?)
    

    declares that three parameters are required to run the query properly. To set parameters for this query you can use the next code:

    MySqlCommand mySqlCommand1;
    ...
    mySqlCommand1.CommandText = "INSERT INTO dept (deptno, dname, loc) VALUES (?, ?, ?)";
    mySqlCommand1.Parameters.Add("param1", 30);
    mySqlCommand1.Parameters.Add("param2", "SALES");
    mySqlCommand1.Parameters.Add("param3", "CHICAGO");
    
    
    Dim mySqlCommand1 as MySqlCommand
    ...
    mySqlCommand1.CommandText = "INSERT INTO dept (deptno, dname, loc) VALUES (?, ?, ?)"
    mySqlCommand1.Parameters.Add("param1", 30)
    mySqlCommand1.Parameters.Add("param2", "SALES")
    mySqlCommand1.Parameters.Add("param3", "CHICAGO")
    
    

    Named parameters require accordance with names of MySqlParameter instances in the collection. Named parameters are declared using ':' or '@' prefix followed by name of the parameter. Note that the name of the MySqlParameter object in the collection of the command should contain the '@' prefix if parameter in CommandText is used with the '@' prefix. If the parameter in CommandText contains the ':' prefix, the name of the MySqlParameter object in the command's collection should be used without any prefix. You can use these prefixes at any combinations to specify parameters. There are two main advantages of named parameters. First, you do not have to care about the order in which parameters are created. Second, named parameter can appear more than once in query text, but you have to create only one instance of it in Parameters collection.

    For example, a simple Update statement that requires named parameters might look like the following:

        UPDATE dept SET dname = :dname, loc = :loc WHERE deptno = @deptno
    

    To set parameters for this query you can use the next code:

    MySqlCommand mySqlCommand1;
    ...
    mySqlCommand1.CommandText = "UPDATE dept SET dname = :dname, +
                                loc = :loc WHERE deptno = @deptno";
    mySqlCommand1.Parameters.Add("@deptno", 20);
    mySqlCommand1.Parameters.Add("dname", "SALES");
    mySqlCommand1.Parameters.Add("loc", "NEW YORK");
    
    
    Dim mySqlCommand1 as MySqlCommand
    ...
    mySqlCommand1.CommandText = "UPDATE dept SET dname = :dname, &_
                                 loc = :loc WHERE deptno = @deptno"
    mySqlCommand1.Parameters.Add("@deptno", 20)
    mySqlCommand1.Parameters.Add("dname", "SALES")
    mySqlCommand1.Parameters.Add("loc", "NEW YORK")
    
    

    MySQL server variables are also denoted using '@' symbol. When encountered in query text, such fragments are treated as parameters only if they are found in the MySqlCommand.Parameters collection; otherwise they are considered server variables.

    When you invoke a stored procedure you have to create collection of parameters that corresponds strictly to set of arguments for the stored procedure in quantity and types. Names of parameters do not matter unless you set MySqlCommand.ParameterCheck property to true. You must not use the "@" prefix in the stored procedure parameter names. Parameters that represent arguments to the procedure must have their Direction property set to Input. You retrieve value returned by a stored function through a parameter with Direction property set to ReturnValue.

    Using automatic parameters synchronization

    The behavior described above assumes that MySqlCommand.ParameterCheck is false (by default). By turning it on you enable automatic synchronization of query text and MySqlCommand.Parameters collection. In this mode all input parameters are checked for validity, new ones are added if necessary, and redundant parameters are deleted. Thus you do not have to take care about quantity of items in MySqlCommand.Parameters collection, you can specify only the ones you really need. The synchronization is done as follows:

    For queries that do not represent a stored procedure the synchronization takes place when:

    For stored procedures synchronization happens when:

    A separate query is executed against the server to establish the correct types of the parameters when synchronization is performed for stored procedures.

    If synchronization is already performed, subsequent calls to these methods do not result in re-synchronization, unless you had modified Parameters collection or one of the properties listed above.

    Using parameters with stored procedures in synchronization mode

    If parameters are added to the command collection in the order that is different from the function parameters order in database, it is necessary to describe the command by setting MySqlCommand.ParameterCheck to true to reoder parameters in a proper way.

    When MySqlCommand.ParameterCheck is true you can specify only those parameters you really need. Omitted parameters will be created and assigned DBNull value. You can set up required parameters in any order you like. The collection will be filled up and sorted as a result of synchronization.

    When working with stored procedures in synchronization mode you can use named parameters only. Parameter's name must match exactly name of procedure's argument. However the ReturnValue parameter needs not to have any specific name.

    In synchronization mode first call to MySqlCommand.Prepare or MySqlCommand.Execute methods leads to recreation of all argument parameters. If name of a parameter is suitable for the description of stored procedure, parameter is preserved in the collection, otherwise it is lost. If MySqlCommand.CommandText property and Parameters collection are unchanged all subsequent invocations of Prepare or Execute methods will not result in recreation of parameters.

    For example, consider you had a stored procedure that accepts two arguments, deptno and dname, and then changed MySqlCommand.CommandText to reference another stored procedure that accepts deptno and loc arguments. In this case you will have first parameter unchanged, and the second parameter recreated with value assigned to DBNull.

    Using OUT and INOUT parameters

    Unfortunately MySQL does not support OUT parameters in protocol yet. However, dotConnect for MySQL allows you to handle OUT parameters using server-side variables. Consider the following CREATE statement:

      CREATE PROCEDURE testproc(IN param1 INTEGER(11), OUT param2 INTEGER(11))
      BEGIN
      SET param2=param1*2;
      END
    

    The procedure takes input parameter, multiplies it by two, and stores outcome in the out parameter. To retrieve value of out parameter declare temporary server variable and then query its value as follows:

    MySqlConnection myConn = new MySqlConnection(
    "user id=root;database=demobase;host=localhost;password=root");
    myConn.Open();
    MySqlCommand command = new MySqlCommand(
    "CALL testproc(10, @param2);SELECT @param2", myConn);
    using (IDataReader reader = command.ExecuteReader()) {
      if (reader.Read())
        Console.WriteLine("@param2 = " + reader[0]);
    }
    myConn.Close();
    
    
    Dim myConn As MySqlConnection = New MySqlConnection( _
    "user id=root;database=demobase;host=localhost;password=root")
    myConn.Open()
    Dim command As MySqlCommand = New MySqlCommand( _
    "CALL testproc(10, @param2);SELECT @param2", myConn)
    Dim reader As IDataReader = command.ExecuteReader()
    If (reader.Read()) Then
      Console.WriteLine("@param2 = " & reader(0))
    End If
    reader.Close()
    myConn.Close()
    
    

    Same technique can be used to handle INOUT parameters. To assign initial value to the parameter use SET statement that preceedes a call to stored procedure. The next example shows how to reform previous call to stored procedure using single INOUT parameter.

      CREATE PROCEDURE testproc(INOUT param1 INTEGER(11))
      BEGIN
      SET param1=param1*2;
      END
    
    MySqlConnection myConn = new MySqlConnection(
    "user id=root;database=demobase;host=localhost;password=root");
    myConn.Open();
    MySqlCommand command = new MySqlCommand(
    "SET @param1=11;CALL testproc(@param1);SELECT @param1", myConn);
    using (IDataReader reader = command.ExecuteReader()) {
      if (reader.Read())
        Console.WriteLine("@param1 = " + reader[0]);
    }
    myConn.Close();
    
    
    Dim myConn As MySqlConnection = New MySqlConnection( _
    "user id=root;database=demobase;host=localhost;password=root")
    myConn.Open()
    Dim command As MySqlCommand = New MySqlCommand( _
    "SET @param1=11;CALL d.testproc(@param1);SELECT @param1", myConn)
    Dim reader As IDataReader = command.ExecuteReader()
    If (reader.Read()) Then
      Console.WriteLine("@param1 = " & reader(0))
    End If
    reader.Close()
    myConn.Close()
    
    

    Performance issues

    In general, setting MySqlCommand.ParameterCheck property to true leads to some performance loss.

    When MySqlCommand.CommandType is "Text" the synchronization is performed on client, so performance reduces very slightly.

    When MySqlCommand.CommandType is "StoredProcedure", dotConnect for MySQL sends additional requests to server which are necessary to determine quantity, names, and other information about parameters. Thus performance mostly depends on how fast these additional round trips are performed.

    To optimize multiple execution of a query you can manually call you can manually call the MySqlCommand.Prepare method that creates a compiled version of the query on server and forces synchronization. Moreover, for prepared query data is transferred and treated in different (binary) mode, which is much faster, especially when it concerns BLOB fields. After the query is prepared, it is not advised to alter MySqlCommand.Text property because the MySqlCommand becomes unprepared again. The recommended practice is to set up query text and parameters, execute MySqlCommand.Prepare method, and afterwards change only parameters' values.

    Examples

    The first example demonstrates how flexible and convenient usage of parameters can be. In the example two new Sales departments are added to table Dept; then all departments with this name are rendered to console.

    First, query text is assigned to MySqlCommand object. When MySqlCommand.ParameterCheck is set to true dotConnect for MySQL automatically creates collection of parameters you can access to set values. Second, MySqlCommand.Prepare method call is issued to achieve the best performance. Two rows are added to table then, each referencing Sales department. Afterwards the query text is changed and again MySqlCommand.Parameters collection is rebuilt. This time it has only one item in it. Notice that this parameter was assigned an Int32 value before and now it holds a string. This is possible since you do not assign MySqlParameter.MySqlType explicitly. Once you set a value to MySqlType or DbType property autodetection of data type ceases to work.

    static void Main(string[] args)
    {
      MySqlConnection myConn = new MySqlConnection(
      "user id=root;database=demobase;host=localhost");
      myConn.Open();
      MySqlCommand myCommand = new MySqlCommand("INSERT INTO Dept VALUES (?, ?, ?)", myConn);
      myCommand.ParameterCheck = true;
      myCommand.Prepare();
      myCommand.Parameters[0].Value = 60;
      myCommand.Parameters[1].Value = "SALES";
      myCommand.Parameters[2].Value = "LA";
      myCommand.ExecuteNonQuery();
      myCommand.Parameters[0].Value = 70;
      myCommand.Parameters[2].Value = "DETROIT";
      myCommand.ExecuteNonQuery();
      myCommand.CommandText = "SELECT * FROM Dept WHERE DName=?";
      myCommand.Parameters[0].Value = "SALES";
      MySqlDataReader myReader = myCommand.ExecuteReader();
      while (myReader.Read())
      {
        Console.WriteLine(myReader.GetInt32(0) + ", " + myReader.GetString(2));
      }
      myReader.Close();
      myConn.Close();
      Console.ReadLine();
    }
    
    
    Sub Main()
      Dim myConn As MySqlConnection = New MySqlConnection( _
      "user id=root;database=demobase;host=localhost")
      myConn.Open()
      Dim myCommand As MySqlCommand = New &_ 
              MySqlCommand("INSERT INTO Dept VALUES (?, ?, ?)", myConn)
      myCommand.ParameterCheck = True
      myCommand.Prepare()
      myCommand.Parameters(0).Value = 60
      myCommand.Parameters(1).Value = "SALES"
      myCommand.Parameters(2).Value = "LA"
      myCommand.ExecuteNonQuery()
      myCommand.Parameters(0).Value = 70
      myCommand.Parameters(2).Value = "DETROIT"
      myCommand.ExecuteNonQuery()
      myCommand.CommandText = "SELECT * FROM Dept WHERE DName=?"
      myCommand.Parameters(0).Value = "SALES"
      Dim myReader As MySqlDataReader = myCommand.ExecuteReader()
      While myReader.Read()
        Console.WriteLine(myReader.GetInt32(0).ToString() + ", " _
                        + myReader.GetString(2))
      End While
      myReader.Close()
      myConn.Close()
      Console.ReadLine()
    End Sub
    
    

    The following example shows how to get a stored function to work. We will not use parameters autosynchronisation here.

    Consider you have a stored procedure that accepts a user name, adds some string to it, then adds server version and returns the outcome as function result. It may be described as follows:

    CREATE FUNCTION myfunc(uname CHAR(20))
      RETURNS CHAR(60)
      RETURN CONCAT(uname,' works with server ',@@version);
    

    To pass a parameter to the function and obtain a return value you can use the following sample code.

    static void CallProc()
    {
      //Establish connection
      MySqlConnection myConn = new MySqlConnection(
      "user id=root;database=demobase;host=localhost;password=root");
      myConn.Open();
      //Set up myCommand to reference stored procedure 'myfunc'
      MySqlCommand myCommand = new MySqlCommand("myfunc", myConn);
      myCommand.CommandType = System.Data.CommandType.StoredProcedure;
    
      //Create input parameter and assign a value
      MySqlParameter myInParam = new MySqlParameter();
      myInParam.Value = "Mark";
      myCommand.Parameters.Add(myInParam);
      myInParam.Direction = System.Data.ParameterDirection.Input;
    
      //Create placeholder for return value
      MySqlParameter myRetParam = new MySqlParameter();
      myRetParam.Direction = System.Data.ParameterDirection.ReturnValue;
      myCommand.Parameters.Add(myRetParam);
    
      //Execute the function. ReturnValue parameter receives result of the stored function
      myCommand.ExecuteNonQuery();
      Console.WriteLine(myRetParam.Value.ToString());
      myConn.Close();
    }
    
    
    Sub CallProc()
      'Establish connection
      Dim myConn As MySqlConnection = New MySqlConnection( _
      "user id=root;database=demobase;host=localhost;password=root")
      myConn.Open()
      'Set up myCommand to reference stored procedure 'myfunc'
      Dim myCommand As MySqlCommand = New MySqlCommand("myfunc", myConn)
      myCommand.CommandType = System.Data.CommandType.StoredProcedure
    
      'Create input parameter and assign a value
      Dim myInParam As MySqlParameter = New MySqlParameter()
      myInParam.Value = "Mark"
      myCommand.Parameters.Add(myInParam)
      myInParam.Direction = System.Data.ParameterDirection.Input
    
      'Create placeholder for return value
      Dim myRetParam As MySqlParameter = New MySqlParameter()
      myRetParam.Direction = System.Data.ParameterDirection.ReturnValue
      myCommand.Parameters.Add(myRetParam)
    
      'Execute the function. ReturnValue parameter receives result of the stored function
      myCommand.ExecuteNonQuery()
      Console.WriteLine(myRetParam.Value.ToString())
      myConn.Close()
    End Sub
    
    

    The last example demonstrates how to call a stored procedure in autosynchronization mode.

    Consider you have a stored procedure that adds a new employee to table Emp. It determines next suitable EmpNo, pastes current date, and checks for input parameters. If they contain a reasonable value, the procedure pastes this value as well; if a parameter contains NULL value, some defaults are used. Here is how source code for this procedure may look:

    CREATE PROCEDURE `AddEmp`(EmpName CHAR(20), Salary INT)
    BEGIN
    DECLARE e_No INT;
    DECLARE e_Name CHAR(20) DEFAULT 'Unnamed';
    DECLARE e_Sal INT DEFAULT 1100;
    IF EmpName IS NOT NULL THEN SET e_Name = EmpName; END IF;
    IF Salary  IS NOT NULL THEN SET  e_Sal = Salary;  END IF;
    SELECT Max(EmpNo) INTO e_No FROM emp;
    INSERT INTO emp (EmpNo, EName, Sal, HireDate)
           VALUES (e_No+10, e_Name, e_Sal, CurDate());
    END
    

    We will invoke this procedure and pass it single parameter - EmpName. Since ParameterCheck is true, the second parameter will be created in the moment of calling ExecuteNonQuery method. So this code will result in adding of new employee with name Roger and default salary (1100).

    Note that in autosynchronisation mode the only thing that matters is name of a parameter. You do not have to take care of creation order and there's no need to create parameters that are intended to have NULL value. Put another words, if we need to add an employee with default name but with specific salary, we can create single argument with ParameterName set to "Salary".

    static void CallProc()
    {
      //Establish connection
      MySqlConnection myConn = new MySqlConnection(
      "user id=root;database=demobase;host=localhost;password=root");
      myConn.Open();
      //Set up myCommand to reference stored procedure 'AddEmp'
      MySqlCommand myCommand = new MySqlCommand("AddEmp", myConn);
      myCommand.CommandType = CommandType.StoredProcedure;
      myCommand.ParameterCheck = true;
    
      //Create input parameter and assign a value
      MySqlParameter myInParam1 = new MySqlParameter();
      myInParam1.Value = "Roger";
      myInParam1.ParameterName = "EmpName";
      myCommand.Parameters.Add(myInParam1);
      myInParam1.Direction = System.Data.ParameterDirection.Input;
    
      //Execute the procedure.
      myCommand.ExecuteNonQuery();
      Console.WriteLine("Done");
      myConn.Close();
    }
    
    
    Sub CallProc()
      'Establish connection
      Dim myConn As MySqlConnection = New MySqlConnection( _
      "user id=root;database=demobase;host=localhost;password=root")
      myConn.Open()
      'Set up myCommand to reference stored procedure 'AddEmp'
      Dim myCommand As MySqlCommand = New MySqlCommand("AddEmp", myConn)
      myCommand.CommandType = System.Data.CommandType.StoredProcedure
      myCommand.ParameterCheck = True
    
      'Create input parameter and assign a value
      Dim myInParam As MySqlParameter = New MySqlParameter
      myInParam.ParameterName = "EmpName"
      myInParam.Value = "Roger"
      myCommand.Parameters.Add(myInParam)
      myInParam.Direction = System.Data.ParameterDirection.Input
    
      'Execute the procedure
      myCommand.ExecuteNonQuery()
      Console.WriteLine("Done.")
      myConn.Close()
    End Sub
    
    

    See Also

    MySqlParameter Class  | Devart.Data.MySql Namespace