phpmysqlsecurity

PDO vs. MySQLi: The Battle of PHP Database APIs

Table of Contents

Introduction

Long gone are the days of using the mysql_ extension, as its methods have been deprecated since PHP 5.5 and removed as of PHP 7. Alas, the internet is still plagued with a ton of old tutorials that beginners will simply copy/paste and use on a shared hosting platform with an older PHP version, thus continuing its legacy.

If you are using MySQL or MariaDB in PHP, then you have the ability to choose either MySQLi or PDO. The former is simply an improved version with procedural and OOP support and added prepared statements, while the latter is an abstraction layer that allows you to use a unified API for all 12 database drivers it supports. Though it should be mentioned that MySQL is undoubtedly the most popular database to use in the PHP world anyway.

In theory, one might assume the discussion should be over. We don't need a vendor-specific API for every type of database that exists, as it's so much simpler to use just one. While there's certainly a lot of truth to this, the problem is that PDO_MYSQL simply doesn't have all of the newest and most advanced features MySQLi does. I honestly don't understand why this is the case, as it would completely eliminate any reason to use the vendor-specific API. That said, I'd imagine that most people don't need these extra features, but there are definitely some who do.

For anyone who's interested, here's a full writeup of PDO and MySQLi.

PDO Advantages

MySQLi has quite a few aspects to play catchup with PDO. It needs to adds features like:

  1. Useful fetch modes
  2. Allow to pass variables and values directly into execute
  3. Ability to auto-detect variable types (What actually happens is that everything is treated as a string when sent to the sever, but is converted to the correct type. This works 100% of the time with native prepared statements but doesn't work with certain edge cases, such as LIKE with emulation mode.)
  4. Provides an option to have automatically buffered results with prepared statements
  5. Named parameters (though useless with emulation mode turned off in PDO, as you can only use the same name once)

As you can see, there are quite a few things MySQLi should learn from PDO if it wants to stay relevant.

If it does, then there should really be no difference at all. People always talk about how you'd have to learn a whole new extension, yet they're actually already nearly identical for the most part. For this article, I'll be using native prepared statements, but emulated ones are perfectly acceptable as well. Here's a short writeup on the differences between the two.

MySQLi Advantages

PDO is also missing some features, albeit far less important ones for most users, such as:

  1. Asynchronous queries
  2. Ability to get more info on affected rows, like updating a row with the same values (can be done in PDO as a constructor setting you can't change it later)
  3. Proper database closing method
  4. Multiple queries at once (though it can if emulation mode is turned on in PDO)
  5. Automatic cleanup with persistent connections

So Which Should I Use?

My opinion is that PDO should be used by default, especially beginners, due to its versatility, general predictability and useful fetch modes. However, MySQLi would be a better choice for advanced users who want the newest, MySQL-specific functionality.

It's somewhat ironic that more experienced PHP developers tend think PDO is the only acceptable option 100% of the time, while beginners tend to use MySQLi. This is absolutely nutty from both ends. Of course most developers don't really need the extra advanced features MySQLi offers, but it certainly could be extremely useful for some, as previously mentioned.

It's especially curious that novices are scared to try something "new" and switch to PDO, while a lot of advanced users recite the good ole "ease of switching from database driver" argument as PDO's advantage. Anyone who believes the myth that you can easily switch among databases in PDO seamlessly has obviously never attempted to do so. Each driver is different, and a switch from Microsoft SQL Server to MySQL will certainly not be automated. First of all let's make one thing clear, the syntax is very similar — almost identical, and I will present that in examples. PDO is also not some abstraction layer over MySQLi, but rather over PDO_MYSQL.

If PDO does end up keeping up with all of the latest or distinct MySQL functionality, then I could see why MySQLi should go away; I'd even encourage it, if it ends up being the case. Though PDO does have several driver-specific features, it doesn't have all nor keep up with the latest. This is precisely why I don't think MySQLi and PDO aren't necessarily competitors, but rather two powerful libraries with completely different focuses for now. Obviously PDO should be more widely used, however. But as said before, the difference is pretty much negligible as is anyway. As mentioned several times earlier, MySQLi's survival relies on it catching up to PDO, along with PDO primarily sticking with features that are used among most of the DB drivers it supports.

Code Differences

As stated earlier, both PDO and MySQLi are extremely similar, but there's slight differences in syntax. MySQLi follows the old-school PHP snake_case convention, while PDO uses camelCase. Additionally, MySQLi's methods are used as object properties, while PDO uses the traditional syntax for functions.

I'll never understand why both PDO and MySQLi complicated things by forcing you to use two separate methods to use prepared statement. Luckily PDO removed the need to use a dedicated bind function — though I'm not sure why the same isn't done for execute(). Non-prepared MySQLi and PDO really aren't so bad, and it's only really the unfortunate implementation of prepared statements that caused them to seem verbose. For instance, in the vendor-specific PostgreSQL API you can do it like this. Here's an example of how you'd do a "non-prepared" query to fetch an associative array with MySQLi and PDO, for reference.

$arr = $mysqli->query("SELECT * FROM myTable")->fetch_all(MYSQLI_ASSOC);
$arr = $pdo->query("SELECT * FROM myTable")->fetchAll(PDO::FETCH_ASSOC);

In reality, the best route is to use a wrapper, query builder or ORM. I have a fairly rudimentary MySQLi wrapper you might like. While PDO is a step in the right direction, as you can bind values directly into execute, it's still not ideal. In the class I made, you can chain all of your calls, while passing in the values to bind as a parameter argument. Check out what you can do.

$arr = $mysqli->query("SELECT * FROM myTable WHERE id > ?", [12])->fetchAll('assoc');

You now have an entire associative array stored in the variable in a far more concise manner. It's strange why both PDO and MySQLi don't do it like this.

For the rest of the tutorial, we'll be using prepared statements, as there isn't a good reason not to use them for SQL injection protection, unless you're using a feature like async, which currently doesn't support them. Otherwise, you'll need to properly manually format your queries.

Creating a New Database Connection

PDO

$dsn = "mysql:host=localhost;dbname=myDatabase;charset=utf8mb4";
$options = [
  PDO::ATTR_EMULATE_PREPARES   => false, // turn off emulation mode for "real" prepared statements
  PDO::ATTR_ERRMODE            => PDO::ERRMODE_EXCEPTION, //turn on errors in the form of exceptions
  PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC, //make the default fetch be an associative array
];
try {
  $pdo = new PDO($dsn, "username", "password", $options);
} catch (Exception $e) {
  error_log($e->getMessage());
  exit('Something weird happened'); //something a user can understand
}

MySQLi

mysqli_report(MYSQLI_REPORT_ERROR | MYSQLI_REPORT_STRICT);
try {
  $mysqli = new mysqli("localhost", "username", "password", "databaseName");
  $mysqli->set_charset("utf8mb4");
} catch(Exception $e) {
  error_log($e->getMessage());
  exit('Error connecting to database'); //Should be a message a typical user could understand
}

Insert, Update, Delete

PDO

$stmt = $pdo->prepare("INSERT INTO myTable (name, age) VALUES (?, ?)");
$stmt->execute([$_POST['name'], 29]);
$stmt = null;

MySQLi

$stmt = $mysqli->prepare("UPDATE myTable SET name = ? WHERE id = ?");
$stmt->bind_param("si", $_POST['name'], $_SESSION['id']);
$stmt->execute();
$stmt->close();

It should be noted that with PDO, you can chain prepare() and execute(), though you won't be to get the affected rows, so I can't see that being useful.

Get Number of Affected Rows

PDO

$stmt->rowCount();

MySQLi

$stmt->affected_rows;

Get Latest Primary Key Inserted

Notice, how both of these use the connection variable, instead of $stmt.

PDO

$pdo->lastInsertId();

MySQLi

$mysqli->insert_id;

Get Rows Matched

PDO

In PDO, the only way to achieve this is by setting it as a connection option to change the behavior of rowCount(), unfortunately. This means rowCount() will either return rows matched or rows changed for your entire database connection, but not both.

$options = [
  PDO::MYSQL_ATTR_FOUND_ROWS => true
];

MySQLi

$mysqli->info;

This will output an entire string of information, like so:

Rows matched: 1 Changed: 0 Warnings: 0

I have no idea why they thought this would be a wise implementation, as it would be far more convenient in an array. Luckily, you can do this.

preg_match_all('/(\S[^:]+): (\d+)/', $mysqli->info, $matches); 
$infoArr = array_combine ($matches[1], $matches[2]);
var_export($infoArr);

Now you can access the values pretty easily. Note, that the value is a string, so you either cast all the values to ints, so === can work or strictly check with ==.

['Rows matched' => '1', 'Changed' => '0', 'Warnings' => '0']

Fetching

Fetch Associative Array

PDO

$stmt = $pdo->prepare("SELECT * FROM myTable WHERE id <= ?");
$stmt->execute([5]);
$arr = $stmt->fetchAll(PDO::FETCH_ASSOC);
if(!$arr) exit('No rows');
var_export($arr);
$stmt = null;

MySQLi

$stmt = $mysqli->prepare("SELECT id, name, age FROM myTable WHERE name = ?");
$stmt->bind_param("s", $_POST['name']);
$stmt->execute();
$arr = $stmt->get_result()->fetch_all(MYSQLI_ASSOC);
if(!$arr) exit('No rows');
var_export($arr);
$stmt->close();

Fetch Single Row

PDO

$stmt = $pdo->prepare("SELECT id, name, age FROM myTable WHERE name = ?");
$stmt->execute([$_POST['name']]);
$arr = $stmt->fetch(PDO::FETCH_ASSOC);
if(!$arr) exit('No rows');
var_export($arr);
$stmt = null;

MySQLi

$stmt = $mysqli->prepare("SELECT id, name, age FROM myTable WHERE name = ?");
$stmt->bind_param("s", $_POST['name']);
$stmt->execute();
$arr = $stmt->get_result()->fetch_assoc();
if(!$arr) exit('No rows');
var_export($arr);
$stmt->close();

Fetch Single Value (Scalar)

PDO

$stmt = $pdo->prepare("SELECT id, name, age FROM myTable WHERE name = ?");
$stmt->execute([$_POST['name']]);
$arr = $stmt->fetch(PDO::FETCH_COLUMN);
if(!$arr) exit('No rows');
var_export($arr);
$stmt = null;

MySQLi

$stmt = $mysqli->prepare("SELECT id, name, age FROM myTable WHERE name = ?");
$stmt->bind_param("s", $_POST['name']);
$stmt->execute();
$arr = $stmt->get_result()->fetch_row()[0];
if(!$arr) exit('No rows');
var_export($arr);
$stmt->close();

Fetch Array of Objects

PDO

class myClass {}
$stmt = $pdo->prepare("SELECT name, age, weight FROM myTable WHERE name = ?");
$stmt->execute(['Joe']);
$arr = $stmt->fetchAll(PDO::FETCH_CLASS, 'myClass');
if(!$arr) exit('No rows');
var_export($arr);
$stmt = null;

MySQLi

class myClass {}
$arr = [];
$stmt = $mysqli->prepare("SELECT id, name, age FROM myTable WHERE id = ?");
$stmt->bind_param("s", $_SESSION['id']);
$stmt->execute();
$result = $stmt->get_result();
while($row = $result->fetch_object('myClass')) {
  $arr[] = $row;
}
if(!$arr) exit('No rows');
var_export($arr);
$stmt->close();

PDO really shines here as you can see. It's very odd why MySQLi doesn't have something like $mysqli_result->fetch_all(MYSQLI_OBJ). PDO even takes it a step further and has an awesome way to deal with the annoying default behavior of it getting called after the class constructor, via bitwising it with fetchAll(PDO::FETCH_CLASS | PDO::FETCH_PROPS_LATE, 'myClass'). It's possible to replicate this behavior in MySQLi, but it relies on either leaving out the constructor and relying on the magic __set() or by only setting it in the constructor if it doesn't equal the default value.

Like

PDO

$search = "%{$_POST['search']}%";
$stmt = $pdo->prepare("SELECT id, name, age FROM myTable WHERE name LIKE ?");
$stmt->execute([$search]);
$arr = $stmt->fetchAll();
if(!$arr) exit('No rows');
var_export($arr);
$stmt = null;

MySQLi

$search = "%{$_POST['search']}%";
$stmt = $mysqli->prepare("SELECT id, name, age FROM myTable WHERE name LIKE ?"); 
$stmt->bind_param("s", $search);
$stmt->execute();
$arr = $stmt->get_result()->fetch_all(MYSQLI_ASSOC);
if(!$arr) exit('No rows');
var_export($arr);
$stmt->close();

Fetch Modes

This is by far my favorite feature about PDO. The fetch modes in PDO are extremely useful and it's quite shocking that MySQLi hasn't added them yet.

Fetch Key/Value Pair

PDO

$stmt = $pdo->prepare("SELECT event_name, location FROM events WHERE id < ?");
$stmt->execute([25]);
$arr = $stmt->fetchAll(PDO::FETCH_KEY_PAIR);
if(!$arr) exit('No rows');
var_export($arr);
$stmt = null;

MySQLi

$arr = [];
$id = 25;
$stmt = $con->prepare("SELECT event_name, location FROM events WHERE id < ?");
$stmt->bind_param("i", $id);
$stmt->execute();
$result = $stmt->get_result();
while($row = $result->fetch_row()) {
  $arr[$row[0]] = $row[1];
}
if(!$arr) exit('No rows');
var_export($arr);
$stmt->close();

Output:

['Cool Event' => 'Seattle', 'Fun Event' => 'Dallas', 'Boring Event' => 'Chicago']

Fetch Group Column

PDO

$stmt = $pdo->prepare("SELECT hair_color, name FROM myTable WHERE id < ?");
$stmt->execute([10]);
$arr = $stmt->fetchAll(PDO::FETCH_GROUP | PDO::FETCH_COLUMN);
if(!$arr) exit('No rows');
var_export($arr);
$stmt = null;

MySQLi

$arr = [];
$id = 10;
$stmt = $con->prepare("SELECT hair_color, name FROM myTable WHERE id < ?");
$stmt->bind_param("i", $id);
$stmt->execute();
$result = $stmt->get_result();
while($row = $result->fetch_row()) {
  $arr[$row[0]][] = $row[1];
}
if(!$arr) exit('No rows');
var_export($arr);
$stmt->close();

Output:

[
  'blonde' => ['Patrick', 'Olivia'],
  'brunette' => ['Kyle', 'Ricky'],
  'red' => ['Jordan', 'Eric']
]

Fetch Key/Value Pair Array

PDO

$stmt = $pdo->prepare("SELECT id, max_bench, max_squat FROM myTable WHERE weight < ?");
$stmt->execute([200]);
$arr = $stmt->fetchAll(PDO::FETCH_UNIQUE);
if(!$arr) exit('No rows');
var_export($arr);
$stmt = null;

MySQLi

$arr = [];
$weight = 200;
$stmt = $con->prepare("SELECT id, max_bench, max_squat FROM myTable WHERE weight < ?");
$stmt->bind_param("i", $weight);
$stmt->execute();
$result = $stmt->get_result();
$firstColName = $result->fetch_field_direct(0)->name;
while($row = $stmtResult->fetch_assoc()) {
  $firstColVal = $row[$firstColName];
  unset($row[$firstColName]);
  $arr[$firstColVal] = $row;
}
if(!$arr) exit('No rows');
var_export($arr);
$stmt->close();

Output:

[
  17 => ['max_bench' => 230, 'max_squat' => 175],
  84 => ['max_bench' => 195, 'max_squat' => 235],
  136 => ['max_bench' => 135, 'max_squat' => 285]
]

Fetch Group

PDO

$stmt = $pdo->prepare("SELECT hair_color, name, age FROM myTable WHERE id < ?");
$stmt->execute([12]);
$arr = $stmt->fetchAll(PDO::FETCH_GROUP);
if(!$arr) exit('No rows');
var_export($arr);
$stmt = null;

MySQLi

$arr = [];
$id = 12;
$stmt = $con->prepare("SELECT hair_color, name, age FROM myTable WHERE id < ?");
$stmt->bind_param("i", $id);
$stmt->execute();
$result = $stmt->get_result();
$firstColName = $result->fetch_field_direct(0)->name;
while($row = $stmtResult->fetch_assoc()) {
  $firstColVal = $row[$firstColName];
  unset($row[$firstColName]);
  $arr[$firstColVal][] = $row;
}
if(!$arr) exit('No rows');
var_export($arr);
$stmt->close();

Output:

[
  'blonde' => [
    ['name' => 'Patrick', 'age' => 22],
    ['name' => 'Olivia', 'age' => 18]
  ],
  'brunette'  => [
    ['name' => 'Kyle', 'age'=> 25],
    ['name' => 'Ricky', 'age' => 34]
  ],
   'red'  => [
    ['name' => 'Jordan', 'age' => 17],
    ['name' => 'Eric', 'age' => 52]
  ]
]

Where In Array

PDO

$inArr = [1, 3, 5];
$clause = implode(',', array_fill(0, count($inArr), '?')); //create 3 question marks
$stmt = $pdo->prepare("SELECT * FROM myTable WHERE id IN ($clause)");
$stmt->execute($inArr);
$resArr = $stmt->fetchAll();
if(!$resArr) exit('No rows');
var_export($resArr);
$stmt = null;

MySQLi

$inArr = [12, 23, 44];
$clause = implode(',', array_fill(0, count($inArr), '?')); //create 3 question marks
$types = str_repeat('i', count($inArr)); //create 3 ints for bind_param
$stmt = $mysqli->prepare("SELECT id, name FROM myTable WHERE id IN ($clause)");
$stmt->bind_param($types, ...$inArr);
$stmt->execute();
$resArr = $stmt->get_result()->fetch_all(MYSQLI_ASSOC);
if(!$resArr) exit('No rows');
var_export($resArr);
$stmt->close();

Where In Array With Other Placeholders

PDO

$inArr = [1, 3, 5];
$clause = implode(',', array_fill(0, count($inArr), '?')); //create 3 question marks
$stmt = $pdo->prepare("SELECT * FROM myTable WHERE id IN ($clause) AND id < ?");
$fullArr = array_merge($inArr, [5]); //merge WHERE IN array with other value(s)
$stmt->execute($fullArr);
$resArr = $stmt->fetchAll();
if(!$resArr) exit('No rows');
var_export($resArr);
$stmt = null;

MySQLi

$inArr = [12, 23, 44];
$clause = implode(',', array_fill(0, count($inArr), '?')); //create 3 question marks
$types = str_repeat('i', count($inArr)); //create 3 ints for bind_param
$types .= 'i'; //add 1 more int type
$fullArr = array_merge($inArr, [26]); //merge WHERE IN array with other value(s)
$stmt = $mysqli->prepare("SELECT id, name FROM myTable WHERE id IN ($clause) AND age > ?");
$stmt->bind_param($types, ...$fullArr); //4 placeholders to bind
$stmt->execute();
$resArr = $stmt->get_result()->fetch_all(MYSQLI_ASSOC);
if(!$resArr) exit('No rows');
var_export($resArr);
$stmt->close();

Transactions

PDO

try {
  $pdo->beginTransaction();
  $stmt1 = $pdo->prepare("INSERT INTO myTable (name, state) VALUES (?, ?)");
  $stmt2 = $pdo->prepare("UPDATE myTable SET age = ? WHERE id = ?");
  if(!$stmt1->execute(['Rick', 'NY'])) throw new Exception('Stmt 1 Failed');
  else if(!$stmt2->execute([27, 139])) throw new Exception('Stmt 2 Failed');
  $stmt1 = null;
  $stmt2 = null;
  $pdo->commit();
} catch(Exception $e) {
  $pdo->rollback();
  throw $e;
}

You might be wondering why I'm solely checking for truthiness on execute() with PDO. This is due to the fact that it can return false, while silently failing. Here's a more detailed explanation.

MySQLi

try {
  $mysqli->autocommit(FALSE); //turn on transactions
  $stmt1 = $mysqli->prepare("INSERT INTO myTable (name, age) VALUES (?, ?)");
  $stmt2 = $mysqli->prepare("UPDATE myTable SET name = ? WHERE id = ?");
  $stmt1->bind_param("si", $_POST['name'], $_POST['age']);
  $stmt2->bind_param("si", $_POST['name'], $_SESSION['id']);
  $stmt1->execute();
  $stmt2->execute();
  $stmt1->close();
  $stmt2->close();
  $mysqli->autocommit(TRUE); //turn off transactions + commit queued queries
} catch(Exception $e) {
  $mysqli->rollback(); //remove all queries from queue if error (undo)
  throw $e;
}

MySQLi also has a gotcha, but the solution is to convert errors to exception with a global handler. Read about it more here.

Named Paramters

This is a PDO-only feature, but it's only useful if emulation mode is turned off. Otherwise, you can only use the same variable once. It should also be noted that the leading colon is not required, but this isn't documented anywhere. It likely will eventually anyway, but you never know, I suppose. You also can't mix ? placeholders with named ones; it's either one or the other.

$stmt = $pdo->prepare("UPDATE myTable SET name = :name WHERE id = :id");
$stmt->execute([':name' => 'David', ':id' => 3]);
$stmt = null;