|
Here is some typical code which validates a user, by looking up their name/password in a table we have previously created:
$user = $_POST['username']; $passwd = $_POST['password']; $qry = "SELECT * FROM MyPasswords WHERE name='$user' and pass='$passwd'"; // DANGER! SQL injection possible. $result = mysqli_query($connect,$qry); // A table object (possibly w/ 0 rows); NULL on query-failure. if (mysqli_fetch_assoc($result)) { // Safer: `if (mysqli_num_rows($result) == 1) ...` // login successful -- we found that name/password in our db! } |
$qry = "SELECT * FROM MyPasswords WHERE name='fred' and pass='xyz123'"; |
BUT:
What if the user had typed in a single-quote in their input?
Suppose they typed Shaquille O'Neal — why will the query fail?
$qry = "SELECT * FROM MyPasswords WHERE name='Shaquille O'Neal' and pass='sugarshaq'"; |
WORSE:
Can the user type in something so that the SELECT statment
always returns a result?
Alas, yes!
Something like:
' or 'hi'='hi leads to a query that always turns true.
$qry = "SELECT * FROM MyPasswords WHERE name='fred' and pass='' or 'hi' = 'hi'";1 |
Solution: Sanitize
Always call
Note: Not only is the name “mysqli_real_escape_string ” an awful name, it is surprising in another way: you must provide it two inputs (the database-connection as well as the string to sanitize). If you don't do this, it will print an easy-to-overlook warning (regardless of yourerror_reporting status!?!), and returnNULL (which gets interpreted as the empty-string).
Now you may feel that if you've already done other validation
on the data and know it doesn’t contain any single-quotes or other
characters SQL might mis-interpret,
then you're safe.
That’s true.
However, you should still call
(Another reason to call
There are even multiple cartoons reminding you to sanitize your SQL queries.
Why use prepared statements (in order of importance):
What they are:
SQL statements where you replace specific values with a question-mark
(“
Example:
Note: Don’t confuse “prepared statement” with “stored procedure” — the latter is just a PL/SQL function. (They are similar though — both set up what is in essence a function-call, so you can just call it with actual-parameters later. However, a prepared-statement only lives while you keep a reference to it while the stored-procedure is something the database remembers forever.)
Example: See the second half of mysqli-example.php.
In php, prepared statements are a bit convoluted. You have to:
$stmt = mysqli_stmt_init($link); $stmt = mysqli_stmt_prepare($stmt, "SELECT numOnShelf,seller from Inventory where Product=? and containerSize>?"); |
$stmt = mysqli_prepare($link, "SELECT numOnShelf,seller from Inventory where Product=? and containerSize>?"); |
(Fwiw, other APIs/DB engines do allow this — for example using SQLite with python allows it.)
In php, you must specify the type of each input (which is the second argument to
mysqli_stmt_bind_param($stmt, 'sd', $productName, $minSize); $productName = "M&M's"; $minSize = 16; |
Note that the contents of the input-variables (“
except, php on rucs...: This doesn't currently work on rucs; see the next item.To process the results of the table, call
$allRows = mysqli_stmt_get_result($stmt); while ($oneRow = mysqli_fetch_assoc($allRows)) { echo $oneRow['custName'], " bought ", $oneRow['product']; |
except, php on rucs…: Alas, the above functionIf you are stuck using really old PHP, then we can also use bind-variables for our results as well as the query’s inputs:mysqli_stmt_get_result is only in PHP ≥ 5.3; rucs is still running the archaically outdated PHP 5.2.8.
while (mysqli_stmt_fetch($stmt)) { echo "I got $col1 and $col2!\n"; } |
stmt.setString(1,"M&M's"); stmt.setInt(2,16); boolean ok = stmt.executeQuery(); if (ok) { ResultSet rs = stmt.getResultSet(); …processRows(rs)… } else { …handleError()… } |
This page licensed CC-BY 4.0 Ian Barland Page last generated 2018.Apr.04 (Wed) | Please mail any suggestions (incl. typos, broken links) to ibarlandradford.edu |