MySQL Connector/Python 8.0.14+: Changed Expression Handling in mysqlx

The X DevAPI allows you to work with JSON documents and SQL tables at the same time. Furthermore, the CRUD style API is more intuitive than SQL statements for some programmers. Either way, the X DevAPI allows you to mix JSON documents, SQL tables, CRUD methods, and SQL statements to give you the best of all worlds. In MySQL Connector/Python, the X DevAPI is implemented in the mysqlx module.

This blog will look at how MySQL Connector/Python handles expressions, and how you in version 8.0.14 and later need to use the mysqlx.expr() method to explicitly define expressions.

Information

The changed way to work with expressions does not apply when defining fields. In that case, you can still specify the expression inline.

Expression Handling

One original feature of the X DevAPI in MySQL Connector/Python was that expressions were automatically handled when you inlined them into statement definitions. For example, you could increase the population like:

result = countryinfo.modify("Name = :country") \
    .set("demographics.Population",
         "CAST(FLOOR(demographics.Population * 1.10) AS unsigned)") \
    .bind("country", country_name) \
    .execute()

Notice the expression in line 3.

While this was nice, it also caused some problems such as Bug 92416 where regular data could end up being interpreted as an expression by mistake. For example:

schema = db.create_schema("db1")
mycol = schema.create_collection("mycol")
mycol.add({"A": "(@)"}).execute()

In this example (@) would be interpreted as an expression even though it should be taken as a string.

The solution has been to require the mysqlx.expr() method to be used to define all expressions. This then allows MySQL to interpret all strings as literals. While it does remove the shortcut method, it also removes any ambiguities and thus makes the code safer.

Tip

The mysqlx.expr() method is also available in MySQL Connector/Python 8.0.13 and earlier as well as other connectors. If you have not yet upgraded to the latest version, it is recommended to start using mysqlx.expr() now to avoid problems when upgrading.

Let's look at an example to better understand how the change works.

Example

As an example, consider an application that uses the world_x database and updates the population of a country with 10%. This can be done using the following expression:

CAST(FLOOR(demographics.Population * 1.10) AS unsigned)

At first, the application will use the inline method to specify the expression, then we will look at changing this to work in MySQL Connector/Python 8.0.14 and later.

Inline Expression

The source code for updating the population using an inline expression can be seen in the following sample program:

import mysqlx
import mysql.connector

connect_args = {
    "host": "127.0.0.1",
    "port": 33060,
    "user": "pyuser",
    "password": "Py@pp4Demo",
};

print("Using inline expression.")
print("MySQL Connector/Python {0}".format(mysql.connector.__version__))

db = mysqlx.get_session(**connect_args)
schema = db.get_schema("world_x")
countryinfo = schema.get_collection("countryinfo")
country_name = "Australia"

db.start_transaction()

# Get the population of the country
population = countryinfo.find("Name = :country") \
    .fields("demographics.Population AS Population") \
    .bind("country", country_name)

before = population.execute()
print("Before ...: {0}".format(before.fetch_one()['Population']))

# Update the population
result = countryinfo.modify("Name = :country") \
    .set("demographics.Population",
         "CAST(FLOOR(demographics.Population * 1.10) AS unsigned)") \
    .bind("country", country_name) \
    .execute()

after = population.execute()
print("After ....: {0}".format(after.fetch_one()['Population']))

# Leave the data in the same state as before the changes
db.rollback()
db.close()

The population is updated in the statement defined and executed in lines 30-34. The population is fetched both before and after and printed together with the MySQL Connector/Python version. At the end, the transaction is rolled back, so it is possible to execute the program several times while getting the same output.

Information

The mysql.connector module is only included in order to print the MySQL Connector/Python version.

The output using MySQL Connector/Python 8.0.13 is:

Using inline expression.
MySQL Connector/Python 8.0.13
Before ...: 18886000
After ....: 20774600

This is as expected. However, in MySQL Connector/Python 8.0.14 and later, the result is quite different:

Using inline expression.
MySQL Connector/Python 8.0.15
Before ...: 18886000
After ....: CAST(FLOOR(demographics.Population * 1.10) AS unsigned)

Now the expression is taken as a literal string – oops.

Warning

This also highlights that you must be careful when working with a schemaless data model. The database will not stop you from putting wrong data types into your documents.

Let's look at how this can be fixed.

Explicit Expressions

The solution to the issue, we just saw, is to use explicit expressions. You can do that using the mysqlx.expr() method. This returns an expression object that you can use in your statements. The same example as before – but using an explicit expression – is:

import mysqlx
import mysql.connector

connect_args = {
    "host": "127.0.0.1",
    "port": 33060,
    "user": "pyuser",
    "password": "Py@pp4Demo",
};

print("Using explicit expression.")
print("MySQL Connector/Python {0}".format(mysql.connector.__version__))

db = mysqlx.get_session(**connect_args)
schema = db.get_schema("world_x")
countryinfo = schema.get_collection("countryinfo")
country_name = "Australia"

db.start_transaction()

# Get the population of the country
population = countryinfo.find("Name = :country") \
    .fields("demographics.Population AS Population") \
    .bind("country", country_name)

before = population.execute()
print("Before ...: {0}".format(before.fetch_one()['Population']))

# Update the population
expr = mysqlx.expr("CAST(FLOOR(demographics.Population * 1.10) AS unsigned)")
result = countryinfo.modify("Name = :country") \
    .set("demographics.Population", expr) \
    .bind("country", country_name) \
    .execute()

after = population.execute()
print("After ....: {0}".format(after.fetch_one()['Population']))

# Leave the data in the same state as before the changes
db.rollback()
db.close()

The only change is the definition of the expression in line 30 and the use of it in line 32.

Tip

The expression object can be re-used if you need the same expression in several statements.

Now, MySQL Connector/Python 8.0.13 and 8.0.15 updates the population to the same value. First 8.0.13:

Using explicit expression.
MySQL Connector/Python 8.0.13
Before ...: 18886000
After ....: 20774600

Then 8.0.15:

Using explicit expression.
MySQL Connector/Python 8.0.15
Before ...: 18886000
After ....: 20774600

Further Reading

If this blog has caught you interest in MySQL Connector/Python whether you are looking at using the traditional Python Database API specification (PEP 249) or the new X DevAPI, then I have written MySQL Connector/Python Revealed published by Apress.
The book is available from Apress (print and DRM free ePub+PDF), Amazon (print and Kindle), Barnes & Noble (print), and others.

Enjoy.

I have worked with MySQL databases since 2006 both as an SQL developer, a database administrator, and for more than eight years as part of the Oracle MySQL Support team. I have spoken at MySQL Connect and Oracle OpenWorld on several occasions. I have contributed to the sys schema and four Oracle Certified Professional (OCP) exams for MySQL 5.6 to 8.0. I have written four books, all published at Apress.

Leave a Reply

Your email address will not be published.

*

This site uses Akismet to reduce spam. Learn how your comment data is processed.