PHP 8.4.1 Released!

Requêtes multiples

MySQL autorise optionnellement le fait d'avoir plusieurs requêtes dans une seule chaîne de requête mais nécessite une gestion spéciale.

Les requêtes multiples ou multirequêtes doivent être exécutées avec la fonction mysqli::multi_query(). Les requêtes individuelles dans la chaîne de requête sont séparées par un point virgule. Ensuite, tous les jeux de résultats retournés par l'exécution des requêtes doivent être récupérés.

Le serveur MySQL autorise d'avoir des requêtes qui retournent des jeux de résultats ainsi que des requêtes qui ne retournent aucun jeu de résultats dans la même requête multiple.

Exemple #1 Requêtes multiples

<?php

mysqli_report
(MYSQLI_REPORT_ERROR | MYSQLI_REPORT_STRICT);
$mysqli = new mysqli("example.com", "user", "password", "database");

$mysqli->query("DROP TABLE IF EXISTS test");
$mysqli->query("CREATE TABLE test(id INT)");

$sql = "SELECT COUNT(*) AS _num FROM test;
INSERT INTO test(id) VALUES (1);
SELECT COUNT(*) AS _num FROM test; "
;

$mysqli->multi_query($sql);

do {
if (
$result = $mysqli->store_result()) {
var_dump($result->fetch_all(MYSQLI_ASSOC));
$result->free();
}
} while (
$mysqli->next_result());

L'exemple ci-dessus va afficher :

array(1) {
  [0]=>
  array(1) {
    ["_num"]=>
    string(1) "0"
  }
}
array(1) {
  [0]=>
  array(1) {
    ["_num"]=>
    string(1) "1"
  }
}

D'un point de vue de la sécurité

Les fonctions mysqli::query() et mysqli::real_query() de l'API ne définissent pas de drapeau de connexion nécessaire pour l'activation des multirequêtes sur le serveur. Un appel supplémentaire à l'API est utilisé pour les multirequêtes pour réduire la probabilité d'injection SQL accidentelle. Un attaquant peut tenter d'ajouter des requêtes comme ; DROP DATABASE mysql ou ; SELECT SLEEP(999). Si l'attaquant arrive à ajouter ce genre de SQL dans la chaîne de requête mais que mysqli::multi_query() n'est pas utilisé, le serveur n'excutera que la première requête, mais pas la seconde représentant la requête SQL malicieuse.

Exemple #2 Injection SQL

<?php

mysqli_report
(MYSQLI_REPORT_ERROR | MYSQLI_REPORT_STRICT);
$mysqli = new mysqli("example.com", "user", "password", "database");
$result = $mysqli->query("SELECT 1; DROP TABLE mysql.user");

L'exemple ci-dessus va afficher :

PHP Fatal error:  Uncaught mysqli_sql_exception: You have an error in your SQL syntax; 
check the manual that corresponds to your MySQL server version for the right syntax to 
use near 'DROP TABLE mysql.user' at line 1

Prepared statements

L'utilisation des requêtes multiples avec des requêtes préparées n'est pas supportée.

Voir aussi

add a note

User Contributed Notes 1 note

up
10
velthuijsen
6 years ago
Suggested improvement(s) to example 1.

reasons:
Multi_query only returns a non false response if a data/result set is returned and only checks for the first query entered. Switching the first SELECT query with the INSERT query will result in a premature exit of the example with the message "Multi query failed: (0)".
The example assumes that once the first query doesn't fail that the other queries have succeeded as well. Or rather it just exits without reporting that one of the queries after the first query failed seeing that if a query fails next_result returns false.

The changes in the example comes after the creation of the string $sql.

<?php
$mysqli
= new mysqli("example.com", "user", "password", "database");
if (
$mysqli->connect_errno) {
echo
"Failed to connect to MySQL: (" . $mysqli->connect_errno . ") " . $mysqli->connect_error;
}

if (!
$mysqli->query("DROP TABLE IF EXISTS test") || !$mysqli->query("CREATE TABLE test(id INT)")) {
echo
"Table creation failed: (" . $mysqli->errno . ") " . $mysqli->error;
}

$sql = "SELECT COUNT(*) AS _num FROM test; ";
$sql.= "INSERT INTO test(id) VALUES (1); ";
$sql.= "SELECT COUNT(*) AS _num FROM test; ";

// changes to example 1 start here

// don't bother checking the result from multi_query since it will return false
// if the first query does not return data even if the query itself succeeds.
$mysqli->multi_query($sql);

do
// while (true); // exit only on error or when there are no more queries to process
{
// check if query currently being processed hasn't failed
if (0 !== $mysqli->errno)
{
echo
"Multi query failed: (" . $mysqli->errno . ") " . $mysqli->error;
break;
}

// store and possibly process result of the query,
// both store_result & use_result will return false
// for queries that do not return results (INSERT for example)
if(false !== ($res = $mysqli->store_result() )
{
var_dump($res->fetch_all(MYSQLI_ASSOC));
$res->free();
}

// exit loop if there ar no more queries to process
if (false === ($mysqli->more_results() )
{
break;
}

// get result of the next query to process
// don't bother to check for success/failure of the result
// since at the start of the loop there is an error check &
// report block.
$mysqli->next_result()

} while (
true); // exit only on error or when there are no more queries to process
?>

Note that the normal while ($mysqli->more_results() && $mysqli->next_result() has been replaced by two checks and while (true);
This is due to the 'problem' that next_result will return false if the query in question failed.
So one either needs to do one last check after the while loop to check if there was an error or one has to split up the different actions.
The changes in the example do the splitting.
To Top