Think back to the
username
argument you passed to
is_admin()
. What exactly does this variable represent? You might assume that
username
is just a string that represents an actual user’s name. As you’re about to see, though, an intruder can easily exploit this kind of oversight and cause major harm by performing Python SQL injection.
Try to check if the following user is an admin or not:
>>>
>>> is_admin("'; select true; --")
Wait… What just happened?
Let’s take another look at the implementation. Print out the actual query being executed in the database:
>>>>>> print("select admin from users where username = '%s'" % "'; select true; --")
select admin from users where username = ''; select true; --'
The resulting text contains three statements. To understand exactly how Python SQL injection works, you need to inspect each part individually. The first statement is as follows:
select admin from users where username = '';
This is your intended query. The semicolon (;) terminates the query, so the result of this query does not matter. Next up is the second statement:
select true;
This statement was constructed by the intruder. It’s designed to always return True.
Lastly, you see this short bit of code:
This snippet defuses anything that comes after it. The intruder added the comment symbol (--) to turn everything you might have put after the last placeholder into a comment.
When you execute the function with this argument, it will always return True. If, for example, you use this function in your login page, an intruder could log in with the username '; select true; --, and they’ll be granted access.
If you think this is bad, it could get worse! Intruders with knowledge of your table structure can use Python SQL injection to cause permanent damage. For example, the intruder can inject an update statement to alter the information in the database:
>>>>>> is_admin('haki')
False
>>> is_admin("'; update users set admin = 'true' where username = 'haki'; select true; --")
>>> is_admin('haki')
Let’s break it down again:
This snippet terminates the query, just like in the previous injection. The next statement is as follows:
update users set admin = 'true' where username = 'haki';
This section updates admin to true for user haki.
Finally, there’s this code snippet:
select true; --
As in the previous example, this piece returns true and comments out everything that follows it.
Why is this worse? Well, if the intruder manages to execute the function with this input, then user haki will become an admin:
psycopgtest=# select * from users;
username | admin
----------+-------
ran | t
haki | t
(2 rows)
The intruder no longer has to use the hack. They can just log in with the username haki. (If the intruder really wanted to cause harm, then they could even issue a DROP DATABASE command.)
Before you forget, restore haki back to its original state:
psycopgtest=# update users set admin = false where username = 'haki';
UPDATE 1
So, why is this happening? Well, what do you know about the username argument? You know it should be a string representing the username, but you don’t actually check or enforce this assertion. This can be dangerous! It’s exactly what attackers are looking for when they try to hack your system.
Crafting Safe Query Parameters
SQL injections rely on this type of vulnerability.
Any time user input is used in a database query, there’s a possible vulnerability for SQL injection. The key to preventing Python SQL injection is to make sure the value is being used as the developer intended. In the previous example, you intended for username to be used as a string. In reality, it was used as a raw SQL statement.
To make sure values are used as they’re intended, you need to escape the value. For example, to prevent intruders from injecting raw SQL in the place of a string argument, you can escape quotation marks:
>>>>>> # BAD EXAMPLE. DON'T DO THIS!
>>> username = username
.replace("'", "''")
This is just one example. There are a lot of special characters and scenarios to think about when trying to prevent Python SQL injection. Lucky for you, modern database adapters, come with built-in tools for preventing Python SQL injection by using query parameters. These are used instead of plain string interpolation to compose a query with parameters.
Note: Different adapters, databases, and programming languages refer to query parameters by different names. Common names include bind variables, replacement variables, and substitution variables.
Now that you have a better understanding of the vulnerability, you’re ready to rewrite the function using query parameters instead of string interpolation:
1def is_admin(username: str) -> bool:
2 with connection.cursor() as cursor:
3 cursor.execute("""
4 SELECT
5 admin
6 FROM
7 users
8 WHERE
9 username = %(username)s
10 """, {
11 'username': username
12 })
13 result = cursor.fetchone()
15 if result is None:
16 # User does not exist
17 return False
19 admin, = result
20 return admin
Here’s what’s different in this example:
In line 9, you used a named parameter username to indicate where the username should go. Notice how the parameter username is no longer surrounded by single quotation marks.
In line 11, you passed the value of username as the second argument to cursor.execute(). The connection will use the type and value of username when executing the query in the database.
To test this function, try some valid and invalid values, including the dangerous string from before:
>>>>>> is_admin('haki')
False
>>> is_admin('ran')
>>> is_admin('foo')
False
>>> is_admin("'; select true; --")
False
Amazing! The function returned the expected result for all values. What’s more, the dangerous string no longer works. To understand why, you can inspect the query generated by execute():
>>>>>> with connection.cursor() as cursor:
... cursor.execute("""
... SELECT
... admin
... FROM
... users
... WHERE
... username = %(username)s
... """, {
... 'username': "'; select true; --"
... })
... print(cursor.query.decode('utf-8'))
SELECT
admin
users
WHERE
username = '''; select true; --'
The connection treated the value of username as a string and escaped any characters that might terminate the string and introduce Python SQL injection.
Passing Safe Query Parameters