MySQL 8: Drop Several Stored Events, Procedures, or Functions
Maybe the biggest new feature in MySQL 8 is the new transaction data dictionary that improves the consistency of schema objects among other things. To further protect the data in the data dictionary, the data dictionary tables are hidden and their content only exposed through the Information Schema. (One exception is when you use the debug binary, then it is possible to get direct access to the data dictionary tables. This is not recommended at all on production systems!)
A side effect of the data dictionary tables being hidden is that those that have had a habit of manipulating the tables directly in MySQL 5.7 and earlier (I will not recommend doing that) will no longer be able to do so. Examples of manipulating the tables include dropping several stored events, procedures, and/or functions by deleting the corresponding rows in the mysql.event
and mysql.proc
tables.
There are some discussions on Stack Overflow on how to do this task. See for example How to delete multiple events in mysql 8.0 database ? it was working in 5.7 but not in 8.0? and MySQL 8 – Remove All Stored Procedures in a Specific Database.
The obvious thought may be to write a stored procedure that can delete the objects, however that requires using a prepared statement which is not supported for DROP EVENT
and similar:
mysql> SET @sql = 'DROP EVENT db1.event1';
Query OK, 0 rows affected (0.00 sec)
mysql> PREPARE stmt_drop FROM @sql;
ERROR 1295 (HY000): This command is not supported in the prepared statement protocol yet
There is a feature request to implement this in Bug 42337.
So what to do instead? My suggestion is to use MySQL Shell. There you can generate the queries and use session.sql()
to execute them without using a prepared statement. However, first some objects are needed.
Setup
Before we start looking at the options to drop several events, procedures, or functions, lets create some objects to work with. For the examples there are three events, three procedures, and three functions that can be created as follows:
mysql> CREATE SCHEMA db1;
Query OK, 1 row affected (0.01 sec)
mysql> use db1;
Database changed
mysql> CREATE EVENT event1 ON SCHEDULE EVERY 1 DAY STARTS NOW() DO DO SLEEP(1);
Query OK, 0 rows affected (0.04 sec)
mysql> CREATE EVENT event2 ON SCHEDULE EVERY 1 DAY STARTS NOW() DO DO SLEEP(1);
Query OK, 0 rows affected (0.00 sec)
mysql> CREATE EVENT `event``3` ON SCHEDULE EVERY 1 DAY STARTS NOW() DO DO SLEEP(1);
Query OK, 0 rows affected (0.00 sec)
mysql> CREATE PROCEDURE proc1() DO SLEEP(1);
Query OK, 0 rows affected (0.01 sec)
mysql> CREATE PROCEDURE proc2() DO SLEEP(1);
Query OK, 0 rows affected (0.00 sec)
mysql> CREATE PROCEDURE `proc``3`() DO SLEEP(1);
Query OK, 0 rows affected (0.00 sec)
mysql> CREATE FUNCTION func1() RETURNS int DETERMINISTIC RETURN 1;
Query OK, 0 rows affected (0.40 sec)
mysql> CREATE FUNCTION func2() RETURNS int DETERMINISTIC RETURN 1;
Query OK, 0 rows affected (0.08 sec)
mysql> CREATE FUNCTION `func``3`() RETURNS int DETERMINISTIC RETURN 1;
Query OK, 0 rows affected (0.30 sec)
mysql> SELECT EVENT_SCHEMA, EVENT_NAME
FROM information_schema.EVENTS
WHERE EVENT_SCHEMA = 'db1';
+--------------+------------+
| EVENT_SCHEMA | EVENT_NAME |
+--------------+------------+
| db1 | event1 |
| db1 | event2 |
| db1 | event`3 |
+--------------+------------+
3 rows in set (0.01 sec)
mysql> SELECT ROUTINE_SCHEMA, ROUTINE_NAME, ROUTINE_TYPE
FROM information_schema.ROUTINES
WHERE ROUTINE_SCHEMA = 'db1';
+----------------+--------------+--------------+
| ROUTINE_SCHEMA | ROUTINE_NAME | ROUTINE_TYPE |
+----------------+--------------+--------------+
| db1 | func1 | FUNCTION |
| db1 | func2 | FUNCTION |
| db1 | func`3 | FUNCTION |
| db1 | proc1 | PROCEDURE |
| db1 | proc2 | PROCEDURE |
| db1 | proc`3 | PROCEDURE |
+----------------+--------------+--------------+
6 rows in set (0.01 sec)
This also shows how the events and routines can be found from the Information Schema.
The third event, procedure, and function are named with a backtick before the digit. This is to ensure our delete method quotes the identifier names correctly. If you are deleting events and routines from a production system, you are encouraged to test carefully that you quote the identifiers correctly.
Now on to delete the objects.
MySQL Shell
MySQL Shell is one of the great recent additions to MySQL. It supports performing DBA and devops tasks using SQL, Python, and JavaScript. Having a full featured programing language available allows you to automate tasks that otherwise would have been cumbersome or impossible.
The Python and JavaScript modes support executing queries either using NoSQL CRUD methods or SQL statements. So, now the task of deleting events, procedures, or functions becomes as simple as executing a query against the Information Schema to find the names of the objects and then generate the queries in a loop. The following will use Python, but it can also be written in JavaScript if you prefer.
I will first go through dropping events, then functions and procedures.
Events – Interactive
It is possible to get the names using the select()
CRUD method on the information_schema.EVENTS
table:
mysql-py> i_s = session.get_schema("information_schema")
mysql-py> events = i_s.EVENTS \
-> .select("sys.quote_identifier(EVENT_SCHEMA) AS EventSchema", "sys.quote_identifier(EVENT_NAME) AS EventName") \
-> .where("EVENT_SCHEMA = 'db1'").execute().fetch_all();
mysql-py> events
[
[
"`db1`",
"`event1`"
],
[
"`db1`",
"`event2`"
],
[
"`db1`",
"`event``3`"
]
]
First an object of the information_schema
is stored in the i_s
variable. This allows you to access the Information Schema EVENTS
table using i_s.EVENTS
. From here the select()
CRUD method is used to find all events in the db1
schema.
The sys.quote_identifier()
function is used to ensure that the schema and event names are quoted correctly, so for example the backtick in event`3
is escaped correctly (by adding a second backtick).
Now events
is a list of the three events that were created earlier. You can easily check which events where found by just “executing” events
. With that, you can delete the events one by one in a loop. For this a query template is first defined, then used to add the name of the schema and event. Usually it is not safe to do that using the Python format()
function, however here we have ensured the names are quotes appropriately by using sys.quote_identifier()
.
mysql-py> sql_fmt = "DROP EVENT {0}.{1}"
mysql-py> for event in events:
-> print(sql_fmt.format(*event))
-> session.sql(sql_fmt.format(*event)).execute()
->
DROP EVENT `db1`.`event1`
DROP EVENT `db1`.`event2`
DROP EVENT `db1`.`event``3`
Query OK, 0 rows affected (0.0038 sec)
That's it. Not exactly a one liner, but not hard either.
This is fine if it is a one off that you need to delete some events, but what if this is a more regular task? MySQL Shell can accommodate for that as well.
Events – Function
I have previously discussed how you can use external libraries in MySQL Shell and even shown an example of using it to have auto-repeating reports. It can also be used to implement a function where you give the schema you want to delete events from as an argument.
Let's look at how the code looks for that:
from mysqlsh import globals
def events_by_schema(schema, verbose=True):
"""Drops all events in the schema passed as an argument.
Requires a connection to exist to the MySQL instance where the
events are to be dropped.
Optionally specify whether to be verbose (enabled by default) by
printing each DROP EVENT statement executed.
Returns the number of events dropped and False if an issue is
encountered so no attempts are made to drop the events.
"""
# Get the session and ensure it is connected
if not globals.session.is_open():
print("Please create a connection first.")
return False
# Define the query to get the events
i_s = globals.session.get_schema("information_schema")
stmt = i_s.EVENTS.select(
"sys.quote_identifier(EVENT_SCHEMA) AS EventSchema",
"sys.quote_identifier(EVENT_NAME) AS EventName")
stmt = stmt.where("EVENT_SCHEMA = :schema")
# Execute the query and check for warnings
result = stmt.bind("schema", schema).execute()
events = result.fetch_all()
if (result.get_warnings_count() > 0):
# Bail out and print the warnings
print("Warnings occurred - bailing out:")
print(result.get_warnings())
return False
# Drop the events and check for warnings after each event
sql_fmt = "DROP EVENT {0}.{1}"
for event in events:
sql = sql_fmt.format(*event)
if verbose:
print(sql)
drop_result = globals.session.sql(sql).execute()
if (drop_result.get_warnings_count() > 0):
print("Warnings occurred:")
print(result.get_warnings())
return len(events)
Yes, this code is a lot longer than the previous example, but in reality it is the same with some extra checks added and obtaining the session (the connection to the MySQL instance) from the mysqlsh.globals
module. Since the schema is now provided as an argument to the function, a placeholder and bind()
are used to ensure it is safe to use the value in a query.
If you save the code in a file in the Python search path, you can import it into MySQL Shell. Recall from my earlier blog that you can include extra directories in your search path by updating mysqlshrc.py
in one of the places where MySQL Shell looks for it; for example in ${HOME}/.mysqlsh
on Linux or %APPDATA%\MySQL\mysqlsh
on Windows. An example of the mysqlshrc.py
file is:
import sys
sys.path.append("D:\MySQL\Shell\Python")
In this example, the code has been saved in the file delete_objects.py
, so you can delete all events in the db1
schema like the following example:
mysql-py> import delete_objects
mysql-py> num_delete_events = delete_objects.events_by_schema('db1')
DROP EVENT `db1`.`event1`
DROP EVENT `db1`.`event2`
DROP EVENT `db1`.`event``3`
That completes the example for events. Now let's turn to functions and procedures.
Procedures and Functions – Interactive
The example of deleting functions and/or procedures is very similar to what have just been seen for events, other than using the information_schema.ROUTINES
table instead of information_schema.EVENTS
to get the routine names and that your need to set a filter on ROUTINE_TYPE
to specify whether you want procedures or functions (or both if the filter is absent). So, I will jump straight into the example by first dropping all functions, then all procedures in the db1
schema:
mysql-py> i_s = session.get_schema("information_schema")
mysql-py> functions = i_s.ROUTINES \
-> .select("sys.quote_identifier(ROUTINE_SCHEMA) AS RoutineSchema", "sys.quote_identifier(ROUTINE_NAME) AS RoutineName") \
-> .where("ROUTINE_SCHEMA = 'db1' AND ROUTINE_TYPE = 'FUNCTION'").execute().fetch_all()
mysql-py> functions
[
[
"`db1`",
"`func1`"
],
[
"`db1`",
"`func2`"
],
[
"`db1`",
"`func``3`"
]
]
mysql-py> for function in functions:
-> print(sql_fmt.format(*function))
-> session.sql(sql_fmt.format(*function)).execute()
->
DROP FUNCTION `db1`.`func1`
DROP FUNCTION `db1`.`func2`
DROP FUNCTION `db1`.`func``3`
Query OK, 0 rows affected (0.0684 sec)
Similar for the procedures:
mysql-py> i_s = session.get_schema("information_schema")
mysql-py> procedures = i_s.ROUTINES \
-> .select("sys.quote_identifier(ROUTINE_SCHEMA) AS RoutineSchema", "sys.quote_identifier(ROUTINE_NAME) AS RoutineName") \
-> .where("ROUTINE_SCHEMA = 'db1' AND ROUTINE_TYPE = 'PROCEDURE'").execute().fetch_all()
mysql-py> procedures
[
[
"`db1`",
"`proc1`"
],
[
"`db1`",
"`proc2`"
],
[
"`db1`",
"`proc``3`"
]
]
mysql-py> sql_fmt = "DROP PROCEDURE {0}.{1}"
mysql-py> for procedure in procedures:
-> print(sql_fmt.format(*procedure))
-> session.sql(sql_fmt.format(*procedure)).execute()
DROP PROCEDURE `db1`.`proc1`
DROP PROCEDURE `db1`.`proc2`
DROP PROCEDURE `db1`.`proc``3`
Query OK, 0 rows affected (0.0976 sec)
Again, it is possible to create a function, so the code can be re-used.
Functions and Procedures – Function
Since the code for deleting functions and procedures is so similar – it is just the filter and DROP FUNCTION
versus DROP PROCEDURE
that is the difference – it is simple to use the same function to delete either. In fact, it would not take much to combine it with events_by_schema()
from above, but that will be left as an exercise for the reader (there is a hint in the next section using MySQL Connector/Python).
The code for the routines_by_schema()
function is:
from mysqlsh import globals
def routines_by_schema(schema, routine_type=None, verbose=True):
"""Drops all routines of a given type in the schema passed as an
argument. If no type is given, both functions and procedures are
dropped. The default is to drop both.
Requires a connection to exist to the MySQL instance where the
routines are to be dropped.
Optionally specify whether to be verbose (enabled by default) by
printing each DROP FUNCTION|PROCEDURE statement executed.
Returns the number of routines dropped and False if an issue is
encountered so no attempts are made to drop the routines.
"""
# Get the session and ensure it is connected
if not globals.session.is_open():
print("Please create a connection first.")
return False
# Define the query to get the routines
i_s = globals.session.get_schema("information_schema")
filters = ["ROUTINE_SCHEMA = :schema"]
if routine_type is not None:
filters.append("ROUTINE_TYPE = :type")
stmt = i_s.ROUTINES.select(
"sys.quote_identifier(ROUTINE_SCHEMA) AS RoutineSchema",
"sys.quote_identifier(ROUTINE_NAME) AS RoutineName",
"ROUTINE_TYPE")
stmt = stmt.where(" AND ".join(filters))
# Execute the query and check for warnings
stmt = stmt.bind("schema", schema)
if routine_type is not None:
stmt = stmt.bind("type", routine_type)
result = stmt.execute()
routines = result.fetch_all()
routines = result.fetch_all()
if (result.get_warnings_count() > 0):
# Bail out and print the warnings
print("Warnings occurred - bailing out:")
print(result.get_warnings())
return False
# Drop the routines and check for warnings after each routine
sql_fmt = "DROP {2} {0}.{1}"
for routine in routines:
sql = sql_fmt.format(*routine)
if verbose:
print(sql)
drop_result = globals.session.sql(sql).execute()
if (drop_result.get_warnings_count() > 0):
print("Warnings occurred:")
print(result.get_warnings())
return len(routines)
The function takes an extra argument compared to events_by_schema()
, so it is possible to either delete both functions and procedures (the default) or just one type. The use of the function is also similar to what have been seen before:
mysql-py> num_delete_functions = delete_objects.routines_by_schema('db1', 'FUNCTION')
DROP FUNCTION `db1`.`func1`
DROP FUNCTION `db1`.`func2`
DROP FUNCTION `db1`.`func``3`
mysql-py> num_delete_procedure = delete_objects.routines_by_schema('db1', 'PROCEDURE')
DROP PROCEDURE `db1`.`proc1`
DROP PROCEDURE `db1`.`proc2`
DROP PROCEDURE `db1`.`proc``3`
# Restore the functions and procedures
mysql-py> num_delete_routines = delete_objects.routines_by_schema('db1')
DROP FUNCTION `db1`.`func1`
DROP FUNCTION `db1`.`func2`
DROP FUNCTION `db1`.`func``3`
DROP PROCEDURE `db1`.`proc1`
DROP PROCEDURE `db1`.`proc2`
DROP PROCEDURE `db1`.`proc``3`
The last thing is to look at how the same actions can be done with MySQL Connector/Python.
MySQL Connector/Python
Given how similar using Python in MySQL Shell is with MySQL Connector/Python, it is natural to make the functions available as a command-line tool or function for Connector/Python programs. The following shows an example of how that can be done – combining events_by_schema()
and routines_by_schema()
into one function. The source code is:
import mysqlx
def objects_by_schema(session, schema, object_type=None, verbose=True):
"""Drops all events, functions, and/or procedures in the schema
passed as an argument.
Requires a connection to exist to the MySQL instance where the
events are to be dropped.
The object_type can be None (drop all events, functions, and
procedures - the default), "EVENT", "FUNCTION", or "PROCEDURE".
Optionally specify whether to be verbose (enabled by default) by
printing each DROP statement executed.
Returns the number of events, functions, and procedures dropped
as a dictionary or False if an issue is encountered so no attempts
are made to drop the events.
"""
# Get the session and ensure it is connected
if not session.is_open():
print("Please create a connection first.")
return False
# Get an object for the Information Schema
# and whether ANSI quotes are used
i_s = session.get_schema("information_schema")
sql_mode = session.sql("SELECT @@session.sql_mode AS sql_mode").execute() \
.fetch_one()["sql_mode"]
sql_modes = sql_mode.split(",")
ansi_quotes = "ANSI_QUOTES" if "ANSI_QUOTES" in sql_modes else ""
events = []
# If dropping events, get a list of all events
if object_type is None or object_type == "EVENT":
events_table = i_s.get_table("EVENTS")
stmt = events_table.select(
"EVENT_SCHEMA AS ObjectSchema", "EVENT_NAME AS ObjectName",
"'EVENT' AS ObjectType")
stmt = stmt.where("EVENT_SCHEMA = :schema")
# Execute the query and check for warnings
result = stmt.bind("schema", schema).execute()
events = result.fetch_all()
if (result.get_warnings_count() > 0):
# Bail out and print the warnings
print("Warnings occurred - bailing out:")
print(result.get_warnings())
return False
routines = []
if object_type is None or object_type in ("FUNCTION", "PROCEDURE"):
routines_table = i_s.get_table("ROUTINES")
filters = ["ROUTINE_SCHEMA = :schema"]
if object_type is not None:
filters.append("ROUTINE_TYPE = :type")
stmt = routines_table.select(
"ROUTINE_SCHEMA AS ObjectSchema", "ROUTINE_NAME AS ObjectName",
"ROUTINE_TYPE AS ObjectType")
stmt = stmt.where(" AND ".join(filters))
# Execute the query and check for warnings
stmt = stmt.bind("schema", schema)
if object_type is not None:
stmt = stmt.bind("type", object_type)
result = stmt.execute()
routines = result.fetch_all()
if (result.get_warnings_count() > 0):
# Bail out and print the warnings
print("Warnings occurred - bailing out:")
print(result.get_warnings())
return False
# Drop the routines and check for warnings after each routine
objects = events + routines
sql_fmt = "DROP {0} {1}.{2}"
objects_deleted = {
"EVENT": 0,
"FUNCTION": 0,
"PROCEDURE": 0,
}
for obj in objects:
objects_deleted[obj[2]] += 1
sql = sql_fmt.format(obj[2],
mysqlx.helpers.quote_identifier(obj[0], ansi_quotes),
mysqlx.helpers.quote_identifier(obj[1], ansi_quotes))
if verbose:
print(sql)
drop_result = session.sql(sql).execute()
if (drop_result.get_warnings_count() > 0):
print("Warnings occurred:")
print(result.get_warnings())
return objects_deleted
if __name__ == "__main__":
import sys
import argparse
import getpass
# Handle the command line arguments
parser = argparse.ArgumentParser(
prog="delete_objects.py",
description="Delete all events, functions, and/or procedures from a "
+ "single schema.")
parser.add_argument("--type", default="ALL",
choices=["ALL", "EVENT", "FUNCTION", "PROCEDURE"],
help="The object type to drop.")
parser.add_argument("--schema", default=None,
help="The schema to drop objects from.")
parser.add_argument("--verbose", type=int, default=1,
help="Whether to produce verbose output.")
parser.add_argument("--user", default=None,
help="The user to connect to MySQL as.")
parser.add_argument("--host", default="127.0.0.1",
help="The host to connect to MySQL on.")
parser.add_argument("--port", type=int, default=33060,
help="The mysqlx port to connect to MySQL on.")
# Parse the arguments and get the password used when connecting to MySQL
args = parser.parse_args(sys.argv[1:])
object_type = args.type
if args.type == "ALL":
object_type = None
verbose = True if args.verbose > 0 else False
password = getpass.getpass("MySQL Password: ")
# Connect to MySQL
session = mysqlx.get_session(user=args.user, password=password,
host=args.host, port=args.port)
# Drop the objects
objects_deleted = objects_by_schema(session, args.schema, object_type,
verbose)
if verbose:
print(objects_deleted)
While the example is pretty extensive, it is not quite complete. There is only support for TCP connections using the user, password, host, and port options, and the password is always provided interactively (the most secure). Support for a configuration file and other options can be added if needed.
Instead of using the sys.quote_identifier()
function, the schema and object names are quoted using the mysqlx.helpers.quote_identifier()
function. Otherwise the program should be self explanatory given the previous examples. You can use python delete_objects.py --help
to get help with the supported arguments.
Thanks for the writeup on how to work around something which worked in MySQL 5.7. Manipulating system objects needs to be handled carefully but facilities to do that should be provided. It SHOULD be possible to do this sort of task on the database server itself. The process SHOULD be easy.
Having to rely on external things to handle this is just broken in my opinion even if the MySQL Shell give the user more flexibility.
Most other RDBMSes use internal system stored procedures to handle this, the implementation being (partly) hidden from the user, but providing a consistent interface even if internals change. This sounds like the perfect usage of the sys schema to handle things like this.