MySQL Shell CLI Integration

Over the last few years, I have become quite smitten with MySQL Shell. For those who may not be familiar with MySQL Shell, it is a new(ish) command line interface (CLI) for connecting to and managing MySQL instances. During a recent episode of Inside MySQL: Sakila Speaks, Fred and I talked to Miguel Araujo about many of the helpful (and lesser known) features of MySQL Shell. This post is the tenth in a series about these “hidden gem” features.
The Problem
I am going to share a problem I had that I wanted to use MySQL Shell to solve. I manage a golf league, and quite a few years ago, I wrote a web application to help me set up schedules, enter scores, etc. When troubleshooting an issue or adding new functionality, I prefer using the latest and most up-to-date data. So, I needed an easy way to pull data from the production server and restore it to the MySQL instance running on my laptop. I had an old shell script that used mysqldump
to grab the data and the mysql
command to import it. It worked, but I wanted to see if I could duplicate those tasks using MySQL Shell.
The Solution
Before I explain everything I need to do, let me share the contents of the shell script, and then I will proceed step-by-step.
In this example, I have MySQL 9.0 Community running on a remote Linux-based server.
Clearing the Deck
Whenever we dump data using util.dumpTables()
, util.dumpSchemas()
, or util.dumpInstance()
, the local directory we specify the dump should be put in must be empty—we can’t do another dump in the same directory. I took the easy way out and decided to hard code the name of the directory in my script, ~/dumps/league_prod
.
With this in mind, I knew I needed to delete the ~/dumps/league_prod
folder before I tried to dump the data from production. For this reason, the first command in my script is:
Grabbing Data From Production
Now that I have cleared out the directory where I want to store my dump, we can get down to grabbing the data from the remote server. Because I want to do this as part of a script that requires no interaction, I want to start MySQL Shell and do the dump in one single command rather than connecting to the server and then running util.dumpSchemas()
from the Shell interface.
Fortunately, we can run MySQL Shell commands as part of a script or other CLI process. The syntax is a little different than if we were running the commands in the MySQL Shell interface.
Here is the command that will handle our dump.
There is a lot going on here, so I will address each item in the command one by one.
mysqlsh
- This part of the command tells my system to run themysqlsh
executable.--ssh opc@gl-db-server
- This section of the command tells MySQL Shell to make an SSH connection with the user namessh_user
to the domaingl-db-server
(which is an alias I have in myhosts
file that points to the Ip address of my server)--ssh-identity-file ~/.ssh/my_server
- This part of the command tells MySQL Shell where the private key is for connecting togl-db-server
over SSH.--
- The purpose of this double dash is to tell MySQL Shell that we are done providing Shell options and that what follows needs to be passed to the command line integration.- The syntax for providing commands this way follows this syntax:
mysqlsh [options] -- [shell_object]+ object_method [arguments]
- The syntax for providing commands this way follows this syntax:
util
- This part of the command tells MySQL Shell that we want to use theutil
global object.dumpSchemas
- This section tells MySQL Shell that we want to run thedumpSchemas()
method of theutil
object.golf_league_schema
- This text Signifies the single schema we want to dump.--output-url ~/dumps/league_prod
- Lastly, we specify theoutput-url
for the dump. This directory is the same one we deleted above.- Note: This directory is on the machine where the script will be run (my laptop) and not on the remote server.
Getting Help
In a previous post, I discussed the robust ‘help’ system in MySQL Shell. You will be happy to learn that this help system extends to using the commands above. To access Help for running commands this way, run the following at a command prompt:
The output from this command will resemble the text below:
This output contains a list of objects available when using MySQL Shell as part of a command-line operation.
To get more info about the util
object, we would use the following command:
The output of this command will tell us what methods we can use through the command line.
Lastly, if we want to get information about using dumpSchemas()
, we would run the command:
The (lengthy) output from this command will resemble the following:
This output was very enlightening regarding how the command should be formatted, what options are available, and how those options should be provided.
In our example, we are only dumping a single schema, golf_league_schema
, and saving the output to ~/dumps/league_prod
.
Loading Data to Local Instance
Now that the data from production has been dumped into a directory on my local system, I need to load that data into the MySQL instance on my local system. Here is the command to handle that:
This command looks different than the first command. Let’s break this down.
mysqlsh
- This part of the command tells my system to run themysqlsh
executable.scott@localhost
—Since I do not need to connect over SSH, I am using a user namedscott
to connect to an instance running onlocalhost
.--
- The purpose of this double dash is to tell MySQL Shell that we are done providing Shell options and that what follows needs to be passed to the command line integration.- The syntax for providing commands this way follows this syntax:
mysqlsh [options] -- [shell_object]+ object_method [arguments]
- The syntax for providing commands this way follows this syntax:
util
- This part of the command tells MySQL Shell that we want to use theutil
global object.loadDump
- This section tells MySQL Shell that we want to run theloadDump()
method of theutil
object.~/dumps/league_prod
- This part of the command is the path to the directory that contains the dump.--sessionInitSql 'drop schema if exists golf_league_manager'
- An option we have available when loading data from a dump is to run SQL statements before the load process begins. In this case, we usesessioninitSql
to drop thegolf_league_schema
schema before loading the dump.--skipBinLog true
- TheskipBinLog
option lets us turn off the bin log when importing a database dump. With large datasets, this can improve the performance of the load.
If you would like to get more information about these options or learn about how to pass other options when running loadDump()
as part of a script or from the command line, use the following command:
User Credentials
You may have noticed that I have not provided any user credentials for either of these connections. That is because my instance of MySQL Shell is configured to always save user credentials when I connect to a MySQL instance. One benefit of saving passwords in MySQL Shell is that when I run commands as part of a script, I do not need to include (or provide) the passwords as part of the process.
The Results
When I run the script above, here is the output I see in my console:
Wrap Up
Like mysqldump
and mysql
executables, MySQL Shell allows us to run commands as part of a scripted process. Because of the way I have MySQL Shell configured, I do not need to provide any passwords when I run this script (nor do I need to include them in the script itself). If you want to learn more about how to integrate MySQL Shell commands into a command line or scripted process, head on over to the documentation.
Photo by Christin Hume on Unsplash
Related Entries
- Running External Scripts in MySQL Shell
- Executing System Commands in MySQL Shell
- Getting Help in MySQL Shell
- Sandboxes in MySQL Shell
- Server Upgrade Checks with MySQL Shell
- MySQL Connection Status with MySQL Shell
- Managing MySQL Shell Configuration Options
- Advanced Data Dump with MySQL Shell
- Advanced Data Load with MySQL Shell
- MySQL Shell Table Export Utility
- Copy Data Directly To A MySQL Instance With MySQL Shell
- Create an InnoDB Replica Set With MySQL Shell
- Using MySQL Shell to Get MySQL Diagnostic Information
- Customizing The MySQL Shell Prompt
- Extending MySQL Shell with Startup Scripts
- Extending MySQL Shell with Plugins
- Doing a 'Incremental' Dump With MySQL Shell