SunshinePHP Developer Conference 2015

mysqli_stmt::prepare

mysqli_stmt_prepare

(PHP 5)

mysqli_stmt::prepare -- mysqli_stmt_preparePrépare une requête SQL pour l'exécution

Description

Style orienté objet

mixed mysqli_stmt::prepare ( string $query )

Style procédural

bool mysqli_stmt_prepare ( mysqli_stmt $stmt , string $query )

Prépare la requête SQL query, pour la session de travail stmt.

Les variables SQL doivent être associées à une variable PHP à l'aide de la fonction mysqli_stmt_bind_param() et/ou mysqli_stmt_bind_result(), avant d'exécuter la requête.

Note:

Si vous passez une requête à mysqli_stmt_prepare() qui est plus longue que max_allowed_packet, les codes d'erreur en retour seront différents selon si vous utilisez MySQL Native Driver (mysqlnd) ou la MySQL Client Library (libmysqlclient). Le comportement est défini comme suit:

  • mysqlnd sur Linux retourne un code d'erreur de 1153. Le message d'erreur sera "got a packet bigger than max_allowed_packet bytes".

  • mysqlnd sur Windows retourne un code d'erreur de 2006. Le message sera du type "server has gone away".

  • libmysqlclient sur toute plateforme retourne le code d'erreur 2006. Le message sera du type "server has gone away".

Liste de paramètres

stmt

Style procédural uniquement : Un identifiant de requête retourné par la fonction mysqli_stmt_init().

query

La requête, sous forme de chaîne. Elle doit être constituée d'une commande SQL valide et unique.

Ce paramètre peut inclure une ou plusieurs variables SQL, en utilisant des points d'interrogation (?) aux bons endroits.

Note:

Il ne faut pas ajouter de point-virgule ou de \g à la fin de la requête.

Note:

Les variables SQL ne sont possibles que dans certaines clauses de la requête SQL. Par exemple, elles peuvent être placées dans des clause VALUES() d'une requête INSERT (pour spécifier une valeur à insérer), ou dans une clause de condition WHERE.

Cependant, elles ne sont pas autorisées pour les identifiants (de tables ou de colonnes), dans les listes de colonnes d'un SELECT, ou pour spécifier des opérateurs comme =. Cette dernière restriction est liée au fait qu'il est impossible de déterminer le type. En général, les variables SQL ne sont valides que dans les commandes de manipulation de données ("Data Manipulation Language" (DML)), et non dans les structures du langages SQL ("Data Definition Language" (DDL)).

Valeurs de retour

Cette fonction retourne TRUE en cas de succès ou FALSE si une erreur survient.

Exemples

Exemple #1 Style orienté objet

<?php
$mysqli 
= new mysqli("localhost""my_user""my_password""world");

/* Vérifie la connexion */
if (mysqli_connect_errno()) {
    
printf("Échec de la connexion : %s\n"mysqli_connect_error());
    exit();
}

$city "Amersfoort";

/* Création d'une requête préparée */
$stmt =  $mysqli->stmt_init();
if (
$stmt->prepare("SELECT District FROM City WHERE Name=?")) {

    
/* Association des variables SQL */
    
$stmt->bind_param("s"$city);

    
/* Exécution de la requête */
    
$stmt->execute();

    
/* Association des variables de résultats */
    
$stmt->bind_result($district);

    
/* Lecture des valeurs */
    
$stmt->fetch();

    
printf("%s est dans la région de %s\n"$city$district);

    
/* Fermeture de la commande */
    
$stmt->close();
}

/* Fermeture de la connexion */
$mysqli->close();
?>

Exemple #2 Style procédural

<?php
$link 
mysqli_connect("localhost""my_user""my_password""world");

/* Vérifie la connexion */
if (mysqli_connect_errno()) {
    
printf("Échec de la connexion : %s\n"mysqli_connect_error());
    exit();
}

$city "Amersfoort";

/* Création d'une requête préparée */
$stmt mysqli_stmt_init($link);
if (
mysqli_stmt_prepare($stmt'SELECT District FROM City WHERE Name=?')) {

    
/* Association des variables SQL */
    
mysqli_stmt_bind_param($stmt"s"$city);

    
/* Exécution de la requête */
    
mysqli_stmt_execute($stmt);

    
/* Association des variables de résultats */
    
mysqli_stmt_bind_result($stmt$district);

    
/* Lecture des valeurs */
    
mysqli_stmt_fetch($stmt);

    
printf("%s est dans la région de %s\n"$city$district);

    
/* Fermeture de la commande */
    
mysqli_stmt_close($stmt);
}

/* Fermeture de la connexion */
mysqli_close($link);
?>

Les exemples ci-dessus vont afficher :

Amersfoort est dans la région de Utrecht

Voir aussi

add a note add a note

User Contributed Notes 9 notes

up
4
logos-php at kith dot org
2 years ago
Note that if you're using a question mark as a placeholder for a string value, you don't surround it with quotation marks in the MySQL query.

For example, do this:

mysqli_stmt_prepare($stmt, "SELECT * FROM foo WHERE foo.Date > ?");

Do not do this:

mysqli_stmt_prepare($stmt, "SELECT * FROM foo WHERE foo.Date > '?'");

If you put quotation marks around a question mark in the query, then PHP doesn't recognize the question mark as a placeholder, and then when you try to use mysqli_stmt_bind_param(), it gives an error to the effect that you have the wrong number of parameters.

The lack of quotation marks around a string placeholder is implicit in the official example on this page, but it's not explicitly stated in the docs, and I had trouble figuring it out, so figured it was worth posting.
up
1
kontakt at arthur minus schiwon dot de
6 years ago
If you wrap the placeholders with quotation marks you will experience warnings like "Number of variables doesn't match number of parameters in prepared statement" (at least with INSERT Statements).
up
0
logos-php at kith dot orgpp
2 years ago
Turns out you can't directly use a prepared statement for a query that has a placeholder in an IN() clause.

There are ways around that (such as constructing a string that consists of n question marks separated by commas, then using that set of placeholders in the IN() clause), but you can't just say IN (?).

This is a MySQL restriction rather than a PHP restriction, but it's not really documented in the MySQL docs either, so I figured it was worth mentioning here.

(Btw, turns out someone else had previously posted the info that I put in my previous comment, about not using quotation marks. Sorry for the repeat; not sure how I missed the earlier comment.)
up
0
ndungi at gmail dot com
5 years ago
The `prepare` , `bind_param`, `bind_result`, `fetch` result, `close` stmt cycle can be tedious at times. Here is an object that does all the mysqli mumbo jumbo for you when all you want is a select leaving you to the bare essential `preparedSelect` on a prepared stmt. The method returns the result set as a 2D associative array with the `select`ed columns as keys. I havent done sufficient error-checking and it also may have some bugs. Help debug and improve on it.

I used the bible.sql db from http://www.biblesql.net/sites/biblesql.net/files/bible.mysql.gz.

Baraka tele!

============================

<?php

class DB
{
    public
$connection;
   
   
#establish db connection
   
public function __construct($host="localhost", $user="user", $pass="", $db="bible")
    {
       
$this->connection = new mysqli($host, $user, $pass, $db);
                 
        if(
mysqli_connect_errno())
        {
            echo(
"Database connect Error : "
           
. mysqli_connect_error($mysqli));
        }   
    }
   
   
#store mysqli object
   
public function connect()
    {
        return
$this->connection;
    }

   
#run a prepared query
   
public function runPreparedQuery($query, $params_r)
    {
       
$stmt = $this->connection->prepare($query);
       
$this->bindParameters($stmt, $params_r);

        if (
$stmt->execute()) {
            return
$stmt;
        } else {
            echo(
"Error in $statement: "
                     
. mysqli_error($this->connection));
            return
0;
        }
       
    }

# To run a select statement with bound parameters and bound results.
# Returns an associative array two dimensional array which u can easily 
# manipulate with array functions.

   
public function preparedSelect($query, $bind_params_r)
    {
       
$select = $this->runPreparedQuery($query, $bind_params_r);
       
$fields_r = $this->fetchFields($select);
       
        foreach (
$fields_r as $field) {
           
$bind_result_r[] = &${$field};
        }
       
       
$this->bindResult($select, $bind_result_r);
       
       
$result_r = array();
       
$i = 0;
        while (
$select->fetch()) {
            foreach (
$fields_r as $field) {
               
$result_r[$i][$field] = $$field;
            }
           
$i++;
        }
       
$select->close();
        return
$result_r;   
    }
   
   
   
#takes in array of bind parameters and binds them to result of
    #executed prepared stmt
   
   
private function bindParameters(&$obj, &$bind_params_r)
    {
       
call_user_func_array(array($obj, "bind_param"), $bind_params_r);
    }
   
    private function
bindResult(&$obj, &$bind_result_r)
    {
       
call_user_func_array(array($obj, "bind_result"), $bind_result_r);
    }
   
   
#returns a list of the selected field names
   
   
private function fetchFields($selectStmt)
    {
       
$metadata = $selectStmt->result_metadata();
       
$fields_r = array();
        while (
$field = $metadata->fetch_field()) {
           
$fields_r[] = $field->name;
        }

        return
$fields_r;
    }
}
#end of class

#An example of the DB class in use

$DB = new DB("localhost", "root", "", "bible");
$var = 5;
$query = "SELECT abbr, name from books where id > ?" ;
$bound_params_r = array("i", $var);

$result_r = $DB->preparedSelect($query, $bound_params_r);

#loop thru result array and display result

foreach ($result_r as $result) {
    echo
$result['abbr'] . " : " . $result['name'] . "<br/>" ;
}

?>
up
0
mhradek AT gmail.com
6 years ago
A particularly helpful adaptation of this function and the call_user_func_array function:

// $params is sent as array($val=>'i', $val=>'d', etc...)

function db_stmt_bind_params($stmt, $params)
{
    $funcArg[] = $stmt;
    foreach($params as $val=>$type)
    {
        $funcArg['type'] .= $type;
        $funcArg[] = $val;
    }
    return call_user_func_array('mysqli_stmt_bind_param', $funcArgs);
}

Thanks to 'sned' for the code.
up
0
lukaszNOSPAMPLEASE at epas dot pl
6 years ago
i've got some bad news for you guys if you haven't found out already.
the trick with mysqli_next_result() only prevents having the connection dropped after a stored procedure call.
apparently you can bind parameters for a prepared stored procedure call, but you'll get messed up records from mysqli_stmt_fetch() after mysqli_stmt_bind_result(), at least when the stored procedure itself contains a prepared statement.
a way to avoid data corruption could be specifying the CLIENT_MULTI_STATEMENTS flag in mysqli_real_connect(), if it wasn't disabled entirely (for security reasons, as they say). another option is to use mysqli_multi_query(), but then you can't bind at all.
up
0
st dot john dot johnson at gmail dot com
7 years ago
In reference to what lachlan76 said before, stored procedures CAN be executed through prepared statements as long as you tell the DB to move to the next result before executing again.

Example (Five calls to a stored procedure):

<?php
for ($i=0;$i<5;$i++) {
 
$statement = $mysqli->stmt_init();
 
$statement->prepare("CALL some_procedure( ? )");

 
// Bind, execute, and bind.
 
$statement->bind_param("i", 1);
 
$statement->execute();
 
$statement->bind_result($results);

  while(
$statement->fetch()) {
   
// Do what you want with your results.
 
}

 
$statement->close();

 
// Now move the mysqli connection to a new result.
 
while($mysqli->next_result()) { }
}
?>

If you include the last statement, this code should execute without the nasty "Commands out of sync" error.
up
0
lachlan76 at gmail dot com
7 years ago
Do not try to use a stored procedure through a prepared statement.

Example:

<?php
$statement
= $mysqli->stmt_init();
$statement->prepare("CALL some_procedure()");
?>

If you attempt to do this, it will fail by dropping the connection during the next query.  Use mysqli_multi_query instead.

Example:

<?php
$mysqli
->multi_query("CALL some_procedure()");
do
{
 
$result = $mysqli->store_result();

  
// Do your processing work here 
 
 
$result->free();
} while(
$mysqli->next_result());
?>

This means that you cannot bind parameters or results, however.
up
0
andrey at php dot net
9 years ago
If you select LOBs use the following order of execution or you risk mysqli allocating more memory that actually used

1)prepare()
2)execute()
3)store_result()
4)bind_result()

If you skip 3) or exchange 3) and 4) then mysqli will allocate memory for the maximal length of the column which is 255 for tinyblob, 64k for blob(still ok), 16MByte for MEDIUMBLOB - quite a lot and 4G for LONGBLOB (good if you have so much memory). Queries which use this order a bit slower when there is a LOB but this is the price of not having memory exhaustion in seconds.
To Top