Quickstart: Use Python to connect and query data in Azure Database for MySQL
APPLIES TO: Azure Database for MySQL - Single Server
Important
Azure Database for MySQL single server is on the retirement path. We strongly recommend that you upgrade to Azure Database for MySQL flexible server. For more information about migrating to Azure Database for MySQL flexible server, see What's happening to Azure Database for MySQL Single Server?
In this quickstart, you connect to an Azure Database for MySQL by using Python. You then use SQL statements to query, insert, update, and delete data in the database from Mac, Ubuntu Linux, and Windows platforms.
Prerequisites
For this quickstart you need:
An Azure account with an active subscription. Create an account for free.
Create an Azure Database for MySQL single server using Azure portal
or Azure CLI if you do not have one.Based on whether you are using public or private access, complete ONE of the actions below to enable connectivity.
Action Connectivity method How-to guide Configure firewall rules Public Portal
CLIConfigure Service Endpoint Public Portal
CLIConfigure private link Private Portal
CLI
Install Python and the MySQL connector
Install Python and the MySQL connector for Python on your computer by using the following steps:
Note
This quickstart is using MySQL Connector/Python Developer Guide.
Download and install Python 3.7 or above for your OS. Make sure to add Python to your
PATH
, because the MySQL connector requires that.Open a command prompt or
bash
shell, and check your Python version by runningpython -V
with the uppercase V switch.The
pip
package installer is included in the latest versions of Python. Updatepip
to the latest version by runningpip install -U pip
.If
pip
isn't installed, you can download and install it withget-pip.py
. For more information, see Installation.Use
pip
to install the MySQL connector for Python and its dependencies:pip install mysql-connector-python
Get connection information
Get the connection information you need to connect to Azure Database for MySQL from the Azure portal. You need the server name, database name, and login credentials.
Sign in to the Azure portal.
In the portal search bar, search for and select the Azure Database for MySQL server you created, such as mydemoserver.
From the server's Overview page, make a note of the Server name and Server admin login name. If you forget your password, you can also reset the password from this page.
Running the Python code samples
For each code example in this article:
Create a new file in a text editor.
Add the code example to the file. In the code, replace the
<mydemoserver>
,<myadmin>
,<mypassword>
, and<mydatabase>
placeholders with the values for your MySQL server and database.SSL is enabled by default on Azure Database for MySQL servers. You may need to download the DigiCertGlobalRootG2 SSL certificate to connect from your local environment. Replace the
ssl_ca
value in the code with path to this file on your computer.Save the file in a project folder with a .py extension, such as C:\pythonmysql\createtable.py or /home/username/pythonmysql/createtable.py.
To run the code, open a command prompt or
bash
shell and change directory into your project folder, for examplecd pythonmysql
. Type thepython
command followed by the file name, for examplepython createtable.py
, and press Enter.Note
On Windows, if python.exe is not found, you may need to add the Python path into your PATH environment variable, or provide the full path to python.exe, for example
C:\python27\python.exe createtable.py
.
Step 1: Create a table and insert data
Use the following code to connect to the server and database, create a table, and load data by using an INSERT SQL statement.The code imports the mysql.connector library, and uses the method:
- connect() function to connect to Azure Database for MySQL using the arguments in the config collection.
- cursor.execute() method executes the SQL query against the MySQL database.
- cursor.close() when you are done using a cursor.
- conn.close() to close the connection the connection.
import mysql.connector
from mysql.connector import errorcode
# Obtain connection string information from the portal
config = {
'host':'<mydemoserver>.mysql.database.azure.com',
'user':'<myadmin>@<mydemoserver>',
'password':'<mypassword>',
'database':'<mydatabase>',
'client_flags': [mysql.connector.ClientFlag.SSL],
'ssl_ca': '<path-to-SSL-cert>/DigiCertGlobalRootG2.crt.pem'
}
# Construct connection string
try:
conn = mysql.connector.connect(**config)
print("Connection established")
except mysql.connector.Error as err:
if err.errno == errorcode.ER_ACCESS_DENIED_ERROR:
print("Something is wrong with the user name or password")
elif err.errno == errorcode.ER_BAD_DB_ERROR:
print("Database does not exist")
else:
print(err)
else:
cursor = conn.cursor()
# Drop previous table of same name if one exists
cursor.execute("DROP TABLE IF EXISTS inventory;")
print("Finished dropping table (if existed).")
# Create table
cursor.execute("CREATE TABLE inventory (id serial PRIMARY KEY, name VARCHAR(50), quantity INTEGER);")
print("Finished creating table.")
# Insert some data into table
cursor.execute("INSERT INTO inventory (name, quantity) VALUES (%s, %s);", ("banana", 150))
print("Inserted",cursor.rowcount,"row(s) of data.")
cursor.execute("INSERT INTO inventory (name, quantity) VALUES (%s, %s);", ("orange", 154))
print("Inserted",cursor.rowcount,"row(s) of data.")
cursor.execute("INSERT INTO inventory (name, quantity) VALUES (%s, %s);", ("apple", 100))
print("Inserted",cursor.rowcount,"row(s) of data.")
# Cleanup
conn.commit()
cursor.close()
conn.close()
print("Done.")
Step 2: Read data
Use the following code to connect and read the data by using a SELECT SQL statement. The code imports the mysql.connector library, and uses cursor.execute() method executes the SQL query against the MySQL database.
The code reads the data rows using the fetchall() method, keeps the result set in a collection row, and uses a for
iterator to loop over the rows.
import mysql.connector
from mysql.connector import errorcode
# Obtain connection string information from the portal
config = {
'host':'<mydemoserver>.mysql.database.azure.com',
'user':'<myadmin>@<mydemoserver>',
'password':'<mypassword>',
'database':'<mydatabase>',
'client_flags': [mysql.connector.ClientFlag.SSL],
'ssl_ca': '<path-to-SSL-cert>/DigiCertGlobalRootG2.crt.pem'
}
# Construct connection string
try:
conn = mysql.connector.connect(**config)
print("Connection established")
except mysql.connector.Error as err:
if err.errno == errorcode.ER_ACCESS_DENIED_ERROR:
print("Something is wrong with the user name or password")
elif err.errno == errorcode.ER_BAD_DB_ERROR:
print("Database does not exist")
else:
print(err)
else:
cursor = conn.cursor()
# Read data
cursor.execute("SELECT * FROM inventory;")
rows = cursor.fetchall()
print("Read",cursor.rowcount,"row(s) of data.")
# Print all rows
for row in rows:
print("Data row = (%s, %s, %s)" %(str(row[0]), str(row[1]), str(row[2])))
# Cleanup
conn.commit()
cursor.close()
conn.close()
print("Done.")
Step 3: Update data
Use the following code to connect and update the data by using an UPDATE SQL statement. The code imports the mysql.connector library, and uses cursor.execute() method executes the SQL query against the MySQL database.
import mysql.connector
from mysql.connector import errorcode
# Obtain connection string information from the portal
config = {
'host':'<mydemoserver>.mysql.database.azure.com',
'user':'<myadmin>@<mydemoserver>',
'password':'<mypassword>',
'database':'<mydatabase>',
'client_flags': [mysql.connector.ClientFlag.SSL],
'ssl_ca': '<path-to-SSL-cert>/DigiCertGlobalRootG2.crt.pem'
}
# Construct connection string
try:
conn = mysql.connector.connect(**config)
print("Connection established")
except mysql.connector.Error as err:
if err.errno == errorcode.ER_ACCESS_DENIED_ERROR:
print("Something is wrong with the user name or password")
elif err.errno == errorcode.ER_BAD_DB_ERROR:
print("Database does not exist")
else:
print(err)
else:
cursor = conn.cursor()
# Update a data row in the table
cursor.execute("UPDATE inventory SET quantity = %s WHERE name = %s;", (300, "apple"))
print("Updated",cursor.rowcount,"row(s) of data.")
# Cleanup
conn.commit()
cursor.close()
conn.close()
print("Done.")
Step 4: Delete data
Use the following code to connect and remove data by using a DELETE SQL statement. The code imports the mysql.connector library, and uses cursor.execute() method executes the SQL query against the MySQL database.
import mysql.connector
from mysql.connector import errorcode
# Obtain connection string information from the portal
config = {
'host':'<mydemoserver>.mysql.database.azure.com',
'user':'<myadmin>@<mydemoserver>',
'password':'<mypassword>',
'database':'<mydatabase>',
'client_flags': [mysql.connector.ClientFlag.SSL],
'ssl_ca': '<path-to-SSL-cert>/DigiCertGlobalRootG2.crt.pem'
}
# Construct connection string
try:
conn = mysql.connector.connect(**config)
print("Connection established")
except mysql.connector.Error as err:
if err.errno == errorcode.ER_ACCESS_DENIED_ERROR:
print("Something is wrong with the user name or password")
elif err.errno == errorcode.ER_BAD_DB_ERROR:
print("Database does not exist")
else:
print(err)
else:
cursor = conn.cursor()
# Delete a data row in the table
cursor.execute("DELETE FROM inventory WHERE name=%(param1)s;", {'param1':"orange"})
print("Deleted",cursor.rowcount,"row(s) of data.")
# Cleanup
conn.commit()
cursor.close()
conn.close()
print("Done.")
Clean up resources
To clean up all resources used during this quickstart, delete the resource group using the following command:
az group delete \
--name $AZ_RESOURCE_GROUP \
--yes